Find base tables where uniqueness is achieved by using only unique indexes, i.e., there is at least one unique index but no uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE)
Type
Problem detection (Each row in the result could represent a flaw in the design)
Define PRIMARY KEY or UNIQUE constraint instead of a unique index that is not function-based and is not partial. Define EXCLUDE constraints instead of function based or partial unique indexes.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH unique_indexes AS (SELECT
n.nspname AS sch,
c2.relname AS tbl
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
WHERE c.relkind = 'i'
AND i.indisunique=TRUE
AND (n.nspname = 'public'
OR u.rolname <> 'postgres')),
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 in ('p','u','x')
and c.relkind = 'r')
SELECT A.table_schema, A.table_name
FROM INFORMATION_SCHEMA.tables A
INNER JOIN INFORMATION_SCHEMA.schemata B
ON A.table_schema=B.schema_name
WHERE A.table_type='BASE TABLE'
AND (A.table_schema = 'public'
OR B.schema_owner<>'postgres')
AND (A.table_schema, A.table_name) NOT IN
(SELECT table_schema, table_name FROM tables_with_keys)
AND (A.table_schema, A.table_name) IN (SELECT sch, tbl
FROM unique_indexes)
ORDER BY A.table_schema, A.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
Performance
Queries of this category provide information about indexes in a database.
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).