Skip to content

Commit

Permalink
Merge pull request #40 from NikolayS/dmius-i2-improve
Browse files Browse the repository at this point in the history
Improve i1,i2,i5 and b1 reports
  • Loading branch information
dmius authored Jan 28, 2019
2 parents f58e2e5 + b7d33bb commit 3aa01ee
Show file tree
Hide file tree
Showing 6 changed files with 157 additions and 49 deletions.
28 changes: 23 additions & 5 deletions sql/b1_table_estimation.sql
Original file line number Diff line number Diff line change
Expand Up @@ -69,15 +69,33 @@ select
case is_na when true then 'TRUE' else '' end as "Is N/A",
coalesce(nullif(schema_name, 'public') || '.', '') || table_name as "Table",
pg_size_pretty(real_size::numeric) as "Size",
'~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' as "Extra",
'~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' as "Bloat",
'~' || pg_size_pretty((real_size - bloat_size)::numeric) as "Live",
case
when extra_size::numeric >= 0
then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)'
else null
end as "Extra",
case
when bloat_size::numeric >= 0
then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)'
else null
end as "Bloat estimate",
case
when (real_size - bloat_size)::numeric >=0
then '~' || pg_size_pretty((real_size - bloat_size)::numeric)
else null
end as "Live",
greatest(last_autovacuum, last_vacuum)::timestamp(0)::text
|| case greatest(last_autovacuum, last_vacuum)
when last_autovacuum then ' (auto)'
else '' end as "Last Vaccuum"
else '' end as "Last Vaccuum",
(
select
coalesce(substring(array_to_string(reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 100)
from pg_class
where oid = tblid
) as "Fillfactor"
from step4
order by real_size desc nulls last
order by bloat_size desc nulls last
;

/*
Expand Down
18 changes: 15 additions & 3 deletions sql/b2_btree_estimation.sql
Original file line number Diff line number Diff line change
Expand Up @@ -101,9 +101,21 @@ select
coalesce(nullif(schema_name, 'public') || '.', '') || table_name
) as "Index (Table)",
pg_size_pretty(real_size::numeric) as "Size",
'~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' as "Extra",
'~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' as "Bloat",
'~' || pg_size_pretty((real_size - bloat_size)::numeric) as "Live",
case
when extra_size::numeric >= 0
then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)'
else null
end as "Extra",
case
when bloat_size::numeric >= 0
then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)'
else null
end as "Bloat",
case
when (real_size - bloat_size)::numeric >=0
then '~' || pg_size_pretty((real_size - bloat_size)::numeric)
else null
end as "Live",
fillfactor
from step4
order by real_size desc nulls last
Expand Down
16 changes: 13 additions & 3 deletions sql/i1_rare_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -76,7 +76,17 @@ WHERE
AND NOT idx_is_btree
AND index_bytes > 100000000
ORDER BY grp, index_bytes DESC )
SELECT reason, schemaname, tablename, indexname,
index_scan_pct, scans_per_write, index_size, table_size
FROM index_groups;
SELECT
reason,
schemaname as schema_name,
tablename as table_name,
indexname as index_name,
index_scan_pct,
scans_per_write,
index_size,
table_size,
idx_scan,
all_scans
FROM index_groups
;

56 changes: 43 additions & 13 deletions sql/i2_redundant_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,25 +10,55 @@
-- is usually very different from master).

with index_data as (
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
select
*,
indkey::text as columns,
array_to_string(indclass, ', ') as opclasses
from pg_index
), redundant as (
select
tnsp.nspname AS schema_name,
trel.relname AS table_name,
irel.relname AS index_name,
am1.amname as access_method,
format('redundant to index: %I', i1.indexrelid::regclass)::text as reason,
i2.indrelid::regclass::text as tablename,
i2.indexrelid::regclass::text as indexname,
pg_get_indexdef(i1.indexrelid) main_indexdef,
pg_get_indexdef(i2.indexrelid) indexdef,
pg_size_pretty(pg_relation_size(i2.indexrelid)) size,
i2.indexrelid
pg_get_indexdef(i1.indexrelid) main_index_def,
pg_size_pretty(pg_relation_size(i1.indexrelid)) main_index_size,
pg_get_indexdef(i2.indexrelid) index_def,
pg_size_pretty(pg_relation_size(i2.indexrelid)) index_size,
s.idx_scan as index_usage
from
index_data as i1
join index_data as i2 on i1.indrelid = i2.indrelid and i1.indexrelid <> i2.indexrelid
join index_data as i2 on (
i1.indrelid = i2.indrelid /* same table */
and i1.indexrelid <> i2.indexrelid /* NOT same index */
)
inner join pg_opclass op1 on i1.indclass[0] = op1.oid
inner join pg_opclass op2 on i2.indclass[0] = op2.oid
inner join pg_am am1 on op1.opcmethod = am1.oid
inner join pg_am am2 on op2.opcmethod = am2.oid
join pg_stat_user_indexes as s on s.indexrelid = i2.indexrelid
join pg_class as trel on trel.oid = i2.indrelid
join pg_namespace as tnsp on trel.relnamespace = tnsp.oid
join pg_class as irel on irel.oid = i2.indexrelid
where
(regexp_replace(i1.indpred, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indpred, 'location \d+', 'location', 'g'))
and (regexp_replace(i1.indexprs, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indexprs, 'location \d+', 'location', 'g'))
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))))
and i1.key_array[1:i2.nkeys]=i2.key_array
not i1.indisprimary -- index 1 is not primary
and not ( -- skip if index1 is (primary or uniq) and is NOT (primary and uniq)
(i1.indisprimary or i1.indisunique)
and (not i2.indisprimary or not i2.indisunique)
)
and am1.amname = am2.amname -- same access type
and (
i2.columns like (i1.columns || '%') -- index 2 includes all columns from index 1
or i1.columns = i2.columns -- index1 and index 2 includes same columns
)
and (
i2.opclasses like (i1.opclasses || '%')
or i1.opclasses = i2.opclasses
)
-- index expressions is same
and pg_get_expr(i1.indexprs, i1.indrelid) is not distinct from pg_get_expr(i2.indexprs, i2.indrelid)
-- index predicates is same
and pg_get_expr(i1.indpred, i1.indrelid) is not distinct from pg_get_expr(i2.indpred, i2.indrelid)
)
select * from redundant;

13 changes: 12 additions & 1 deletion sql/i4_invalid_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,18 @@ select
coalesce(nullif(pn.nspname, 'public') || '.', '') || pct.relname as "relation_name",
pci.relname as index_name,
pn.nspname as schema_name,
pct.relname as table_name
pct.relname as table_name,
pg_size_pretty(pg_relation_size(pidx.indexrelid)) index_size,
format(
'DROP INDEX CONCURRENTLY %s; -- %s, table %s',
pidx.indexrelid::regclass::text,
'Invalid index',
pct.relname) as drop_code,
replace(
format('%s; -- table %s', pg_get_indexdef(pidx.indexrelid), pct.relname),
'CREATE INDEX',
'CREATE INDEX CONCURRENTLY'
) as revert_code
from pg_index pidx
join pg_class as pci on pci.oid = pidx.indexrelid
join pg_class as pct on pct.oid = pidx.indrelid
Expand Down
75 changes: 51 additions & 24 deletions sql/i5_indexes_migration.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,14 +31,14 @@
with unused as (
select
format('unused (idx_scan: %s)', pg_stat_user_indexes.idx_scan)::text as reason,
pg_stat_user_indexes.relname as tablename,
pg_stat_user_indexes.schemaname || '.' || indexrelname::text as indexname,
pg_stat_user_indexes.relname as table_name,
pg_stat_user_indexes.schemaname || '.' || indexrelname::text as index_name,
pg_stat_user_indexes.idx_scan,
(coalesce(n_tup_ins, 0) + coalesce(n_tup_upd, 0) - coalesce(n_tup_hot_upd, 0) + coalesce(n_tup_del, 0)) as write_activity,
pg_stat_user_tables.seq_scan,
pg_stat_user_tables.n_live_tup,
pg_get_indexdef(pg_index.indexrelid) as indexdef,
pg_size_pretty(pg_relation_size(pg_index.indexrelid::regclass)) as size,
pg_get_indexdef(pg_index.indexrelid) as index_def,
pg_size_pretty(pg_relation_size(pg_index.indexrelid::regclass)) as index_size,
pg_index.indexrelid
from pg_stat_user_indexes
join pg_stat_user_tables
Expand All @@ -50,47 +50,74 @@ with unused as (
and pg_index.indisunique is false
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
), index_data as (
select *, string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys
select
*,
indkey::text as columns,
array_to_string(indclass, ', ') as opclasses
from pg_index
), redundant as (
select
i2.indrelid::regclass::text as table_name,
i2.indexrelid::regclass::text as index_name,
am1.amname as access_method,
format('redundant to index: %I', i1.indexrelid::regclass)::text as reason,
i2.indrelid::regclass::text as tablename,
i2.indexrelid::regclass::text as indexname,
pg_get_indexdef(i1.indexrelid) main_indexdef,
pg_get_indexdef(i2.indexrelid) indexdef,
pg_size_pretty(pg_relation_size(i2.indexrelid)) size,
pg_get_indexdef(i1.indexrelid) main_index_def,
pg_get_indexdef(i2.indexrelid) index_def,
pg_size_pretty(pg_relation_size(i2.indexrelid)) index_size,
s.idx_scan as index_usage,
i2.indexrelid
from
index_data as i1
join index_data as i2 on i1.indrelid = i2.indrelid and i1.indexrelid <> i2.indexrelid
join index_data as i2 on (
i1.indrelid = i2.indrelid /* same table */
and i1.indexrelid <> i2.indexrelid /* NOT same index */
)
inner join pg_opclass op1 on i1.indclass[0] = op1.oid
inner join pg_opclass op2 on i2.indclass[0] = op2.oid
inner join pg_am am1 on op1.opcmethod = am1.oid
inner join pg_am am2 on op2.opcmethod = am2.oid
join pg_stat_user_indexes as s on s.indexrelid = i2.indexrelid
where
(regexp_replace(i1.indpred, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indpred, 'location \d+', 'location', 'g'))
and (regexp_replace(i1.indexprs, 'location \d+', 'location', 'g') IS NOT DISTINCT FROM regexp_replace(i2.indexprs, 'location \d+', 'location', 'g'))
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))))
and i1.key_array[1:i2.nkeys]=i2.key_array
not i1.indisprimary -- index 1 is not primary
and not ( -- skip if index1 is (primary or uniq) and is NOT (primary and uniq)
(i1.indisprimary or i1.indisunique)
and (not i2.indisprimary or not i2.indisunique)
)
and am1.amname = am2.amname -- same access type
and (
i2.columns like (i1.columns || '%') -- index 2 includes all columns from index 1
or i1.columns = i2.columns -- index1 and index 2 includes same columns
)
and (
i2.opclasses like (i1.opclasses || '%')
or i1.opclasses = i2.opclasses
)
-- index expressions are same
and pg_get_expr(i1.indexprs, i1.indrelid) is not distinct from pg_get_expr(i2.indexprs, i2.indrelid)
-- index predicates are same
and pg_get_expr(i1.indpred, i1.indrelid) is not distinct from pg_get_expr(i2.indpred, i2.indrelid)
), together as (
select reason, tablename, indexname, size, indexdef, null as main_indexdef, indexrelid
select reason, table_name, index_name, index_size, index_def, null as main_index_def, indexrelid
from unused
union all
select reason, tablename, indexname, size, indexdef, main_indexdef, indexrelid
select reason, table_name, index_name, index_size, index_def, main_index_def, indexrelid
from redundant
order by tablename asc, indexname
where index_usage = 0
), droplines as (
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(indexname), max(size), string_agg(reason, ', '), tablename) as line
select format('DROP INDEX CONCURRENTLY %s; -- %s, %s, table %s', max(index_name), max(index_size), string_agg(reason, ', '), table_name) as line
from together t1
group by tablename, indexrelid
order by tablename, indexrelid
group by table_name, index_name
order by table_name, index_name
), createlines as (
select
replace(
format('%s; -- table %s', max(indexdef), tablename),
format('%s; -- table %s', max(index_def), table_name),
'CREATE INDEX',
'CREATE INDEX CONCURRENTLY'
)as line
from together t2
group by tablename, indexrelid
order by tablename, indexrelid
group by table_name, index_name
order by table_name, index_name
)
select '-- Do migration: --' as run_in_separate_transactions
union all
Expand Down

0 comments on commit 3aa01ee

Please # to comment.