Find base table columns that have both default value determined through a domain and default value that is directly attached to the column. Do not duplicate specifications of default values to avoid confusion and surprises. If column and domain both have a default value, then in case of inserting data the default value that is associated directly with the column is used.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Drop either the default value of the domain or the default value that is directly associated with the column. If you drop the default value of the domain, then do not forget that the domain could be used in case of different columns.
Data Source
INFORMATION_SCHEMA only
SQL Query
SELECT c.table_schema, c.table_name, c.column_name, c.data_type, c.domain_schema, c.domain_name, c.column_default, domain_default
FROM information_schema.columns AS c INNER JOIN information_schema.domains d USING (domain_schema, domain_name)
WHERE c.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)
AND column_default IS NOT NULL
AND domain_default IS NOT NULL
ORDER BY c.table_schema, c.table_name, c.column_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
WITH duplicate_defaults AS (SELECT c.table_schema, c.table_name, c.column_name, c.data_type, c.domain_schema, c.domain_name, c.column_default, domain_default
FROM information_schema.columns AS c INNER JOIN information_schema.domains d USING (domain_schema, domain_name)
WHERE c.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)
AND column_default IS NOT NULL
AND domain_default IS NOT NULL)
SELECT DISTINCT format('ALTER DOMAIN %1$I.%2$I DROP DEFAULT;', domain_schema, domain_name) AS statements
FROM duplicate_defaults
ORDER BY statements;
Drop the domain default.
WITH duplicate_defaults AS (SELECT c.table_schema, c.table_name, c.column_name, c.data_type, c.domain_schema, c.domain_name, c.column_default, domain_default
FROM information_schema.columns AS c INNER JOIN information_schema.domains d USING (domain_schema, domain_name)
WHERE c.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)
AND column_default IS NOT NULL
AND domain_default IS NOT NULL)
SELECT DISTINCT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I DROP DEFAULT;', table_schema, table_name, column_name) AS statements
FROM duplicate_defaults
ORDER BY statements;
Drop the column default.
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.
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.
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.
Duplication of implementation elements
Queries of this catergory provide information about the duplication of the database objects.