This query assesses the utilization of user-defined domains within the database schema. It verifies a specific structural requirement: the database must contain at least one user-defined domain that is referenced by at least two distinct non-foreign key columns in base tables. This metric serves as an indicator of proper domain reuse and data type standardization. The query validates whether the schema design effectively leverages domains to enforce consistent data definitions across multiple attributes.
Notes
This query implements a requirement that might occur in a learning situation. The condition in the query ensures that if the requirement is not fulfilled, then the query returns one row, otherwise it does not return a row. The result is achieved by using a PostgreSQL feature that permits SELECT statements without the FROM clause. The number of domains (one in this case) serves here as an example. It could be replaced with some other threshold.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Create additional domains and use these to define columns of base tables.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH fk as (select
(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 target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk. target_col) with ordinality as f(target_col_num, ordin)),
fk_with_names as (select target_schema, target_table, a_target.attname as target_col
from fk_unnest fk 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),
domains AS (SELECT domain_schema, domain_name
FROM Information_schema.domains AS d
WHERE domain_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
AND (SELECT Count(*)
FROM Information_schema.columns AS c INNER JOIN Information_schema.tables AS t USING (table_schema, table_name)
WHERE d.domain_schema=c.domain_schema
AND d.domain_name=c.domain_name
AND t.table_type='BASE TABLE'
AND (table_schema, table_name, c.column_name) NOT IN (SELECT target_schema, target_table, target_col
FROM fk_with_names))>=2)
SELECT 'Too few domains that are used in case of at least two non-foreign key columns of base tables, must be at least one' As comment, (SELECT Count(*) AS cnt FROM domains) AS number_of_domains
WHERE (SELECT Count(*) AS cnt FROM domains)<1;
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
Assessment
Queries of this category could be used specifically in the learning environment to assess as to whether student projects have filled certain criteria.
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Domains
Queries of this category provide information about reusable specifications of column properties.