Goal This query identifies foreign key relationships where the identifier of the referenced column diverges from the foreign key column solely due to the inclusion of the table name. It specifically targets cases where the referenced column name is formed by concatenating the target table name with the target column name (e.g., referenced_col = table_name || '_' || fk_col). This naming redundancy prevents the use of the simplified SQL USING syntax for join operations, necessitating verbose ON clauses. Harmonizing these identifiers by standardizing the naming convention improves schema readability and query conciseness.
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
Fixing Suggestion The Example: A parent table Car_state_type has a key named car_state_type_code (verbose). The child table Car refers to it simply as state_type_code (concise). The Problem: Because car_state_type_code is not equal to state_type_code, you cannot join these tables using the shortcut syntax USING (state_type_code). You are forced to write the longer ON condition.
The Solution: The foreign key column name should be car_state_type_code.
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 foreign_col<>target_col
and (foreign_col=target_table || '_' || target_col
or foreign_col=target_col || '_' || target_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.