Find implementations of state machines that uses a set of one or more Boolean columns. These columns could have the type Boolean or could probably (based on the column name and non-participation in a foreign key) contain values that represent truth values.
Notes
The query finds all the base tables that have at least one Boolean column where the name of the column refers to an event that may be caused by a state transition. The query shows all the Boolean columns of the tables. The query takes into account columns with the type Boolean as well as columns that do not have the Boolean type although the name of the column indicates that the column contains truth values. It returns the name of table and its schema as well as names and types of columns. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser. The query may return false positive results if the columns are not used for the registration of data about the state. 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)
Create a state classifier table and associated it with the table in question by using a foreign key (see Level 2 Status Pattern, Current Status from L. Silverston ja P. Agnew, „The Data Model Resource Book, Volume 3: Universal Patterns for Data Modeling,“ Chichester, John Wiley & Sons Ltd, 2009.) or use a temporal type instead of the type Boolean.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
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),
boolean_columns AS (SELECT table_schema, table_name, column_name, ordinal_position, data_type
FROM INFORMATION_SCHEMA.columns AS c
WHERE (data_type='boolean'
OR (column_name~*'^(is|has|on)_'
AND (data_type<>'boolean')
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)))
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)),
has_event_cols AS (SELECT table_schema, table_name
FROM boolean_columns
WHERE 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 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)')
SELECT table_schema, table_name, Count(*) AS nr_of_columns, string_agg(column_name || '(' || data_type || ')', '; ' ORDER BY ordinal_position) AS boolean_columns
FROM boolean_columns
WHERE (table_schema, table_name) IN (SELECT
table_schema, table_name
FROM has_event_cols)
GROUP BY table_schema, table_name
ORDER BY Count(*) DESC, table_schema, table_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems about base tables
A selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview
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 database evolution
Queries of this category provide information about the means that influence database evolution.
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.
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.
L. Silverston ja P. Agnew, „The Data Model Resource Book, Volume 3: Universal Patterns for Data Modeling,“ Chichester, John Wiley & Sons Ltd, 2009. Level 1 Status Pattern