The list of all the queries

Reasonable upper bound to the length of textual values is missing

Query goal: Find non-foreign key base table columns that are not used to record comments/descriptions/explanations etc. and that have TEXT or VARCHAR type without restrictions to the field size (field size in case of VARCHAR or a CHECK constraint).
Notes about the query: 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: Perhaps you should either use VARCHAR(n) type or should have a check constraint that constrains the maximum length lower than the length of the string that has 1GB in size. For instance, column e_mail should have type VARCHAR(254) or in case of using type TEXT it should have a check constraint that restricts the length of values in the column.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH domains AS (
SELECT cdu.table_schema, cdu.table_name, cdu.column_name, (SELECT data_type FROM INFORMATION_SCHEMA.domains AS d
WHERE d.domain_schema=dc.domain_schema AND d.domain_name=dc.domain_name) AS data_type, 
(SELECT character_maximum_length FROM INFORMATION_SCHEMA.domains AS d
WHERE d.domain_schema=dc.domain_schema AND d.domain_name=dc.domain_name) AS character_maximum_length, 
cc.check_clause
FROM ((INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN
INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)) INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc
USING (domain_schema, domain_name)) INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc
USING (constraint_catalog, constraint_schema, constraint_name)
WHERE t.table_type='BASE TABLE' AND cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
cdu.table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND catalog_name IS NOT NULL AND schema_name IS NOT NULL)),

text_length_domains AS (
SELECT table_schema, table_name, column_name, data_type
FROM domains
WHERE ((data_type LIKE 'character varying' AND character_maximum_length IS NULL) OR data_type = 'text') AND
(check_clause~*'(.*length.*(.+).*(<|=).*[[:digit:]].*)' 
OR check_clause~*'(.*[[:digit:]].*(<|=).*length.*(.+).*)')
OR check_clause~*'~[[:space:]]+''\^\.\{[0]{0,1},[[:digit:]]+\}\$'''
OR (check_clause~'[[:space:]]~[*]{0,1}[[:space:]]'
AND check_clause!~'[[:space:]]!~[*]{0,1}[[:space:]]'
AND check_clause~*'\^.*\$'
AND check_clause!~*'([*]|[+]|,[}])')),

text_length_chk AS (SELECT 
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS table_schema,
c.relname as table_name, 
a.attname AS column_name,
t.typname AS type_name
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
INNER JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE
INNER JOIN pg_type t ON a.atttypid=t.oid
WHERE cardinality(o.conkey)=1 
AND o.contype = 'c' 
AND a.atttypmod=-1 
AND (substring(pg_get_constraintdef(o.oid),7)~*'(.*length.*(.+).*(<|=).*[[:digit:]].*)' 
OR substring(pg_get_constraintdef(o.oid),7)~*'(.*[[:digit:]].*(<|=).*length.*(.+).*)'
OR substring(pg_get_constraintdef(o.oid),7)~*'~[[:space:]]+''\^\.\{[0]{0,1},[[:digit:]]+\}\$'''
OR (substring(pg_get_constraintdef(o.oid),7)~'[[:space:]]~[*]{0,1}[[:space:]]'
AND substring(pg_get_constraintdef(o.oid),7)!~'[[:space:]]!~[*]{0,1}[[:space:]]'
AND substring(pg_get_constraintdef(o.oid),7)~*'\^.*\$'
AND substring(pg_get_constraintdef(o.oid),7)!~*'([*]|[+]|,[}])')
)

UNION SELECT table_schema, table_name, column_name, data_type
FROM text_length_domains),

text_columns AS (SELECT table_schema, table_name, column_name, data_type, ordinal_position
FROM INFORMATION_SCHEMA.columns
WHERE ((data_type LIKE 'character varying' AND character_maximum_length IS NULL) OR data_type = 'text') AND 
column_name!~*'(komment|kirjeldus|comment|desc|tekst|text|tutvustus|selgitus|explanation|kokkuvote|summary|valjund|output|kehand|body|detailid|details|vastus|response|andmed|data|info|informatsioon|information|juhend|instruction|note|content|sisu|teade|message|nimekiri|list|aruanne|report|memo|resume)' 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)),

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  table_schema, table_name, column_name, data_type
FROM text_columns AS tc
WHERE NOT EXISTS (SELECT 1 FROM text_length_chk AS tlc WHERE tc.table_schema=tlc.table_schema AND tc.table_name=tlc.table_name
AND tc.column_name=tlc.column_name) AND
NOT EXISTS (SELECT 1 FROM fk_columns AS f WHERE tc.table_schema=f.table_schema AND tc.table_name=f.table_name
AND tc.column_name=f.column_name)
ORDER BY table_schema, table_name, ordinal_position;

Collections where the query belongs to

Collection nameCollection description
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 .

Categories where the query belongs to

Category nameCategory description
CHECK constraintsQueries of this category provide information about CHECK constraints.
Field sizeQueries of this category provide information about the maximum size of values that can be recorded in column fields
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
https://stackoverflow.com/questions/29560016/how-to-add-a-length-constraint-to-a-text-field

The list of all the queries