This query identifies tables that use a single-column surrogate primary key but lack any other UNIQUE constraints or unique indexes. The absence of additional unique constraints suggests that the natural business key has not been enforced, creating a risk of data duplication that violates business rules. Tables consisting of only a single column are excluded from this check.
Notes
This query is designed to be comprehensive, ensuring accuracy by accounting for various PostgreSQL features. It correctly identifies surrogate keys by recognizing sequences created both externally and internally (via an IDENTITY column), and can trace this association even when it is defined through a domain. Furthermore, it understands that uniqueness can be enforced through multiple mechanisms, checking not only for standard UNIQUE constraints but also for PostgreSQL-specific EXCLUDE constraints and unique indexes.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Find and enforce natural keys, i.e., keys that values have a meaning to database end users and are used to refer to the entities outside the software system.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH tables_with_unique AS (SELECT
nspname AS schema_name,
c.relname AS table_name
FROM pg_constraint o INNER JOIN pg_class c on c.oid = o.conrelid
INNER JOIN pg_namespace n on n.oid=c.relnamespace
WHERE o.contype IN ('x','u')
AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
UNION SELECT
n.nspname AS table_schema,
c2.relname AS table_name
FROM
pg_catalog.pg_class AS c INNER JOIN pg_catalog.pg_index AS i ON i.indexrelid = c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid = c2.oid
INNER JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid
INNER JOIN pg_catalog.pg_authid AS u ON n.nspowner = u.oid
INNER JOIN pg_catalog.pg_attribute AS a ON a.attrelid = c.oid
WHERE c.relkind = 'i'
AND i.indisunique=TRUE
AND a.attnum>=1
AND a.attisdropped = FALSE
AND (n.nspname = 'public'
OR u.rolname <> 'postgres')
AND NOT EXISTS (SELECT * FROM pg_catalog.pg_constraint AS o WHERE o.conindid=i.indexrelid AND o.contype IN ('u','p'))),
tables_with_only_surrogate AS (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.is_nullable='NO'
AND (table_schema, table_name) NOT IN (
SELECT table_schema, table_name
FROM tables_with_unique))
SELECT table_schema, table_name
FROM tables_with_only_surrogate AS twos
WHERE (SELECT Count(*) AS cnt FROM information_schema.columns AS c WHERE c.table_schema=twos.table_schema AND c.table_name=twos.table_name)>1
ORDER BY table_schema, table_name;
Collections
This query belongs to the following collections:
Name
Description
Find problems about integrity constraints
A 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 automatically
Queries, 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
This query is classified under the following categories:
Name
Description
Default value
Queries of this catergory provide information about the use of default values.
Sequence generators
Queries of this category provide information about sequence generators and their usage.
Uniqueness
Queries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.
Validity and completeness
Queries 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).
Further reading and related materials:
Reference
Smell "Superfluous key": Sharma, T., Fragkoulis, M., Rizou, S., Bruntink, M. and Spinellis, D.: Smelly relations: measuring and understanding database schema quality. In: Proceedings of the 40th International Conference on Software Engineering: Software Engineering in Practice, pp. 55-64. ACM, (2018).