The list of all the queries

Perhaps a unneccessary surrogate key

Query goal: Find base tables that have the primary key that is not a surrogate key and an alternate key that is a surrogate key. Perhaps the surrogate key column is not needed.
Notes about the query: Find base table columns that do not belong to a foreign key, have UNIQUE constraint, and have an associated sequence generator. Do it only if the base table also has the primary key.
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: Drop the surrogate key column and its associated UNIQUE constraint.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

with keys as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col,
o.contype
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('u','p') and cardinality(o.conkey)=1),
keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin, contype
from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)),

keys_with_names AS (select key_schema, key_table, a_key.attname as key_col, contype
from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false
),

fk as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype='f'),
fk_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from fk, unnest(fk.key_col) with ordinality as k(key_col_num, ordin)),

fk_with_names AS (select key_schema, key_table, a_key.attname as key_col
from fk_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false),

ukey_not_fk AS (select key_schema, key_table, key_col
from keys_with_names
where contype='u'
except select key_schema, key_table, key_col
from fk_with_names)

SELECT c.table_schema, c.table_name , c.column_name
FROM information_schema.columns c
LEFT JOIN information_schema.domains d USING (domain_schema, domain_name)
INNER JOIN information_schema.schemata s
ON c.table_schema=s.schema_name
WHERE (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%' OR c.is_identity='YES')
AND c.data_type IN ('smallint','integer','bigint')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres')
AND EXISTS (SELECT *
FROM ukey_not_fk AS uk
WHERE uk.key_schema=c.table_schema
AND uk.key_table=c.table_name
AND uk.key_col=c.column_name)
AND EXISTS (SELECT *
FROM keys_with_names AS kn
WHERE kn.key_schema=c.table_schema
AND kn.key_table=c.table_name
AND kn.contype='p')

ORDER BY table_schema, 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
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.

The list of all the queries