diff --git a/README.md b/README.md index 74c52d4..3bc19e9 100644 --- a/README.md +++ b/README.md @@ -43,6 +43,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg 19. [Sequence overflow](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/sequence_overflow.sql)). 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)). 21. Duplicated (completely identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/duplicated_foreign_keys.sql)). +22. Intersected (partially identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/intersected_foreign_keys.sql)). ## Local development diff --git a/sql/bloated_tables.sql b/sql/bloated_tables.sql index 2dfbe73..c3dfee9 100644 --- a/sql/bloated_tables.sql +++ b/sql/bloated_tables.sql @@ -35,14 +35,14 @@ with from 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 + inner join pg_namespace nsp on nsp.oid = pc.relnamespace + left join pg_stats ps on ps.schemaname = nsp.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 + nsp.nspname = :schema_name_param::text group by table_oid, pc.reltuples, heap_pages, toast_pages, toast_tuples, fill_factor, block_size, page_header_size ), diff --git a/sql/btree_indexes_on_array_columns.sql b/sql/btree_indexes_on_array_columns.sql index e3d3a40..6573f28 100644 --- a/sql/btree_indexes_on_array_columns.sql +++ b/sql/btree_indexes_on_array_columns.sql @@ -10,9 +10,9 @@ -- 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, - i.indexrelid::regclass as index_name, - col.attname as column_name, + i.indrelid::regclass::text as table_name, + i.indexrelid::regclass::text as index_name, + col.attname::text as column_name, col.attnotnull as column_not_null, pg_relation_size(i.indexrelid) as index_size from pg_catalog.pg_index i @@ -24,4 +24,4 @@ from pg_catalog.pg_index i 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 -order by ic.oid::regclass::text, i.indexrelid::regclass::text; +order by table_name, index_name; diff --git a/sql/check_not_valid_constraints.sql b/sql/check_not_valid_constraints.sql index e9f46c0..6a62b77 100644 --- a/sql/check_not_valid_constraints.sql +++ b/sql/check_not_valid_constraints.sql @@ -6,7 +6,7 @@ */ select - c.conrelid::regclass as table_name, -- Name of the table + c.conrelid::regclass::text as table_name, -- Name of the table c.conname as constraint_name, -- Name of the constraint c.contype as constraint_type -- Type of the constraint from @@ -16,4 +16,4 @@ 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 nsp.nspname = :schema_name_param::text -- Make the query schema-aware -order by c.conrelid::regclass::text, c.conname; +order by table_name, c.conname; diff --git a/sql/columns_with_json_type.sql b/sql/columns_with_json_type.sql index 2a3ae42..c19c001 100644 --- a/sql/columns_with_json_type.sql +++ b/sql/columns_with_json_type.sql @@ -23,4 +23,4 @@ where not col.attisdropped and col.atttypid = 'json'::regtype and nsp.nspname = :schema_name_param::text -order by t.oid::regclass::text, col.attname::text; +order by table_name, column_name; diff --git a/sql/columns_without_description.sql b/sql/columns_without_description.sql index fa813d4..494daf0 100644 --- a/sql/columns_without_description.sql +++ b/sql/columns_without_description.sql @@ -20,4 +20,4 @@ where not col.attisdropped and (col_description(t.oid, col.attnum) is null or length(trim(col_description(t.oid, col.attnum))) = 0) and nsp.nspname = :schema_name_param::text -order by t.oid::regclass::text, col.attname::text; +order by table_name, column_name; diff --git a/sql/duplicated_foreign_keys.sql b/sql/duplicated_foreign_keys.sql index aaacaab..cac329b 100644 --- a/sql/duplicated_foreign_keys.sql +++ b/sql/duplicated_foreign_keys.sql @@ -32,7 +32,7 @@ with constraint_name, table_oid, foreign_table_oid, - array_agg(attname || ', ' || attnotnull::text order by attposition) as columns + array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns from fk_with_attributes group by constraint_name, table_oid, foreign_table_oid ) @@ -50,4 +50,4 @@ from 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; +order by table_name, c1.constraint_name, c2.constraint_name; diff --git a/sql/duplicated_indexes.sql b/sql/duplicated_indexes.sql index 433c40f..7a1c8f9 100644 --- a/sql/duplicated_indexes.sql +++ b/sql/duplicated_indexes.sql @@ -12,7 +12,7 @@ select from ( select x.indexrelid::regclass as idx, - x.indrelid::regclass as table_name, + x.indrelid::regclass::text as table_name, -- cast to text for sorting purposes ( x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' || x.indcollation::text || ' ' || diff --git a/sql/foreign_keys_without_index.sql b/sql/foreign_keys_without_index.sql index 0ccc8dd..a95ae32 100644 --- a/sql/foreign_keys_without_index.sql +++ b/sql/foreign_keys_without_index.sql @@ -8,9 +8,9 @@ -- Finds foreign keys for which no index was created in the referencing (child) table. -- This will cause the child table to be scanned sequentially when deleting an entry from the referenced (parent) table. select - c.conrelid::regclass as table_name, + c.conrelid::regclass::text as table_name, c.conname as constraint_name, - array_agg(col.attname || ', ' || col.attnotnull::text order by u.attposition) as columns + array_agg(col.attname::text || ', ' || col.attnotnull::text order by u.attposition) as columns from pg_catalog.pg_constraint c inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true @@ -28,4 +28,4 @@ where array_position(pi.indkey::int[], (c.conkey::int[])[1]) = 0 /* ordering of columns in foreign key and in index is the same */ ) group by c.conrelid, c.conname, c.oid -order by (c.conrelid::regclass)::text, columns; +order by table_name, columns; diff --git a/sql/indexes_with_boolean.sql b/sql/indexes_with_boolean.sql index 01df01f..95601b8 100644 --- a/sql/indexes_with_boolean.sql +++ b/sql/indexes_with_boolean.sql @@ -9,7 +9,7 @@ select pi.indrelid::regclass::text as table_name, pi.indexrelid::regclass::text as index_name, - col.attname as column_name, + col.attname::text as column_name, col.attnotnull as column_not_null, pg_relation_size(pi.indexrelid) as index_size from diff --git a/sql/indexes_with_null_values.sql b/sql/indexes_with_null_values.sql index 23d32d1..d32c801 100644 --- a/sql/indexes_with_null_values.sql +++ b/sql/indexes_with_null_values.sql @@ -7,8 +7,8 @@ -- Finds indexes that can contain null values. select - x.indrelid::regclass as table_name, - x.indexrelid::regclass as index_name, + x.indrelid::regclass::text as table_name, + x.indexrelid::regclass::text as index_name, string_agg(a.attname, ', ') as nullable_fields, -- In fact, there will always be only one column. pg_relation_size(x.indexrelid) as index_size from diff --git a/sql/intersected_foreign_keys.sql b/sql/intersected_foreign_keys.sql new file mode 100644 index 0000000..93017a7 --- /dev/null +++ b/sql/intersected_foreign_keys.sql @@ -0,0 +1,55 @@ +/* + * Copyright (c) 2019-2024. Ivan Vakhrushev and others. + * https://github.com/mfvanek/pg-index-health-sql + * + * Licensed under the Apache License 2.0 + */ + +-- Finds partially identical foreign keys (with overlapping sets of columns). +-- +-- Based on query from https://habr.com/ru/articles/803841/ +with + fk_with_attributes as ( + select + 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 + 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 + constraint_name, + table_oid, + foreign_table_oid, + array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns + from fk_with_attributes + group by constraint_name, table_oid, foreign_table_oid + ) + +select + c1.table_oid::regclass::text as table_name, + c1.constraint_name, + c1.columns, + c2.constraint_name as intersected_constraint_name, + c2.columns as intersected_constraint_columns +from + fk_with_attributes_grouped c1 + inner join fk_with_attributes_grouped c2 + 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 -- arrays overlap/have any elements in common? +where + c2.columns != c1.columns -- skip full duplicates +order by table_name, c1.constraint_name, c2.constraint_name; diff --git a/sql/intersected_indexes.sql b/sql/intersected_indexes.sql index 0b951f2..ebd1947 100644 --- a/sql/intersected_indexes.sql +++ b/sql/intersected_indexes.sql @@ -24,7 +24,7 @@ with ) select - a.indrelid::regclass as table_name, + a.indrelid::regclass::text as table_name, a.info || '; ' || b.info as intersected_indexes from (select * from index_info) a @@ -34,4 +34,4 @@ from (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; +order by table_name, intersected_indexes; diff --git a/sql/invalid_indexes.sql b/sql/invalid_indexes.sql index e63dbf0..6cc49e6 100644 --- a/sql/invalid_indexes.sql +++ b/sql/invalid_indexes.sql @@ -8,11 +8,12 @@ -- Finds invalid indexes that might have appeared as a result of -- unsuccessful execution of the 'create index concurrently' command. select - x.indrelid::regclass as table_name, - x.indexrelid::regclass as index_name + x.indrelid::regclass::text as table_name, + x.indexrelid::regclass::text as index_name from pg_catalog.pg_index x 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; + x.indisvalid = false +order by table_name, index_name; diff --git a/sql/non_primary_key_columns_with_serial_types.sql b/sql/non_primary_key_columns_with_serial_types.sql index 93136d0..70b3d00 100644 --- a/sql/non_primary_key_columns_with_serial_types.sql +++ b/sql/non_primary_key_columns_with_serial_types.sql @@ -42,4 +42,4 @@ where /* column default value = nextval from owned sequence */ 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; +order by table_name, column_name; diff --git a/sql/primary_keys_with_serial_types.sql b/sql/primary_keys_with_serial_types.sql index e4ccfc2..918cf35 100644 --- a/sql/primary_keys_with_serial_types.sql +++ b/sql/primary_keys_with_serial_types.sql @@ -12,8 +12,8 @@ -- See also https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial -- and https://stackoverflow.com/questions/55300370/postgresql-serial-vs-identity select - col.attrelid::regclass as table_name, - col.attname as column_name, + col.attrelid::regclass::text as table_name, + col.attname::text as column_name, col.attnotnull as column_not_null, case col.atttypid when 'int'::regtype then 'serial' @@ -33,4 +33,4 @@ where 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; +order by table_name, column_name; diff --git a/sql/sequence_overflow.sql b/sql/sequence_overflow.sql index b45100b..6af7598 100644 --- a/sql/sequence_overflow.sql +++ b/sql/sequence_overflow.sql @@ -21,12 +21,12 @@ with from pg_sequence s inner join pg_class c on c.oid = s.seqrelid - left join pg_namespace n on n.oid = c.relnamespace + left join pg_namespace nsp on nsp.oid = c.relnamespace where - not pg_is_other_temp_schema(n.oid) and -- not temporary + not pg_is_other_temp_schema(nsp.oid) and -- not temporary c.relkind = 'S'::char and -- sequence object not s.seqcycle and -- skip cycle sequences - n.nspname = :schema_name_param::text + nsp.nspname = :schema_name_param::text ), sequence_state as ( diff --git a/sql/tables_without_description.sql b/sql/tables_without_description.sql index 4db43b5..069b6d9 100644 --- a/sql/tables_without_description.sql +++ b/sql/tables_without_description.sql @@ -16,4 +16,4 @@ where pc.relkind = 'r' and (obj_description(pc.oid) is null or length(trim(obj_description(pc.oid))) = 0) and nsp.nspname = :schema_name_param::text -order by pc.oid::regclass::text; +order by table_name; diff --git a/sql/tables_without_primary_key.sql b/sql/tables_without_primary_key.sql index 8d6af07..b948f91 100644 --- a/sql/tables_without_primary_key.sql +++ b/sql/tables_without_primary_key.sql @@ -20,4 +20,4 @@ where where c.contype = 'p' ) and nsp.nspname = :schema_name_param::text -order by pc.oid::regclass::text; +order by table_name; diff --git a/sql/unused_indexes.sql b/sql/unused_indexes.sql index dbab76b..e05c951 100644 --- a/sql/unused_indexes.sql +++ b/sql/unused_indexes.sql @@ -31,4 +31,4 @@ where not i.indisunique and i.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */ psui.idx_scan < 50::integer -order by psui.relname, pg_relation_size(i.indexrelid) desc; +order by table_name, pg_relation_size(i.indexrelid) desc;