Goal This query identifies foreign key columns where the identifier is identical to the name of the referenced table. This naming pattern typically results in a mismatch between the foreign key column and the referenced primary key column (e.g., a column named department referencing a table department with a primary key department_id). This mismatch precludes the use of the simplified ANSI SQL USING clause in join operations, necessitating the use of the more verbose ON clause. Harmonizing the column name to match the referenced key enables more concise query formulation.

The Example: A table Employees has a column named Department that links to the Department table (where the ID is department_id). The Problem: Because the column is named Department and not department_id, you cannot use the shortcut syntax: JOIN Department USING (department_id). You are forced to write: JOIN Department ON Employees.Department = Department.department_id.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Data Source system catalog only
SQL Query
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_columns as (
select fk.conname, fk.foreign_schema, fk.foreign_table, a_foreign.attname as foreign_col, fk.target_schema, fk.target_table, a_target.attname 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)
select conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col
from fk_columns
where ((foreign_schema<>target_schema) or (foreign_schema=target_schema and foreign_table<>target_table)) 
and target_col=foreign_table
order by target_schema, target_table, conname;

Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
Comfortability of data managementQueries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
NamingQueries of this category provide information about the style of naming.
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.