-
Notifications
You must be signed in to change notification settings - Fork 9
/
s04_ts_size.sql
155 lines (148 loc) · 3.6 KB
/
s04_ts_size.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
COLUMN name NEW_VALUE _instname NOPRINT
select lower(instance_name) name from v$instance;
COLUMN conname NEW_VALUE _conname NOPRINT
select case
when a.conname = 'CDB$ROOT' then 'ROOT'
when a.conname = 'PDB$SEED' then 'SEED'
else a.conname
end as conname
from (select SYS_CONTEXT('USERENV', 'CON_NAME') conname from dual) a;
COLUMN conid NEW_VALUE _conid NOPRINT
select SYS_CONTEXT('USERENV', 'CON_ID') conid from dual;
set termout off
set heading on
set markup html on
spool storage_04_ts_size-&_instname-&_conname-&_conid..html
select * from (
WITH
alloc AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
tablespace_name,
COUNT(*) datafiles,
ROUND(SUM(bytes)/POWER(10,9)) gb
FROM dba_data_files
GROUP BY
tablespace_name
),
free AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
tablespace_name,
ROUND(SUM(bytes)/POWER(10,9)) gb
FROM dba_free_space
GROUP BY
tablespace_name
),
tablespaces AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
a.tablespace_name,
a.datafiles,
a.gb alloc_gb,
(a.gb - f.gb) used_gb,
f.gb free_gb
FROM alloc a, free f
WHERE a.tablespace_name = f.tablespace_name
ORDER BY
a.tablespace_name
),
total AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
SUM(alloc_gb) alloc_gb,
SUM(used_gb) used_gb,
SUM(free_gb) free_gb
FROM tablespaces
)
SELECT v.tablespace_name,
v.datafiles,
v.alloc_gb,
v.used_gb,
CASE WHEN v.alloc_gb > 0 THEN
LPAD(TRIM(TO_CHAR(ROUND(100 * v.used_gb / v.alloc_gb, 1), '990.0')), 8)
END pct_used,
v.free_gb,
CASE WHEN v.alloc_gb > 0 THEN
LPAD(TRIM(TO_CHAR(ROUND(100 * v.free_gb / v.alloc_gb, 1), '990.0')), 8)
END pct_free
FROM (
SELECT tablespace_name,
datafiles,
alloc_gb,
used_gb,
free_gb
FROM tablespaces
UNION ALL
SELECT '### Total Data ###' tablespace_name,
TO_NUMBER(NULL) datafiles,
alloc_gb,
used_gb,
free_gb
FROM total
) v
)
union all
select * from (
WITH
alloc AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
tablespace_name,
COUNT(*) datafiles,
ROUND(SUM(bytes)/POWER(10,9)) gb
FROM dba_temp_files
GROUP BY
tablespace_name
),
free AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
tablespace_name,
ROUND(SUM(free_space)/POWER(10,9)) gb
FROM dba_temp_free_space
GROUP BY
tablespace_name
),
tablespaces AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
a.tablespace_name,
a.datafiles,
a.gb alloc_gb,
(a.gb - f.gb) used_gb,
f.gb free_gb
FROM alloc a, free f
WHERE a.tablespace_name = f.tablespace_name
ORDER BY
a.tablespace_name
),
total AS (
SELECT /*+ MATERIALIZE NO_MERGE */ /* 2b.201 */
SUM(alloc_gb) alloc_gb,
SUM(used_gb) used_gb,
SUM(free_gb) free_gb
FROM tablespaces
)
SELECT v.tablespace_name,
v.datafiles,
v.alloc_gb,
v.used_gb,
CASE WHEN v.alloc_gb > 0 THEN
LPAD(TRIM(TO_CHAR(ROUND(100 * v.used_gb / v.alloc_gb, 1), '990.0')), 8)
END pct_used,
v.free_gb,
CASE WHEN v.alloc_gb > 0 THEN
LPAD(TRIM(TO_CHAR(ROUND(100 * v.free_gb / v.alloc_gb, 1), '990.0')), 8)
END pct_free
FROM (
SELECT tablespace_name,
datafiles,
alloc_gb,
used_gb,
free_gb
FROM tablespaces
UNION ALL
SELECT '### Total Temp ###' tablespace_name,
TO_NUMBER(NULL) datafiles,
alloc_gb,
used_gb,
free_gb
FROM total
) v
);
spool off
set markup html off