Skip to content

Commit f28916e

Browse files
mfvanekBLoHny
andauthored
Query to find duplicated foreign keys (#50)
* add check duplicated foreign key (cherry picked from commit 6e9737f) * ignore lint check and add 'as' state (cherry picked from commit 1bbb2ff) * fix lint error (cherry picked from commit 988cf7a) * Renamed * Fix linter errors * Removed unnecessary parts * Added info about new check --------- Co-authored-by: BLoHny <[email protected]>
1 parent 6a31f62 commit f28916e

10 files changed

+79
-25
lines changed

CONTRIBUTING.md

Lines changed: 4 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -5,15 +5,17 @@
55
Each database structure check starts with an SQL query to the pg_catalog.
66

77
1. [SQLFluff](https://github.com/sqlfluff/sqlfluff) is used as a linter for all sql queries
8-
2. All queries should be schema-aware, i.e. we filter out database objects on schema basis:
8+
2. All queries must be schema-aware, i.e. we filter out database objects on schema basis:
99
```sql
1010
where
1111
nsp.nspname = :schema_name_param::text
1212
```
13-
3. All tables and indexes names in the query results should be schema-qualified.
13+
3. All tables and indexes names in the query results must be schema-qualified.
1414
We use `::regclass` on `oid` for that.
1515
```sql
1616
select
1717
psui.relid::regclass::text as table_name,
1818
psui.indexrelid::regclass::text as index_name,
1919
```
20+
4. All query results must be ordered in some way.
21+
5. Do not forget to update `README.md`.

README.md

Lines changed: 3 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -42,6 +42,7 @@ For more information please see [PostgreSQL Versioning Policy](https://www.postg
4242
18. B-tree indexes [on array columns](https://habr.com/ru/articles/800121/) ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/btree_indexes_on_array_columns.sql)).
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)).
45+
21. Duplicated (completely identical) foreign keys ([sql](https://github.com/mfvanek/pg-index-health-sql/blob/master/sql/duplicated_foreign_keys.sql)).
4546

4647
## Local development
4748

@@ -57,7 +58,7 @@ docker run \
5758
-e USE_FIND_ALGORITHM=true \
5859
-e VALIDATE_SQLFLUFF=true \
5960
-v $(pwd):/tmp/lint \
60-
ghcr.io/super-linter/super-linter:slim-v6
61+
ghcr.io/super-linter/super-linter:slim-v7
6162
```
6263

6364
#### Windows
@@ -70,5 +71,5 @@ docker run ^
7071
-e USE_FIND_ALGORITHM=true ^
7172
-e VALIDATE_SQLFLUFF=true ^
7273
-v "%cd%":/tmp/lint ^
73-
ghcr.io/super-linter/super-linter:slim-v6
74+
ghcr.io/super-linter/super-linter:slim-v7
7475
```

sql/bloated_indexes.sql

Lines changed: 5 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -27,17 +27,17 @@ with
2727
pi.indrelid as table_oid,
2828
pi.indexrelid as index_oid,
2929
pi.indnatts,
30-
pn.nspname,
30+
nsp.nspname,
3131
coalesce(substring(array_to_string(pc.reloptions, ' ') from 'fillfactor=([0-9]+)')::smallint, 90) as fill_factor,
3232
string_to_array(textin(int2vectorout(pi.indkey)), ' ')::int[] as indkey
3333
from
3434
pg_catalog.pg_index pi
3535
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
36-
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
36+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
3737
where
3838
pc.relam = (select oid from pg_catalog.pg_am where amname = 'btree') and
3939
pc.relpages > 0 and
40-
pn.nspname = :schema_name_param::text
40+
nsp.nspname = :schema_name_param::text
4141
),
4242

4343
nested_indexes_attributes as (
@@ -102,8 +102,8 @@ with
102102
max(case when i.atttypid = 'pg_catalog.name'::regtype then 1 else 0 end) > 0 as stats_not_available
103103
from
104104
named_indexes_attributes i
105-
inner join pg_catalog.pg_namespace n on n.oid = i.relnamespace
106-
inner join pg_catalog.pg_stats s on s.schemaname = n.nspname and s.tablename = i.attrelname and s.attname = i.attname
105+
inner join pg_catalog.pg_namespace nsp on nsp.oid = i.relnamespace
106+
inner join pg_catalog.pg_stats s on s.schemaname = nsp.nspname and s.tablename = i.attrelname and s.attname = i.attname
107107
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
108108
),
109109

sql/check_not_valid_constraints.sql

Lines changed: 2 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -11,10 +11,9 @@ select
1111
c.contype as constraint_type -- Type of the constraint
1212
from
1313
pg_catalog.pg_constraint c
14-
inner join pg_catalog.pg_class t on t.oid = c.conrelid
15-
inner join pg_catalog.pg_namespace n on n.oid = t.relnamespace
14+
inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace
1615
where
1716
not c.convalidated and -- Constraints that have not yet been validated
1817
c.contype in ('c', 'f') and -- Focus on check and foreign key constraints
19-
n.nspname = :schema_name_param::text -- Make the query schema-aware
18+
nsp.nspname = :schema_name_param::text -- Make the query schema-aware
2019
order by c.conrelid::regclass::text, c.conname;

sql/duplicated_foreign_keys.sql

Lines changed: 53 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,53 @@
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 completely identical foreign keys
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 || ', ' || 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 duplicate_constraint_name,
45+
c2.columns as duplicate_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
53+
order by c1.table_oid::regclass::text, c1.constraint_name, c2.constraint_name;

sql/foreign_keys_without_index.sql

Lines changed: 2 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -14,9 +14,8 @@ select
1414
from
1515
pg_catalog.pg_constraint c
1616
inner join lateral unnest(c.conkey) with ordinality u(attnum, attposition) on true
17-
inner join pg_catalog.pg_class t on t.oid = c.conrelid
18-
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
19-
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid and col.attnum = u.attnum
17+
inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace
18+
inner join pg_catalog.pg_attribute col on col.attrelid = c.conrelid and col.attnum = u.attnum
2019
where
2120
c.contype = 'f' and
2221
nsp.nspname = :schema_name_param::text and

sql/functions_without_description.sql

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -8,12 +8,12 @@
88
-- Finds functions and procedures that don't have a description.
99
-- See also https://www.postgresql.org/docs/current/sql-comment.html
1010
select
11-
case when n.nspname = 'public'::text then p.proname else n.nspname || '.' || p.proname end as function_name,
11+
case when nsp.nspname = 'public'::text then p.proname else nsp.nspname || '.' || p.proname end as function_name,
1212
pg_get_function_identity_arguments(p.oid) as function_signature
1313
from
14-
pg_catalog.pg_namespace n
15-
inner join pg_catalog.pg_proc p on p.pronamespace = n.oid
14+
pg_catalog.pg_namespace nsp
15+
inner join pg_catalog.pg_proc p on p.pronamespace = nsp.oid
1616
where
1717
(obj_description(p.oid) is null or length(trim(obj_description(p.oid))) = 0) and
18-
n.nspname = :schema_name_param::text
18+
nsp.nspname = :schema_name_param::text
1919
order by function_name, function_signature;

sql/indexes_with_boolean.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -15,10 +15,10 @@ select
1515
from
1616
pg_catalog.pg_index pi
1717
inner join pg_catalog.pg_class pc on pc.oid = pi.indexrelid
18-
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
18+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
1919
inner join pg_catalog.pg_attribute col on col.attrelid = pi.indrelid and col.attnum = any(pi.indkey)
2020
where
21-
pn.nspname = :schema_name_param::text and
21+
nsp.nspname = :schema_name_param::text and
2222
not pi.indisunique and
2323
pi.indisready and
2424
pi.indisvalid and

sql/tables_without_description.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -11,9 +11,9 @@ select
1111
pg_table_size(pc.oid) as table_size
1212
from
1313
pg_catalog.pg_class pc
14-
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
14+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
1515
where
1616
pc.relkind = 'r' and
1717
(obj_description(pc.oid) is null or length(trim(obj_description(pc.oid))) = 0) and
18-
pn.nspname = :schema_name_param::text
18+
nsp.nspname = :schema_name_param::text
1919
order by pc.oid::regclass::text;

sql/tables_without_primary_key.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -11,13 +11,13 @@ select
1111
pg_table_size(pc.oid) as table_size
1212
from
1313
pg_catalog.pg_class pc
14-
inner join pg_catalog.pg_namespace pn on pn.oid = pc.relnamespace
14+
inner join pg_catalog.pg_namespace nsp on nsp.oid = pc.relnamespace
1515
where
1616
pc.relkind = 'r' and
1717
pc.oid not in (
1818
select c.conrelid as table_oid
1919
from pg_catalog.pg_constraint c
2020
where c.contype = 'p'
2121
) and
22-
pn.nspname = :schema_name_param::text
22+
nsp.nspname = :schema_name_param::text
2323
order by pc.oid::regclass::text;

0 commit comments

Comments
 (0)