The list of all the queries

Do not use approach that one size fits all (primary key columns)

Query goal: Find base base tables have the simple primary key that contains the 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.
Notes about the query: The query does not take into account as to whether the table has any other declared key. The query considers a possibility that the primary key column may be declared based on 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
Fixing suggestion: Declare alternate keys in the table. Rename the primary key column - for instance according to the pattern "table_name"_id.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

with simple_keys as (select 
n.nspname 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
inner join pg_namespace n on c.relnamespace=n.oid
where o.contype='p'
and  c.relkind = 'r' 
and cardinality(o.conkey)=1)
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')
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 about namesA selection of queries that return information about the names of database objects. 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
Database design antipatternsQueries of this category provide information about possible occurrences of SQL database design antipatterns.
NamingQueries of this category provide information about the style of naming.
Sequence generatorsQueries of this category provide information about sequence generators and their usage.
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.

Reference materials for further reading

Reference
This is one of the antipatterns from the Bill Karwin's book of SQL antipatterns. See Chapter 4: ID Required.
Dintyala, P., Narechania, A., Arulraj, J.: SQLCheck: automated detection and diagnosis of SQL anti-patterns. In: 2020 ACM SIGMOD International Conference on Management of Data, pp. 2331–2345. (2020). https://doi.org/10.1145/3318464.3389754 (Generic primary key (ID, code))
Balogh, G., Gergely, T., Beszédes, Á., Szarka, A., Fábián, Z.: Capturing expert knowledge to guide data flow and structure analysis of large corporate databases. Acta Polytechnica Hungarica 16(4), 7–26 (2019). (Using monolithic primary keys)

The list of all the queries