Skip to content

Commit e2fb860

Browse files
committed
Create index_drops.sql
1 parent 690466c commit e2fb860

File tree

1 file changed

+184
-0
lines changed

1 file changed

+184
-0
lines changed

index_drops.sql

+184
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,184 @@
1+
/* index_drops.sql
2+
Copyright (C) 2013 Sean Scott
3+
4+
This program is free software; you can redistribute it and/or modify
5+
it under the terms of the GNU General Public License as published by
6+
the Free Software Foundation; either version 2 of the License, or
7+
(at your option) any later version.
8+
9+
This program is distributed in the hope that it will be useful,
10+
but WITHOUT ANY WARRANTY; without even the implied warranty of
11+
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
12+
GNU General Public License for more details.
13+
14+
You should have received a copy of the GNU General Public License along
15+
with this program; if not, write to the Free Software Foundation, Inc.,
16+
51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA.
17+
18+
These scripts provide a variety of different methods for looking at indexes that
19+
are candidates to be dropped. */
20+
21+
/* Indexes that don't have statistics */
22+
select index_name
23+
from dba_indexes
24+
where index_name not in (
25+
select index_name
26+
from v$segment_statistics);
27+
28+
/* Indexes that are candidates for being dropped (not part of a constraint, not in
29+
an execution plan). */
30+
select owner
31+
, index_name
32+
from dba_indexes
33+
where (owner, index_name) not in (
34+
select owner, object_name
35+
from dba_hist_sql_plan
36+
where object_type = 'INDEX') --Exclude indexes that have been used in an execution plan.
37+
and (owner, index_name) not in (
38+
select owner, index_name
39+
from dba_constraints
40+
where constraint_type in ('P','R')) --Exclude indexes that are part of a referential integrity constraint.
41+
order by 1;
42+
43+
column cardinality format 999,999,999.90
44+
column sample_pct format 999,999,999.90
45+
46+
/* Indexes that may be empty/droppable because they have 0 distinct keys, 0 rows,
47+
and aren't part of a PK/FK constraint. */
48+
select owner
49+
, index_name
50+
, uniqueness
51+
, index_type
52+
, num_rows
53+
, decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality
54+
, status
55+
, last_analyzed
56+
from dba_indexes
57+
where distinct_keys = 0
58+
and num_rows = 0
59+
and (owner, index_name) not in (
60+
select owner, index_name
61+
from dba_constraints
62+
where constraint_type in ('P','R'));
63+
64+
/* Small indexes that may be droppable because they're small and not used in a
65+
FK/PK constraint. Sometimes, a FTS may be as good or better than doing an index
66+
lookup against a tiny index/table. */
67+
select owner
68+
, index_name
69+
, pct_free
70+
, logging
71+
, index_type
72+
, distinct_keys
73+
, num_rows
74+
, decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality
75+
, status
76+
, last_analyzed
77+
, decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/sample_size) * 100 as sample_pct
78+
from dba_indexes
79+
where (distinct_keys < 20
80+
or num_rows < 20)
81+
and distinct_keys != 0
82+
and num_rows != 0
83+
and (owner, index_name) not in (
84+
select owner, index_name
85+
from dba_constraints
86+
where constraint_type in ('P','R'))
87+
order by 8 desc, 1, 2;
88+
89+
select owner
90+
, index_name
91+
, pct_free
92+
, logging
93+
, index_type
94+
, distinct_keys
95+
, num_rows
96+
, decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality
97+
, status
98+
, last_analyzed
99+
, decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/sample_size) * 100 as sample_pct
100+
from dba_indexes
101+
where uniqueness != 'UNIQUE'
102+
and distinct_keys != 0
103+
and num_rows != 0
104+
order by 8 desc, 1, 2;
105+
106+
/* Identify potentially redundant indexes based on predicates */
107+
column column_name_list format a50
108+
column column_name_list_dup format a50
109+
110+
select /*+ rule */
111+
a.table_owner
112+
, a.table_name
113+
, a.index_owner
114+
, a.index_name
115+
, column_name_list
116+
, column_name_list_dup
117+
, dup duplicate_indexes
118+
, i.uniqueness
119+
, i.partitioned
120+
, i.leaf_blocks
121+
, i.distinct_keys
122+
, i.num_rows
123+
, i.clustering_factor
124+
from (
125+
select table_owner
126+
, table_name
127+
, index_owner
128+
, index_name
129+
, column_name_list_dup
130+
, dup
131+
, max(dup) OVER (partition by table_owner, table_name, index_name) dup_mx
132+
from (
133+
select table_owner
134+
, table_name
135+
, index_owner
136+
, index_name
137+
, substr(SYS_CONNECT_BY_PATH(column_name, ','), 2) column_name_list_dup
138+
, dup
139+
from (
140+
select index_owner
141+
, index_name
142+
, table_owner
143+
, table_name
144+
, column_name
145+
, count(1) OVER (partition by index_owner, index_name) cnt
146+
, ROW_NUMBER () OVER (partition by index_owner, index_name order by column_position) as seq
147+
, count(1) OVER (partition by table_owner, table_name, column_name, column_position) as dup
148+
from dba_ind_columns
149+
where index_owner in ('&OWNER'))
150+
where dup != 1
151+
start with seq = 1
152+
connect by prior seq + 1 = seq
153+
and prior index_owner = index_owner
154+
and prior index_name = index_name)) a
155+
, (
156+
select table_owner
157+
, table_name
158+
, index_owner
159+
, index_name
160+
, substr(SYS_CONNECT_BY_PATH(column_name, ','), 2) column_name_list
161+
from (
162+
select index_owner
163+
, index_name
164+
, table_owner
165+
, table_name
166+
, column_name
167+
, count(1) OVER (partition by index_owner, index_name) cnt
168+
, ROW_NUMBER () OVER (partition by index_owner, index_name order by column_position) as seq
169+
from dba_ind_columns
170+
where index_owner in ('&OWNER'))
171+
where seq = cnt
172+
start with seq = 1
173+
connect by prior seq + 1 = seq
174+
and prior index_owner = index_owner
175+
and prior index_name = index_name) b
176+
, dba_indexes i
177+
where a.dup = a.dup_mx
178+
and a.index_owner = b.index_owner
179+
and a.index_name = b.index_name
180+
and a.index_owner = i.owner
181+
and a.index_name = i.index_name
182+
order by a.table_owner
183+
, a.table_name
184+
, column_name_list_dup;

0 commit comments

Comments
 (0)