Find columns of base tables that have the default value CURRENT_USER or SESSION_USER but the name of the column does not refer to the fact that it contains usernames.
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)
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|person|worker|user|subject|_by$)'
ORDER BY c.table_schema, c.table_name, c.column_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems automatically
Queries, 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:
Name
Description
Default value
Queries of this catergory provide information about the use of default values.
Naming
Queries of this category provide information about the style of naming.