The list of all the queries

Perhaps the type of a base table column/domain should be BOOLEAN (based on types and default values)

Query goal: Find base table columns and domains that have a textual type and the default value that represents a truth-value. For instance, the type of a column could be VARCHAR and the column has the default value 'TRUE'.
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: Specify for each column/domain a right data type that takes into account expected values in the column/domain. Use BOOLEAN type instead of emulating it based on some other data type. Change the type of the column/domain to BOOLEAN and determine that the default value is either TRUE or FALSE.
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~*'^''(true|false|yes|no|on|off|jah|ei)''::.*$'
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~*'^''(true|false|yes|no|on|off|jah|ei)''::.*$'
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;

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, 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 where the query belongs to

Category nameCategory description
Boolean dataQueries of this category provide information about truth-values data that is kept in the database.
Comfortability of data managementQueries 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 typesQueries of this category provide information about the data types and their usage.
Default valueQueries of this catergory provide information about the use of default values.
DomainsQueries of this category provide information about reusable specifications of column properties.
Validity and completenessQueries 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).

The list of all the queries