Find foreign key constraints in case of which some candidate key values cannot be used as foreign key values. Primary key/unique columns and foreign key columns should have the same data type and field size. If, for instance, the primary key column has type INTEGER and foreign key column has type SMALLINT, then one cannot use all the primary key values as foreign key values.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Change the types or field sizes of the primary key/unique columns or the foreign key columns.
Data Source
INFORMATION_SCHEMA+system catalog
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,
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 conname, 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 conname, 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),
data_types AS (SELECT table_schema, table_name, column_name,
CASE WHEN data_type='numeric' THEN data_type || '(' || numeric_precision || ',' || numeric_scale || ')'
WHEN character_maximum_length IS NOT NULL THEN data_type || '(' || character_maximum_length || ')'
WHEN datetime_precision IS NOT NULL AND data_type<>'date' THEN data_type || '(' || datetime_precision || ')'
ELSE data_type END AS data_type, character_maximum_length, datetime_precision, numeric_precision, numeric_scale
FROM INFORMATION_SCHEMA.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
select fk.*, dtf.data_type AS foreign_data_type, dtt.data_type AS target_data_type
from fk_with_names AS fk inner join data_types AS dtf ON fk.foreign_schema=dtf.table_schema AND fk.foreign_table=dtf.table_name AND fk.foreign_col=dtf.column_name
inner join data_types AS dtt ON fk.target_schema=dtt.table_schema AND fk.target_table=dtt.table_name AND fk.target_col=dtt.column_name
WHERE dtf.data_type<>dtt.data_type
AND (dtf.character_maximum_length>dtt.character_maximum_length
OR (dtf.character_maximum_length IS NULL AND dtt.character_maximum_length IS NOT NULL)
OR dtf.datetime_precision>dtt.datetime_precision
OR dtf.numeric_precision>dtt.numeric_precision
OR dtf.numeric_scale>dtt.numeric_scale
)
order by target_schema, target_table, conname;
Collections
This query belongs to the following collections:
Name
Description
Find problems about integrity constraints
A selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
Find problems automatically
Queries, 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:
Name
Description
Data types
Queries of this category provide information about the data types and their usage.
Fatal problems
Queries of this category provide information about problems that render a part of a database unusable.
Inconsistencies
Queries of this catergory provide information about inconsistencies of solving the same problem in different places.
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.
Further reading and related materials:
Reference
Blaha, M.R., Premerlani, W.J.: Observed idiosyncracies of relational database designs. In: 2nd Working Conference on Reverse Engineering, pp. 116–125. IEEE, (1995). https://doi.org/10.1109/WCRE.1995.514700 (Mismatched referential integrity domains)