The list of all the queries

Using system-defined names of constraints (constraints that involve one column)

Query goal: Find the constraint types in case of which there exists system-defined names.
Notes about the query: The query considers only constraints that involve one column. PostgreSQL 14 added primary keys, unique constraints, and foreign keys to system catalogs. Thus the query was modified to exclude the results from the system catalog. The query uses regexp_like() function that was added to PostgreSQL 15.
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: Give names to constraints explicitly. Use a uniform style.
Data source: system catalog only
SQL query: Click on query to copy it

WITH pkey_constraint_names AS (
select 
'PRIMARY KEY' AS type,
o.conname AS constraint_name,
n.nspname as schema_name,
c.relname as table_name, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid 
inner join pg_namespace AS n on n.oid=c.relnamespace
inner join pg_authid AS a ON n.nspowner=a.oid
where (n.nspname='public' OR a.rolname<>'postgres')
and o.contype ='p'  and cardinality(o.conkey)=1),

ukey_constraint_names AS (
select 
'UNIQUE' AS type,
o.conname AS constraint_name,
n.nspname as schema_name,
c.relname as table_name, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid 
inner join pg_namespace AS n on n.oid=c.relnamespace
inner join pg_authid AS a ON n.nspowner=a.oid
where (n.nspname='public' OR a.rolname<>'postgres')
and o.contype ='u'  and cardinality(o.conkey)=1),

chk_constraint_names AS (select 
'CHECK' AS type,
o.conname AS constraint_name,
(select nspname from pg_namespace where oid=c.relnamespace) as schema_name,
c.relname as table_name, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid 
inner join pg_namespace AS n on n.oid=c.relnamespace
inner join pg_authid AS a ON n.nspowner=a.oid
where (n.nspname='public' OR a.rolname<>'postgres')
and o.contype ='c'  and cardinality(o.conkey)=1),

fk_constraint_names AS (select 
'FOREIGN KEY' AS type,
o.conname AS constraint_name,
n.nspname as schema_name,
c.relname as table_name, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid 
inner join pg_namespace AS n on n.oid=c.relnamespace
inner join pg_authid AS a ON n.nspowner=a.oid
where (n.nspname='public' OR a.rolname<>'postgres')
and o.contype ='f'  and cardinality(o.conkey)=1),

exclude_constraint_names AS (select 
'EXCLUDE' AS type,
o.conname AS constraint_name,
n.nspname as schema_name,
c.relname as table_name, 
(select a.attname from pg_attribute a where a.attrelid = c.oid and a.attnum = o.conkey[1] and a.attisdropped = false) as column_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid 
inner join pg_namespace AS n on n.oid=c.relnamespace
inner join pg_authid AS a ON n.nspowner=a.oid
where (n.nspname='public' OR a.rolname<>'postgres')
and o.contype ='x'  and cardinality(o.conkey)=1),

stats AS (SELECT type, Count(*) AS cnt_total, 
Count(*) FILTER (WHERE lower(constraint_name) = lower(table_name) || '_pkey') AS cnt_system_generated
FROM pkey_constraint_names
GROUP BY type

UNION SELECT type, Count(*) AS cnt_total, 
Count(*) FILTER (WHERE lower(constraint_name) = lower(table_name) || '_' || lower(column_name) || '_key') AS cnt_system_generated
FROM ukey_constraint_names
GROUP BY type

UNION SELECT type, Count(*) AS cnt_total, 
Count(*) FILTER (WHERE regexp_like(constraint_name, '^' || table_name || '_' || column_name || '_check[[:digit:]]*$','i')) AS cnt_system_generated
FROM chk_constraint_names
GROUP BY type

UNION SELECT type, Count(*) AS cnt_total, 
Count(*) FILTER (WHERE regexp_like(constraint_name, '^' || table_name || '_' || column_name || '_fkey[[:digit:]]*$','i')) AS cnt_system_generated
FROM fk_constraint_names
GROUP BY type

UNION SELECT type, Count(*) AS cnt_total, 
Count(*) FILTER (WHERE lower(constraint_name) = lower(table_name) || '_' || lower(column_name) || '_excl') AS cnt_system_generated
FROM exclude_constraint_names
GROUP BY type
)
SELECT type AS constraint_type, cnt_total AS number_of_constraints, cnt_system_generated AS number_of_constraints_with_system_generated_names, cnt_total - cnt_system_generated AS number_of_constraints_with_user_defined_names
FROM stats
WHERE cnt_system_generated>0
ORDER BY cnt_system_generated DESC, constraint_type;

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
CHECK constraintsQueries of this category provide information about CHECK constraints.
NamingQueries of this category provide information about the style of naming.
Relationships between tablesQueries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.

Reference materials for further reading

Reference
https://martinfowler.com/bliki/TwoHardThings.html
https://stackoverflow.com/questions/7662/database-table-and-column-naming-conventions
https://openacs.org/doc/eng-standards-constraint-naming
Smell "Using system-generated object names, particularly for constraints": Factor, P.: SQL Code Smells. Redgate. Http://assets.red-gate.com/community/books/sql-code-smells.pdf

The list of all the queries