Goal This query identifies a potential schema mismatch regarding data precision. It flags base table columns that default to CURRENT_USER or SESSION_USER but define a character length differing from the PostgreSQL standard identifier limit (typically 63 bytes, defined by NAMEDATALEN - 1).

Risk (Length < 63): Poses a hard runtime failure risk if a username exceeds the defined length. Inefficiency (Length > 63): Indicates imprecise modeling, as the stored value can technically never exceed the system limit.
Notes The query finds default values that are associated directly with a base table column as well as default values that are specified through a domain. The query does not find default values of domains that are not associated with any table.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion The ideal configuration for such columns is VARCHAR(63) to align perfectly with the internal system limits.
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT c.table_schema, c.table_name, c.column_name, c.data_type, c.character_maximum_length AS suspected_field_size, c.domain_schema, c.domain_name, coalesce(c.column_default, domain_default) AS default_value,
CASE WHEN c.column_default IS NOT NULL THEN 'Column default' ELSE 'Domain default' END AS default_type
FROM information_schema.columns AS c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.tables AS t  USING (table_schema, table_name)
WHERE c.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 (column_default IS NOT NULL OR domain_default IS NOT NULL)
AND coalesce(c.column_default, domain_default)~*'(current_user|session_user)'
AND c.character_maximum_length<>63
ORDER BY c.table_schema, c.table_name, c.column_name;

Collections

This query belongs to the following collections:

NameDescription
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

This query is classified under the following categories:

NameDescription
Default valueQueries of this catergory provide information about the use of default values.
Field sizeQueries of this category provide information about the maximum size of values that can be recorded in column fields