From bd73b77fbeb0440c304283ede1a935990551e18d Mon Sep 17 00:00:00 2001 From: Ivan Vakhrushev Date: Sun, 6 Oct 2024 00:11:14 +0400 Subject: [PATCH] Removed unnecessary parts --- sql/bloated_indexes.sql | 10 ++-- sql/check_not_valid_constraints.sql | 5 +- sql/duplicated_foreign_keys.sql | 70 +++++++++++---------------- sql/foreign_keys_without_index.sql | 5 +- sql/functions_without_description.sql | 8 +-- sql/indexes_with_boolean.sql | 4 +- sql/tables_without_description.sql | 4 +- sql/tables_without_primary_key.sql | 4 +- 8 files changed, 48 insertions(+), 62 deletions(-) diff --git a/sql/bloated_indexes.sql b/sql/bloated_indexes.sql index a77409b..657e4b5 100644 --- a/sql/bloated_indexes.sql +++ b/sql/bloated_indexes.sql @@ -27,17 +27,17 @@ with pi.indrelid as table_oid, pi.indexrelid as index_oid, pi.indnatts, - pn.nspname, + nsp.nspname, coalesce(substring(array_to_string(pc.reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 90) as fill_factor, string_to_array(textin(int2vectorout(pi.indkey)), ' ')::int[] as indkey from pg_catalog.pg_index pi 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_namespace nsp on nsp.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 + nsp.nspname = :schema_name_param::text ), nested_indexes_attributes as ( @@ -102,8 +102,8 @@ with max(case when i.atttypid = 'pg_catalog.name'::regtype then 1 else 0 end) > 0 as stats_not_available from named_indexes_attributes i - 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 + inner join pg_catalog.pg_namespace nsp on nsp.oid = i.relnamespace + inner join pg_catalog.pg_stats s on s.schemaname = nsp.nspname and s.tablename = i.attrelname and s.attname = i.attname group by 1, 2, 3, 4, 5, 6, 7, 8, 9 ), diff --git a/sql/check_not_valid_constraints.sql b/sql/check_not_valid_constraints.sql index 0a88130..e9f46c0 100644 --- a/sql/check_not_valid_constraints.sql +++ b/sql/check_not_valid_constraints.sql @@ -11,10 +11,9 @@ select c.contype as constraint_type -- Type of the constraint from pg_catalog.pg_constraint c - inner join pg_catalog.pg_class t on t.oid = c.conrelid - inner join pg_catalog.pg_namespace n on n.oid = t.relnamespace + inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace where 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 + nsp.nspname = :schema_name_param::text -- Make the query schema-aware order by c.conrelid::regclass::text, c.conname; diff --git a/sql/duplicated_foreign_keys.sql b/sql/duplicated_foreign_keys.sql index 54fb68a..aaacaab 100644 --- a/sql/duplicated_foreign_keys.sql +++ b/sql/duplicated_foreign_keys.sql @@ -5,61 +5,49 @@ * Licensed under the Apache License 2.0 */ --- Finds potentially duplicated foreign keys +-- Finds completely identical foreign keys -- -- Based on query from https://habr.com/ru/articles/803841/ --- noqa: disable=PRS with fk_with_attributes as ( select - c.conname as fk_name, - c.conrelid, - c.confrelid, - fk_conkey.conkey_order as att_order, - fk_conkey.conkey_number, - fk_confkey.confkey_number, - rel_att.attname as rel_att_name, - rel_att.atttypid as rel_att_type_id_1, - rel_att.atttypmod as rel_att_type_mod_1, - rel_att.attnotnull as rel_att_notnull_1, - frel_att.attname as frel_att_name, - frel_att.atttypid as frel_att_type_id_2, - frel_att.atttypmod as frel_att_type_mod_2, - frel_att.attnotnull as frel_att_notnull_2 + c.conname as constraint_name, + c.conrelid as table_oid, + c.confrelid as foreign_table_oid, + u.attposition, + col.attname, + col.attnotnull from pg_catalog.pg_constraint c - cross join lateral unnest(c.conkey) with ordinality fk_conkey(conkey_number, conkey_order) - left join lateral unnest(c.confkey) with ordinality fk_confkey(confkey_number, confkey_order) - on fk_confkey.confkey_order = fk_conkey.conkey_order - left join pg_catalog.pg_attribute rel_att - on rel_att.attrelid = c.conrelid and rel_att.attnum = fk_conkey.conkey_number - left join pg_catalog.pg_attribute frel_att - on frel_att.attrelid = c.confrelid and frel_att.attnum = fk_confkey.confkey_number - where c.contype = 'f' + inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace + inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true + inner join pg_catalog.pg_attribute col on col.attrelid = c.conrelid and col.attnum = u.attnum + where + c.contype = 'f' and + nsp.nspname = :schema_name_param::text ), fk_with_attributes_grouped as ( select - fk_name, - conrelid, - confrelid, - array_agg(rel_att_name order by att_order) as rel_att_names, - array_agg(frel_att_name order by att_order) as frel_att_names + constraint_name, + table_oid, + foreign_table_oid, + array_agg(attname || ', ' || attnotnull::text order by attposition) as columns from fk_with_attributes - group by fk_name, conrelid, confrelid + group by constraint_name, table_oid, foreign_table_oid ) select - r_from.oid::regclass::text as table_name, - c1.fk_name as constraint_name, - c2.fk_name as duplicate_constraint_name + c1.table_oid::regclass::text as table_name, + c1.constraint_name, + c1.columns, + c2.constraint_name as duplicate_constraint_name, + c2.columns as duplicate_constraint_columns from - pg_catalog.pg_class r_from - inner join pg_catalog.pg_namespace nsp on nsp.oid = r_from.relnamespace - inner join fk_with_attributes_grouped c1 on c1.conrelid = r_from.oid + fk_with_attributes_grouped c1 inner join fk_with_attributes_grouped c2 - on c2.fk_name > c1.fk_name and c2.conrelid = c1.conrelid and c2.confrelid = c1.confrelid and c2.rel_att_names = c1.rel_att_names -where - r_from.relkind = 'r' and - nsp.nspname = :schema_name_param::text -order by r_from.oid::regclass::text, c1.fk_name; + on c2.constraint_name > c1.constraint_name and -- to prevent duplicated rows in output + c2.table_oid = c1.table_oid and + c2.foreign_table_oid = c1.foreign_table_oid and + c2.columns = c1.columns +order by c1.table_oid::regclass::text, c1.constraint_name, c2.constraint_name; diff --git a/sql/foreign_keys_without_index.sql b/sql/foreign_keys_without_index.sql index 0ccd94c..0ccc8dd 100644 --- a/sql/foreign_keys_without_index.sql +++ b/sql/foreign_keys_without_index.sql @@ -14,9 +14,8 @@ select from pg_catalog.pg_constraint c 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 + inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace + inner join pg_catalog.pg_attribute col on col.attrelid = c.conrelid 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 20c7a78..febab21 100644 --- a/sql/functions_without_description.sql +++ b/sql/functions_without_description.sql @@ -8,12 +8,12 @@ -- Finds functions and procedures that don't have a description. -- See also https://www.postgresql.org/docs/current/sql-comment.html select - case when n.nspname = 'public'::text then p.proname else n.nspname || '.' || p.proname end as function_name, + case when nsp.nspname = 'public'::text then p.proname else nsp.nspname || '.' || p.proname end as function_name, pg_get_function_identity_arguments(p.oid) as function_signature from - pg_catalog.pg_namespace n - inner join pg_catalog.pg_proc p on p.pronamespace = n.oid + pg_catalog.pg_namespace nsp + inner join pg_catalog.pg_proc p on p.pronamespace = nsp.oid where (obj_description(p.oid) is null or length(trim(obj_description(p.oid))) = 0) and - n.nspname = :schema_name_param::text + nsp.nspname = :schema_name_param::text order by function_name, function_signature; diff --git a/sql/indexes_with_boolean.sql b/sql/indexes_with_boolean.sql index 64ac374..01df01f 100644 --- a/sql/indexes_with_boolean.sql +++ b/sql/indexes_with_boolean.sql @@ -15,10 +15,10 @@ select from pg_catalog.pg_index pi 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_namespace nsp on nsp.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 + nsp.nspname = :schema_name_param::text and not pi.indisunique and pi.indisready and pi.indisvalid and diff --git a/sql/tables_without_description.sql b/sql/tables_without_description.sql index 3a46060..4db43b5 100644 --- a/sql/tables_without_description.sql +++ b/sql/tables_without_description.sql @@ -11,9 +11,9 @@ select pg_table_size(pc.oid) as table_size from pg_catalog.pg_class pc - inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace + inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace where pc.relkind = 'r' and (obj_description(pc.oid) is null or length(trim(obj_description(pc.oid))) = 0) and - pn.nspname = :schema_name_param::text + nsp.nspname = :schema_name_param::text order by pc.oid::regclass::text; diff --git a/sql/tables_without_primary_key.sql b/sql/tables_without_primary_key.sql index d3d9115..8d6af07 100644 --- a/sql/tables_without_primary_key.sql +++ b/sql/tables_without_primary_key.sql @@ -11,7 +11,7 @@ select pg_table_size(pc.oid) as table_size from pg_catalog.pg_class pc - inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace + inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace where pc.relkind = 'r' and pc.oid not in ( @@ -19,5 +19,5 @@ where from pg_catalog.pg_constraint c where c.contype = 'p' ) and - pn.nspname = :schema_name_param::text + nsp.nspname = :schema_name_param::text order by pc.oid::regclass::text;