Find columns of base tables that do not have type BOOLEAN but are used to record Boolean values. Based on column names these implement a state machine or record agreements. At the same time the columns do not have a default value. There are only two truth values - TRUE and FALSE - in case of two-valued logic. It should be possible to select one of these as the default value of the column.
Notes
The query takes into account both column names in Estonian and in English.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH 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 c.table_schema, c.table_name, c.column_name, c.data_type, c.character_maximum_length, c.is_nullable
FROM INFORMATION_SCHEMA.columns AS c LEFT JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name)
WHERE column_name~*'^(is|has|on)_'
AND (c.data_type<>'boolean')
AND coalesce(c.column_default, d.domain_default) IS NULL
AND (column_name~*'(accept|active|agree|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 column_name~*'(aktiiv|avatud|eemalda|esita|kaivita|kinnita|kustuta|loo|lopeta|lukusta|meili|mitteaktiivne|nahtav|nous|peata|peida|peidetud|prindi|puhas|registreeri|saada|saadetud|suletud|sulge|taasta|tyhista)')
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)
AND NOT EXISTS (SELECT *
FROM fk_columns
WHERE fk_columns.table_schema=c.table_schema
AND fk_columns.table_name=c.table_name
AND fk_columns.column_name=c.column_name)
ORDER BY c.table_schema, c.table_name, c.ordinal_position;
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
Boolean data
Queries of this category provide information about truth-values data that is kept in the database.
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.
State machine
Queries of this category provide information about registration of states of entities in a database.