The list of all the queries

Perhaps the type of a base table column should be BOOLEAN (based on column names)

Query goal: Find base table columns that based on the name seem to hold truth values. Find columns that name starts with "is_" or "has_" or "can_" or "on_" and that do not have Boolean type.
Notes about the query: The query assumes that the names are using snake_case style. The query considers both column names in English and Estonian.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: Medium (Medium number of false-positive results)
Query license: MIT License
Fixing suggestion: Specify for each column a right data type that takes into account expected values in the column. Use Boolean type instead of emulating it based on some other data type. Change the column type to BOOLEAN.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

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, 
coalesce(c.column_default, d.domain_default) AS column_default, 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|can|on)_' 
AND (c.data_type<>'boolean') 
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.column_name;

Collections where the query belongs to

Collection nameCollection description
Find problems about base tablesA 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
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
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 .
Lexicon bad smells and linguistic antipatternsQueries made to find the occurrences of lexicon bad smells and linguistic antipatterns

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.
Data typesQueries of this category provide information about the data types and their usage.
NamingQueries of this category provide information about the style of naming.
Result quality depends on namesQueries 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 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).

Reference materials for further reading

Reference
Linguistic antipattern "D.2 Name suggests boolean but type is not": Arnaoudova, V., Di Penta, M., Antoniol, G., 2016. Linguistic antipatterns: What they are and how developers perceive them. Empirical Software Engineering, 21(1), pp.104-158.
https://stackoverflow.com/questions/3037188/naming-of-boolean-column-in-database-table

The list of all the queries