From 55d8d4f14dbe130ffb3e0b60a2ccecb56d4d96ab Mon Sep 17 00:00:00 2001 From: jsmith Date: Wed, 4 May 2022 14:56:55 +0000 Subject: [PATCH] Add 'PostgreSQL/monitoring/bloat.sql' --- PostgreSQL/monitoring/bloat.sql | 47 +++++++++++++++++++++++++++++++++ 1 file changed, 47 insertions(+) create mode 100644 PostgreSQL/monitoring/bloat.sql diff --git a/PostgreSQL/monitoring/bloat.sql b/PostgreSQL/monitoring/bloat.sql new file mode 100644 index 0000000..b0f7fb0 --- /dev/null +++ b/PostgreSQL/monitoring/bloat.sql @@ -0,0 +1,47 @@ +with foo as ( + 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 +), rs as ( + 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 foo +), sml as ( + 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 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 +) + +SELECT + current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,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::FLOAT/iotta END)::NUMERIC,1) AS ibloat, + CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes +FROM sml +ORDER BY wastedbytes DESC