Find base table columns with a check constraint that refers to a temporal function (current_timestamp, localtimestamp, current_date, or now) that return type is inconsistent with the data type of the column.
Notes
The query considers both check constraints that are directly associated with a table as well as check constraints that are associated with the table through a domain.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Change the check constraint or the data type of the column. For instance, if column reg_time has type TIMESTAMP, then instead of reg_time <= CURRENT_TIMESTAMP or reg_time<=CURRENT_DATE, one should use cart_item_created_at <= LOCALTIMESTAMP.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH domains AS (
SELECT cdu.table_schema, cdu.table_name, cdu.column_name, (SELECT data_type FROM INFORMATION_SCHEMA.domains AS d
WHERE d.domain_schema=dc.domain_schema AND d.domain_name=dc.domain_name) AS data_type, cc.check_clause
FROM ((INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN
INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)) INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc
USING (domain_schema, domain_name)) INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_catalog, constraint_schema, constraint_name)
WHERE t.table_type='BASE TABLE' AND cc.check_clause NOT LIKE '%IS NOT NULL' AND
cdu.table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND catalog_name IS NOT NULL AND schema_name IS NOT NULL)),
temp_domains AS (SELECT table_schema, table_name, column_name, data_type, check_clause
FROM domains
WHERE data_type IN ('date','timestamp with time zone','timestamp without time zone')),
temp_simple_chk AS (SELECT
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS table_schema,
c.relname as table_name,
a.attname AS column_name,
t.typname AS data_type,
pg_get_constraintdef(o.oid) AS check_clause
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
INNER JOIN pg_type t ON a.atttypid=t.oid
WHERE cardinality(o.conkey)=1 AND o.contype = 'c' AND t.typname IN ('date', 'timestamp', 'timestamptz')
UNION SELECT table_schema, table_name, column_name, data_type, check_clause
FROM temp_domains)
SELECT table_schema, table_name, column_name, data_type, check_clause
FROM temp_simple_chk
WHERE (data_type IN ('timestamp without time zone','timestamp') AND check_clause~*'(current_timestamp|now[(]|current_date)')
OR (data_type IN ('timestamp with time zone','timestamptz') AND check_clause~*'(localtimestamp|current_date)')
OR (data_type='date' AND check_clause~*'(current_timestamp|localtimestamp|now[(])')
ORDER BY table_schema, table_name, column_name;
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
CHECK constraints
Queries of this category provide information about CHECK constraints.
Domains
Queries of this category provide information about reusable specifications of column properties.
Inconsistencies
Queries of this catergory provide information about inconsistencies of solving the same problem in different places.