Goal The naming must be consistent. Find foreign key constraints where the candidate key column and foreign key column names have different prefixes. Thus, for instance, one cannot use USING syntax for joining the tables.
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 Use the same prefix in case of the candidate key and foreign key column names. For instance, if the primary key column name is id_person, then the foreign key column should not have the name code_person and nr_person and vice versa.
Data Source system catalog only
SQL Query
WITH 
fk_constraint_names AS (select 
o.conname,
(select nspname from pg_namespace where oid=f.relnamespace) as foreign_ns,
f.relname as foreign_table,
(select a.attname from pg_attribute a where a.attrelid = f.oid and a.attnum = o.confkey[1] and a.attisdropped = false) as foreign_colname,
(select nspname from pg_namespace where oid=c.relnamespace) as target_ns,
c.relname as target_table, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as target_colname
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')
SELECT foreign_ns, foreign_table, foreign_colname, target_ns, target_table, target_colname
FROM fk_constraint_names
WHERE 
lower(regexp_replace(foreign_colname,'^(([[:alpha:]]|_)[[:alnum:]]{0,4})_.*','\1'))<>lower(regexp_replace(target_colname,'^(([[:alpha:]]|_)[[:alnum:]]{0,4})_.*','\1'))
AND lower(regexp_replace(foreign_colname,'^(([[:alpha:]]|_)[[:alnum:]]{0,4})_.*','\1')) IN ('id','kood','code','nr')
AND lower(regexp_replace(target_colname,'^(([[:alpha:]]|_)[[:alnum:]]{0,4})_.*','\1')) IN ('id','kood','code','nr')
ORDER BY target_ns, target_table;

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
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
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
The corresponding code smell in case of cleaning code is "G11: Inconsistency". (Robert C. Martin, Clean Code)