Skip to content

Commit c520947

Browse files
neilschellyYannig
authored andcommitted
This query yields identical numbers to the existing query, but returns in less than a second instead of 30+ seconds
1 parent e7e3fca commit c520947

File tree

1 file changed

+56
-63
lines changed

1 file changed

+56
-63
lines changed

default-metrics.toml

Lines changed: 56 additions & 63 deletions
Original file line numberDiff line numberDiff line change
@@ -47,74 +47,67 @@ context = "tablespace"
4747
labels = [ "tablespace", "type" ]
4848
metricsdesc = { bytes = "Generic counter metric of tablespaces bytes in Oracle.", max_bytes = "Generic counter metric of tablespaces max bytes in Oracle.", free = "Generic counter metric of tablespaces free bytes in Oracle." }
4949
request = '''
50-
SELECT
51-
Z.name as tablespace,
52-
dt.contents as type,
53-
Z.bytes as bytes,
54-
Z.max_bytes as max_bytes,
55-
Z.free_bytes as free
56-
FROM
50+
SELECT
51+
df.tablespace_name as tablespace,
52+
df.type as type,
53+
sum(df.bytes) as bytes,
54+
sum(df.max_bytes) as max_bytes,
55+
sum(f.free) as free
56+
FROM
5757
(
5858
SELECT
59-
X.name as name,
60-
SUM(nvl(X.free_bytes,0)) as free_bytes,
61-
SUM(X.bytes) as bytes,
62-
SUM(X.max_bytes) as max_bytes
59+
ddf.file_id,
60+
dt.contents as type,
61+
ddf.file_name,
62+
ddf.tablespace_name,
63+
TRUNC(ddf.bytes) as bytes,
64+
TRUNC(GREATEST(ddf.bytes,ddf.maxbytes)) as max_bytes
6365
FROM
64-
(
65-
SELECT
66-
ddf.tablespace_name as name,
67-
ddf.status as status,
68-
ddf.bytes as bytes,
69-
sum(coalesce(dfs.bytes, 0)) as free_bytes,
70-
CASE
71-
WHEN ddf.maxbytes = 0 THEN ddf.bytes
72-
ELSE ddf.maxbytes
73-
END as max_bytes
74-
FROM
75-
sys.dba_data_files ddf,
76-
sys.dba_tablespaces dt,
77-
sys.dba_free_space dfs
78-
WHERE ddf.tablespace_name = dt.tablespace_name
79-
AND ddf.file_id = dfs.file_id(+)
80-
GROUP BY
81-
ddf.tablespace_name,
82-
ddf.file_name,
83-
ddf.status,
84-
ddf.bytes,
85-
ddf.maxbytes
86-
) X
87-
GROUP BY X.name
88-
UNION ALL
66+
dba_data_files ddf,
67+
dba_tablespaces dt
68+
WHERE ddf.tablespace_name = dt.tablespace_name
69+
) df,
70+
(
8971
SELECT
90-
Y.name as name,
91-
MAX(nvl(Y.free_bytes,0)) as free_bytes,
92-
SUM(Y.bytes) as bytes,
93-
SUM(Y.max_bytes) as max_bytes
94-
FROM
72+
TRUNC(SUM(bytes)) AS free,
73+
file_id
74+
FROM dba_free_space
75+
GROUP BY file_id
76+
) f
77+
WHERE df.file_id = f.file_id (+)
78+
GROUP BY df.tablespace_name, df.type
79+
UNION ALL
80+
SELECT
81+
Y.name as tablespace_name,
82+
Y.type as type,
83+
SUM(Y.bytes) as bytes,
84+
SUM(Y.max_bytes) as max_bytes,
85+
MAX(nvl(Y.free_bytes,0)) as free
86+
FROM
87+
(
88+
SELECT
89+
dtf.tablespace_name as name,
90+
dt.contents as type,
91+
dtf.status as status,
92+
dtf.bytes as bytes,
9593
(
9694
SELECT
97-
dtf.tablespace_name as name,
98-
dtf.status as status,
99-
dtf.bytes as bytes,
100-
(
101-
SELECT
102-
((f.total_blocks - s.tot_used_blocks)*vp.value)
103-
FROM
104-
(SELECT tablespace_name, sum(used_blocks) tot_used_blocks FROM gv$sort_segment WHERE tablespace_name!='DUMMY' GROUP BY tablespace_name) s,
105-
(SELECT tablespace_name, sum(blocks) total_blocks FROM dba_temp_files where tablespace_name !='DUMMY' GROUP BY tablespace_name) f,
106-
(SELECT value FROM v$parameter WHERE name = 'db_block_size') vp
107-
WHERE f.tablespace_name=s.tablespace_name AND f.tablespace_name = dtf.tablespace_name
108-
) as free_bytes,
109-
CASE
110-
WHEN dtf.maxbytes = 0 THEN dtf.bytes
111-
ELSE dtf.maxbytes
112-
END as max_bytes
95+
((f.total_blocks - s.tot_used_blocks)*vp.value)
11396
FROM
114-
sys.dba_temp_files dtf
115-
) Y
116-
GROUP BY Y.name
117-
) Z, sys.dba_tablespaces dt
118-
WHERE
119-
Z.name = dt.tablespace_name
97+
(SELECT tablespace_name, sum(used_blocks) tot_used_blocks FROM gv$sort_segment WHERE tablespace_name!='DUMMY' GROUP BY tablespace_name) s,
98+
(SELECT tablespace_name, sum(blocks) total_blocks FROM dba_temp_files where tablespace_name !='DUMMY' GROUP BY tablespace_name) f,
99+
(SELECT value FROM v$parameter WHERE name = 'db_block_size') vp
100+
WHERE f.tablespace_name=s.tablespace_name AND f.tablespace_name = dtf.tablespace_name
101+
) as free_bytes,
102+
CASE
103+
WHEN dtf.maxbytes = 0 THEN dtf.bytes
104+
ELSE dtf.maxbytes
105+
END as max_bytes
106+
FROM
107+
sys.dba_temp_files dtf,
108+
sys.dba_tablespaces dt
109+
WHERE dtf.tablespace_name = dt.tablespace_name
110+
) Y
111+
GROUP BY Y.name, Y.type
112+
ORDER BY tablespace
120113
'''

0 commit comments

Comments
 (0)