forked from fatdba/Oracle-Database-Scripts
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Fat200objects.sql
235 lines (234 loc) · 6.23 KB
/
Fat200objects.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
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
PROMPT
PROMPT
PROMPT~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
PROMPT------ /) (\
PROMPT------ .-._((,~~.))_.-,
PROMPT------ `-. @@ ,-'
PROMPT------ / ,o--o. \
PROMPT------ ( ( .__. ) )
PROMPT------ ) `----' (
PROMPT------ / \
PROMPT------ / \
PROMPT------ / \
PROMPT------ "The Silly Cow"
PROMPT----- Script: Fat200objects.sql
PROMPT----- Author: Prashant 'The FatDBA'
PROMPT----- Version: V1.1 (Date: 04-02-2007)
PROMPT-----
PROMPT-----
PROMPT-----
WITH schema_object AS (
SELECT
segment_type,
owner,
segment_name,
tablespace_name,
COUNT(*) segments,
SUM(extents) extents,
SUM(blocks) blocks,
SUM(bytes) bytes
FROM dba_segments
WHERE 'Y' = 'Y'
GROUP BY
segment_type,
owner,
segment_name,
tablespace_name
), totals AS (
SELECT
SUM(segments) segments,
SUM(extents) extents,
SUM(blocks) blocks,
SUM(bytes) bytes
FROM schema_object
), top_200_pre AS (
SELECT
ROWNUM rank, v1.*
FROM (
SELECT so.segment_type,
so.owner,
so.segment_name,
so.tablespace_name,
so.segments,
so.extents,
so.blocks,
so.bytes,
ROUND((so.segments / t.segments) * 100, 3) segments_perc,
ROUND((so.extents / t.extents) * 100, 3) extents_perc,
ROUND((so.blocks / t.blocks) * 100, 3) blocks_perc,
ROUND((so.bytes / t.bytes) * 100, 3) bytes_perc
FROM schema_object so,
totals t
ORDER BY
bytes_perc DESC NULLS LAST
) v1
WHERE ROWNUM < 201
), top_200 AS (
SELECT p.*,
(SELECT object_id
FROM dba_objects o
WHERE o.object_type = p.segment_type
AND o.owner = p.owner
AND o.object_name = p.segment_name
AND o.object_type NOT LIKE '%PARTITION%') object_id,
(SELECT data_object_id
FROM dba_objects o
WHERE o.object_type = p.segment_type
AND o.owner = p.owner
AND o.object_name = p.segment_name
AND o.object_type NOT LIKE '%PARTITION%') data_object_id,
(SELECT SUM(p2.bytes_perc) FROM top_200_pre p2 WHERE p2.rank <= p.rank) bytes_perc_cum
FROM top_200_pre p
), top_200_totals AS (
SELECT
SUM(segments) segments,
SUM(extents) extents,
SUM(blocks) blocks,
SUM(bytes) bytes,
SUM(segments_perc) segments_perc,
SUM(extents_perc) extents_perc,
SUM(blocks_perc) blocks_perc,
SUM(bytes_perc) bytes_perc
FROM top_200
), top_100_totals AS (
SELECT
SUM(segments) segments,
SUM(extents) extents,
SUM(blocks) blocks,
SUM(bytes) bytes,
SUM(segments_perc) segments_perc,
SUM(extents_perc) extents_perc,
SUM(blocks_perc) blocks_perc,
SUM(bytes_perc) bytes_perc
FROM top_200
WHERE rank < 101
), top_20_totals AS (
SELECT
SUM(segments) segments,
SUM(extents) extents,
SUM(blocks) blocks,
SUM(bytes) bytes,
SUM(segments_perc) segments_perc,
SUM(extents_perc) extents_perc,
SUM(blocks_perc) blocks_perc,
SUM(bytes_perc) bytes_perc
FROM top_200
WHERE rank < 21
)
SELECT v.rank,
v.segment_type,
v.owner,
v.segment_name,
v.object_id,
v.data_object_id,
v.tablespace_name,
CASE
WHEN v.segment_type LIKE 'INDEX%' THEN
(SELECT i.table_name
FROM dba_indexes i
WHERE i.owner = v.owner AND i.index_name = v.segment_name)
WHEN v.segment_type LIKE 'LOB%' THEN
(SELECT l.table_name
FROM dba_lobs l
WHERE l.owner = v.owner AND l.segment_name = v.segment_name)
END table_name,
v.segments,
v.extents,
v.blocks,
v.bytes,
ROUND(v.bytes / POWER(10,9), 3) gb,
LPAD(TO_CHAR(v.segments_perc, '990.000'), 7) segments_perc,
LPAD(TO_CHAR(v.extents_perc, '990.000'), 7) extents_perc,
LPAD(TO_CHAR(v.blocks_perc, '990.000'), 7) blocks_perc,
LPAD(TO_CHAR(v.bytes_perc, '990.000'), 7) bytes_perc,
LPAD(TO_CHAR(v.bytes_perc_cum, '990.000'), 7) perc_cum
FROM (
SELECT d.rank,
d.segment_type,
d.owner,
d.segment_name,
d.object_id,
d.data_object_id,
d.tablespace_name,
d.segments,
d.extents,
d.blocks,
d.bytes,
d.segments_perc,
d.extents_perc,
d.blocks_perc,
d.bytes_perc,
d.bytes_perc_cum
FROM top_200 d
UNION ALL
SELECT TO_NUMBER(NULL) rank,
NULL segment_type,
NULL owner,
NULL segment_name,
TO_NUMBER(NULL),
TO_NUMBER(NULL),
'TOP 20' tablespace_name,
st.segments,
st.extents,
st.blocks,
st.bytes,
st.segments_perc,
st.extents_perc,
st.blocks_perc,
st.bytes_perc,
TO_NUMBER(NULL) bytes_perc_cum
FROM top_20_totals st
UNION ALL
SELECT TO_NUMBER(NULL) rank,
NULL segment_type,
NULL owner,
NULL segment_name,
TO_NUMBER(NULL),
TO_NUMBER(NULL),
'TOP 100' tablespace_name,
st.segments,
st.extents,
st.blocks,
st.bytes,
st.segments_perc,
st.extents_perc,
st.blocks_perc,
st.bytes_perc,
TO_NUMBER(NULL) bytes_perc_cum
FROM top_100_totals st
UNION ALL
SELECT TO_NUMBER(NULL) rank,
NULL segment_type,
NULL owner,
NULL segment_name,
TO_NUMBER(NULL),
TO_NUMBER(NULL),
'TOP 200' tablespace_name,
st.segments,
st.extents,
st.blocks,
st.bytes,
st.segments_perc,
st.extents_perc,
st.blocks_perc,
st.bytes_perc,
TO_NUMBER(NULL) bytes_perc_cum
FROM top_200_totals st
UNION ALL
SELECT TO_NUMBER(NULL) rank,
NULL segment_type,
NULL owner,
NULL segment_name,
TO_NUMBER(NULL),
TO_NUMBER(NULL),
'TOTAL' tablespace_name,
t.segments,
t.extents,
t.blocks,
t.bytes,
100 segemnts_perc,
100 extents_perc,
100 blocks_perc,
100 bytes_perc,
TO_NUMBER(NULL) bytes_perc_cum
FROM totals t) v;