Skip to content

Commit f58e2e5

Browse files
authored
Merge pull request #39 from NikolayS/dmius-redundat-indexes
Redundat indexes list
2 parents 670651a + 39afed8 commit f58e2e5

File tree

4 files changed

+142
-75
lines changed

4 files changed

+142
-75
lines changed

sql/i2_redundant_indexes.sql

+4-74
Original file line numberDiff line numberDiff line change
@@ -1,55 +1,15 @@
1-
--Unused/Redundant Indexes Do & Undo Migration DDL
1+
-- List of redundant indexes
22

3-
-- Use it to generate a database migration (e.g. RoR's db:migrate or Sqitch)
4-
-- to drop unused and redundant indexes.
5-
6-
-- This query generates a set of `DROP INDEX` statements, that
7-
-- can be used in your migration script. Also, it generates
8-
-- `CREATE INDEX`, put them to revert/rollback migration script.
9-
10-
-- It is also a good idea to manually double check all indexes being dropped.
11-
-- WARNING here: when you are dropping an index B which is redundant to some index A,
12-
-- check that you don't drop the A itself at the same time (it can be in "unused").
13-
-- So if B is "redundant" to A and A is "unused", the script will suggest
14-
-- dropping both. If so, it is probably better to drop B and leave A.
15-
-- -- in this case there is a chance that A will be used. If it will still be unused,
16-
-- you will drop it during the next cleanup routine procedure.
3+
-- Use it to see redundant indexes list
174

185
-- This query doesn't need any additional extensions to be installed
196
-- (except plpgsql), and doesn't create anything (like views or smth)
207
-- -- so feel free to use it in your clouds (Heroku, AWS RDS, etc)
218

22-
-- It also does't do anything except reading system catalogs and
23-
-- printing NOTICEs, so you can easily run it on your
24-
-- production *master* database.
259
-- (Keep in mind, that on replicas, the whole picture of index usage
2610
-- is usually very different from master).
2711

28-
-- TODO: take into account type of index and opclass
29-
-- TODO: schemas
30-
31-
with unused as (
32-
select
33-
format('unused (idx_scan: %s)', pg_stat_user_indexes.idx_scan)::text as reason,
34-
pg_stat_user_indexes.relname as tablename,
35-
pg_stat_user_indexes.schemaname || '.' || indexrelname::text as indexname,
36-
pg_stat_user_indexes.idx_scan,
37-
(coalesce(n_tup_ins, 0) + coalesce(n_tup_upd, 0) - coalesce(n_tup_hot_upd, 0) + coalesce(n_tup_del, 0)) as write_activity,
38-
pg_stat_user_tables.seq_scan,
39-
pg_stat_user_tables.n_live_tup,
40-
pg_get_indexdef(pg_index.indexrelid) as indexdef,
41-
pg_size_pretty(pg_relation_size(pg_index.indexrelid::regclass)) as size,
42-
pg_index.indexrelid
43-
from pg_stat_user_indexes
44-
join pg_stat_user_tables
45-
on pg_stat_user_indexes.relid = pg_stat_user_tables.relid
46-
join pg_index
47-
ON pg_index.indexrelid = pg_stat_user_indexes.indexrelid
48-
where
49-
pg_stat_user_indexes.idx_scan = 0 /* < 10 or smth */
50-
and pg_index.indisunique is false
51-
and pg_stat_user_indexes.idx_scan::float/(coalesce(n_tup_ins,0)+coalesce(n_tup_upd,0)-coalesce(n_tup_hot_upd,0)+coalesce(n_tup_del,0)+1)::float<0.01
52-
), index_data as (
12+
with index_data as (
5313
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
5414
from pg_index
5515
), redundant as (
@@ -69,36 +29,6 @@ with unused as (
6929
and (regexp_replace(i1.indexprs, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indexprs, 'location \d+', 'location', 'g'))
7030
and ((i1.nkeys > i2.nkeys and not i2.indisunique) OR (i1.nkeys=i2.nkeys and ((i1.indisunique and i2.indisunique and (i1.indexrelid>i2.indexrelid)) or (not i1.indisunique and not i2.indisunique and (i1.indexrelid>i2.indexrelid)) or (i1.indisunique and not i2.indisunique))))
7131
and i1.key_array[1:i2.nkeys]=i2.key_array
72-
), together as (
73-
select reason, tablename, indexname, size, indexdef, null as main_indexdef, indexrelid
74-
from unused
75-
union all
76-
select reason, tablename, indexname, size, indexdef, main_indexdef, indexrelid
77-
from redundant
78-
order by tablename asc, indexname
79-
), droplines as (
80-
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(indexname), max(size), string_agg(reason, ', '), tablename) as line
81-
from together t1
82-
group by tablename, indexrelid
83-
order by tablename, indexrelid
84-
), createlines as (
85-
select
86-
replace(
87-
format('%s; -- table %s', max(indexdef), tablename),
88-
'CREATE INDEX',
89-
'CREATE INDEX CONCURRENTLY'
90-
)as line
91-
from together t2
92-
group by tablename, indexrelid
93-
order by tablename, indexrelid
9432
)
95-
select '-- Do migration: --' as run_in_separate_transactions
96-
union all
97-
select * from droplines
98-
union all
99-
select ''
100-
union all
101-
select '-- Revert migration: --'
102-
union all
103-
select * from createlines;
33+
select * from redundant;
10434

sql/i4_invalid_indexes.sql

+21
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
-- List of invalid indexes
2+
3+
-- Use it to see invalid indexes list
4+
5+
-- This query doesn't need any additional extensions to be installed
6+
-- (except plpgsql), and doesn't create anything (like views or smth)
7+
-- -- so feel free to use it in your clouds (Heroku, AWS RDS, etc)
8+
9+
-- (Keep in mind, that on replicas, the whole picture of index usage
10+
-- is usually very different from master).
11+
12+
select
13+
coalesce(nullif(pn.nspname, 'public') || '.', '') || pct.relname as "relation_name",
14+
pci.relname as index_name,
15+
pn.nspname as schema_name,
16+
pct.relname as table_name
17+
from pg_index pidx
18+
join pg_class as pci on pci.oid = pidx.indexrelid
19+
join pg_class as pct on pct.oid = pidx.indrelid
20+
left join pg_namespace pn on pn.oid = pct.relnamespace
21+
where pidx.indisvalid = false;

sql/i5_indexes_migration.sql

+104
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,104 @@
1+
--Unused/Redundant Indexes Do & Undo Migration DDL
2+
3+
-- Use it to generate a database migration (e.g. RoR's db:migrate or Sqitch)
4+
-- to drop unused and redundant indexes.
5+
6+
-- This query generates a set of `DROP INDEX` statements, that
7+
-- can be used in your migration script. Also, it generates
8+
-- `CREATE INDEX`, put them to revert/rollback migration script.
9+
10+
-- It is also a good idea to manually double check all indexes being dropped.
11+
-- WARNING here: when you are dropping an index B which is redundant to some index A,
12+
-- check that you don't drop the A itself at the same time (it can be in "unused").
13+
-- So if B is "redundant" to A and A is "unused", the script will suggest
14+
-- dropping both. If so, it is probably better to drop B and leave A.
15+
-- -- in this case there is a chance that A will be used. If it will still be unused,
16+
-- you will drop it during the next cleanup routine procedure.
17+
18+
-- This query doesn't need any additional extensions to be installed
19+
-- (except plpgsql), and doesn't create anything (like views or smth)
20+
-- -- so feel free to use it in your clouds (Heroku, AWS RDS, etc)
21+
22+
-- It also does't do anything except reading system catalogs and
23+
-- printing NOTICEs, so you can easily run it on your
24+
-- production *master* database.
25+
-- (Keep in mind, that on replicas, the whole picture of index usage
26+
-- is usually very different from master).
27+
28+
-- TODO: take into account type of index and opclass
29+
-- TODO: schemas
30+
31+
with unused as (
32+
select
33+
format('unused (idx_scan: %s)', pg_stat_user_indexes.idx_scan)::text as reason,
34+
pg_stat_user_indexes.relname as tablename,
35+
pg_stat_user_indexes.schemaname || '.' || indexrelname::text as indexname,
36+
pg_stat_user_indexes.idx_scan,
37+
(coalesce(n_tup_ins, 0) + coalesce(n_tup_upd, 0) - coalesce(n_tup_hot_upd, 0) + coalesce(n_tup_del, 0)) as write_activity,
38+
pg_stat_user_tables.seq_scan,
39+
pg_stat_user_tables.n_live_tup,
40+
pg_get_indexdef(pg_index.indexrelid) as indexdef,
41+
pg_size_pretty(pg_relation_size(pg_index.indexrelid::regclass)) as size,
42+
pg_index.indexrelid
43+
from pg_stat_user_indexes
44+
join pg_stat_user_tables
45+
on pg_stat_user_indexes.relid = pg_stat_user_tables.relid
46+
join pg_index
47+
ON pg_index.indexrelid = pg_stat_user_indexes.indexrelid
48+
where
49+
pg_stat_user_indexes.idx_scan = 0 /* < 10 or smth */
50+
and pg_index.indisunique is false
51+
and pg_stat_user_indexes.idx_scan::float/(coalesce(n_tup_ins,0)+coalesce(n_tup_upd,0)-coalesce(n_tup_hot_upd,0)+coalesce(n_tup_del,0)+1)::float<0.01
52+
), index_data as (
53+
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
54+
from pg_index
55+
), redundant as (
56+
select
57+
format('redundant to index: %I', i1.indexrelid::regclass)::text as reason,
58+
i2.indrelid::regclass::text as tablename,
59+
i2.indexrelid::regclass::text as indexname,
60+
pg_get_indexdef(i1.indexrelid) main_indexdef,
61+
pg_get_indexdef(i2.indexrelid) indexdef,
62+
pg_size_pretty(pg_relation_size(i2.indexrelid)) size,
63+
i2.indexrelid
64+
from
65+
index_data as i1
66+
join index_data as i2 on i1.indrelid = i2.indrelid and i1.indexrelid <> i2.indexrelid
67+
where
68+
(regexp_replace(i1.indpred, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indpred, 'location \d+', 'location', 'g'))
69+
and (regexp_replace(i1.indexprs, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indexprs, 'location \d+', 'location', 'g'))
70+
and ((i1.nkeys > i2.nkeys and not i2.indisunique) OR (i1.nkeys=i2.nkeys and ((i1.indisunique and i2.indisunique and (i1.indexrelid>i2.indexrelid)) or (not i1.indisunique and not i2.indisunique and (i1.indexrelid>i2.indexrelid)) or (i1.indisunique and not i2.indisunique))))
71+
and i1.key_array[1:i2.nkeys]=i2.key_array
72+
), together as (
73+
select reason, tablename, indexname, size, indexdef, null as main_indexdef, indexrelid
74+
from unused
75+
union all
76+
select reason, tablename, indexname, size, indexdef, main_indexdef, indexrelid
77+
from redundant
78+
order by tablename asc, indexname
79+
), droplines as (
80+
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(indexname), max(size), string_agg(reason, ', '), tablename) as line
81+
from together t1
82+
group by tablename, indexrelid
83+
order by tablename, indexrelid
84+
), createlines as (
85+
select
86+
replace(
87+
format('%s; -- table %s', max(indexdef), tablename),
88+
'CREATE INDEX',
89+
'CREATE INDEX CONCURRENTLY'
90+
)as line
91+
from together t2
92+
group by tablename, indexrelid
93+
order by tablename, indexrelid
94+
)
95+
select '-- Do migration: --' as run_in_separate_transactions
96+
union all
97+
select * from droplines
98+
union all
99+
select ''
100+
union all
101+
select '-- Revert migration: --'
102+
union all
103+
select * from createlines;
104+

start.psql

+13-1
Original file line numberDiff line numberDiff line change
@@ -12,8 +12,10 @@
1212
\echo ' b5 – Tables and Columns Without Stats (so bloat cannot be estimated)'
1313
\echo ' e1 – List of extensions installed in the current DB'
1414
\echo ' i1 – Unused/Rarely Used Indexes'
15-
\echo ' i2 – Unused/Redundant Indexes Do & Undo Migration DDL'
15+
\echo ' i2 – Redundant Indexes'
1616
\echo ' i3 – FKs with Missing/Bad Indexes'
17+
\echo ' i4 – Invalid Indexes'
18+
\echo ' i5 – Unused/Redundant Indexes Do & Undo Migration DDL'
1719
\echo ' p1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?'
1820
\echo ' s1 – Slowest Queries, by Total Time (requires pg_stat_statements extension)'
1921
\echo ' s2 – Slowest Queries Report (requires pg_stat_statements)'
@@ -39,6 +41,8 @@ select
3941
:d_stp::text = 'i1' as d_step_is_i1,
4042
:d_stp::text = 'i2' as d_step_is_i2,
4143
:d_stp::text = 'i3' as d_step_is_i3,
44+
:d_stp::text = 'i4' as d_step_is_i4,
45+
:d_stp::text = 'i5' as d_step_is_i5,
4246
:d_stp::text = 'p1' as d_step_is_p1,
4347
:d_stp::text = 's1' as d_step_is_s1,
4448
:d_stp::text = 's2' as d_step_is_s2,
@@ -104,6 +108,14 @@ select
104108
\ir ./sql/i3_non_indexed_fks.sql
105109
\prompt 'Press <Enter> to continue…' d_dummy
106110
\ir ./start.psql
111+
\elif :d_step_is_i4
112+
\ir ./sql/i4_invalid_indexes.sql
113+
\prompt 'Press <Enter> to continue…' d_dummy
114+
\ir ./start.psql
115+
\elif :d_step_is_i5
116+
\ir ./sql/i5_indexes_migration.sql
117+
\prompt 'Press <Enter> to continue…' d_dummy
118+
\ir ./start.psql
107119
\elif :d_step_is_p1
108120
\ir ./sql/p1_alignment_padding.sql
109121
\prompt 'Press <Enter> to continue…' d_dummy

0 commit comments

Comments
 (0)