The list of all the queries

Only ID primary key

Query goal: Find base base tables have the simple primary key that contains a column with the (case insensitive) name id and an integer type. In addition, the primary key values are generated automatically by the system by using a sequence generator. In addition the base table must not have any unique constraint.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

with simple_keys as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as table_schema,
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
where o.contype='p' 
and c.relkind = 'r' 
and cardinality(o.conkey)=1),

tables_with_keys AS (select 
(select nspname from pg_namespace where oid=c.relnamespace) as table_schema,
c.relname as table_name 
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype='u'
and c.relkind = 'r')

SELECT sk.table_schema, sk.table_name
FROM simple_keys AS sk INNER JOIN information_schema.columns c
USING (table_schema, table_name, column_name)
LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN information_schema.schemata s
ON sk.table_schema=s.schema_name
WHERE (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%'  OR C.is_identity='YES')
AND (sk.table_schema = 'public' OR S.schema_owner<>'postgres')
AND Upper(sk.column_name)='ID'
AND c.data_type IN ('smallint','integer', 'bigint')
AND NOT EXISTS (SELECT * 
FROM tables_with_keys AS twk
WHERE twk.table_schema=sk.table_schema
AND twk.table_name=sk.table_name)
ORDER BY sk.table_schema, sk.table_name;

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA selection of queries that return information about the state of integrity constraints in the datadabase. Contains all the types of queries - problem detection, software measure, and general overview
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
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.
Validity and completenessQueries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).

Reference materials for further reading

Reference
This is extension of one of the antipatterns from the Bill Karwin's book of SQL antipatterns. See Chapter 4: ID Required.

The list of all the queries