diff --git a/sql/index_bloat.sql b/sql/index_bloat.sql index 67a9182..e11d52a 100644 --- a/sql/index_bloat.sql +++ b/sql/index_bloat.sql @@ -1,10 +1,9 @@ ---pgstattuple extension required ---WARNING: without index name/mask query will read all available indexes which could cause I/O spikes +\prompt 'This utility will read indexes with given mask using pgstattuple extension and return top 100 bloated indexes.\nWARNING: without index mask query will read all available indexes which could cause I/O spikes.\nPlease enter mask for index name (check all indexes if nothing is specified): ' indexname + with indexes as ( select * from pg_stat_user_indexes ) -select schemaname, -table_name, +select table_name, pg_size_pretty(table_size) as table_size, index_name, pg_size_pretty(index_size) as index_size, @@ -12,8 +11,9 @@ idx_scan as index_scans, round((free_space*100/index_size)::numeric, 1) as waste_percent, pg_size_pretty(free_space) as waste from ( - select schemaname, p.relname as table_name, indexrelname as index_name, - (select (case when avg_leaf_density = 'NaN' then 0 + select (case when schemaname = 'public' then format('%I', p.relname) else format('%I.%I', schemaname, p.relname) end) as table_name, + indexrelname as index_name, + (select (case when avg_leaf_density = 'NaN' then 0 else greatest(ceil(index_size * (1 - avg_leaf_density / (coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'90')::real)))::bigint, 0) end) from pgstatindex(p.indexrelid::regclass::text) ) as free_space, @@ -26,6 +26,7 @@ from ( where pg_get_indexdef(p.indexrelid) like '%USING btree%' and i.indisvalid and (c.relpersistence = 'p' or not pg_is_in_recovery()) and --put your index name/mask here - indexrelname ~ '' + indexrelname ~ :'indexname' ) t -order by free_space desc; \ No newline at end of file +order by free_space desc +limit 100; \ No newline at end of file diff --git a/sql/table_bloat.sql b/sql/table_bloat.sql index 61ab172..7b81d2c 100644 --- a/sql/table_bloat.sql +++ b/sql/table_bloat.sql @@ -1,7 +1,7 @@ +\prompt 'This utility will read tables with given mask using pgstattuple extension and return top 20 bloated tables.\nWARNING: without table mask query will read all available tables which could cause I/O spikes.\nPlease enter mask for table name (check all tables if nothing is specified): ' tablename --pgstattuple extension required --WARNING: without table name/mask query will read all available tables which could cause I/O spikes -select nspname, -relname, +select table_name, pg_size_pretty(relation_size + toast_relation_size) as total_size, pg_size_pretty(toast_relation_size) as toast_size, round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) table_waste_percent, @@ -9,7 +9,8 @@ pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bi round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) total_waste_percent, pg_size_pretty((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)::bigint) total_waste from ( - select nspname, relname, + select + (case when n.nspname = 'public' then format('%I', c.relname) else format('%I.%I', n.nspname, c.relname) end) as table_name, (select free_space from pgstattuple(c.oid)) as free_space, pg_relation_size(c.oid) as relation_size, (case when reltoastrelid = 0 then 0 else (select free_space from pgstattuple(c.reltoastrelid)) end) as toast_free_space, @@ -20,7 +21,7 @@ from ( where nspname not in ('pg_catalog', 'information_schema') and nspname !~ '^pg_toast' and nspname !~ '^pg_temp' and relkind in ('r', 'm') and (relpersistence = 'p' or not pg_is_in_recovery()) --put your table name/mask here - and relname ~ '' + and relname ~ :'tablename' ) t order by (toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor) desc limit 20; \ No newline at end of file