Find base table columns that name refers to the possibility that the column is used to record names or textual descriptions but the column seems to have a simple check constraint that restricts spaces in these.
Notes
The query considers both CHECK constraints that are associated directly with a table as well as CHECK constraints that are associated with a table through a domain. The query considers both column names in English and in Estonian.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH text_domains_with_checks AS (
SELECT cdu.table_schema, cdu.table_name, cdu.column_name, d.data_type, d.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)
INNER JOIN INFORMATION_SCHEMA.domains AS d USING (domain_schema, domain_name)
WHERE t.table_type IN ('BASE TABLE', 'FOREIGN')
AND d.data_type LIKE '%char%'
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 schema_name IS NOT NULL)),
text_columns_with_checks 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 data_type,
a.atttypmod-4 AS character_maximum_length,
substring(pg_get_constraintdef(o.oid),7) as consrc
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 t.typname in ('bpchar','char','varchar')
UNION SELECT table_schema, table_name, column_name, data_type, character_maximum_length, check_clause
FROM text_domains_with_checks)
SELECT table_schema, table_name, column_name, data_type, character_maximum_length, consrc
FROM text_columns_with_checks
WHERE consrc~'\^[^\. ]*\$'
AND consrc!~'(\\s|\[\[:space:\]\])(\*|\+)'
AND column_name~*'(nimi|nimetus|kirjeldus|selgitus|kommentaar|name|description|comment)'
ORDER BY table_schema, table_name, column_name;
Categories
This query is classified under the following categories:
Name
Description
CHECK constraints
Queries of this category provide information about CHECK constraints.
Regular expressions
Queries of this catergory provide information about the use of regular expressions.
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.