Skip to content

Instantly share code, notes, and snippets.

@sebastianwebber
Created September 30, 2014 18:19
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save sebastianwebber/199ac0204c9e4c5677e0 to your computer and use it in GitHub Desktop.
Save sebastianwebber/199ac0204c9e4c5677e0 to your computer and use it in GitHub Desktop.
Views to generate pg_repack command line and show bloat tables
-- the original
-- avaliable on: https://wiki.postgresql.org/wiki/Show_database_bloat
CREATE VIEW vw_bloat_objects AS
SELECT
current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/
ROUND(CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages/otta::numeric END,1) AS tbloat,
CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::bigint END AS wastedbytes,
iname, /*ituples::bigint, ipages::bigint, iotta,*/
ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS ibloat,
CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes
FROM (
SELECT
schemaname, tablename, cc.reltuples, cc.relpages, bs,
CEIL((cc.reltuples*((datahdr+ma-
(CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta,
COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages,
COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols
FROM (
SELECT
ma,bs,schemaname,tablename,
(datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr,
(maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2
FROM (
SELECT
schemaname, tablename, hdr, ma, bs,
SUM((1-null_frac)*avg_width) AS datawidth,
MAX(null_frac) AS maxfracsum,
hdr+(
SELECT 1+count(*)/8
FROM pg_stats s2
WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename
) AS nullhdr
FROM pg_stats s, (
SELECT
(SELECT current_setting('block_size')::numeric) AS bs,
CASE WHEN substring(v,12,3) IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr,
CASE WHEN v ~ 'mingw32' THEN 8 ELSE 4 END AS ma
FROM (SELECT version() AS v) AS foo
) AS constants
GROUP BY 1,2,3,4,5
) AS foo
) AS rs
JOIN pg_class cc ON cc.relname = rs.tablename
JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname AND nn.nspname <> 'information_schema'
LEFT JOIN pg_index i ON indrelid = cc.oid
LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid
) AS sml
ORDER BY wastedbytes DESC;
-- shows only table information
CREATE VIEW vw_bloat_tables AS
SELECT DISTINCT
current_database,
schemaname,
tablename,
tbloat,
wastedbytes
FROM vw_bloat_objects
WHERE schemaname NOT IN ('pg_catalog', 'information_schema')
AND schemaname !~ '^pg_toast';
-- generates pg_repack cmd
CREATE VIEW vw_bloat_tables_repackcmd AS
SELECT
'pg_repack ' ||
' --username=' || current_user ||
' --dbname=' || current_database ||
' --table=' || schemaname || '.' || tablename ||
' --order-by=\'' ||
(
SELECT
array_to_string(array_agg(cols.attname), ',')
FROM (
SELECT
pg_attribute.attname
FROM pg_index, pg_class, pg_attribute
WHERE pg_class.oid = (vw_bloat_tables.schemaname || '.' || vw_bloat_tables.tablename)::regclass
AND indrelid = pg_class.oid
AND pg_attribute.attrelid = pg_class.oid
AND pg_attribute.attnum = any(pg_index.indkey)
AND indisprimary
ORDER BY pg_attribute.attnum
) as cols
) || '\' -e ' as cmd
FROM vw_bloat_tables;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment