Specify for each column/domain a right data type that takes into account expected values in the column/domain. Find base table columns and domains that refer to the nextval function by using the default value mechanism but do not have the type INTEGER, SMALLINT, or BIGINT. This check is performed in case of identity columns: ERROR: identity column type must be smallint, integer, or bigint.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Change the data type to integer, smallint, or bigint or drop the default value.
Data Source
INFORMATION_SCHEMA only
SQL Query
WITH columns AS (SELECT A.table_schema AS schema, A.table_name, A.column_name AS object, A.data_type, a.column_default AS default_value, 'COLUMN' AS object_type
FROM information_schema.columns A INNER JOIN information_schema.schemata S ON A.table_schema=S.schema_name
WHERE A.column_default ILIKE '%nextval%'
AND A.data_type NOT IN ('smallint','integer','bigint')
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM information_schema.tables
WHERE table_type='BASE TABLE')),
domains AS (SELECT D.domain_schema AS schema, NULL AS table_name, D.domain_name AS object, D.data_type, D.domain_default AS default_value, 'DOMAIN' AS object_type
FROM information_schema.domains D INNER JOIN information_schema.schemata S ON D.domain_schema=S.schema_name
WHERE D.domain_default ILIKE '%nextval%'
AND D.data_type NOT IN ('smallint','integer','bigint')
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres'))
SELECT schema, table_name, object, object_type, data_type, default_value
FROM columns
UNION SELECT schema, table_name, object, object_type, data_type, default_value
FROM domains
ORDER BY schema, object_type, object;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
SELECT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I DROP DEFAULT;', A.table_schema, A.table_name, A.column_name) AS statements
FROM information_schema.columns A INNER JOIN information_schema.schemata S
ON A.table_schema=S.schema_name
WHERE A.column_default LIKE 'nextval%'
AND A.data_type NOT IN ('smallint','integer','bigint')
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
AND (A.table_schema, A.table_name) IN (SELECT table_schema, table_name
FROM information_schema.tables
WHERE table_type='BASE TABLE')
ORDER BY A.table_schema, A.table_name, A.column_name;
Drop the default that is associated directly with the base table column.
SELECT format('ALTER DOMAIN %1$I.%2$I DROP DEFAULT;', D.domain_schema, D.domain_name) AS statements
FROM information_schema.domains D INNER JOIN information_schema.schemata S ON D.domain_schema=S.schema_name
WHERE D.domain_default LIKE 'nextval%'
AND D.data_type NOT IN ('smallint','integer','bigint')
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres')
ORDER BY domain_schema, domain_name;
Drop the default that is associated with the domain.
Collections
This query belongs to the following collections:
Name
Description
Find problems about base tables
A selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. 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.
Default value
Queries of this catergory provide information about the use of default values.
Sequence generators
Queries of this category provide information about sequence generators and their usage.
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).