Find pairs of tables that have both a foreign key that references to the other table. Such cycles can involve more than two tables but the query detects only cycles with two tables.
Notes
If the foreign key columns are optional, i.e., permit NULLs or deferrable, then this might be acceptable.
Type
General (Overview of some aspect of the database.)
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,
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,
o.conkey AS target_col,
CASE WHEN o.confupdtype='a' THEN 'NO ACTION'
WHEN o.confupdtype='r' THEN 'RESTRICT'
WHEN o.confupdtype='c' THEN 'CASCADE'
WHEN o.confupdtype='n' THEN 'SET NULL'
WHEN o.confupdtype='d' THEN 'SET DEFAULT' END AS on_update,
CASE WHEN o.confdeltype='a' THEN 'NO ACTION'
WHEN o.confdeltype='r' THEN 'RESTRICT'
WHEN o.confdeltype='c' THEN 'CASCADE'
WHEN o.confdeltype='n' THEN 'SET NULL'
WHEN o.confdeltype='d' THEN 'SET DEFAULT' END AS on_delete,
condeferrable AS is_deferrable,
condeferred AS is_deferred
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_unnest as (select conname, foreign_schema, foreign_table, foreign_table_oid, foreign_col, foreign_col_num, target_schema, target_table, target_table_oid, target_col, target_col_num, ordin, on_update, on_delete, is_deferrable, is_deferred
from fk, unnest(fk.foreign_col, fk. target_col) with ordinality as f(foreign_col_num, target_col_num, ordin)),
fk_with_names as (select conname, foreign_schema, foreign_table, a_foreign.attname as foreign_col, foreign_col_num, target_schema, target_table, a_target.attname as target_col, target_col_num, on_update, on_delete,
(SELECT is_nullable
FROM information_schema.columns AS c
WHERE c.table_schema=fk.target_schema
AND c.table_name=fk.target_table
AND c.column_name=a_target.attname) AS is_target_nullable,
is_deferrable, is_deferred
from fk_unnest fk inner join pg_attribute a_foreign on fk.foreign_col_num = 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_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false),
intersection as (select foreign_schema, foreign_table, target_schema, target_table
from fk
intersect select target_schema, target_table, foreign_schema, foreign_table
from fk),
cycles as (select foreign_schema, foreign_table, target_schema, target_table
from intersection
where ((foreign_schema=target_schema and foreign_table<>target_table)
or (foreign_schema<>target_schema)))
select target_schema, target_table, target_col, is_target_nullable, foreign_schema, foreign_table, foreign_col, on_update, on_delete, is_deferrable, is_deferred, conname
from fk_with_names AS fwn
where exists (select *
from cycles
where cycles.foreign_schema=fwn.foreign_schema
and cycles.foreign_table=fwn.foreign_table
and cycles.target_schema=fwn.target_schema
and cycles.target_table=fwn.target_table)
and exists (select *
from cycles
where cycles.target_schema=fwn.foreign_schema
and cycles.target_table=fwn.foreign_table
and cycles.foreign_schema=fwn.target_schema
and cycles.foreign_table=fwn.target_table)
order by target_schema, target_table, foreign_schema, foreign_table;
Collections
This query belongs to the following collections:
Name
Description
Find problems about base tables
A selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview
Find problems by overview
Queries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .
Categories
This query is classified under the following categories:
Name
Description
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.
Structure of base tables
Queries of this category provide information about the structuring of base tables at the database conceptual level