Find columns of base tables without a default value that are either Boolean columns that based on the name seem to implement a state machine or temporal columns that based on the name seem to keep registration or update time. These columns often have a default value.
Notes
The query considers both column names in Estonian and in English.
Type
Problem detection (Each row in the result could represent a flaw in the design)
SELECT A.table_schema, A.table_name , A.column_name, A.data_type
FROM information_schema.columns A
INNER JOIN information_schema.tables T USING (table_schema, table_name)
INNER JOIN information_schema.schemata S ON A.table_schema=S.schema_name
LEFT JOIN information_schema.domains D USING (domain_schema, domain_name)
WHERE domain_default IS NULL
AND column_default IS NULL
AND ((A.data_type ='boolean'
AND (A.column_name~*'(accept|active|approve|change|clean|clear|close|create|delete|dirty|disable|enable|execute|hidden|inactive|lock|maile|modif|open|obsolete|on_hold|overlook|print|public|register|remove|restore|request|sent|submit|reject|update|use|valid|visible|withdraw)'
OR A.column_name~*'(aktiiv|avatud|eemalda|esita|kaivita|kinnita|kustuta|loo|lopeta|lukusta|meili|mitteaktiivne|nahtav|peata|peida|peidetud|prindi|puhas|registreeri|saada|saadetud|suletud|sulge|taasta|tyhista)'))
OR
(A.data_type IN ('timestamp without time zone', 'timestamp with time zone', 'date','time without time zone', 'time with time zone')
AND A.column_name~*'(reg|muutm|create|update|change)'))
AND T.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR S.schema_owner<>'postgres')
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
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.
Default value
Queries of this catergory provide information about the use of default values.
Result quality depends on names
Queries of this category use names (for instance, column names) to try to guess the meaning of a database object. Thus, the goodness of names determines the number of false positive and false negative results.
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).