Query goal: | Find incorrectly implemented adjacency lists. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Drop the foreign key constraint and recreate it with correct column names. |
Data source: | system catalog only |
SQL query: | Click on query to copy it
with fk as (select o.conname, (select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema, f.relname as foreign_table, f.oid as foreign_table_oid, unnest(o.confkey) AS foreign_col, (select nspname from pg_namespace where oid=c.relnamespace) as target_schema, c.relname as target_table, c.oid as target_table_oid, unnest(o.conkey) AS target_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid inner join pg_class f on f.oid = o.confrelid where o.contype = 'f'), fk_grouped as ( select fk.conname, fk.foreign_schema, foreign_table, array_agg(fk.foreign_table || '.' || a_foreign.attname order by a_foreign.attnum) as foreign_col, fk.target_schema, fk.target_table, array_agg(fk.target_table || '.' || a_target.attname order by a_target.attnum) as target_col from fk inner join pg_attribute a_foreign on fk.foreign_col = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false inner join pg_attribute a_target on fk.target_col = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false group by fk.conname, fk.foreign_schema, fk.foreign_table, fk.target_schema, fk.target_table) select conname, foreign_schema as schema, foreign_table as table, foreign_col, target_col from fk_grouped where foreign_schema=target_schema and foreign_table=target_table and foreign_col@> target_col and foreign_col<@ target_col order by foreign_schema, foreign_table; |
SQL query | Description |
---|---|
with fk as (select o.conname, (select nspname from pg_namespace where oid=f.relnamespace) as foreign_schema, f.relname as foreign_table, f.oid as foreign_table_oid, unnest(o.confkey) AS foreign_col, (select nspname from pg_namespace where oid=m.relnamespace) as target_schema, m.relname as target_table, m.oid as target_table_oid, unnest(o.conkey) AS target_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid inner join pg_class f on f.oid = o.confrelid inner join pg_class m on m.oid = o.conrelid where o.contype = 'f' and o.conrelid in (select oid from pg_class c where c.relkind = 'r')), fk_grouped as ( select fk.conname, fk.foreign_schema, foreign_table, array_agg(fk.foreign_table || '.' || a_foreign.attname order by a_foreign.attnum) as foreign_col, fk.target_schema, fk.target_table, array_agg(fk.target_table || '.' || a_target.attname order by a_target.attnum) as target_col from fk inner join pg_attribute a_foreign on fk.foreign_col = a_foreign.attnum and fk.foreign_table_oid = a_foreign.attrelid and a_foreign.attisdropped = false inner join pg_attribute a_target on fk.target_col = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false group by fk.conname, fk.foreign_schema, fk.foreign_table, fk.target_schema, fk.target_table) select format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', foreign_schema, foreign_table, conname) AS statements from fk_grouped where foreign_schema=target_schema and foreign_table=target_table and foreign_col@> target_col and foreign_col<@ target_col order by foreign_schema, foreign_table; | Drop the foreign key constraint. |
Collection name | Collection description |
---|---|
Find problems automatically | Queries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not . |
Category name | Category description |
---|---|
Fatal problems | Queries of this category provide information about problems that render a part of a database unusable. |
Hierarchical data | Queries of this catergory provide information about storing hierarchical data in the database. |
Relationships between tables | Queries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly. |
Reference |
---|
https://blog.duncanworthy.me/sql/hierarchical-data-pt1-adjacency-list/ |