Skip to content

Commit 64adbf8

Browse files
committed
bloat estimation
1 parent f5bb3ff commit 64adbf8

File tree

5 files changed

+255
-2
lines changed

5 files changed

+255
-2
lines changed

bloat/btree_estimation.sql

Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
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+

bloat/index_pgstattuple.sql

Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,31 @@
1+
--https://github.com/dataegret/pg-utils/tree/master/sql
2+
--pgstattuple extension required
3+
--WARNING: without index name/mask query will read all available indexes which could cause I/O spikes
4+
with indexes as (
5+
select * from pg_stat_user_indexes
6+
)
7+
select schemaname,
8+
table_name,
9+
pg_size_pretty(table_size) as table_size,
10+
index_name,
11+
pg_size_pretty(index_size) as index_size,
12+
idx_scan as index_scans,
13+
round((free_space*100/index_size)::numeric, 1) as waste_percent,
14+
pg_size_pretty(free_space) as waste
15+
from (
16+
select schemaname, p.relname as table_name, indexrelname as index_name,
17+
(select (case when avg_leaf_density = 'NaN' then 0
18+
else greatest(ceil(index_size * (1 - avg_leaf_density / (coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'90')::real)))::bigint, 0) end)
19+
from pgstatindex(schemaname || '.' || p.indexrelid::regclass::text)
20+
) as free_space,
21+
pg_relation_size(p.indexrelid) as index_size,
22+
pg_relation_size(p.relid) as table_size,
23+
idx_scan
24+
from indexes p
25+
join pg_class c on p.indexrelid = c.oid
26+
where pg_get_indexdef(p.indexrelid) like '%USING btree%' and
27+
--put your index name/mask here
28+
indexrelname ~ ''
29+
) t
30+
order by free_space desc;
31+

bloat/table_estimation.sql

Lines changed: 74 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,74 @@
1+
-- enhanced version of https://github.com/ioguix/pgsql-bloat-estimation/blob/master/table/table_bloat.sql
2+
3+
/* WARNING: executed with a non-superuser role, the query inspect only tables you are granted to read.
4+
* This query is compatible with PostgreSQL 9.0 and more
5+
*/
6+
7+
with data as (
8+
SELECT current_database(), schemaname, tblname, bs*tblpages AS real_size,
9+
(tblpages-est_tblpages)*bs AS extra_size,
10+
CASE WHEN tblpages - est_tblpages > 0
11+
THEN 100 * (tblpages - est_tblpages)/tblpages::float
12+
ELSE 0
13+
END AS extra_ratio, fillfactor, (tblpages-est_tblpages_ff)*bs AS bloat_size,
14+
CASE WHEN tblpages - est_tblpages_ff > 0
15+
THEN 100 * (tblpages - est_tblpages_ff)/tblpages::float
16+
ELSE 0
17+
END AS bloat_ratio, is_na
18+
-- , (pst).free_percent + (pst).dead_tuple_percent AS real_frag
19+
FROM (
20+
SELECT ceil( reltuples / ( (bs-page_hdr)/tpl_size ) ) + ceil( toasttuples / 4 ) AS est_tblpages,
21+
ceil( reltuples / ( (bs-page_hdr)*fillfactor/(tpl_size*100) ) ) + ceil( toasttuples / 4 ) AS est_tblpages_ff,
22+
tblpages, fillfactor, bs, tblid, schemaname, tblname, heappages, toastpages, is_na
23+
-- , stattuple.pgstattuple(tblid) AS pst
24+
FROM (
25+
SELECT
26+
( 4 + tpl_hdr_size + tpl_data_size + (2*ma)
27+
- CASE WHEN tpl_hdr_size%ma = 0 THEN ma ELSE tpl_hdr_size%ma END
28+
- CASE WHEN ceil(tpl_data_size)::int%ma = 0 THEN ma ELSE ceil(tpl_data_size)::int%ma END
29+
) AS tpl_size, bs - page_hdr AS size_per_block, (heappages + toastpages) AS tblpages, heappages,
30+
toastpages, reltuples, toasttuples, bs, page_hdr, tblid, schemaname, tblname, fillfactor, is_na
31+
FROM (
32+
SELECT
33+
tbl.oid AS tblid, ns.nspname AS schemaname, tbl.relname AS tblname, tbl.reltuples,
34+
tbl.relpages AS heappages, coalesce(toast.relpages, 0) AS toastpages,
35+
coalesce(toast.reltuples, 0) AS toasttuples,
36+
coalesce(substring(
37+
array_to_string(tbl.reloptions, ' ')
38+
FROM '%fillfactor=#"__#"%' FOR '#')::smallint, 100) AS fillfactor,
39+
current_setting('block_size')::numeric AS bs,
40+
CASE WHEN version()~'mingw32' OR version()~'64-bit|x86_64|ppc64|ia64|amd64' THEN 8 ELSE 4 END AS ma,
41+
24 AS page_hdr,
42+
23 + CASE WHEN MAX(coalesce(null_frac,0)) > 0 THEN ( 7 + count(*) ) / 8 ELSE 0::int END
43+
+ CASE WHEN tbl.relhasoids THEN 4 ELSE 0 END AS tpl_hdr_size,
44+
sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 1024) ) AS tpl_data_size,
45+
bool_or(att.atttypid = 'pg_catalog.name'::regtype) AS is_na
46+
FROM pg_attribute AS att
47+
JOIN pg_class AS tbl ON att.attrelid = tbl.oid
48+
JOIN pg_namespace AS ns ON ns.oid = tbl.relnamespace
49+
JOIN pg_stats AS s ON s.schemaname=ns.nspname
50+
AND s.tablename = tbl.relname AND s.inherited=false AND s.attname=att.attname
51+
LEFT JOIN pg_class AS toast ON tbl.reltoastrelid = toast.oid
52+
WHERE att.attnum > 0 AND NOT att.attisdropped
53+
AND tbl.relkind = 'r'
54+
GROUP BY 1,2,3,4,5,6,7,8,9,10, tbl.relhasoids
55+
ORDER BY 2,3
56+
) AS s
57+
) AS s2
58+
) AS s3
59+
-- WHERE NOT is_na
60+
-- AND tblpages*((pst).free_percent + (pst).dead_tuple_percent)::float4/100 >= 1
61+
)
62+
select current_database, schemaname, tblname,
63+
real_size, pg_size_pretty(real_size::numeric) as real_size_pretty,
64+
extra_size, pg_size_pretty(extra_size::numeric) as extra_size_pretty,
65+
extra_ratio as "extra_ratio, %",
66+
bloat_size, pg_size_pretty(bloat_size::numeric) as bloat_size_pretty,
67+
bloat_ratio as "bloat_ratio, %",
68+
fillfactor,
69+
is_na,
70+
real_size - bloat_size as live_data_size
71+
from data
72+
order by bloat_size desc
73+
;
74+

bloat/table_pgstattuple.sql

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,28 @@
1+
--https://github.com/dataegret/pg-utils/tree/master/sql
2+
--pgstattuple extension required
3+
--WARNING: without table name/mask query will read all available tables which could cause I/O spikes
4+
select nspname,
5+
relname,
6+
pg_size_pretty(relation_size + toast_relation_size) as total_size,
7+
pg_size_pretty(toast_relation_size) as toast_size,
8+
round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) table_waste_percent,
9+
pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bigint) table_waste,
10+
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,
11+
pg_size_pretty((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)::bigint) total_waste
12+
from (
13+
select nspname, relname,
14+
(select free_space from pgstattuple(c.oid)) as free_space,
15+
pg_relation_size(c.oid) as relation_size,
16+
(case when reltoastrelid = 0 then 0 else (select free_space from pgstattuple(c.reltoastrelid)) end) as toast_free_space,
17+
coalesce(pg_relation_size(c.reltoastrelid), 0) as toast_relation_size,
18+
coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'100')::real AS fillfactor
19+
from pg_class c
20+
left join pg_namespace n on (n.oid = c.relnamespace)
21+
where nspname not in ('pg_catalog', 'information_schema')
22+
and nspname !~ '^pg_toast' and relkind = 'r'
23+
--put your table name/mask here
24+
and relname ~ ''
25+
) t
26+
order by (toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor) desc
27+
limit 20;
28+

start.psql

Lines changed: 26 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,17 +1,25 @@
11
\echo Menu:
22
\echo ' 1 – Basic Node Information (master/replica, lag, DB size, tmp files)'
3-
\echo ' 2 – ....'
3+
\echo ' 2 – Sizes of tables'
4+
\echo ' b1 – Table bloat, rough estimation'
5+
\echo ' b2 – B-tree indexes bloat, rough estimation'
6+
\echo ' b3 – Table bloat, more precise (requires pgstattuple extension; expensive)'
7+
\echo ' b4 – Index bloat, more precise (requires pgstattuple extension; expensive)'
48
\echo ' 3 - Slowest Queries'
59
\echo ' i1 - Unused/Redundant Indexes'
610
\echo ' i2 - Rarely Used Indexes'
7-
\echo ' q – Quit from this tool'
11+
\echo ' q – Quit'
812
\echo
913
\echo 'Type your choice and press <Enter>:'
1014
\prompt d_step_unq
1115
\set d_stp '\'' :d_step_unq '\''
1216
select
1317
:d_stp::text = '1' as d_step_is_1,
1418
:d_stp::text = '2' as d_step_is_2,
19+
:d_stp::text = 'b1' as d_step_is_b1,
20+
:d_stp::text = 'b2' as d_step_is_b2,
21+
:d_stp::text = 'b3' as d_step_is_b3,
22+
:d_stp::text = 'b4' as d_step_is_b4,
1523
:d_stp::text = '3' as d_step_is_3,
1624
:d_stp::text = 'i1' as d_step_is_i1,
1725
:d_stp::text = 'i2' as d_step_is_i2,
@@ -24,6 +32,22 @@ select
2432
\echo ' 2 is chosen!'
2533
\prompt 'Press <Enter> to continue…' d_dummy
2634
\i ./start.psql
35+
\elif :d_step_is_b1
36+
\i ./bloat/table_estimation.sql
37+
\prompt 'Press <Enter> to continue…' d_dummy
38+
\i ./start.psql
39+
\elif :d_step_is_b2
40+
\i ./bloat/btree_estimation.sql
41+
\prompt 'Press <Enter> to continue…' d_dummy
42+
\i ./start.psql
43+
\elif :d_step_is_b3
44+
\i ./bloat/table_pgstattuple.sql
45+
\prompt 'Press <Enter> to continue…' d_dummy
46+
\i ./start.psql
47+
\elif :d_step_is_b4
48+
\i ./bloat/index_pgstattuple.sql
49+
\prompt 'Press <Enter> to continue…' d_dummy
50+
\i ./start.psql
2751
\elif :d_step_is_3
2852
\echo ' 3 is chosen!'
2953
\prompt 'Press <Enter> to continue…' d_dummy

0 commit comments

Comments
 (0)