Browse Source

table_bloat_approx.sql: add table mask prompt, combine table and schema names. index_candidates_to_partial.sql: fix typo

pull/12/head
Alexey Ermakov 3 years ago
parent
commit
f7d9d90dfa
  1. 2
      sql/index_candidates_to_partial.sql
  2. 9
      sql/table_bloat_approx.sql

2
sql/index_candidates_to_partial.sql

@ -14,6 +14,6 @@ FROM pg_index @@ -14,6 +14,6 @@ FROM pg_index
JOIN pg_attribute ON pg_attribute.attrelid = pg_index.indrelid AND pg_attribute.attnum = ANY(pg_index.indkey)
JOIN pg_stats ON (pg_stats.schemaname || '.' || pg_stats.tablename)::regclass = pg_attribute.attrelid AND pg_stats.attname = pg_attribute.attname
WHERE pg_relation_size(pg_index.indexrelid) > 10*8192
AND (SELECt SUM(a) FROM unnest(most_common_freqs[1:5]) a) >= 0.95
AND (SELECT SUM(a) FROM unnest(most_common_freqs[1:5]) a) >= 0.95
AND array_length(pg_index.indkey, 1) = 1
ORDER BY pg_relation_size(pg_index.indexrelid) DESC,1,2,3;

9
sql/table_bloat_approx.sql

@ -1,8 +1,8 @@ @@ -1,8 +1,8 @@
\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
--faster version of table_bloat.sql which returns approximate results and doesn't read whole table (but reads toast tables)
--pgstattuple v1.3+ extension required (available since postgresql 9.5)
--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,
@ -10,7 +10,8 @@ pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bi @@ -10,7 +10,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 approx_free_space from pgstattuple_approx(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,
@ -21,7 +22,7 @@ from ( @@ -21,7 +22,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;
Loading…
Cancel
Save