The list of all the queries

Perhaps an unnecessary default value (the empty string or a string that consists of only whitespace) of a base table column/domain

Query goal: Find table columns and domains with the default value that is the empty string or a string that consists of only whitespace (for instance, newlines, spaces).
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: If a textual value can be missing, then perhaps it is better to permit NULLs in the column. If the column or domain has NOT NULL constraint, then drop the NOT NULL constraint and the default value. If the column or domain does not have the NOT NULL constraint, then drop the default.
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, is_nullable
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~*'^''[[:space:]]*''::'
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, CASE WHEN
NOT EXISTS (SELECT * 
FROM information_schema.domain_constraints AS dc INNER JOIN information_schema.check_constraints AS chk USING (constraint_schema, constraint_name)
WHERE D.domain_schema=Dc.domain_schema
AND D.domain_name=Dc.domain_name
AND chk.check_clause~*'IS NOT NULL')=TRUE THEN 'YES' ELSE 'NO' END AS is_nullable
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~*'^''[[:space:]]*''::'
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres'))
SELECT schema, table_name, object, object_type, data_type, CASE WHEN default_value ~* '^''''::' THEN 'Column default is the empty string'
WHEN default_value ~* '^''[[:space:]]+''::' THEN 'Column default consists of whitespace' END AS column_default, is_nullable 
FROM columns
UNION SELECT schema, table_name, object, object_type, data_type, CASE WHEN default_value~* '^''''::' THEN 'Domain default is the empty string'
WHEN default_value ~* '^''[[:space:]]+''::' THEN 'Domain default consists of whitespace' END AS domain_default, is_nullable 
FROM domains
ORDER BY schema, table_name, object_type, object;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
SELECT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I DROP DEFAULT;', A.table_schema, A.table_name, A.column_name) AS statements
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~*'^''[[:space:]]*''::'
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')
ORDER BY A.table_schema, A.table_name, A.ordinal_position;
Drop the column default value.
SELECT format('ALTER DOMAIN %1$I.%2$I DROP DEFAULT;', D.domain_schema, D.domain_name) AS statements
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~*'^''[[:space:]]*''::'
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres')
ORDER BY D.domain_schema, D.domain_name;
Drop the domain default value.
SELECT format('ALTER TABLE %1$I.%2$I ALTER COLUMN %3$I DROP NOT NULL;', A.table_schema, A.table_name, A.column_name) AS statements
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~*'^''[[:space:]]*''::'
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')
AND  is_nullable='NO'
ORDER BY A.table_schema, A.table_name, A.ordinal_position;
Drop the column's NOT NULL constraint.
SELECT format('ALTER DOMAIN %1$I.%2$I DROP NOT NULL;', D.domain_schema, D.domain_name) AS statements
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~*'^''[[:space:]]*''::'
AND (D.domain_schema = 'public'
OR S.schema_owner<>'postgres')
AND EXISTS (SELECT * 
FROM information_schema.domain_constraints AS dc INNER JOIN information_schema.check_constraints AS chk USING (constraint_schema, constraint_name)
WHERE D.domain_schema=Dc.domain_schema
AND D.domain_name=Dc.domain_name
AND chk.check_clause~*'IS NOT NULL')
ORDER BY D.domain_schema, D.domain_name;
Drop the domain's NOT NULL constraint.

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 .

Categories where the query belongs to

Category nameCategory description
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.
Default valueQueries of this catergory provide information about the use of default values.
Missing dataQueries of this category provide information about missing data (NULLs) in a database.
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://en.wikipedia.org/wiki/Whitespace_character

The list of all the queries