Skip to content

Commit 44af90c

Browse files
authored
Add ordering to the query (#47)
* Add ordering to the query * More strict rules * More strict rules #2
1 parent a367123 commit 44af90c

24 files changed

+420
-374
lines changed

.github/linters/.sqlfluff

Lines changed: 16 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,7 @@
11
[sqlfluff]
22
dialect = postgres
3-
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06, ST09
4-
warnings = AM06, ST05
5-
max_line_length = 180
3+
warnings = LT01
4+
max_line_length = 280
65
templater = raw
76

87
[sqlfluff:indentation]
@@ -11,8 +10,20 @@ allow_implicit_indents = True
1110
indented_on_contents = False
1211
indented_ctes = True
1312

14-
[sqlfluff:rules:layout.operators]
15-
operator_new_lines = before
13+
[sqlfluff:layout:type:binary_operator]
14+
line_position = trailing
15+
16+
[sqlfluff:layout:type:comparison_operator]
17+
line_position = trailing
1618

1719
[sqlfluff:rules:references.keywords]
1820
ignore_words = columns,toast
21+
22+
[sqlfluff:rules:structure.join_condition_order]
23+
preferred_first_table_in_join_clause = later
24+
25+
[sqlfluff:rules:aliasing.table]
26+
aliasing = implicit
27+
28+
[sqlfluff:rules:aliasing.column]
29+
aliasing = explicit

README.md

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -41,7 +41,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
4141
17. Tables with [not valid constraints](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/check_not_valid_constraints.sql)).
4242
18. B-tree indexes [on array columns](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/btree_indexes_on_array_columns.sql)).
4343
19. [Sequence overflow](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/sequence_overflow.sql)).
44-
20. Primary keys with [serial types](https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/primary_keys_with_serial_types.sql))
44+
20. Primary keys with [serial types](https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/primary_keys_with_serial_types.sql)).
4545

4646
## Local development
4747

sql/bloated_indexes.sql

Lines changed: 151 additions & 141 deletions
Original file line numberDiff line numberDiff line change
@@ -17,149 +17,159 @@
1717
-- Please note!
1818
-- The user on whose behalf this sql query will be executed
1919
-- have to have read permissions for the corresponding tables.
20-
-- noqa: disable=PRS
21-
with indexes_data as (
22-
select
23-
pc.relname as inner_index_name,
24-
pc.reltuples,
25-
pc.relpages,
26-
pi.indrelid as table_oid,
27-
pi.indexrelid as index_oid,
28-
coalesce(substring(array_to_string(pc.reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 90) as fill_factor,
29-
pi.indnatts,
30-
string_to_array(textin(int2vectorout(pi.indkey)), ' ')::int[] as indkey,
31-
pn.nspname
32-
from
33-
pg_catalog.pg_index pi
34-
join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
35-
join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
36-
where
37-
pc.relam = (select oid from pg_catalog.pg_am where amname = 'btree') and
38-
pc.relpages > 0 and
39-
pn.nspname = :schema_name_param::text
40-
),
41-
nested_indexes_attributes as (
42-
select
43-
inner_index_name,
44-
reltuples,
45-
relpages,
46-
table_oid,
47-
index_oid,
48-
fill_factor,
49-
indkey,
50-
nspname,
51-
pg_catalog.generate_series(1, indnatts) as attpos
52-
from indexes_data
53-
),
54-
named_indexes_attributes as (
55-
select
56-
ic.table_oid,
57-
ct.relnamespace,
58-
ic.inner_index_name,
59-
ic.attpos,
60-
ic.indkey,
61-
ic.indkey[ic.attpos] as indattpos,
62-
ic.reltuples,
63-
ic.relpages,
64-
ic.index_oid,
65-
ic.fill_factor,
66-
coalesce(a1.attnum, a2.attnum) as attnum,
67-
coalesce(a1.attname, a2.attname) as attname,
68-
coalesce(a1.atttypid, a2.atttypid) as atttypid,
69-
ic.nspname,
70-
case when a1.attnum is null then ic.inner_index_name else ct.relname end as attrelname
71-
from
72-
nested_indexes_attributes ic
73-
join pg_catalog.pg_class ct on ct.oid = ic.table_oid
74-
left join pg_catalog.pg_attribute a1 on ic.indkey[ic.attpos] <> 0 and a1.attrelid = ic.table_oid and a1.attnum = ic.indkey[ic.attpos]
75-
left join pg_catalog.pg_attribute a2 on ic.indkey[ic.attpos] = 0 and a2.attrelid = ic.index_oid and a2.attnum = ic.attpos
76-
),
77-
rows_data_stats as (
78-
select
79-
i.table_oid,
80-
i.reltuples,
81-
i.relpages,
82-
i.index_oid,
83-
i.fill_factor,
84-
current_setting('block_size')::bigint as block_size,
85-
/* max_align: 4 on 32bits, 8 on 64bits */
86-
case when version() ~ 'mingw32' or version() ~ '64-bit|x86_64|ppc64|ia64|amd64' then 8 else 4 end as max_align,
87-
/* per page header, fixed size: 20 for 7.x, 24 for others */
88-
24 as page_header_size,
89-
/* per page btree opaque data */
90-
16 as page_opaque_data_size,
91-
/* per tuple header: add indexattributebitmapdata if some cols are null-able */
92-
case when max(coalesce(s.null_frac, 0)) = 0 then 2 /* indextupledata size */
93-
else 2 + ((32 + 8 - 1) / 8) /* indextupledata size + indexattributebitmapdata size (max num filed per index + 8 - 1 /8) */
94-
end as index_tuple_header_size,
95-
/* remove null values and save space using it fractional part from stats */
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
98-
from
99-
named_indexes_attributes i
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
102-
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
103-
),
104-
rows_header_stats as (
105-
select
106-
max_align,
107-
block_size,
108-
reltuples,
109-
relpages,
110-
index_oid,
111-
fill_factor,
112-
table_oid,
113-
(index_tuple_header_size + max_align -
114-
/* add padding to the index tuple header to align on max_align */
115-
case when index_tuple_header_size % max_align = 0 then max_align else index_tuple_header_size % max_align end +
116-
null_data_width + max_align -
117-
/* add padding to the data to align on max_align */
20+
-- noqa: disable=PRS,ST06,AM06
21+
with
22+
indexes_data as (
23+
select
24+
pc.relname as inner_index_name,
25+
pc.reltuples,
26+
pc.relpages,
27+
pi.indrelid as table_oid,
28+
pi.indexrelid as index_oid,
29+
pi.indnatts,
30+
pn.nspname,
31+
coalesce(substring(array_to_string(pc.reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 90) as fill_factor,
32+
string_to_array(textin(int2vectorout(pi.indkey)), ' ')::int[] as indkey
33+
from
34+
pg_catalog.pg_index pi
35+
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
36+
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
37+
where
38+
pc.relam = (select oid from pg_catalog.pg_am where amname = 'btree') and
39+
pc.relpages > 0 and
40+
pn.nspname = :schema_name_param::text
41+
),
42+
43+
nested_indexes_attributes as (
44+
select
45+
inner_index_name,
46+
reltuples,
47+
relpages,
48+
table_oid,
49+
index_oid,
50+
fill_factor,
51+
indkey,
52+
nspname,
53+
pg_catalog.generate_series(1, indnatts) as attpos
54+
from indexes_data
55+
),
56+
57+
named_indexes_attributes as (
58+
select
59+
ic.table_oid,
60+
ct.relnamespace,
61+
ic.inner_index_name,
62+
ic.attpos,
63+
ic.indkey,
64+
ic.indkey[ic.attpos] as indattpos,
65+
ic.reltuples,
66+
ic.relpages,
67+
ic.index_oid,
68+
ic.fill_factor,
69+
coalesce(a1.attnum, a2.attnum) as attnum,
70+
coalesce(a1.attname, a2.attname) as attname,
71+
coalesce(a1.atttypid, a2.atttypid) as atttypid,
72+
ic.nspname,
73+
case when a1.attnum is null then ic.inner_index_name else ct.relname end as attrelname
74+
from
75+
nested_indexes_attributes ic
76+
inner join pg_catalog.pg_class ct on ct.oid = ic.table_oid
77+
left join pg_catalog.pg_attribute a1 on ic.indkey[ic.attpos] <> 0 and a1.attrelid = ic.table_oid and a1.attnum = ic.indkey[ic.attpos]
78+
left join pg_catalog.pg_attribute a2 on ic.indkey[ic.attpos] = 0 and a2.attrelid = ic.index_oid and a2.attnum = ic.attpos
79+
),
80+
81+
rows_data_stats as (
82+
select
83+
i.table_oid,
84+
i.reltuples,
85+
i.relpages,
86+
i.index_oid,
87+
i.fill_factor,
88+
current_setting('block_size')::bigint as block_size,
89+
/* max_align: 4 on 32bits, 8 on 64bits */
90+
case when version() ~ 'mingw32' or version() ~ '64-bit|x86_64|ppc64|ia64|amd64' then 8 else 4 end as max_align,
91+
/* per page header, fixed size: 20 for 7.x, 24 for others */
92+
24 as page_header_size,
93+
/* per page btree opaque data */
94+
16 as page_opaque_data_size,
95+
/* per tuple header: add indexattributebitmapdata if some cols are nullable */
11896
case
119-
when null_data_width = 0 then 0
120-
when null_data_width::integer % max_align = 0 then max_align
121-
else null_data_width::integer % max_align end
97+
when max(coalesce(s.null_frac, 0)) = 0 then 2 /* indextupledata size */
98+
else 2 + ((32 + 8 - 1) / 8) /* indextupledata size + indexattributebitmapdata size (max num filed per index + 8 - 1 /8) */
99+
end as index_tuple_header_size,
100+
/* remove null values and save space using it fractional part from stats */
101+
sum((1 - coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 0)) as null_data_width,
102+
max(case when i.atttypid = 'pg_catalog.name'::regtype then 1 else 0 end) > 0 as stats_not_available
103+
from
104+
named_indexes_attributes i
105+
inner join pg_catalog.pg_namespace n on n.oid = i.relnamespace
106+
inner join pg_catalog.pg_stats s on s.schemaname = n.nspname and s.tablename = i.attrelname and s.attname = i.attname
107+
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
108+
),
109+
110+
rows_header_stats as (
111+
select
112+
max_align,
113+
block_size,
114+
reltuples,
115+
relpages,
116+
index_oid,
117+
fill_factor,
118+
table_oid,
119+
(
120+
index_tuple_header_size + max_align -
121+
/* add padding to the index tuple header to align on max_align */
122+
case when index_tuple_header_size % max_align = 0 then max_align else index_tuple_header_size % max_align end +
123+
null_data_width + max_align -
124+
/* add padding to the data to align on max_align */
125+
case
126+
when null_data_width = 0 then 0
127+
when null_data_width::integer % max_align = 0 then max_align
128+
else null_data_width::integer % max_align
129+
end
122130
)::numeric as null_data_header_width,
123-
page_header_size,
124-
page_opaque_data_size,
125-
stats_not_available
126-
from rows_data_stats
127-
),
128-
relation_stats as (
129-
select
130-
/* itemiddata size + computed avg size of a tuple (null_data_header_width) */
131-
coalesce(1 +
132-
ceil(reltuples / floor((block_size - page_opaque_data_size - page_header_size) * fill_factor / (100 * (4 + null_data_header_width)::float))),
133-
0)::bigint as estimated_pages_count,
134-
block_size,
135-
table_oid::regclass::text as table_name,
136-
index_oid::regclass::text as index_name,
137-
pg_relation_size(index_oid) as index_size,
138-
relpages,
139-
stats_not_available
140-
from rows_header_stats
141-
),
142-
corrected_relation_stats as (
143-
select
144-
table_name,
145-
index_name,
146-
index_size,
147-
block_size,
148-
relpages,
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
151-
from relation_stats
152-
),
153-
bloat_stats as (
154-
select
155-
table_name,
156-
index_name,
157-
index_size,
158-
block_size * pages_ff_diff as bloat_size,
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
162-
)
131+
page_header_size,
132+
page_opaque_data_size,
133+
stats_not_available
134+
from rows_data_stats
135+
),
136+
137+
relation_stats as (
138+
select
139+
/* itemiddata size + computed avg size of a tuple (null_data_header_width) */
140+
coalesce(1 + ceil(reltuples / floor((block_size - page_opaque_data_size - page_header_size) * fill_factor / (100 * (4 + null_data_header_width)::float))), 0)::bigint as estimated_pages_count,
141+
block_size,
142+
table_oid::regclass::text as table_name,
143+
index_oid::regclass::text as index_name,
144+
pg_relation_size(index_oid) as index_size,
145+
relpages,
146+
stats_not_available
147+
from rows_header_stats
148+
),
149+
150+
corrected_relation_stats as (
151+
select
152+
table_name,
153+
index_name,
154+
index_size,
155+
block_size,
156+
relpages,
157+
(case when relpages - estimated_pages_count > 0 then relpages - estimated_pages_count else 0 end)::bigint as pages_ff_diff,
158+
stats_not_available
159+
from relation_stats
160+
),
161+
162+
bloat_stats as (
163+
select
164+
table_name,
165+
index_name,
166+
index_size,
167+
block_size * pages_ff_diff as bloat_size,
168+
round(100 * block_size * pages_ff_diff / index_size::numeric, 2)::numeric(5, 2) as bloat_percentage,
169+
stats_not_available
170+
from corrected_relation_stats
171+
)
172+
163173
select *
164174
from bloat_stats
165175
where

0 commit comments

Comments
 (0)