Query goal: | Find columns of base tables that have the default value CURRENT_USER or SESSION_USER but the field size is not 63 (default maximum identifier length in PostgreSQL). |
Notes about the query: | 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. |
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: | Use the filed size 63. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
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; |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Default value | Queries of this catergory provide information about the use of default values. |
Field size | Queries of this category provide information about the maximum size of values that can be recorded in column fields |
Reference |
---|
https://www.postgresql.org/docs/16/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS |