Skip to content

Commit 0fcb826

Browse files
authored
Add check to find intersected foreign keys (#51)
* Clean up * Add query to find intersected (partially identical) foreign keys
1 parent f28916e commit 0fcb826

20 files changed

+92
-35
lines changed

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -43,6 +43,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
4343
19. [Sequence overflow](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/sequence_overflow.sql)).
4444
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)).
4545
21. Duplicated (completely identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/duplicated_foreign_keys.sql)).
46+
22. Intersected (partially identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/intersected_foreign_keys.sql)).
4647

4748
## Local development
4849

sql/bloated_tables.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -35,14 +35,14 @@ with
3535
from
3636
pg_attribute pa
3737
inner join pg_class pc on pc.oid = pa.attrelid
38-
inner join pg_namespace pn on pn.oid = pc.relnamespace
39-
left join pg_stats ps on ps.schemaname = pn.nspname and ps.tablename = pc.relname and ps.inherited = false and ps.attname = pa.attname
38+
inner join pg_namespace nsp on nsp.oid = pc.relnamespace
39+
left join pg_stats ps on ps.schemaname = nsp.nspname and ps.tablename = pc.relname and ps.inherited = false and ps.attname = pa.attname
4040
left join pg_class toast on toast.oid = pc.reltoastrelid
4141
where
4242
not pa.attisdropped and
4343
pc.relkind = 'r' and
4444
pc.relpages > 0 and
45-
pn.nspname = :schema_name_param::text
45+
nsp.nspname = :schema_name_param::text
4646
group by table_oid, pc.reltuples, heap_pages, toast_pages, toast_tuples, fill_factor, block_size, page_header_size
4747
),
4848

sql/btree_indexes_on_array_columns.sql

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -10,9 +10,9 @@
1010
-- GIN-index should be used instead for such columns
1111
-- Based on query from https://habr.com/ru/articles/800121/
1212
select
13-
i.indrelid::regclass as table_name,
14-
i.indexrelid::regclass as index_name,
15-
col.attname as column_name,
13+
i.indrelid::regclass::text as table_name,
14+
i.indexrelid::regclass::text as index_name,
15+
col.attname::text as column_name,
1616
col.attnotnull as column_not_null,
1717
pg_relation_size(i.indexrelid) as index_size
1818
from pg_catalog.pg_index i
@@ -24,4 +24,4 @@ from pg_catalog.pg_index i
2424
where
2525
nsp.nspname = :schema_name_param::text and
2626
typ.typcategory = 'A' -- A stands for Array type. See - https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
27-
order by ic.oid::regclass::text, i.indexrelid::regclass::text;
27+
order by table_name, index_name;

sql/check_not_valid_constraints.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -6,7 +6,7 @@
66
*/
77

88
select
9-
c.conrelid::regclass as table_name, -- Name of the table
9+
c.conrelid::regclass::text as table_name, -- Name of the table
1010
c.conname as constraint_name, -- Name of the constraint
1111
c.contype as constraint_type -- Type of the constraint
1212
from
@@ -16,4 +16,4 @@ where
1616
not c.convalidated and -- Constraints that have not yet been validated
1717
c.contype in ('c', 'f') and -- Focus on check and foreign key constraints
1818
nsp.nspname = :schema_name_param::text -- Make the query schema-aware
19-
order by c.conrelid::regclass::text, c.conname;
19+
order by table_name, c.conname;

sql/columns_with_json_type.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -23,4 +23,4 @@ where
2323
not col.attisdropped and
2424
col.atttypid = 'json'::regtype and
2525
nsp.nspname = :schema_name_param::text
26-
order by t.oid::regclass::text, col.attname::text;
26+
order by table_name, column_name;

sql/columns_without_description.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -20,4 +20,4 @@ where
2020
not col.attisdropped and
2121
(col_description(t.oid, col.attnum) is null or length(trim(col_description(t.oid, col.attnum))) = 0) and
2222
nsp.nspname = :schema_name_param::text
23-
order by t.oid::regclass::text, col.attname::text;
23+
order by table_name, column_name;

sql/duplicated_foreign_keys.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -32,7 +32,7 @@ with
3232
constraint_name,
3333
table_oid,
3434
foreign_table_oid,
35-
array_agg(attname || ', ' || attnotnull::text order by attposition) as columns
35+
array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns
3636
from fk_with_attributes
3737
group by constraint_name, table_oid, foreign_table_oid
3838
)
@@ -50,4 +50,4 @@ from
5050
c2.table_oid = c1.table_oid and
5151
c2.foreign_table_oid = c1.foreign_table_oid and
5252
c2.columns = c1.columns
53-
order by c1.table_oid::regclass::text, c1.constraint_name, c2.constraint_name;
53+
order by table_name, c1.constraint_name, c2.constraint_name;

sql/duplicated_indexes.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -12,7 +12,7 @@ select
1212
from (
1313
select
1414
x.indexrelid::regclass as idx,
15-
x.indrelid::regclass as table_name,
15+
x.indrelid::regclass::text as table_name, -- cast to text for sorting purposes
1616
(
1717
x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
1818
x.indcollation::text || ' ' ||

sql/foreign_keys_without_index.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -8,9 +8,9 @@
88
-- Finds foreign keys for which no index was created in the referencing (child) table.
99
-- This will cause the child table to be scanned sequentially when deleting an entry from the referenced (parent) table.
1010
select
11-
c.conrelid::regclass as table_name,
11+
c.conrelid::regclass::text as table_name,
1212
c.conname as constraint_name,
13-
array_agg(col.attname || ', ' || col.attnotnull::text order by u.attposition) as columns
13+
array_agg(col.attname::text || ', ' || col.attnotnull::text order by u.attposition) as columns
1414
from
1515
pg_catalog.pg_constraint c
1616
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
@@ -28,4 +28,4 @@ where
2828
array_position(pi.indkey::int[], (c.conkey::int[])[1]) = 0 /* ordering of columns in foreign key and in index is the same */
2929
)
3030
group by c.conrelid, c.conname, c.oid
31-
order by (c.conrelid::regclass)::text, columns;
31+
order by table_name, columns;

sql/indexes_with_boolean.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -9,7 +9,7 @@
99
select
1010
pi.indrelid::regclass::text as table_name,
1111
pi.indexrelid::regclass::text as index_name,
12-
col.attname as column_name,
12+
col.attname::text as column_name,
1313
col.attnotnull as column_not_null,
1414
pg_relation_size(pi.indexrelid) as index_size
1515
from

sql/indexes_with_null_values.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -7,8 +7,8 @@
77

88
-- Finds indexes that can contain null values.
99
select
10-
x.indrelid::regclass as table_name,
11-
x.indexrelid::regclass as index_name,
10+
x.indrelid::regclass::text as table_name,
11+
x.indexrelid::regclass::text as index_name,
1212
string_agg(a.attname, ', ') as nullable_fields, -- In fact, there will always be only one column.
1313
pg_relation_size(x.indexrelid) as index_size
1414
from

sql/intersected_foreign_keys.sql

Lines changed: 55 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,55 @@
1+
/*
2+
* Copyright (c) 2019-2024. Ivan Vakhrushev and others.
3+
* https://github.com/mfvanek/pg-index-health-sql
4+
*
5+
* Licensed under the Apache License 2.0
6+
*/
7+
8+
-- Finds partially identical foreign keys (with overlapping sets of columns).
9+
--
10+
-- Based on query from https://habr.com/ru/articles/803841/
11+
with
12+
fk_with_attributes as (
13+
select
14+
c.conname as constraint_name,
15+
c.conrelid as table_oid,
16+
c.confrelid as foreign_table_oid,
17+
u.attposition,
18+
col.attname,
19+
col.attnotnull
20+
from
21+
pg_catalog.pg_constraint c
22+
inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace
23+
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
24+
inner join pg_catalog.pg_attribute col on col.attrelid = c.conrelid and col.attnum = u.attnum
25+
where
26+
c.contype = 'f' and
27+
nsp.nspname = :schema_name_param::text
28+
),
29+
30+
fk_with_attributes_grouped as (
31+
select
32+
constraint_name,
33+
table_oid,
34+
foreign_table_oid,
35+
array_agg(attname::text || ', ' || attnotnull::text order by attposition) as columns
36+
from fk_with_attributes
37+
group by constraint_name, table_oid, foreign_table_oid
38+
)
39+
40+
select
41+
c1.table_oid::regclass::text as table_name,
42+
c1.constraint_name,
43+
c1.columns,
44+
c2.constraint_name as intersected_constraint_name,
45+
c2.columns as intersected_constraint_columns
46+
from
47+
fk_with_attributes_grouped c1
48+
inner join fk_with_attributes_grouped c2
49+
on c2.constraint_name > c1.constraint_name and -- to prevent duplicated rows in output
50+
c2.table_oid = c1.table_oid and
51+
c2.foreign_table_oid = c1.foreign_table_oid and
52+
c2.columns && c1.columns -- arrays overlap/have any elements in common?
53+
where
54+
c2.columns != c1.columns -- skip full duplicates
55+
order by table_name, c1.constraint_name, c2.constraint_name;

sql/intersected_indexes.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -24,7 +24,7 @@ with
2424
)
2525

2626
select
27-
a.indrelid::regclass as table_name,
27+
a.indrelid::regclass::text as table_name,
2828
a.info || '; ' || b.info as intersected_indexes
2929
from
3030
(select * from index_info) a
@@ -34,4 +34,4 @@ from
3434
(b.cols like a.cols || '%' and coalesce(substr(b.cols, length(a.cols) + 1, 1), ' ') = ' ')
3535
) and
3636
a.pred = b.pred)
37-
order by a.indrelid::regclass::text;
37+
order by table_name, intersected_indexes;

sql/invalid_indexes.sql

Lines changed: 4 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -8,11 +8,12 @@
88
-- Finds invalid indexes that might have appeared as a result of
99
-- unsuccessful execution of the 'create index concurrently' command.
1010
select
11-
x.indrelid::regclass as table_name,
12-
x.indexrelid::regclass as index_name
11+
x.indrelid::regclass::text as table_name,
12+
x.indexrelid::regclass::text as index_name
1313
from
1414
pg_catalog.pg_index x
1515
inner join pg_catalog.pg_stat_all_indexes psai on psai.indexrelid = x.indexrelid
1616
where
1717
psai.schemaname = :schema_name_param::text and
18-
x.indisvalid = false;
18+
x.indisvalid = false
19+
order by table_name, index_name;

sql/non_primary_key_columns_with_serial_types.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -42,4 +42,4 @@ where
4242
/* column default value = nextval from owned sequence */
4343
pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || (pg_get_serial_sequence(col.attrelid::regclass::text, col.attname))::regclass || '''::regclass)' and
4444
nsp.nspname = :schema_name_param::text
45-
order by t.oid::regclass::text, col.attname::text;
45+
order by table_name, column_name;

sql/primary_keys_with_serial_types.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -12,8 +12,8 @@
1212
-- See also https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial
1313
-- and https://stackoverflow.com/questions/55300370/postgresql-serial-vs-identity
1414
select
15-
col.attrelid::regclass as table_name,
16-
col.attname as column_name,
15+
col.attrelid::regclass::text as table_name,
16+
col.attname::text as column_name,
1717
col.attnotnull as column_not_null,
1818
case col.atttypid
1919
when 'int'::regtype then 'serial'
@@ -33,4 +33,4 @@ where
3333
c.contype = 'p' and -- primary keys
3434
pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)::regclass || '''::regclass)' and
3535
nsp.nspname = :schema_name_param::text
36-
order by t.oid::regclass::text, col.attname::text;
36+
order by table_name, column_name;

sql/sequence_overflow.sql

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -21,12 +21,12 @@ with
2121
from
2222
pg_sequence s
2323
inner join pg_class c on c.oid = s.seqrelid
24-
left join pg_namespace n on n.oid = c.relnamespace
24+
left join pg_namespace nsp on nsp.oid = c.relnamespace
2525
where
26-
not pg_is_other_temp_schema(n.oid) and -- not temporary
26+
not pg_is_other_temp_schema(nsp.oid) and -- not temporary
2727
c.relkind = 'S'::char and -- sequence object
2828
not s.seqcycle and -- skip cycle sequences
29-
n.nspname = :schema_name_param::text
29+
nsp.nspname = :schema_name_param::text
3030
),
3131

3232
sequence_state as (

sql/tables_without_description.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -16,4 +16,4 @@ where
1616
pc.relkind = 'r' and
1717
(obj_description(pc.oid) is null or length(trim(obj_description(pc.oid))) = 0) and
1818
nsp.nspname = :schema_name_param::text
19-
order by pc.oid::regclass::text;
19+
order by table_name;

sql/tables_without_primary_key.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -20,4 +20,4 @@ where
2020
where c.contype = 'p'
2121
) and
2222
nsp.nspname = :schema_name_param::text
23-
order by pc.oid::regclass::text;
23+
order by table_name;

sql/unused_indexes.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -31,4 +31,4 @@ where
3131
not i.indisunique and
3232
i.indexrelid not in (select * from foreign_key_indexes) and /* retain indexes on foreign keys */
3333
psui.idx_scan < 50::integer
34-
order by psui.relname, pg_relation_size(i.indexrelid) desc;
34+
order by table_name, pg_relation_size(i.indexrelid) desc;

0 commit comments

Comments
 (0)