Goal This query identifies foreign key columns where the identifier differs from the referenced candidate key identifier. It explicitly excludes self-referencing constraints (recursive relationships), where name divergence is structurally mandatory. The primary objective is to identify opportunities to harmonize column names across the schema. Synchronizing the foreign key name with the referenced column name facilitates the use of the ANSI SQL USING clause in join operations (e.g., JOIN t1 USING (client_id)), which is significantly more concise than the explicit ON predicate required when names differ.
Notes If the foreign key column name refers to a role, then there is no problem. Thus the query can give false positive results.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Low (Many false-positive results)
License MIT License
Fixing Suggestion If the difference is unintentional and minor, then change the names so that these would be identical. On the other hand, if the foreign key column name describes the role of the entity type in the context of the implemented relationship type, then no renaming is needed.
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 *
from fk_columns
where ((foreign_schema<>target_schema) or (foreign_schema=target_schema and foreign_table<>target_table)) and foreign_col<>target_col
order by target_schema, target_table, conname;

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.

Further reading and related materials:

Reference
https://www.neilwithdata.com/join-using