Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add check to find intersected foreign keys #51

Merged
merged 2 commits into from
Oct 6, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand Down
6 changes: 3 additions & 3 deletions sql/bloated_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
),

Expand Down
8 changes: 4 additions & 4 deletions sql/btree_indexes_on_array_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
4 changes: 2 additions & 2 deletions sql/check_not_valid_constraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
2 changes: 1 addition & 1 deletion sql/columns_with_json_type.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
2 changes: 1 addition & 1 deletion sql/columns_without_description.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
4 changes: 2 additions & 2 deletions sql/duplicated_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
)
Expand All @@ -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;
2 changes: 1 addition & 1 deletion sql/duplicated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 || ' ' ||
Expand Down
6 changes: 3 additions & 3 deletions sql/foreign_keys_without_index.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
2 changes: 1 addition & 1 deletion sql/indexes_with_boolean.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
4 changes: 2 additions & 2 deletions sql/indexes_with_null_values.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
55 changes: 55 additions & 0 deletions sql/intersected_foreign_keys.sql
Original file line number Diff line number Diff line change
@@ -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;
4 changes: 2 additions & 2 deletions sql/intersected_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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;
7 changes: 4 additions & 3 deletions sql/invalid_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
2 changes: 1 addition & 1 deletion sql/non_primary_key_columns_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
6 changes: 3 additions & 3 deletions sql/primary_keys_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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'
Expand All @@ -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;
6 changes: 3 additions & 3 deletions sql/sequence_overflow.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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 (
Expand Down
2 changes: 1 addition & 1 deletion sql/tables_without_description.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
2 changes: 1 addition & 1 deletion sql/tables_without_primary_key.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
2 changes: 1 addition & 1 deletion sql/unused_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;