Query goal: | Find base table columns and domains that have a textual type but the default value that represents a temporal value (either a static value or invocation of a function that returns such value). Specify for each column/domain a right data type that takes into account expected values in the column/domain. |
Notes about the query: | The query finds default values that are associated directly with a base table column as well as default values that are specified through a domain. The query does not find default values of domains that are not associated with any table. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Change the data type of the column/domain. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
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.data_type IN ('character varying','text','character') AND A.column_default~*'(localtimestamp|current_timestamp|localtime|current_time|current_date|now|[[:digit:]]{4}(-|/|\|.)[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{1,2}|[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{4}|[[:digit:]]{1,2}:[[:digit:]]{1,2})' 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.data_type IN ('character varying','text','character') AND D.domain_default~*'(localtimestamp|current_timestamp|localtime|current_time|current_date|now|[[:digit:]]{4}(-|/|\|.)[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{1,2}|[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{1,2}(-|/|\|.)[[:digit:]]{4}|[[:digit:]]{1,2}:[[:digit:]]{1,2})' 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; |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Comfortability of data management | Queries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient. |
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. |
Domains | Queries of this category provide information about reusable specifications of column properties. |
System-defined functions | Queries of this category provide information about the use of system-defined functions. |
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). |