From 40f34380a89b10118686f9bdad74dedfc624c212 Mon Sep 17 00:00:00 2001 From: dmius Date: Thu, 17 Jan 2019 01:43:33 +0300 Subject: [PATCH 01/12] Report i2 and i5 reworked, i1 improved. --- sql/i1_rare_indexes.sql | 13 +++++- sql/i2_redundant_indexes.sql | 52 ++++++++++++++++++------ sql/i5_indexes_migration.sql | 76 ++++++++++++++++++++++++------------ 3 files changed, 102 insertions(+), 39 deletions(-) diff --git a/sql/i1_rare_indexes.sql b/sql/i1_rare_indexes.sql index e94f3e4..fdd0658 100644 --- a/sql/i1_rare_indexes.sql +++ b/sql/i1_rare_indexes.sql @@ -76,7 +76,16 @@ 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 +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; diff --git a/sql/i2_redundant_indexes.sql b/sql/i2_redundant_indexes.sql index 2801247..7d481d7 100644 --- a/sql/i2_redundant_indexes.sql +++ b/sql/i2_redundant_indexes.sql @@ -10,25 +10,51 @@ -- 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 + 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, - 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 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 index2 is primary or unique + (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 include all columns from index 1 + or i1.columns = i2.columns -- index1 and index 2 include 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; - diff --git a/sql/i5_indexes_migration.sql b/sql/i5_indexes_migration.sql index 96c5b6d..3467d5c 100644 --- a/sql/i5_indexes_migration.sql +++ b/sql/i5_indexes_migration.sql @@ -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 @@ -50,47 +50,75 @@ 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 index2 is primary or unique + (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 include all columns from index 1 + or i1.columns = i2.columns -- index1 and index 2 include 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) ), 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 + order by table_name asc, index_name ), 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, indexrelid + order by table_name, indexrelid ), 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, indexrelid + order by table_name, indexrelid ) select '-- Do migration: --' as run_in_separate_transactions union all From bbfd94d82ebba379bb7bc7fb9108b62e9ae5951c Mon Sep 17 00:00:00 2001 From: dmius Date: Thu, 17 Jan 2019 17:33:31 +0300 Subject: [PATCH 02/12] i2 generation value of _name columns reworked --- sql/i2_redundant_indexes.sql | 8 ++++++-- 1 file changed, 6 insertions(+), 2 deletions(-) diff --git a/sql/i2_redundant_indexes.sql b/sql/i2_redundant_indexes.sql index 7d481d7..9ce20ef 100644 --- a/sql/i2_redundant_indexes.sql +++ b/sql/i2_redundant_indexes.sql @@ -17,8 +17,9 @@ with index_data as ( from pg_index ), redundant as ( select - i2.indrelid::regclass::text as table_name, - i2.indexrelid::regclass::text as index_name, + 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, pg_get_indexdef(i1.indexrelid) main_index_def, @@ -37,6 +38,9 @@ with index_data as ( 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 not i1.indisprimary -- index 1 is not primary and not ( -- skip if index1 is primary or uniq and index2 is primary or unique From fa4beb3fd1aa8804457086d9faa5bd4d917018ff Mon Sep 17 00:00:00 2001 From: dmius Date: Fri, 18 Jan 2019 19:52:09 +0300 Subject: [PATCH 03/12] Drop and revert code added for invalid indexes --- sql/i4_invalid_indexes.sql | 8 +++++++- 1 file changed, 7 insertions(+), 1 deletion(-) diff --git a/sql/i4_invalid_indexes.sql b/sql/i4_invalid_indexes.sql index 0566c7a..895708c 100644 --- a/sql/i4_invalid_indexes.sql +++ b/sql/i4_invalid_indexes.sql @@ -13,7 +13,13 @@ 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, + 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 From 8e40d2345a54e2e6ed6605c0061e3bfd76fa032f Mon Sep 17 00:00:00 2001 From: dmius Date: Mon, 21 Jan 2019 08:37:14 +0300 Subject: [PATCH 04/12] Index size added to i4:invalid indexes report --- sql/i4_invalid_indexes.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/sql/i4_invalid_indexes.sql b/sql/i4_invalid_indexes.sql index 895708c..4969347 100644 --- a/sql/i4_invalid_indexes.sql +++ b/sql/i4_invalid_indexes.sql @@ -14,6 +14,7 @@ select pci.relname as index_name, pn.nspname as schema_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), From 45f54d2dae5e88e04742147cfbe1dc0115411a1a Mon Sep 17 00:00:00 2001 From: dmius Date: Wed, 23 Jan 2019 18:41:42 +0300 Subject: [PATCH 05/12] b1: fillfactor column added --- sql/b1_table_estimation.sql | 8 +++++++- 1 file changed, 7 insertions(+), 1 deletion(-) diff --git a/sql/b1_table_estimation.sql b/sql/b1_table_estimation.sql index b37bbc3..5c844e3 100644 --- a/sql/b1_table_estimation.sql +++ b/sql/b1_table_estimation.sql @@ -75,7 +75,13 @@ select 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 ; From 56eded56e7ebfba3f20d7d455d8f84bd725affaf Mon Sep 17 00:00:00 2001 From: dmius Date: Thu, 24 Jan 2019 08:28:55 +0300 Subject: [PATCH 06/12] b1: Column fillfactor renamed --- sql/b1_table_estimation.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/b1_table_estimation.sql b/sql/b1_table_estimation.sql index 5c844e3..31099b6 100644 --- a/sql/b1_table_estimation.sql +++ b/sql/b1_table_estimation.sql @@ -81,7 +81,7 @@ select coalesce(substring(array_to_string(reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 100) from pg_class where oid = tblid - ) as fillfactor + ) as "Fill Factor" from step4 order by real_size desc nulls last ; From 5ba8c4754b8b67400434bc371197aba2137a4f6d Mon Sep 17 00:00:00 2001 From: dmius Date: Thu, 24 Jan 2019 14:03:38 +0300 Subject: [PATCH 07/12] b1: Column fillfactor renamed --- sql/b1_table_estimation.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/b1_table_estimation.sql b/sql/b1_table_estimation.sql index 31099b6..64b6564 100644 --- a/sql/b1_table_estimation.sql +++ b/sql/b1_table_estimation.sql @@ -81,7 +81,7 @@ select coalesce(substring(array_to_string(reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 100) from pg_class where oid = tblid - ) as "Fill Factor" + ) as "Fillfactor" from step4 order by real_size desc nulls last ; From f1effb54dcfcc7075960a3a51a412d4d2796064a Mon Sep 17 00:00:00 2001 From: dmius Date: Fri, 25 Jan 2019 08:43:26 +0300 Subject: [PATCH 08/12] b1: Bloat > Bloat estimate, b1,b2: '-' instead negative value of bloat, extra and live --- sql/b1_table_estimation.sql | 20 ++++++++++++++++---- sql/b2_btree_estimation.sql | 18 +++++++++++++++--- 2 files changed, 31 insertions(+), 7 deletions(-) diff --git a/sql/b1_table_estimation.sql b/sql/b1_table_estimation.sql index 64b6564..af9dc76 100644 --- a/sql/b1_table_estimation.sql +++ b/sql/b1_table_estimation.sql @@ -69,9 +69,21 @@ 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 '-' + end as "Extra", + case + when bloat_size::numeric >= 0 + then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' + else '-' + end as "Bloat estimate", + case + when (real_size - bloat_size)::numeric >=0 + then '~' || pg_size_pretty((real_size - bloat_size)::numeric) + else '-' + end as "Live", greatest(last_autovacuum, last_vacuum)::timestamp(0)::text || case greatest(last_autovacuum, last_vacuum) when last_autovacuum then ' (auto)' @@ -83,7 +95,7 @@ select where oid = tblid ) as "Fillfactor" from step4 -order by real_size desc nulls last +order by bloat_size desc nulls last ; /* diff --git a/sql/b2_btree_estimation.sql b/sql/b2_btree_estimation.sql index 56b81d5..afd84c7 100644 --- a/sql/b2_btree_estimation.sql +++ b/sql/b2_btree_estimation.sql @@ -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 '-' + end as "Extra", + case + when bloat_size::numeric >= 0 + then '~' || pg_size_pretty(bloat_size::numeric)::text || ' (' || round(bloat_ratio::numeric, 2)::text || '%)' + else '-' + end as "Bloat", + case + when (real_size - bloat_size)::numeric >=0 + then '~' || pg_size_pretty((real_size - bloat_size)::numeric) + else '-' + end as "Live", fillfactor from step4 order by real_size desc nulls last From 97565f88778ff96532cce988cd389afefc3a340f Mon Sep 17 00:00:00 2001 From: dmius Date: Fri, 25 Jan 2019 20:48:41 +0300 Subject: [PATCH 09/12] i1 raw index and table size added --- sql/i1_rare_indexes.sql | 9 ++++++--- 1 file changed, 6 insertions(+), 3 deletions(-) diff --git a/sql/i1_rare_indexes.sql b/sql/i1_rare_indexes.sql index fdd0658..1a8169c 100644 --- a/sql/i1_rare_indexes.sql +++ b/sql/i1_rare_indexes.sql @@ -39,6 +39,7 @@ SELECT schemaname, tablename, indexname, as scans_per_write, pg_size_pretty(index_bytes) as index_size, pg_size_pretty(table_size) as table_size, + table_size as table_bytes, idx_is_btree, index_bytes FROM indexes JOIN table_scans @@ -84,8 +85,10 @@ SELECT index_scan_pct, scans_per_write, index_size, - table_size, idx_scan, - all_scans -FROM index_groups; + all_scans, + index_bytes, + table_bytes +FROM index_groups +; From e6978c2f043d39dd13c8124026f1fda8d6242230 Mon Sep 17 00:00:00 2001 From: dmius Date: Fri, 25 Jan 2019 21:05:04 +0300 Subject: [PATCH 10/12] i1 pretty table size reverted --- sql/i1_rare_indexes.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/sql/i1_rare_indexes.sql b/sql/i1_rare_indexes.sql index 1a8169c..b51eb5a 100644 --- a/sql/i1_rare_indexes.sql +++ b/sql/i1_rare_indexes.sql @@ -85,6 +85,7 @@ SELECT index_scan_pct, scans_per_write, index_size, + table_size, idx_scan, all_scans, index_bytes, From 123a9636c5b24f069ee561b86760d50015ba2ae9 Mon Sep 17 00:00:00 2001 From: dmius Date: Fri, 25 Jan 2019 21:42:38 +0300 Subject: [PATCH 11/12] i1 *_bytes reverted --- sql/i1_rare_indexes.sql | 5 +---- 1 file changed, 1 insertion(+), 4 deletions(-) diff --git a/sql/i1_rare_indexes.sql b/sql/i1_rare_indexes.sql index b51eb5a..ccc49c2 100644 --- a/sql/i1_rare_indexes.sql +++ b/sql/i1_rare_indexes.sql @@ -39,7 +39,6 @@ SELECT schemaname, tablename, indexname, as scans_per_write, pg_size_pretty(index_bytes) as index_size, pg_size_pretty(table_size) as table_size, - table_size as table_bytes, idx_is_btree, index_bytes FROM indexes JOIN table_scans @@ -87,9 +86,7 @@ SELECT index_size, table_size, idx_scan, - all_scans, - index_bytes, - table_bytes + all_scans FROM index_groups ; From b7d33bb8fe9e7ce16300a8d5c3367b7c92599d31 Mon Sep 17 00:00:00 2001 From: dmius Date: Mon, 28 Jan 2019 09:06:03 +0300 Subject: [PATCH 12/12] PR remarks fixed --- sql/b1_table_estimation.sql | 6 +++--- sql/b2_btree_estimation.sql | 6 +++--- sql/i2_redundant_indexes.sql | 6 +++--- sql/i4_invalid_indexes.sql | 6 +++++- sql/i5_indexes_migration.sql | 19 +++++++++---------- 5 files changed, 23 insertions(+), 20 deletions(-) diff --git a/sql/b1_table_estimation.sql b/sql/b1_table_estimation.sql index af9dc76..2e456ba 100644 --- a/sql/b1_table_estimation.sql +++ b/sql/b1_table_estimation.sql @@ -72,17 +72,17 @@ select case when extra_size::numeric >= 0 then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' - else '-' + 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 '-' + else null end as "Bloat estimate", case when (real_size - bloat_size)::numeric >=0 then '~' || pg_size_pretty((real_size - bloat_size)::numeric) - else '-' + else null end as "Live", greatest(last_autovacuum, last_vacuum)::timestamp(0)::text || case greatest(last_autovacuum, last_vacuum) diff --git a/sql/b2_btree_estimation.sql b/sql/b2_btree_estimation.sql index afd84c7..6da0e17 100644 --- a/sql/b2_btree_estimation.sql +++ b/sql/b2_btree_estimation.sql @@ -104,17 +104,17 @@ select case when extra_size::numeric >= 0 then '~' || pg_size_pretty(extra_size::numeric)::text || ' (' || round(extra_ratio::numeric, 2)::text || '%)' - else '-' + 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 '-' + else null end as "Bloat", case when (real_size - bloat_size)::numeric >=0 then '~' || pg_size_pretty((real_size - bloat_size)::numeric) - else '-' + else null end as "Live", fillfactor from step4 diff --git a/sql/i2_redundant_indexes.sql b/sql/i2_redundant_indexes.sql index 9ce20ef..53ea132 100644 --- a/sql/i2_redundant_indexes.sql +++ b/sql/i2_redundant_indexes.sql @@ -43,14 +43,14 @@ with index_data as ( join pg_class as irel on irel.oid = i2.indexrelid where not i1.indisprimary -- index 1 is not primary - and not ( -- skip if index1 is primary or uniq and index2 is primary or unique + 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 include all columns from index 1 - or i1.columns = i2.columns -- index1 and index 2 include same columns + 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 || '%') diff --git a/sql/i4_invalid_indexes.sql b/sql/i4_invalid_indexes.sql index 4969347..cf79739 100644 --- a/sql/i4_invalid_indexes.sql +++ b/sql/i4_invalid_indexes.sql @@ -15,7 +15,11 @@ select pn.nspname as schema_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, + 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', diff --git a/sql/i5_indexes_migration.sql b/sql/i5_indexes_migration.sql index 3467d5c..cda8141 100644 --- a/sql/i5_indexes_migration.sql +++ b/sql/i5_indexes_migration.sql @@ -79,22 +79,22 @@ with unused as ( join pg_stat_user_indexes as s on s.indexrelid = i2.indexrelid where not i1.indisprimary -- index 1 is not primary - and not ( -- skip if index1 is primary or uniq and index2 is primary or unique + 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 include all columns from index 1 - or i1.columns = i2.columns -- index1 and index 2 include same columns + 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 + -- 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 is same + -- 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, table_name, index_name, index_size, index_def, null as main_index_def, indexrelid @@ -103,12 +103,11 @@ with unused as ( select reason, table_name, index_name, index_size, index_def, main_index_def, indexrelid from redundant where index_usage = 0 - order by table_name asc, index_name ), droplines as ( 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 table_name, indexrelid - order by table_name, indexrelid + group by table_name, index_name + order by table_name, index_name ), createlines as ( select replace( @@ -117,8 +116,8 @@ with unused as ( 'CREATE INDEX CONCURRENTLY' )as line from together t2 - group by table_name, indexrelid - order by table_name, indexrelid + group by table_name, index_name + order by table_name, index_name ) select '-- Do migration: --' as run_in_separate_transactions union all