Goal Find check constraints of base tables that cover exactly one column where the default value of the column is special value 'infinity' or '-infinity'. Find only such constraints that probably check a range of permitted values but do not consider that one of the values might be 'infinity' or '-infinity'. Such special values belong to the types DATE, TIMESTAMP, NUMERIC, REAL, and DOUBLE PRECISION.
Notes The query considers constraints and default values that are connected directly to the table as well as constraints and default values that are connected to the table through a domain. The query takes into account the possibility that NOT isfinite(..) expression could be used to check the infinity value.
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
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)),
inf_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','numeric','real','double precision')),
inf_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 type_name,
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', 'numeric', 'float4', 'float8')
UNION SELECT table_schema, table_name, column_name, data_type, check_clause
FROM inf_domains),
defs AS (SELECT c.table_schema, t.table_type, c.table_name, c.column_name,  c.data_type, c.domain_schema, c.domain_name, coalesce(c.column_default, domain_default) AS default_value,
CASE WHEN c.column_default IS NOT NULL THEN 'Column default' ELSE 'Domain default' END AS default_type
FROM information_schema.columns AS c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.tables AS t  USING (table_schema, table_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 OR domain_default IS NOT NULL)),
infinity_defs AS (SELECT  table_schema, table_type, table_name, column_name, 
data_type, domain_schema, domain_name, default_value, default_type
FROM defs
WHERE default_value~*'infinity')
SELECT DISTINCT table_schema, table_name, column_name, data_type, domain_schema, domain_name, default_value, default_type, check_clause
FROM inf_simple_chk INNER JOIN infinity_defs USING (table_schema, table_name, column_name)
WHERE check_clause~'[0-9]+'
AND (check_clause~*'(between)'
OR (check_clause~*'<' AND check_clause~*'>'))
AND check_clause!~*'(infinity|not[[:space:]]isfinite[(])'
ORDER BY table_schema, table_name, column_name;

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.
Data typesQueries of this category provide information about the data types and their usage.
Default valueQueries of this catergory provide information about the use of default values.