|
| 1 | +-- enhanced version of https://github.com/ioguix/pgsql-bloat-estimation/blob/master/btree/btree_bloat.sql |
| 2 | + |
| 3 | +-- WARNING: executed with a non-superuser role, the query inspect only index on tables you are granted to read. |
| 4 | +-- WARNING: rows with is_na = 't' are known to have bad statistics ("name" type is not supported). |
| 5 | +-- This query is compatible with PostgreSQL 8.2 and after |
| 6 | + |
| 7 | + with data as ( |
| 8 | + SELECT current_database(), nspname AS schemaname, tblname, idxname, bs*(relpages)::bigint AS real_size, |
| 9 | + bs*(relpages-est_pages)::bigint AS extra_size, |
| 10 | + 100 * (relpages-est_pages)::float / relpages AS extra_ratio, |
| 11 | + fillfactor, bs*(relpages-est_pages_ff) AS bloat_size, |
| 12 | + 100 * (relpages-est_pages_ff)::float / relpages AS bloat_ratio, |
| 13 | + is_na |
| 14 | + -- , 100-(sub.pst).avg_leaf_density, est_pages, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, sub.reltuples, sub.relpages -- (DEBUG INFO) |
| 15 | + FROM ( |
| 16 | + SELECT coalesce(1 + |
| 17 | + ceil(reltuples/floor((bs-pageopqdata-pagehdr)/(4+nulldatahdrwidth)::float)), 0 -- ItemIdData size + computed avg size of a tuple (nulldatahdrwidth) |
| 18 | + ) AS est_pages, |
| 19 | + coalesce(1 + |
| 20 | + ceil(reltuples/floor((bs-pageopqdata-pagehdr)*fillfactor/(100*(4+nulldatahdrwidth)::float))), 0 |
| 21 | + ) AS est_pages_ff, |
| 22 | + bs, nspname, table_oid, tblname, idxname, relpages, fillfactor, is_na |
| 23 | + -- , stattuple.pgstatindex(quote_ident(nspname)||'.'||quote_ident(idxname)) AS pst, index_tuple_hdr_bm, maxalign, pagehdr, nulldatawidth, nulldatahdrwidth, reltuples -- (DEBUG INFO) |
| 24 | + FROM ( |
| 25 | + SELECT maxalign, bs, nspname, tblname, idxname, reltuples, relpages, relam, table_oid, fillfactor, |
| 26 | + ( index_tuple_hdr_bm + |
| 27 | + maxalign - CASE -- Add padding to the index tuple header to align on MAXALIGN |
| 28 | + WHEN index_tuple_hdr_bm%maxalign = 0 THEN maxalign |
| 29 | + ELSE index_tuple_hdr_bm%maxalign |
| 30 | + END |
| 31 | + + nulldatawidth + maxalign - CASE -- Add padding to the data to align on MAXALIGN |
| 32 | + WHEN nulldatawidth = 0 THEN 0 |
| 33 | + WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign |
| 34 | + ELSE nulldatawidth::integer%maxalign |
| 35 | + END |
| 36 | + )::numeric AS nulldatahdrwidth, pagehdr, pageopqdata, is_na |
| 37 | + -- , index_tuple_hdr_bm, nulldatawidth -- (DEBUG INFO) |
| 38 | + FROM ( |
| 39 | + SELECT |
| 40 | + i.nspname, i.tblname, i.idxname, i.reltuples, i.relpages, i.relam, a.attrelid AS table_oid, |
| 41 | + current_setting('block_size')::numeric AS bs, fillfactor, |
| 42 | + CASE -- MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) |
| 43 | + WHEN version() ~ 'mingw32' OR version() ~ '64-bit|x86_64|ppc64|ia64|amd64' THEN 8 |
| 44 | + ELSE 4 |
| 45 | + END AS maxalign, |
| 46 | + /* per page header, fixed size: 20 for 7.X, 24 for others */ |
| 47 | + 24 AS pagehdr, |
| 48 | + /* per page btree opaque data */ |
| 49 | + 16 AS pageopqdata, |
| 50 | + /* per tuple header: add IndexAttributeBitMapData if some cols are null-able */ |
| 51 | + CASE WHEN max(coalesce(s.null_frac,0)) = 0 |
| 52 | + THEN 2 -- IndexTupleData size |
| 53 | + ELSE 2 + (( 32 + 8 - 1 ) / 8) -- IndexTupleData size + IndexAttributeBitMapData size ( max num filed per index + 8 - 1 /8) |
| 54 | + END AS index_tuple_hdr_bm, |
| 55 | + /* data len: we remove null values save space using it fractionnal part from stats */ |
| 56 | + sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024)) AS nulldatawidth, |
| 57 | + max( CASE WHEN a.atttypid = 'pg_catalog.name'::regtype THEN 1 ELSE 0 END ) > 0 AS is_na |
| 58 | + FROM pg_attribute AS a |
| 59 | + JOIN ( |
| 60 | + SELECT nspname, tbl.relname AS tblname, idx.relname AS idxname, idx.reltuples, idx.relpages, idx.relam, |
| 61 | + indrelid, indexrelid, indkey::smallint[] AS attnum, |
| 62 | + coalesce(substring( |
| 63 | + array_to_string(idx.reloptions, ' ') |
| 64 | + from 'fillfactor=([0-9]+)')::smallint, 90) AS fillfactor |
| 65 | + FROM pg_index |
| 66 | + JOIN pg_class idx ON idx.oid=pg_index.indexrelid |
| 67 | + JOIN pg_class tbl ON tbl.oid=pg_index.indrelid |
| 68 | + JOIN pg_namespace ON pg_namespace.oid = idx.relnamespace |
| 69 | + WHERE pg_index.indisvalid AND tbl.relkind = 'r' AND idx.relpages > 0 |
| 70 | + ) AS i ON a.attrelid = i.indexrelid |
| 71 | + JOIN pg_stats AS s ON s.schemaname = i.nspname |
| 72 | + AND ((s.tablename = i.tblname AND s.attname = pg_catalog.pg_get_indexdef(a.attrelid, a.attnum, TRUE)) -- stats from tbl |
| 73 | + OR (s.tablename = i.idxname AND s.attname = a.attname))-- stats from functionnal cols |
| 74 | + JOIN pg_type AS t ON a.atttypid = t.oid |
| 75 | + WHERE a.attnum > 0 |
| 76 | + GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9 |
| 77 | + ) AS s1 |
| 78 | + ) AS s2 |
| 79 | + JOIN pg_am am ON s2.relam = am.oid WHERE am.amname = 'btree' |
| 80 | + ) AS sub |
| 81 | + -- WHERE NOT is_na |
| 82 | +) |
| 83 | +select |
| 84 | + current_database, schemaname, tblname, idxname, |
| 85 | + real_size, pg_size_pretty(real_size::numeric) as real_size_pretty, |
| 86 | + extra_size, pg_size_pretty(extra_size::numeric) as extra_size_pretty, |
| 87 | + extra_ratio as "extra_ratio, %", |
| 88 | + bloat_size, pg_size_pretty(bloat_size::numeric) as bloat_size_pretty, |
| 89 | + bloat_ratio as "bloat_ratio, %", |
| 90 | + fillfactor, |
| 91 | + is_na, |
| 92 | + real_size - bloat_size as live_data_size |
| 93 | +from data |
| 94 | +order by bloat_size desc |
| 95 | +; |
| 96 | + |
0 commit comments