Find the cases when the names of columns in different foreign keys that reference to the same candidate key are different. If different names reflect different roles, then it is legitimate. However, there could also be accidental differences that makes it more difficult to use the database.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH fk as (select
(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'),
fk_unnest as (select 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 foreign_schema, foreign_table, a_foreign.attname as foreign_col, target_schema, target_table, a_target.attname as target_col
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)
SELECT foreign_schema, foreign_table, foreign_col, Count(DISTINCT target_col) AS nr_of_different_ref_names,
string_agg(DISTINCT target_col, '; ' ORDER BY target_col) AS different_column_names,
string_agg(target_schema || '.' || target_table || '.' || target_col,'; ' ORDER BY target_schema, target_table, target_col) AS referencing_cols
FROM fk_with_names
GROUP BY foreign_schema, foreign_table, foreign_col
HAVING Count(DISTINCT target_col)>1
ORDER BY Count(DISTINCT target_col) DESC, foreign_schema, foreign_table, foreign_col;
Categories
This query is classified under the following categories:
Name
Description
Comfortability of data management
Queries 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.
Naming
Queries of this category provide information about the style of naming.
Relationships between tables
Queries 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.