Skip to content

Commit 3aa01ee

Browse files
authored
Merge pull request #40 from NikolayS/dmius-i2-improve
Improve i1,i2,i5 and b1 reports
2 parents f58e2e5 + b7d33bb commit 3aa01ee

6 files changed

+157
-49
lines changed

sql/b1_table_estimation.sql

+23-5
Original file line numberDiff line numberDiff line change
@@ -69,15 +69,33 @@ select
6969
case is_na when true then 'TRUE' else '' end as "Is N/A",
7070
coalesce(nullif(schema_name, 'public') || '.', '') || table_name as "Table",
7171
pg_size_pretty(real_size::numeric) as "Size",
72-
'~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' as "Extra",
73-
'~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' as "Bloat",
74-
'~' || pg_size_pretty((real_size - bloat_size)::numeric) as "Live",
72+
case
73+
when extra_size::numeric >= 0
74+
then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)'
75+
else null
76+
end as "Extra",
77+
case
78+
when bloat_size::numeric >= 0
79+
then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)'
80+
else null
81+
end as "Bloat estimate",
82+
case
83+
when (real_size - bloat_size)::numeric >=0
84+
then '~' || pg_size_pretty((real_size - bloat_size)::numeric)
85+
else null
86+
end as "Live",
7587
greatest(last_autovacuum, last_vacuum)::timestamp(0)::text
7688
|| case greatest(last_autovacuum, last_vacuum)
7789
when last_autovacuum then ' (auto)'
78-
else '' end as "Last Vaccuum"
90+
else '' end as "Last Vaccuum",
91+
(
92+
select
93+
coalesce(substring(array_to_string(reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 100)
94+
from pg_class
95+
where oid = tblid
96+
) as "Fillfactor"
7997
from step4
80-
order by real_size desc nulls last
98+
order by bloat_size desc nulls last
8199
;
82100

83101
/*

sql/b2_btree_estimation.sql

+15-3
Original file line numberDiff line numberDiff line change
@@ -101,9 +101,21 @@ select
101101
coalesce(nullif(schema_name, 'public') || '.', '') || table_name
102102
) as "Index (Table)",
103103
pg_size_pretty(real_size::numeric) as "Size",
104-
'~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' as "Extra",
105-
'~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' as "Bloat",
106-
'~' || pg_size_pretty((real_size - bloat_size)::numeric) as "Live",
104+
case
105+
when extra_size::numeric >= 0
106+
then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)'
107+
else null
108+
end as "Extra",
109+
case
110+
when bloat_size::numeric >= 0
111+
then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)'
112+
else null
113+
end as "Bloat",
114+
case
115+
when (real_size - bloat_size)::numeric >=0
116+
then '~' || pg_size_pretty((real_size - bloat_size)::numeric)
117+
else null
118+
end as "Live",
107119
fillfactor
108120
from step4
109121
order by real_size desc nulls last

sql/i1_rare_indexes.sql

+13-3
Original file line numberDiff line numberDiff line change
@@ -76,7 +76,17 @@ WHERE
7676
AND NOT idx_is_btree
7777
AND index_bytes > 100000000
7878
ORDER BY grp, index_bytes DESC )
79-
SELECT reason, schemaname, tablename, indexname,
80-
index_scan_pct, scans_per_write, index_size, table_size
81-
FROM index_groups;
79+
SELECT
80+
reason,
81+
schemaname as schema_name,
82+
tablename as table_name,
83+
indexname as index_name,
84+
index_scan_pct,
85+
scans_per_write,
86+
index_size,
87+
table_size,
88+
idx_scan,
89+
all_scans
90+
FROM index_groups
91+
;
8292

sql/i2_redundant_indexes.sql

+43-13
Original file line numberDiff line numberDiff line change
@@ -10,25 +10,55 @@
1010
-- is usually very different from master).
1111

1212
with index_data as (
13-
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
13+
select
14+
*,
15+
indkey::text as columns,
16+
array_to_string(indclass, ', ') as opclasses
1417
from pg_index
1518
), redundant as (
1619
select
20+
tnsp.nspname AS schema_name,
21+
trel.relname AS table_name,
22+
irel.relname AS index_name,
23+
am1.amname as access_method,
1724
format('redundant to index: %I', i1.indexrelid::regclass)::text as reason,
18-
i2.indrelid::regclass::text as tablename,
19-
i2.indexrelid::regclass::text as indexname,
20-
pg_get_indexdef(i1.indexrelid) main_indexdef,
21-
pg_get_indexdef(i2.indexrelid) indexdef,
22-
pg_size_pretty(pg_relation_size(i2.indexrelid)) size,
23-
i2.indexrelid
25+
pg_get_indexdef(i1.indexrelid) main_index_def,
26+
pg_size_pretty(pg_relation_size(i1.indexrelid)) main_index_size,
27+
pg_get_indexdef(i2.indexrelid) index_def,
28+
pg_size_pretty(pg_relation_size(i2.indexrelid)) index_size,
29+
s.idx_scan as index_usage
2430
from
2531
index_data as i1
26-
join index_data as i2 on i1.indrelid = i2.indrelid and i1.indexrelid <> i2.indexrelid
32+
join index_data as i2 on (
33+
i1.indrelid = i2.indrelid /* same table */
34+
and i1.indexrelid <> i2.indexrelid /* NOT same index */
35+
)
36+
inner join pg_opclass op1 on i1.indclass[0] = op1.oid
37+
inner join pg_opclass op2 on i2.indclass[0] = op2.oid
38+
inner join pg_am am1 on op1.opcmethod = am1.oid
39+
inner join pg_am am2 on op2.opcmethod = am2.oid
40+
join pg_stat_user_indexes as s on s.indexrelid = i2.indexrelid
41+
join pg_class as trel on trel.oid = i2.indrelid
42+
join pg_namespace as tnsp on trel.relnamespace = tnsp.oid
43+
join pg_class as irel on irel.oid = i2.indexrelid
2744
where
28-
(regexp_replace(i1.indpred, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indpred, 'location \d+', 'location', 'g'))
29-
and (regexp_replace(i1.indexprs, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indexprs, 'location \d+', 'location', 'g'))
30-
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))))
31-
and i1.key_array[1:i2.nkeys]=i2.key_array
45+
not i1.indisprimary -- index 1 is not primary
46+
and not ( -- skip if index1 is (primary or uniq) and is NOT (primary and uniq)
47+
(i1.indisprimary or i1.indisunique)
48+
and (not i2.indisprimary or not i2.indisunique)
49+
)
50+
and am1.amname = am2.amname -- same access type
51+
and (
52+
i2.columns like (i1.columns || '%') -- index 2 includes all columns from index 1
53+
or i1.columns = i2.columns -- index1 and index 2 includes same columns
54+
)
55+
and (
56+
i2.opclasses like (i1.opclasses || '%')
57+
or i1.opclasses = i2.opclasses
58+
)
59+
-- index expressions is same
60+
and pg_get_expr(i1.indexprs, i1.indrelid) is not distinct from pg_get_expr(i2.indexprs, i2.indrelid)
61+
-- index predicates is same
62+
and pg_get_expr(i1.indpred, i1.indrelid) is not distinct from pg_get_expr(i2.indpred, i2.indrelid)
3263
)
3364
select * from redundant;
34-

sql/i4_invalid_indexes.sql

+12-1
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,18 @@ select
1313
coalesce(nullif(pn.nspname, 'public') || '.', '') || pct.relname as "relation_name",
1414
pci.relname as index_name,
1515
pn.nspname as schema_name,
16-
pct.relname as table_name
16+
pct.relname as table_name,
17+
pg_size_pretty(pg_relation_size(pidx.indexrelid)) index_size,
18+
format(
19+
'DROP INDEX CONCURRENTLY %s; -- %s, table %s',
20+
pidx.indexrelid::regclass::text,
21+
'Invalid index',
22+
pct.relname) as drop_code,
23+
replace(
24+
format('%s; -- table %s', pg_get_indexdef(pidx.indexrelid), pct.relname),
25+
'CREATE INDEX',
26+
'CREATE INDEX CONCURRENTLY'
27+
) as revert_code
1728
from pg_index pidx
1829
join pg_class as pci on pci.oid = pidx.indexrelid
1930
join pg_class as pct on pct.oid = pidx.indrelid

sql/i5_indexes_migration.sql

+51-24
Original file line numberDiff line numberDiff line change
@@ -31,14 +31,14 @@
3131
with unused as (
3232
select
3333
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,
34+
pg_stat_user_indexes.relname as table_name,
35+
pg_stat_user_indexes.schemaname || '.' || indexrelname::text as index_name,
3636
pg_stat_user_indexes.idx_scan,
3737
(coalesce(n_tup_ins, 0) + coalesce(n_tup_upd, 0) - coalesce(n_tup_hot_upd, 0) + coalesce(n_tup_del, 0)) as write_activity,
3838
pg_stat_user_tables.seq_scan,
3939
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,
40+
pg_get_indexdef(pg_index.indexrelid) as index_def,
41+
pg_size_pretty(pg_relation_size(pg_index.indexrelid::regclass)) as index_size,
4242
pg_index.indexrelid
4343
from pg_stat_user_indexes
4444
join pg_stat_user_tables
@@ -50,47 +50,74 @@ with unused as (
5050
and pg_index.indisunique is false
5151
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
5252
), index_data as (
53-
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
53+
select
54+
*,
55+
indkey::text as columns,
56+
array_to_string(indclass, ', ') as opclasses
5457
from pg_index
5558
), redundant as (
5659
select
60+
i2.indrelid::regclass::text as table_name,
61+
i2.indexrelid::regclass::text as index_name,
62+
am1.amname as access_method,
5763
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,
64+
pg_get_indexdef(i1.indexrelid) main_index_def,
65+
pg_get_indexdef(i2.indexrelid) index_def,
66+
pg_size_pretty(pg_relation_size(i2.indexrelid)) index_size,
67+
s.idx_scan as index_usage,
6368
i2.indexrelid
6469
from
6570
index_data as i1
66-
join index_data as i2 on i1.indrelid = i2.indrelid and i1.indexrelid <> i2.indexrelid
71+
join index_data as i2 on (
72+
i1.indrelid = i2.indrelid /* same table */
73+
and i1.indexrelid <> i2.indexrelid /* NOT same index */
74+
)
75+
inner join pg_opclass op1 on i1.indclass[0] = op1.oid
76+
inner join pg_opclass op2 on i2.indclass[0] = op2.oid
77+
inner join pg_am am1 on op1.opcmethod = am1.oid
78+
inner join pg_am am2 on op2.opcmethod = am2.oid
79+
join pg_stat_user_indexes as s on s.indexrelid = i2.indexrelid
6780
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
81+
not i1.indisprimary -- index 1 is not primary
82+
and not ( -- skip if index1 is (primary or uniq) and is NOT (primary and uniq)
83+
(i1.indisprimary or i1.indisunique)
84+
and (not i2.indisprimary or not i2.indisunique)
85+
)
86+
and am1.amname = am2.amname -- same access type
87+
and (
88+
i2.columns like (i1.columns || '%') -- index 2 includes all columns from index 1
89+
or i1.columns = i2.columns -- index1 and index 2 includes same columns
90+
)
91+
and (
92+
i2.opclasses like (i1.opclasses || '%')
93+
or i1.opclasses = i2.opclasses
94+
)
95+
-- index expressions are same
96+
and pg_get_expr(i1.indexprs, i1.indrelid) is not distinct from pg_get_expr(i2.indexprs, i2.indrelid)
97+
-- index predicates are same
98+
and pg_get_expr(i1.indpred, i1.indrelid) is not distinct from pg_get_expr(i2.indpred, i2.indrelid)
7299
), together as (
73-
select reason, tablename, indexname, size, indexdef, null as main_indexdef, indexrelid
100+
select reason, table_name, index_name, index_size, index_def, null as main_index_def, indexrelid
74101
from unused
75102
union all
76-
select reason, tablename, indexname, size, indexdef, main_indexdef, indexrelid
103+
select reason, table_name, index_name, index_size, index_def, main_index_def, indexrelid
77104
from redundant
78-
order by tablename asc, indexname
105+
where index_usage = 0
79106
), droplines as (
80-
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(indexname), max(size), string_agg(reason, ', '), tablename) as line
107+
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(index_name), max(index_size), string_agg(reason, ', '), table_name) as line
81108
from together t1
82-
group by tablename, indexrelid
83-
order by tablename, indexrelid
109+
group by table_name, index_name
110+
order by table_name, index_name
84111
), createlines as (
85112
select
86113
replace(
87-
format('%s; -- table %s', max(indexdef), tablename),
114+
format('%s; -- table %s', max(index_def), table_name),
88115
'CREATE INDEX',
89116
'CREATE INDEX CONCURRENTLY'
90117
)as line
91118
from together t2
92-
group by tablename, indexrelid
93-
order by tablename, indexrelid
119+
group by table_name, index_name
120+
order by table_name, index_name
94121
)
95122
select '-- Do migration: --' as run_in_separate_transactions
96123
union all

0 commit comments

Comments
 (0)