Skip to content

Commit 4499765

Browse files
authored
Optimize bloat queries (#45)
* Fix for tables bloat * Fix for indexes bloat
1 parent 62f46cd commit 4499765

File tree

2 files changed

+32
-19
lines changed

2 files changed

+32
-19
lines changed

sql/bloated_indexes.sql

Lines changed: 18 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -54,6 +54,7 @@ nested_indexes_attributes as (
5454
named_indexes_attributes as (
5555
select
5656
ic.table_oid,
57+
ct.relnamespace,
5758
ic.inner_index_name,
5859
ic.attpos,
5960
ic.indkey,
@@ -92,10 +93,12 @@ rows_data_stats as (
9293
else 2 + ((32 + 8 - 1) / 8) /* indextupledata size + indexattributebitmapdata size (max num filed per index + 8 - 1 /8) */
9394
end as index_tuple_header_size,
9495
/* remove null values and save space using it fractional part from stats */
95-
sum((1 - coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0)) as null_data_width
96+
sum((1 - coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0)) as null_data_width,
97+
max(case when i.atttypid = 'pg_catalog.name'::regtype then 1 else 0 end) > 0 as stats_not_available
9698
from
9799
named_indexes_attributes i
98-
join pg_catalog.pg_stats s on s.schemaname = i.nspname and s.tablename = i.attrelname and s.attname = i.attname
100+
join pg_catalog.pg_namespace n on n.oid = i.relnamespace
101+
join pg_catalog.pg_stats s on s.schemaname = n.nspname and s.tablename = i.attrelname and s.attname = i.attname
99102
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
100103
),
101104
rows_header_stats as (
@@ -118,20 +121,22 @@ rows_header_stats as (
118121
else null_data_width::integer % max_align end
119122
)::numeric as null_data_header_width,
120123
page_header_size,
121-
page_opaque_data_size
124+
page_opaque_data_size,
125+
stats_not_available
122126
from rows_data_stats
123127
),
124128
relation_stats as (
125129
select
126-
/* itemiddata size + computed avg size of a tuple (nulldatahdrwidth) */
130+
/* itemiddata size + computed avg size of a tuple (null_data_header_width) */
127131
coalesce(1 +
128132
ceil(reltuples / floor((block_size - page_opaque_data_size - page_header_size) * fill_factor / (100 * (4 + null_data_header_width)::float))),
129133
0)::bigint as estimated_pages_count,
130134
block_size,
131135
table_oid::regclass::text as table_name,
132136
index_oid::regclass::text as index_name,
133137
pg_relation_size(index_oid) as index_size,
134-
relpages
138+
relpages,
139+
stats_not_available
135140
from rows_header_stats
136141
),
137142
corrected_relation_stats as (
@@ -141,9 +146,8 @@ corrected_relation_stats as (
141146
index_size,
142147
block_size,
143148
relpages,
144-
(case
145-
when relpages - estimated_pages_count > 0 then relpages - estimated_pages_count
146-
else 0 end)::bigint as pages_ff_diff
149+
(case when relpages - estimated_pages_count > 0 then relpages - estimated_pages_count else 0 end)::bigint as pages_ff_diff,
150+
stats_not_available
147151
from relation_stats
148152
),
149153
bloat_stats as (
@@ -152,11 +156,13 @@ corrected_relation_stats as (
152156
index_name,
153157
index_size,
154158
block_size * pages_ff_diff as bloat_size,
155-
round(100 * block_size * pages_ff_diff / index_size::float)::integer as bloat_percentage
156-
from
157-
corrected_relation_stats
159+
round(100 * block_size * pages_ff_diff / index_size::numeric, 2)::numeric(5, 2) as bloat_percentage,
160+
stats_not_available
161+
from corrected_relation_stats
158162
)
159163
select *
160164
from bloat_stats
161-
where bloat_percentage >= :bloat_percentage_threshold::integer
165+
where
166+
not stats_not_available and
167+
bloat_percentage >= :bloat_percentage_threshold::numeric(5, 2)
162168
order by table_name, index_name;

sql/bloated_tables.sql

Lines changed: 14 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -29,12 +29,13 @@ with tables_stats as (
2929
24 as page_header_size,
3030
23 + case when max(coalesce(ps.null_frac, 0)) > 0 then (7 + count(ps.attname)) / 8 else 0::int end +
3131
case when bool_or(pa.attname = 'oid' and pa.attnum < 0) then 4 else 0 end as table_tuple_header_size,
32-
sum((1 - coalesce(ps.null_frac, 0)) * coalesce(ps.avg_width, 0)) as null_data_width
32+
sum((1 - coalesce(ps.null_frac, 0)) * coalesce(ps.avg_width, 0)) as null_data_width,
33+
bool_or(pa.atttypid = 'pg_catalog.name'::regtype) or sum(case when pa.attnum > 0 then 1 else 0 end) <> count(ps.attname) as stats_not_available
3334
from
3435
pg_attribute as pa
3536
join pg_class as pc on pa.attrelid = pc.oid
3637
join pg_namespace as pn on pn.oid = pc.relnamespace
37-
join pg_stats as ps on ps.schemaname = pn.nspname and ps.tablename = pc.relname and ps.inherited = false and ps.attname = pa.attname
38+
left join pg_stats as ps on ps.schemaname = pn.nspname and ps.tablename = pc.relname and ps.inherited = false and ps.attname = pa.attname
3839
left join pg_class as toast on pc.reltoastrelid = toast.oid
3940
where
4041
not pa.attisdropped and
@@ -58,7 +59,8 @@ tables_pages_size as (
5859
block_size,
5960
page_header_size,
6061
table_oid,
61-
fill_factor
62+
fill_factor,
63+
stats_not_available
6264
from tables_stats
6365
),
6466
relation_stats as (
@@ -68,7 +70,8 @@ relation_stats as (
6870
table_pages_count,
6971
block_size,
7072
table_oid::regclass::text as table_name,
71-
pg_table_size(table_oid) as table_size
73+
pg_table_size(table_oid) as table_size,
74+
stats_not_available
7275
from tables_pages_size
7376
),
7477
corrected_relation_stats as (
@@ -77,18 +80,22 @@ corrected_relation_stats as (
7780
table_size,
7881
(case when table_pages_count - estimated_pages_count > 0 then table_pages_count - estimated_pages_count
7982
else 0 end)::bigint as pages_ff_diff,
80-
block_size
83+
block_size,
84+
stats_not_available
8185
from relation_stats
8286
),
8387
bloat_stats as (
8488
select
8589
table_name,
8690
table_size,
8791
block_size * pages_ff_diff as bloat_size,
88-
case when table_size > 0 then round(100 * block_size * pages_ff_diff / table_size::float)::integer else 0 end as bloat_percentage
92+
case when table_size > 0 then round(100 * block_size * pages_ff_diff / table_size::numeric, 2) else 0 end ::numeric(5, 2) as bloat_percentage,
93+
stats_not_available
8994
from corrected_relation_stats
9095
)
9196
select *
9297
from bloat_stats
93-
where bloat_percentage >= :bloat_percentage_threshold::integer
98+
where
99+
not stats_not_available and
100+
bloat_percentage >= :bloat_percentage_threshold::numeric(5, 2)
94101
order by table_name;

0 commit comments

Comments
 (0)