Skip to content

Commit

Permalink
More strict rules
Browse files Browse the repository at this point in the history
  • Loading branch information
mfvanek committed Jun 5, 2024
1 parent a13376e commit eac772e
Show file tree
Hide file tree
Showing 23 changed files with 202 additions and 157 deletions.
20 changes: 16 additions & 4 deletions .github/linters/.sqlfluff
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
[sqlfluff]
dialect = postgres
exclude_rules = LT01, LT02, LT03, LT08, AM03, AM05, AL01, AL05, ST06, ST09
warnings = AM06, ST05
exclude_rules = LT01
warnings = LT02
max_line_length = 180
templater = raw

Expand All @@ -11,8 +11,20 @@ allow_implicit_indents = True
indented_on_contents = False
indented_ctes = True

[sqlfluff:rules:layout.operators]
operator_new_lines = before
[sqlfluff:layout:type:binary_operator]
line_position = trailing

[sqlfluff:layout:type:comparison_operator]
line_position = trailing

[sqlfluff:rules:references.keywords]
ignore_words = columns,toast

[sqlfluff:rules:structure.join_condition_order]
preferred_first_table_in_join_clause = later

[sqlfluff:rules:aliasing.table]
aliasing = implicit

[sqlfluff:rules:aliasing.column]
aliasing = explicit
20 changes: 14 additions & 6 deletions sql/bloated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@
-- Please note!
-- The user on whose behalf this sql query will be executed
-- have to have read permissions for the corresponding tables.
-- noqa: disable=PRS
-- noqa: disable=PRS,ST06,AM06
with indexes_data as (
select
pc.relname as inner_index_name,
Expand All @@ -31,13 +31,14 @@ with indexes_data as (
pn.nspname
from
pg_catalog.pg_index pi
join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
where
pc.relam = (select oid from pg_catalog.pg_am where amname = 'btree') and
pc.relpages > 0 and
pn.nspname = :schema_name_param::text
),

nested_indexes_attributes as (
select
inner_index_name,
Expand All @@ -51,6 +52,7 @@ nested_indexes_attributes as (
pg_catalog.generate_series(1, indnatts) as attpos
from indexes_data
),

named_indexes_attributes as (
select
ic.table_oid,
Expand All @@ -70,10 +72,11 @@ named_indexes_attributes as (
case when a1.attnum is null then ic.inner_index_name else ct.relname end as attrelname
from
nested_indexes_attributes ic
join pg_catalog.pg_class ct on ct.oid = ic.table_oid
inner join pg_catalog.pg_class ct on ct.oid = ic.table_oid
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]
left join pg_catalog.pg_attribute a2 on ic.indkey[ic.attpos] = 0 and a2.attrelid = ic.index_oid and a2.attnum = ic.attpos
),

rows_data_stats as (
select
i.table_oid,
Expand All @@ -97,10 +100,11 @@ rows_data_stats as (
max(case when i.atttypid = 'pg_catalog.name'::regtype then 1 else 0 end) > 0 as stats_not_available
from
named_indexes_attributes i
join pg_catalog.pg_namespace n on n.oid = i.relnamespace
join pg_catalog.pg_stats s on s.schemaname = n.nspname and s.tablename = i.attrelname and s.attname = i.attname
inner join pg_catalog.pg_namespace n on n.oid = i.relnamespace
inner join pg_catalog.pg_stats s on s.schemaname = n.nspname and s.tablename = i.attrelname and s.attname = i.attname
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
),

rows_header_stats as (
select
max_align,
Expand All @@ -125,6 +129,7 @@ rows_header_stats as (
stats_not_available
from rows_data_stats
),

relation_stats as (
select
/* itemiddata size + computed avg size of a tuple (null_data_header_width) */
Expand All @@ -139,6 +144,7 @@ relation_stats as (
stats_not_available
from rows_header_stats
),

corrected_relation_stats as (
select
table_name,
Expand All @@ -150,6 +156,7 @@ corrected_relation_stats as (
stats_not_available
from relation_stats
),

bloat_stats as (
select
table_name,
Expand All @@ -160,6 +167,7 @@ bloat_stats as (
stats_not_available
from corrected_relation_stats
)

select *
from bloat_stats
where
Expand Down
16 changes: 11 additions & 5 deletions sql/bloated_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@
-- Please note!
-- The user on whose behalf this sql query will be executed
-- have to have read permissions for the corresponding tables.
-- noqa: disable=ST06
with tables_stats as (
select
pc.oid as table_oid,
Expand All @@ -32,18 +33,19 @@ with tables_stats as (
sum((1 - coalesce(ps.null_frac, 0)) * coalesce(ps.avg_width, 0)) as null_data_width,
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
from
pg_attribute as pa
join pg_class as pc on pa.attrelid = pc.oid
join pg_namespace as pn on pn.oid = pc.relnamespace
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
left join pg_class as toast on pc.reltoastrelid = toast.oid
pg_attribute pa
inner join pg_class pc on pc.oid = pa.attrelid
inner join pg_namespace pn on pn.oid = pc.relnamespace
left join pg_stats ps on ps.schemaname = pn.nspname and ps.tablename = pc.relname and ps.inherited = false and ps.attname = pa.attname
left join pg_class toast on toast.oid = pc.reltoastrelid
where
not pa.attisdropped and
pc.relkind = 'r' and
pc.relpages > 0 and
pn.nspname = :schema_name_param::text
group by table_oid, pc.reltuples, heap_pages, toast_pages, toast_tuples, fill_factor, block_size, page_header_size
),

tables_pages_size as (
select
(4 + table_tuple_header_size + null_data_width + (2 * max_align) -
Expand All @@ -63,6 +65,7 @@ tables_pages_size as (
stats_not_available
from tables_stats
),

relation_stats as (
select
ceil(reltuples / ((block_size - page_header_size) * fill_factor / (tpl_size * 100))) +
Expand All @@ -74,6 +77,7 @@ relation_stats as (
stats_not_available
from tables_pages_size
),

corrected_relation_stats as (
select
table_name,
Expand All @@ -84,6 +88,7 @@ corrected_relation_stats as (
stats_not_available
from relation_stats
),

bloat_stats as (
select
table_name,
Expand All @@ -93,6 +98,7 @@ bloat_stats as (
stats_not_available
from corrected_relation_stats
)

select *
from bloat_stats
where
Expand Down
22 changes: 11 additions & 11 deletions sql/btree_indexes_on_array_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,17 +10,17 @@
-- GIN-index should be used instead for such columns
-- Based on query from https://habr.com/ru/articles/800121/
select
i.indrelid::regclass as table_name, -- Name of the table
i.indexrelid::regclass as index_name, -- Name of the index
pg_relation_size(i.indexrelid) as index_size, -- Size of the index
col.attname as column_name, -- Column name
col.attnotnull as column_not_null -- Column not null
from pg_catalog.pg_index as i
inner join pg_catalog.pg_class as ic on i.indexrelid = ic.oid
inner join pg_catalog.pg_namespace as nsp on nsp.oid = ic.relnamespace
inner join pg_catalog.pg_am as a on ic.relam = a.oid and a.amname = 'btree'
inner join pg_catalog.pg_attribute as col on i.indrelid = col.attrelid and col.attnum = any((string_to_array(i.indkey::text, ' ')::int2[])[:i.indnkeyatts])
inner join pg_catalog.pg_type as typ on typ.oid = col.atttypid
i.indrelid::regclass as table_name,
i.indexrelid::regclass as index_name,
col.attname as column_name,
col.attnotnull as column_not_null,
pg_relation_size(i.indexrelid) as index_size
from pg_catalog.pg_index i
inner join pg_catalog.pg_class ic on ic.oid = i.indexrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = ic.relnamespace
inner join pg_catalog.pg_am a on a.oid = ic.relam and a.amname = 'btree'
inner join pg_catalog.pg_attribute col on col.attrelid = i.indrelid and col.attnum = any((string_to_array(i.indkey::text, ' ')::int2[])[:i.indnkeyatts])
inner join pg_catalog.pg_type typ on typ.oid = col.atttypid
where
nsp.nspname = :schema_name_param::text and
typ.typcategory = 'A' -- A stands for Array type. See - https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
Expand Down
10 changes: 5 additions & 5 deletions sql/check_not_valid_constraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,10 +11,10 @@ select
c.contype as constraint_type -- Type of the constraint
from
pg_catalog.pg_constraint c
join pg_catalog.pg_class t on t.oid = c.conrelid
join pg_catalog.pg_namespace n on n.oid = t.relnamespace
inner join pg_catalog.pg_class t on t.oid = c.conrelid
inner join pg_catalog.pg_namespace n on n.oid = t.relnamespace
where
not c.convalidated -- Constraints that have not yet been validated
and c.contype in ('c', 'f') -- Focus on check and foreign key constraints
and n.nspname = :schema_name_param::text -- Make the query schema-aware
not c.convalidated and -- Constraints that have not yet been validated
c.contype in ('c', 'f') and -- Focus on check and foreign key constraints
n.nspname = :schema_name_param::text -- Make the query schema-aware
order by c.conrelid::regclass::text, c.conname;
4 changes: 2 additions & 2 deletions sql/columns_with_json_type.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,8 +15,8 @@ select
col.attnotnull as column_not_null
from
pg_catalog.pg_class t
join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
where
t.relkind = 'r' and
col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */
Expand Down
4 changes: 2 additions & 2 deletions sql/columns_without_description.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,8 +12,8 @@ select
col.attnotnull as column_not_null
from
pg_catalog.pg_class t
join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
where
t.relkind = 'r' and
col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */
Expand Down
12 changes: 7 additions & 5 deletions sql/duplicated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,13 +13,15 @@ from (
select
x.indexrelid::regclass as idx,
x.indrelid::regclass as table_name,
(x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
x.indcollation::text || ' ' ||
coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || ' ' ||
coalesce(pg_get_expr(x.indpred, x.indrelid), '')) as grouping_key
(
x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
x.indcollation::text || ' ' ||
coalesce(pg_get_expr(x.indexprs, x.indrelid), '') || ' ' ||
coalesce(pg_get_expr(x.indpred, x.indrelid), '')
) as grouping_key
from
pg_catalog.pg_index x
join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = x.indexrelid
where psai.schemaname = :schema_name_param::text
) sub
group by table_name, grouping_key
Expand Down
6 changes: 3 additions & 3 deletions sql/ext/slowest_queries_by_total_execution_time.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,10 +10,10 @@
-- Compatible with PostgreSQL 12 and lower.
-- noqa: disable=PRS
select
round(total_time::numeric, 3) as total_time_ms,
calls as calls_count,
round(mean_time::numeric, 3) as average_time_ms,
query
query,
round(total_time::numeric, 3) as total_time_ms,
round(mean_time::numeric, 3) as average_time_ms
from pg_stat_statements
order by total_time desc
limit :limit_count::integer;
6 changes: 3 additions & 3 deletions sql/ext/slowest_queries_by_total_execution_time_13.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,10 +10,10 @@
-- Compatible with PostgreSQL 13 and higher.
-- noqa: disable=PRS
select
round(total_exec_time::numeric, 3) as total_time_ms,
calls as calls_count,
round(mean_exec_time::numeric, 3) as average_time_ms,
query
query,
round(total_exec_time::numeric, 3) as total_time_ms,
round(mean_exec_time::numeric, 3) as average_time_ms
from pg_stat_statements
order by total_exec_time desc
limit :limit_count::integer;
8 changes: 4 additions & 4 deletions sql/foreign_keys_without_index.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,10 +13,10 @@ select
array_agg(col.attname || ', ' || col.attnotnull::text order by u.attposition) as columns
from
pg_catalog.pg_constraint c
join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true
join pg_catalog.pg_class t on c.conrelid = t.oid
join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
join pg_catalog.pg_attribute col on col.attrelid = t.oid and col.attnum = u.attnum
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
inner join pg_catalog.pg_class t on t.oid = c.conrelid
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid and col.attnum = u.attnum
where
c.contype = 'f' and
nsp.nspname = :schema_name_param::text and
Expand Down
2 changes: 1 addition & 1 deletion sql/functions_without_description.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ select
pg_get_function_identity_arguments(p.oid) as function_signature
from
pg_catalog.pg_namespace n
join pg_catalog.pg_proc p on p.pronamespace = n.oid
inner join pg_catalog.pg_proc p on p.pronamespace = n.oid
where
(obj_description(p.oid) is null or length(trim(obj_description(p.oid))) = 0) and
n.nspname = :schema_name_param::text
Expand Down
20 changes: 10 additions & 10 deletions sql/indexes_with_boolean.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,18 +9,18 @@
select
pi.indrelid::regclass::text as table_name,
pi.indexrelid::regclass::text as index_name,
pg_relation_size(pi.indexrelid) as index_size,
col.attname as column_name,
col.attnotnull as column_not_null
col.attnotnull as column_not_null,
pg_relation_size(pi.indexrelid) as index_size
from
pg_catalog.pg_index pi
join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
join pg_catalog.pg_attribute col on col.attrelid = pi.indrelid and col.attnum = any(pi.indkey)
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = pi.indrelid and col.attnum = any(pi.indkey)
where
pn.nspname = :schema_name_param::text
and not pi.indisunique
and pi.indisready
and pi.indisvalid
and col.atttypid = 'boolean'::regtype
pn.nspname = :schema_name_param::text and
not pi.indisunique and
pi.indisready and
pi.indisvalid and
col.atttypid = 'boolean'::regtype
order by table_name, index_name;
4 changes: 2 additions & 2 deletions sql/indexes_with_null_values.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,8 +13,8 @@ select
pg_relation_size(x.indexrelid) as index_size
from
pg_catalog.pg_index x
join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid
join pg_catalog.pg_attribute a on a.attrelid = x.indrelid and a.attnum = any(x.indkey)
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = x.indexrelid
inner join pg_catalog.pg_attribute a on a.attrelid = x.indrelid and a.attnum = any(x.indkey)
where
not x.indisunique and
not a.attnotnull and
Expand Down
Loading

0 comments on commit eac772e

Please sign in to comment.