@@ -54,6 +54,7 @@ nested_indexes_attributes as (
54
54
named_indexes_attributes as (
55
55
select
56
56
ic .table_oid ,
57
+ ct .relnamespace ,
57
58
ic .inner_index_name ,
58
59
ic .attpos ,
59
60
ic .indkey ,
@@ -92,10 +93,12 @@ rows_data_stats as (
92
93
else 2 + ((32 + 8 - 1 ) / 8 ) /* indextupledata size + indexattributebitmapdata size (max num filed per index + 8 - 1 /8) */
93
94
end as index_tuple_header_size,
94
95
/* 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
96
98
from
97
99
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
99
102
group by 1 , 2 , 3 , 4 , 5 , 6 , 7 , 8 , 9
100
103
),
101
104
rows_header_stats as (
@@ -118,20 +121,22 @@ rows_header_stats as (
118
121
else null_data_width::integer % max_align end
119
122
)::numeric as null_data_header_width,
120
123
page_header_size,
121
- page_opaque_data_size
124
+ page_opaque_data_size,
125
+ stats_not_available
122
126
from rows_data_stats
123
127
),
124
128
relation_stats as (
125
129
select
126
- /* itemiddata size + computed avg size of a tuple (nulldatahdrwidth ) */
130
+ /* itemiddata size + computed avg size of a tuple (null_data_header_width ) */
127
131
coalesce(1 +
128
132
ceil(reltuples / floor((block_size - page_opaque_data_size - page_header_size) * fill_factor / (100 * (4 + null_data_header_width)::float))),
129
133
0 )::bigint as estimated_pages_count,
130
134
block_size,
131
135
table_oid::regclass::text as table_name,
132
136
index_oid::regclass::text as index_name,
133
137
pg_relation_size(index_oid) as index_size,
134
- relpages
138
+ relpages,
139
+ stats_not_available
135
140
from rows_header_stats
136
141
),
137
142
corrected_relation_stats as (
@@ -141,9 +146,8 @@ corrected_relation_stats as (
141
146
index_size,
142
147
block_size,
143
148
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
147
151
from relation_stats
148
152
),
149
153
bloat_stats as (
@@ -152,11 +156,13 @@ corrected_relation_stats as (
152
156
index_name,
153
157
index_size,
154
158
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
158
162
)
159
163
select *
160
164
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 )
162
168
order by table_name, index_name;
0 commit comments