Skip to content

Commit f66bda4

Browse files
committed
print migration (do / undo) for unused indexes
1 parent 1d842c3 commit f66bda4

File tree

2 files changed

+110
-6
lines changed

2 files changed

+110
-6
lines changed

index.psql

Lines changed: 12 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,8 @@
11
\echo Menu:
2-
\echo ' 1 – Master / replica info (with lag)'
3-
\echo ' 2 – Bloat'
4-
\echo ' 3 – pg_stat_statementis'
2+
\echo ' 1 – Basic Node Information (master/replica, lag, DB size, tmp files)'
3+
\echo ' 2 – '
4+
\echo ' 3 - Slowest Queries'
5+
\echo ' 4 - Unused Indexes'
56
\echo ' q – Quit from this tool'
67
\echo
78
\echo 'Type your choice (1-3) and press <Enter>:'
@@ -11,18 +12,23 @@ select
1112
:d_stp::text = '1' as d_step_is_1,
1213
:d_stp::text = '2' as d_step_is_2,
1314
:d_stp::text = '3' as d_step_is_3,
15+
:d_stp::text = '4' as d_step_is_4,
1416
:d_stp::text = 'q' as d_step_is_q \gset
1517
\if :d_step_is_1
1618
\i ./general/basic.sql
17-
\prompt 'Press any key…' d_dummy
19+
\prompt 'Press <Enter>' d_dummy
1820
\i ./index.psql
1921
\elif :d_step_is_2
2022
\echo ' 2 is chosen!'
21-
\prompt 'Press any key…' d_dummy
23+
\prompt 'Press <Enter>' d_dummy
2224
\i ./index.psql
2325
\elif :d_step_is_3
2426
\echo ' 3 is chosen!'
25-
\prompt 'Press any key…' d_dummy
27+
\prompt 'Press <Enter>' d_dummy
28+
\i ./index.psql
29+
\elif :d_step_is_4
30+
\i ./indexes/unused.sql
31+
\prompt 'Press <Enter>' d_dummy
2632
\i ./index.psql
2733
\elif :d_step_is_q
2834
\echo '...bye!'

indexes/unused.sql

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

0 commit comments

Comments
 (0)