Goal 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)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion 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 system catalog only
SQL Query
WITH all_simple_checks AS (SELECT
  (SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS object_schema,
  c.relname || '.' || a.attname AS target,  
  COALESCE(basetype.typname, t.typname) AS data_type,
  o.conname AS constraint_name,  
  pg_get_constraintdef(o.oid) AS check_clause,
  'TABLE CHECK' AS check_type
FROM pg_constraint o
INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = o.conrelid AND a.attnum = o.conkey[1]
INNER JOIN pg_type t ON a.atttypid = t.oid
LEFT JOIN pg_type basetype ON t.typtype = 'd' AND t.typbasetype = basetype.oid
WHERE o.contype = 'c' AND cardinality(o.conkey) = 1
UNION SELECT
  ns.nspname AS object_schema,
  t.typname AS target,  
  basetype.typname AS data_type,
  c.conname AS constraint_name,
  pg_get_constraintdef(c.oid) AS check_clause,
  'DOMAIN CHECK' AS check_type
FROM pg_constraint c
INNER JOIN pg_type t ON c.contypid = t.oid
INNER JOIN pg_namespace ns ON t.typnamespace = ns.oid
INNER JOIN pg_type basetype ON t.typbasetype = basetype.oid
WHERE
  c.contype = 'c'
  AND c.contypid <> 0
  AND pg_get_constraintdef(c.oid) <> 'CHECK ((VALUE IS NOT NULL))')
SELECT object_schema, target, check_clause, check_type, constraint_name, data_type
FROM all_simple_checks
WHERE  (data_type = 'timestamp' AND check_clause~*'(current_timestamp|now[(]|current_date)')
OR (data_type = 'timestamptz' AND check_clause~*'(localtimestamp|current_date)')
OR (data_type='date' AND check_clause~*'(current_timestamp|localtimestamp|now[(])')
ORDER BY check_type, object_schema, target;

Collections

This query belongs to the following collections:

NameDescription
Find problems automaticallyQueries, 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:

NameDescription
CHECK constraintsQueries of this category provide information about CHECK constraints.
DomainsQueries of this category provide information about reusable specifications of column properties.
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.