The list of all the queries

Each table is both referencing and referenced table (perhaps there is a cycle in relationships)

Query goal: Find as to whether the relationships between tables form a complete bidirected graph. Tables are vertices in the graph. There is a directed edge between two vertices if one of the tables refers to another through foreign key relationship on mandatory columns.
Notes about the query: The query does not take into account the existence of tables that do not participate in any relationship - not as the referencing table nor as a referenced table.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
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,
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
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'
and condeferrable=false),
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
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
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
where (fk.target_schema, fk.target_table, a_target.attname) IN (SELECT c.table_schema, c.table_name, c.column_name
FROM information_schema.columns AS c
WHERE c.is_nullable='NO')),
table_paryicipates_in_relationship AS (SELECT foreign_schema AS table_schema, foreign_table AS table_name
FROM fk_with_names
UNION SELECT target_schema AS table_schema, target_table AS table_name
FROM fk_with_names)
SELECT 'Perhaps the relationships form a cycle' AS warning
WHERE (SELECT Count(DISTINCT target_schema || '.' || target_table) AS cnt
FROM fk_with_names)=(SELECT Count(*) AS cnt
FROM table_paryicipates_in_relationship)
AND (SELECT Count(*) AS cnt
FROM table_paryicipates_in_relationship)>0;

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, 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 .

Categories where the query belongs to

Category nameCategory description
Relationships between tablesQueries 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 tablesQueries of this category provide information about the structuring of base tables at the database conceptual level

Reference materials for further reading

Reference
https://mathworld.wolfram.com/CompleteGraph.html
https://mathworld.wolfram.com/DirectedGraph.html

The list of all the queries