Find domains that declare a default value and that are used in case of multiple foreign key constraints that point to different tables. Domains should be used in a manner that does not cause unnecessary coupling of concerns. For instance, let us assume that columns client_state_type_code of table Client (that is used to implement the relationship with table Client_state_type) and worker_state_type_code of table Worker (that is used to implement the relationship with table Worker_state_type) have been defined based on the same domain. It the domain has a default value, then it determines the initial state of both clients and workers. However, it must be possible to determine the initial state independently in case of clients and workers.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Drop the default value that is associated with the domain and declare the default value directly to 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,
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_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 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),
suspicious_fk AS (SELECT conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, domain_schema, domain_name
FROM fk_with_names AS f INNER JOIN INFORMATION_SCHEMA.columns AS c ON f.target_schema=c.table_schema AND f.target_table=c.table_name AND f.target_col=c.column_name
INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name)
WHERE domain_default IS NOT NULL)
SELECT domain_schema, domain_name, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, conname
FROM suspicious_fk
WHERE (domain_schema, domain_name) IN (
SELECT domain_schema, domain_name
FROM suspicious_fk
GROUP BY domain_schema, domain_name
HAVING COUNT(DISTINCT foreign_schema || '_' || foreign_table)>1)
ORDER BY domain_schema, domain_name, target_schema, target_table, target_col;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
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_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 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),
suspicious_fk AS (SELECT conname, foreign_schema, foreign_table, foreign_col, target_schema, target_table, target_col, domain_schema, domain_name
FROM fk_with_names AS f INNER JOIN INFORMATION_SCHEMA.columns AS c ON f.target_schema=c.table_schema AND f.target_table=c.table_name AND f.target_col=c.column_name
INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name)
WHERE domain_default IS NOT NULL)
SELECT DISTINCT format('ALTER DOMAIN %1$I.%2$I DROP NOT NULL;', domain_schema, domain_name) AS statements
FROM suspicious_fk
WHERE (domain_schema, domain_name) IN (
SELECT domain_schema, domain_name
FROM suspicious_fk
GROUP BY domain_schema, domain_name
HAVING COUNT(DISTINCT foreign_schema || '_' || foreign_table)>1)
ORDER BY statements;
Drop the default value that is associated with the domain.
Collections
This query belongs to the following collections:
Name
Description
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
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Default value
Queries of this catergory provide information about the use of default values.
Domains
Queries of this category provide information about reusable specifications of column properties.
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.
Validity and completeness
Queries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).