Query goal: | Find base tables columns with temporal types (date and timestamp) that do not belong to a foreign key and that do not have any associated simple CHECK constraints, i.e., constraint that involves only one column. For instance, in the column registration_time that does not have any associated CHECK constraints could be values '1200-01-01 00:00' or '5900-12-31 00:00'. Rows with these values most probably represent wrong propositions and the system should restrict registration of such data. |
Notes about the query: | The query will miss columns that have a check constraint but it does not restrict the range of permitted values. The query would report columns that do have such restriction but it is a part of a composite constraint, i.e., a constraint that involves more than one column. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Add a CHECK constraint to the column that further (in addition to the data type) restricts values in the column. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
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 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 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 type_name 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 FROM temp_domains), temp_columns AS (SELECT table_schema, table_name, column_name, data_type FROM INFORMATION_SCHEMA.columns WHERE data_type IN ('date','timestamp with time zone','timestamp without time zone') AND (table_schema, table_name) IN (SELECT table_schema, table_name FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND 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)), fk_columns AS (select target_schema as table_schema, target_table as table_name, a.attname as column_name from (select (select nspname from pg_namespace where oid=c.relnamespace) as target_schema, c.relname as target_table, c.oid as target_table_oid, unnest(o.conkey) AS target_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid where o.contype = 'f') t inner join pg_attribute a on t.target_col = a.attnum and t.target_table_oid = a.attrelid and a.attisdropped = false) SELECT table_schema, table_name, column_name, data_type FROM temp_columns AS tc WHERE NOT EXISTS (SELECT 1 FROM temp_simple_chk AS tsc WHERE tc.table_schema=tsc.table_schema AND tc.table_name=tsc.table_name AND tc.column_name=tsc.column_name) AND NOT EXISTS (SELECT 1 FROM fk_columns AS f WHERE tc.table_schema=f.table_schema AND tc.table_name=f.table_name AND tc.column_name=f.column_name) ORDER BY table_schema, table_name, column_name; |
SQL query | Description |
---|---|
SELECT format('ALTER DOMAIN %1$I.%2$I ADD CONSTRAINT chk_%2$s CHECK(VALUE >=''2022-01-01 00:00:00'' AND VALUE<''2100-01-01 00:00:00'');', domain_schema, domain_name) AS statements FROM INFORMATION_SCHEMA.domains AS d WHERE (data_type~*'timestamp') AND domain_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 NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.domain_constraints AS dc INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name) WHERE d.domain_schema=dc.domain_schema AND d.domain_name=dc.domain_name AND cc.check_clause NOT LIKE '%IS NOT NULL' ) AND EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.columns AS c WHERE d.domain_schema=c.domain_schema AND d.domain_name=c.domain_name AND (table_schema, table_name) IN (SELECT table_schema, table_name FROM INFORMATION_SCHEMA.tables WHERE table_type IN ('BASE TABLE')) AND 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)) ORDER BY domain_schema, domain_name; | Add a constraint to the domains that have a timestamp type |
WITH timestamp_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 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 ~*'timestamp'), timestamp_columns AS (SELECT table_schema, table_name, column_name, data_type, character_maximum_length, domain_name, ordinal_position FROM INFORMATION_SCHEMA.columns WHERE (data_type ~*'timestamp') AND (table_schema, table_name) IN (SELECT table_schema, table_name FROM INFORMATION_SCHEMA.tables WHERE table_type IN ('BASE TABLE')) AND 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)), fk_columns AS (select target_schema as table_schema, target_table as table_name, a.attname as column_name from (select (select nspname from pg_namespace where oid=c.relnamespace) as target_schema, c.relname as target_table, c.oid as target_table_oid, unnest(o.conkey) AS target_col from pg_constraint o inner join pg_class c on c.oid = o.conrelid where o.contype = 'f') t inner join pg_attribute a on t.target_col = a.attnum and t.target_table_oid = a.attrelid and a.attisdropped = false) SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT chk_%2$s_%3$s CHECK (%3$I>=''2022-01-01 00:00:00'' AND %3$I<''2100-01-01 00:00:00'');', table_schema, table_name , column_name) AS statements FROM timestamp_columns AS tc WHERE domain_name IS NULL AND NOT EXISTS (SELECT 1 FROM timestamp_simple_chk AS tsc WHERE tc.table_schema=tsc.table_schema AND tc.table_name=tsc.table_name AND tc.column_name=tsc.column_name) AND NOT EXISTS (SELECT 1 FROM fk_columns AS f WHERE tc.table_schema=f.table_schema AND tc.table_name=f.table_name AND tc.column_name=f.column_name) ORDER BY table_schema, table_name, ordinal_position; | Add a constraint to the columns that have a timestamp type |
Collection name | Collection description |
---|---|
Find problems about integrity constraints | A selection of queries that return information about the state of integrity constraints in the datadabase. 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 . |
Category name | Category description |
---|---|
CHECK constraints | Queries of this category provide information about CHECK constraints. |
Data types | Queries of this category provide information about the data types and their usage. |
Temporal data | Queries of this category provide information about temporal (time-related) data that is kept in the database. |
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). |