Goal This query identifies a semantic mismatch between column definitions and their identifiers. It flags base table columns that are configured with a DEFAULT value of CURRENT_USER or SESSION_USER (indicating they store user identity) but whose names fail to reflect this purpose. Specifically, it searches for columns lacking semantic cues such as "user", "login", "owner", or "by" in their names. This obscuration reduces schema self-documentation, as developers cannot intuitively determine that the column is intended for audit or ownership tracking.
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. The query considers both column names in English and Estonian.
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 Change the name of the column.
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT c.table_schema, c.table_name, c.column_name AS suspected_column_name, c.data_type, c.character_maximum_length, 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.column_name!~'(isik|tootaja|kasutaja|subjekt|lisaja|muutja|registreerija|omanik|person|worker|user|owner|login|subject|_by$)'
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.
NamingQueries of this category provide information about the style of naming.