diff --git a/.github/linters/.sqlfluff b/.github/linters/.sqlfluff index 8624b1a..8114bd0 100644 --- a/.github/linters/.sqlfluff +++ b/.github/linters/.sqlfluff @@ -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 @@ -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 diff --git a/sql/bloated_indexes.sql b/sql/bloated_indexes.sql index 659bcbd..1cb9132 100644 --- a/sql/bloated_indexes.sql +++ b/sql/bloated_indexes.sql @@ -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, @@ -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, @@ -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, @@ -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, @@ -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, @@ -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) */ @@ -139,6 +144,7 @@ relation_stats as ( stats_not_available from rows_header_stats ), + corrected_relation_stats as ( select table_name, @@ -150,6 +156,7 @@ corrected_relation_stats as ( stats_not_available from relation_stats ), + bloat_stats as ( select table_name, @@ -160,6 +167,7 @@ bloat_stats as ( stats_not_available from corrected_relation_stats ) + select * from bloat_stats where diff --git a/sql/bloated_tables.sql b/sql/bloated_tables.sql index c5b7eee..7a94156 100644 --- a/sql/bloated_tables.sql +++ b/sql/bloated_tables.sql @@ -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, @@ -32,11 +33,11 @@ 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 @@ -44,6 +45,7 @@ with tables_stats as ( 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) - @@ -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))) + @@ -74,6 +77,7 @@ relation_stats as ( stats_not_available from tables_pages_size ), + corrected_relation_stats as ( select table_name, @@ -84,6 +88,7 @@ corrected_relation_stats as ( stats_not_available from relation_stats ), + bloat_stats as ( select table_name, @@ -93,6 +98,7 @@ bloat_stats as ( stats_not_available from corrected_relation_stats ) + select * from bloat_stats where diff --git a/sql/btree_indexes_on_array_columns.sql b/sql/btree_indexes_on_array_columns.sql index a5f0bb5..e3d3a40 100644 --- a/sql/btree_indexes_on_array_columns.sql +++ b/sql/btree_indexes_on_array_columns.sql @@ -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 diff --git a/sql/check_not_valid_constraints.sql b/sql/check_not_valid_constraints.sql index fde4e74..0a88130 100644 --- a/sql/check_not_valid_constraints.sql +++ b/sql/check_not_valid_constraints.sql @@ -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; diff --git a/sql/columns_with_json_type.sql b/sql/columns_with_json_type.sql index bd096f1..2a3ae42 100644 --- a/sql/columns_with_json_type.sql +++ b/sql/columns_with_json_type.sql @@ -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. */ diff --git a/sql/columns_without_description.sql b/sql/columns_without_description.sql index 41c9a68..fa813d4 100644 --- a/sql/columns_without_description.sql +++ b/sql/columns_without_description.sql @@ -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. */ diff --git a/sql/duplicated_indexes.sql b/sql/duplicated_indexes.sql index 0562e39..433c40f 100644 --- a/sql/duplicated_indexes.sql +++ b/sql/duplicated_indexes.sql @@ -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 diff --git a/sql/ext/slowest_queries_by_total_execution_time.sql b/sql/ext/slowest_queries_by_total_execution_time.sql index 434fb5e..ca53d37 100644 --- a/sql/ext/slowest_queries_by_total_execution_time.sql +++ b/sql/ext/slowest_queries_by_total_execution_time.sql @@ -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; diff --git a/sql/ext/slowest_queries_by_total_execution_time_13.sql b/sql/ext/slowest_queries_by_total_execution_time_13.sql index 846176d..d8ae986 100644 --- a/sql/ext/slowest_queries_by_total_execution_time_13.sql +++ b/sql/ext/slowest_queries_by_total_execution_time_13.sql @@ -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; diff --git a/sql/foreign_keys_without_index.sql b/sql/foreign_keys_without_index.sql index 6a2c4b3..0ccd94c 100644 --- a/sql/foreign_keys_without_index.sql +++ b/sql/foreign_keys_without_index.sql @@ -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 diff --git a/sql/functions_without_description.sql b/sql/functions_without_description.sql index f76ef9b..20c7a78 100644 --- a/sql/functions_without_description.sql +++ b/sql/functions_without_description.sql @@ -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 diff --git a/sql/indexes_with_boolean.sql b/sql/indexes_with_boolean.sql index f26aeae..64ac374 100644 --- a/sql/indexes_with_boolean.sql +++ b/sql/indexes_with_boolean.sql @@ -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; diff --git a/sql/indexes_with_null_values.sql b/sql/indexes_with_null_values.sql index 473a07e..23d32d1 100644 --- a/sql/indexes_with_null_values.sql +++ b/sql/indexes_with_null_values.sql @@ -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 diff --git a/sql/intersected_indexes.sql b/sql/intersected_indexes.sql index 1ccf51f..0b951f2 100644 --- a/sql/intersected_indexes.sql +++ b/sql/intersected_indexes.sql @@ -8,27 +8,30 @@ -- Finds indexes with overlapping sets of columns. -- For example, (A) and (A+B) and (A+B+C). -- Some of these indexes can usually be safely deleted. -with index_info as ( - select - pi.indrelid, - pi.indexrelid, - array_to_string(pi.indkey, ' ') as cols, - 'idx=' || pi.indexrelid::regclass || ', size=' || pg_relation_size(pi.indexrelid) as info, - coalesce(pg_get_expr(pi.indpred, pi.indrelid, true), '') as pred - from - pg_catalog.pg_index pi - join pg_catalog.pg_stat_all_indexes psai on pi.indexrelid = psai.indexrelid - where psai.schemaname = :schema_name_param::text -) +-- noqa: disable=ST09,ST05 +with + index_info as ( + select + pi.indrelid, + pi.indexrelid, + array_to_string(pi.indkey, ' ') as cols, + 'idx=' || pi.indexrelid::regclass || ', size=' || pg_relation_size(pi.indexrelid) as info, + coalesce(pg_get_expr(pi.indpred, pi.indrelid, true), '') as pred + from + pg_catalog.pg_index pi + inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = pi.indexrelid + where psai.schemaname = :schema_name_param::text + ) + select a.indrelid::regclass as table_name, a.info || '; ' || b.info as intersected_indexes from - (select * from index_info) as a - join - (select * from index_info) as b - on (a.indrelid = b.indrelid and a.indexrelid > b.indexrelid and ( - (a.cols like b.cols || '%' and coalesce(substr(a.cols, length(b.cols) + 1, 1), ' ') = ' ') or - (b.cols like a.cols || '%' and coalesce(substr(b.cols, length(a.cols) + 1, 1), ' ') = ' ')) and - a.pred = b.pred) + (select * from index_info) a + inner join + (select * from index_info) b on (a.indrelid = b.indrelid and a.indexrelid > b.indexrelid and ( + (a.cols like b.cols || '%' and coalesce(substr(a.cols, length(b.cols) + 1, 1), ' ') = ' ') or + (b.cols like a.cols || '%' and coalesce(substr(b.cols, length(a.cols) + 1, 1), ' ') = ' ') + ) and + a.pred = b.pred) order by a.indrelid::regclass::text; diff --git a/sql/invalid_indexes.sql b/sql/invalid_indexes.sql index f7efdf4..e63dbf0 100644 --- a/sql/invalid_indexes.sql +++ b/sql/invalid_indexes.sql @@ -12,7 +12,7 @@ select x.indexrelid::regclass as index_name 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 and x.indisvalid = false; diff --git a/sql/non_primary_key_columns_with_serial_types.sql b/sql/non_primary_key_columns_with_serial_types.sql index 8dbce7f..93136d0 100644 --- a/sql/non_primary_key_columns_with_serial_types.sql +++ b/sql/non_primary_key_columns_with_serial_types.sql @@ -15,13 +15,14 @@ select case col.atttypid when 'int'::regtype then 'serial' when 'int8'::regtype then 'bigserial' - when 'int2'::regtype then 'smallserial' end as column_type, + when 'int2'::regtype then 'smallserial' + end as column_type, pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name 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 - join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum + inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace + inner join pg_catalog.pg_attribute col on col.attrelid = t.oid + inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum left join lateral ( select sum(case when c.contype = 'p' then +1 else -1 end) as res from pg_constraint c @@ -30,7 +31,8 @@ from c.conkey[1] = col.attnum and c.contype in ('p', 'f') and /* primary or foreign key */ array_length(c.conkey, 1) = 1 /* single column */ - group by c.conrelid, c.conkey[1]) c on true + group by c.conrelid, c.conkey[1] + ) c on true where t.relkind = 'r' and col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */ diff --git a/sql/primary_keys_with_serial_types.sql b/sql/primary_keys_with_serial_types.sql index 83d52b4..e4ccfc2 100644 --- a/sql/primary_keys_with_serial_types.sql +++ b/sql/primary_keys_with_serial_types.sql @@ -18,17 +18,19 @@ select case col.atttypid when 'int'::regtype then 'serial' when 'int8'::regtype then 'bigserial' - when 'int2'::regtype then 'smallserial' end as column_type, - pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name -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 - join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum - join pg_catalog.pg_constraint c on c.conrelid = col.attrelid and col.attnum = any(c.conkey) + when 'int2'::regtype then 'smallserial' + end as column_type, + pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name +from + pg_catalog.pg_class t + inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace + inner join pg_catalog.pg_attribute col on col.attrelid = t.oid + inner join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum + inner join pg_catalog.pg_constraint c on c.conrelid = col.attrelid and col.attnum = any(c.conkey) where - col.atttypid = any('{int,int8,int2}'::regtype[]) - and not col.attisdropped - and c.contype = 'p' -- primary keys - and pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)::regclass || '''::regclass)' - and nsp.nspname = :schema_name_param::text + col.atttypid = any('{int,int8,int2}'::regtype[]) and + not col.attisdropped and + c.contype = 'p' and -- primary keys + pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)::regclass || '''::regclass)' and + nsp.nspname = :schema_name_param::text order by t.oid::regclass::text, col.attname::text; diff --git a/sql/sequence_overflow.sql b/sql/sequence_overflow.sql index c9e6f72..b45100b 100644 --- a/sql/sequence_overflow.sql +++ b/sql/sequence_overflow.sql @@ -5,39 +5,44 @@ * Licensed under the Apache License 2.0 */ -with all_sequences as ( - select - s.seqrelid::regclass::text as sequence_name, - s.seqtypid::regtype as data_type, - s.seqstart as start_value, - s.seqmin as min_value, - s.seqmax as max_value, - s.seqincrement as increment_by, - case when has_sequence_privilege(c.oid, 'select,usage'::text) - then pg_sequence_last_value(c.oid::regclass) - else null::bigint end as last_value - from - pg_sequence s - join pg_class c on c.oid = s.seqrelid - left join pg_namespace n on n.oid = c.relnamespace - where - not pg_is_other_temp_schema(n.oid) -- not temporary - and c.relkind = 'S'::char -- sequence object - and not s.seqcycle -- skip cycle sequences - and n.nspname = :schema_name_param::text -), -sequence_state as ( - select - t.sequence_name, - t.data_type, - case when t.increment_by > 0 -- ascending or descending sequence - then 100.0 * (t.max_value - coalesce(t.last_value, t.start_value)) / (t.max_value - t.min_value) - else 100.0 * (coalesce(t.last_value, t.start_value) - t.min_value) / (t.max_value - t.min_value) - end ::numeric(5, 2) as remaining_percentage -- percentage of remaining values - from all_sequences as t -) +with + all_sequences as ( + select + s.seqrelid::regclass::text as sequence_name, + s.seqtypid::regtype as data_type, + s.seqstart as start_value, + s.seqmin as min_value, + s.seqmax as max_value, + s.seqincrement as increment_by, + case + when has_sequence_privilege(c.oid, 'select,usage'::text) then pg_sequence_last_value(c.oid::regclass) + else null::bigint + end as last_value + from + pg_sequence s + inner join pg_class c on c.oid = s.seqrelid + left join pg_namespace n on n.oid = c.relnamespace + where + not pg_is_other_temp_schema(n.oid) and -- not temporary + c.relkind = 'S'::char and -- sequence object + not s.seqcycle and -- skip cycle sequences + n.nspname = :schema_name_param::text + ), + + sequence_state as ( + select + t.sequence_name, + t.data_type, + case + -- ascending or descending sequence + when t.increment_by > 0 then 100.0 * (t.max_value - coalesce(t.last_value, t.start_value)) / (t.max_value - t.min_value) + else 100.0 * (coalesce(t.last_value, t.start_value) - t.min_value) / (t.max_value - t.min_value) + end ::numeric(5, 2) as remaining_percentage -- percentage of remaining values + from all_sequences t + ) + select s.* -from sequence_state as s +from sequence_state s where s.remaining_percentage <= :remaining_percentage_threshold::numeric(5, 2) order by s.sequence_name; diff --git a/sql/tables_with_missing_indexes.sql b/sql/tables_with_missing_indexes.sql index 2245419..fa02b2a 100644 --- a/sql/tables_with_missing_indexes.sql +++ b/sql/tables_with_missing_indexes.sql @@ -7,16 +7,18 @@ -- Finds tables that may not have enough indexes. -- It is important to understand that this check will give a false positive result for small tables. -with tables_without_indexes as ( - select - psat.relid::regclass::text as table_name, - pg_table_size(psat.relid) as table_size, - coalesce(psat.seq_scan, 0) - coalesce(psat.idx_scan, 0) as too_much_seq, - coalesce(psat.seq_scan, 0) as seq_scan, - coalesce(psat.idx_scan, 0) as idx_scan - from pg_catalog.pg_stat_all_tables psat - where psat.schemaname = :schema_name_param::text -) +with + tables_without_indexes as ( + select + psat.relid::regclass::text as table_name, + pg_table_size(psat.relid) as table_size, + coalesce(psat.seq_scan, 0) - coalesce(psat.idx_scan, 0) as too_much_seq, + coalesce(psat.seq_scan, 0) as seq_scan, + coalesce(psat.idx_scan, 0) as idx_scan + from pg_catalog.pg_stat_all_tables psat + where psat.schemaname = :schema_name_param::text + ) + select table_name, table_size, @@ -26,4 +28,4 @@ from tables_without_indexes where (seq_scan + idx_scan) > 100::integer and /*table in use*/ too_much_seq > 0 /*too much sequential scans*/ -order by table_name, too_much_seq desc; +order by table_name asc, too_much_seq desc; diff --git a/sql/tables_without_description.sql b/sql/tables_without_description.sql index 11c5c3f..3a46060 100644 --- a/sql/tables_without_description.sql +++ b/sql/tables_without_description.sql @@ -11,7 +11,7 @@ select pg_table_size(pc.oid) as table_size from pg_catalog.pg_class pc - join pg_catalog.pg_namespace pn on pc.relnamespace = pn.oid + inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace where pc.relkind = 'r' and (obj_description(pc.oid) is null or length(trim(obj_description(pc.oid))) = 0) and diff --git a/sql/tables_without_primary_key.sql b/sql/tables_without_primary_key.sql index 838f782..d3d9115 100644 --- a/sql/tables_without_primary_key.sql +++ b/sql/tables_without_primary_key.sql @@ -11,12 +11,13 @@ select pg_table_size(pc.oid) as table_size from pg_catalog.pg_class pc - join pg_catalog.pg_namespace pn on pc.relnamespace = pn.oid + inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace where pc.relkind = 'r' and pc.oid not in ( select c.conrelid as table_oid from pg_catalog.pg_constraint c - where c.contype = 'p') and + where c.contype = 'p' + ) and pn.nspname = :schema_name_param::text order by pc.oid::regclass::text; diff --git a/sql/unused_indexes.sql b/sql/unused_indexes.sql index 2f3b6d5..dbab76b 100644 --- a/sql/unused_indexes.sql +++ b/sql/unused_indexes.sql @@ -8,22 +8,24 @@ -- Finds potentially unused indexes. -- This sql query have to be executed on all hosts in the cluster. -- The final result can be obtained as an intersection of results from all hosts. -with foreign_key_indexes as ( - select i.indexrelid - from - pg_catalog.pg_constraint c - join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true - join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.indkey::int[]) - where c.contype = 'f' -) +with + foreign_key_indexes as ( + select i.indexrelid + from + pg_catalog.pg_constraint c + inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true + inner join pg_catalog.pg_index i on i.indrelid = c.conrelid and (c.conkey::int[] <@ i.indkey::int[]) + where c.contype = 'f' + ) + select psui.relid::regclass::text as table_name, psui.indexrelid::regclass::text as index_name, - pg_relation_size(i.indexrelid) as index_size, - psui.idx_scan as index_scans + psui.idx_scan as index_scans, + pg_relation_size(i.indexrelid) as index_size from pg_catalog.pg_stat_user_indexes psui - join pg_catalog.pg_index i on psui.indexrelid = i.indexrelid + inner join pg_catalog.pg_index i on i.indexrelid = psui.indexrelid where psui.schemaname = :schema_name_param::text and not i.indisunique and