|
| 1 | +-- Credit: https://github.com/ioguix/pgsql-bloat-estimation/tree/master/table |
| 2 | +-- minor tweaks to exclude pg tables |
| 3 | +/* WARNING: executed with a non-superuser role, the query inspect only tables and materialized view (9.3+) you are granted to read. |
| 4 | +* This query is compatible with PostgreSQL 9.0 and more |
| 5 | +*/ |
| 6 | +SELECT current_database(), schemaname, tblname, bs*tblpages AS real_size, |
| 7 | + (tblpages-est_tblpages)*bs AS extra_size, |
| 8 | + CASE WHEN tblpages - est_tblpages > 0 |
| 9 | + THEN 100 * (tblpages - est_tblpages)/tblpages::float |
| 10 | + ELSE 0 |
| 11 | + END AS extra_pct, fillfactor, |
| 12 | + CASE WHEN tblpages - est_tblpages_ff > 0 |
| 13 | + THEN (tblpages-est_tblpages_ff)*bs |
| 14 | + ELSE 0 |
| 15 | + END AS bloat_size, |
| 16 | + CASE WHEN tblpages - est_tblpages_ff > 0 |
| 17 | + THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float |
| 18 | + ELSE 0 |
| 19 | + END AS bloat_pct, is_na |
| 20 | + -- , tpl_hdr_size, tpl_data_size, (pst).free_percent + (pst).dead_tuple_percent AS real_frag -- (DEBUG INFO) |
| 21 | +FROM ( |
| 22 | + SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages, |
| 23 | + ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff, |
| 24 | + tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na |
| 25 | + -- , tpl_hdr_size, tpl_data_size, pgstattuple(tblid) AS pst -- (DEBUG INFO) |
| 26 | + FROM ( |
| 27 | + SELECT |
| 28 | + ( 4 + tpl_hdr_size + tpl_data_size + (2*ma) |
| 29 | + - CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END |
| 30 | + - CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END |
| 31 | + ) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages, |
| 32 | + toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na |
| 33 | + -- , tpl_hdr_size, tpl_data_size |
| 34 | + FROM ( |
| 35 | + SELECT |
| 36 | + tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples, |
| 37 | + tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages, |
| 38 | + coalesce(toast.reltuples, 0) AS toasttuples, |
| 39 | + coalesce(substring( |
| 40 | + array_to_string(tbl.reloptions, ' ') |
| 41 | + FROM 'fillfactor=([0-9]+)')::smallint, 100) AS fillfactor, |
| 42 | + current_setting('block_size')::numeric AS bs, |
| 43 | + CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma, |
| 44 | + 24 AS page_hdr, |
| 45 | + 23 + CASE WHEN MAX(coalesce(s.null_frac,0)) > 0 THEN ( 7 + count(s.attname) ) / 8 ELSE 0::int END |
| 46 | + + CASE WHEN bool_or(att.attname = 'oid' and att.attnum < 0) THEN 4 ELSE 0 END AS tpl_hdr_size, |
| 47 | + sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0) ) AS tpl_data_size, |
| 48 | + bool_or(att.atttypid = 'pg_catalog.name'::regtype) |
| 49 | + OR sum(CASE WHEN att.attnum > 0 THEN 1 ELSE 0 END) <> count(s.attname) AS is_na |
| 50 | + FROM pg_attribute AS att |
| 51 | + JOIN pg_class AS tbl ON att.attrelid = tbl.oid |
| 52 | + JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace |
| 53 | + LEFT JOIN pg_stats AS s ON s.schemaname=ns.nspname |
| 54 | + AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname |
| 55 | + LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid |
| 56 | + WHERE NOT att.attisdropped |
| 57 | + AND tbl.relname not like '%pg%' |
| 58 | + AND tbl.relkind in ('r','m') |
| 59 | + GROUP BY 1,2,3,4,5,6,7,8,9,10 |
| 60 | + ORDER BY 2,3 |
| 61 | + ) AS s |
| 62 | + ) AS s2 |
| 63 | +) AS s3 |
| 64 | +-- WHERE NOT is_na |
| 65 | +-- AND tblpages*((pst).free_percent + (pst).dead_tuple_percent)::float4/100 >= 1 |
| 66 | +ORDER BY bloat_pct DESC; |
0 commit comments