The list of all the queries

Inappropriate field size or data type for column that strores database username

Query goal: Find columns of base tables that based on the default value of the column contain database username. However, the type of the column is not VARCHAR(63) or VARCHAR(128).
Notes about the query: Default maximum identifier length in PostgreSQL is 63 bytes. Maximum identifier length in SQL standard is 128. The query considers both default values that are associated directly to the column as well as default values that are associated through a domain.
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
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

WITH def_values AS (SELECT c.table_schema, c.table_name, c.ordinal_position, c.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 t.table_type='BASE TABLE' 
AND (column_default IS NOT NULL OR domain_default IS NOT NULL))
SELECT table_schema, table_name, column_name,  data_type, character_maximum_length, domain_schema, domain_name, default_value, default_type
FROM def_values
WHERE default_value~*'(current_user|session_user)'
AND ((data_type='character varying' AND character_maximum_length NOT IN (63, 128)) 
OR data_type<>'character varying')
ORDER BY table_schema, table_name, ordinal_position;

Collections where the query belongs to

Collection nameCollection description
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
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

Reference materials for further reading

Reference
https://www.postgresql.org/docs/current/limits.html

The list of all the queries