If something has to be unique, then it must be said to the system so that it could use the information for internal optimizations and enforce the constraint. Find columns that contain Universally Unique Identifiers but are not a part of any simple PRIMARY KEY/UNIQUE constraint and are also not part of a foreign key.
Type
Problem detection (Each row in the result could represent a flaw in the design)
with simple_keys as (select
nspname as target_schema,
c.relname as target_table,
(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 in ('p','u')
and cardinality(o.conkey)=1
and n.nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
fk as (select
(select nspname from pg_namespace where oid=m.relnamespace) as target_schema,
m.relname as target_table,
m.oid as target_table_oid,
o.conkey AS target_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_class m on m.oid = o.conrelid
where o.contype = 'f' and o.conrelid in (select oid from pg_class c where c.relkind = 'r')),
fk_unnest as (select target_schema, target_table, target_table_oid, target_col, target_col_num, ordin
from fk, unnest(fk. target_col) with ordinality as f(target_col_num, ordin)),
fk_with_names as (select target_schema, target_table, a_target.attname as target_col
from fk_unnest fk inner join pg_attribute a_target on fk.target_col_num = a_target.attnum and fk.target_table_oid = a_target.attrelid and a_target.attisdropped = false),
uuid_columns AS (SELECT table_schema, table_name, column_name
FROM INFORMATION_SCHEMA.columns
WHERE data_type='uuid' AND
(table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT table_schema, table_name, column_name
FROM uuid_columns AS uc
WHERE NOT EXISTS (SELECT *
FROM fk_with_names AS fwn
WHERE uc.table_schema=fwn.target_schema
AND uc.table_name=fwn.target_table
AND uc.column_name=fwn.target_col)
AND NOT EXISTS (
SELECT *
FROM simple_keys AS sk
WHERE uc.table_schema=sk.target_schema
AND uc.table_name=sk.target_table
AND uc.column_name=sk.column_name)
ORDER BY table_schema, table_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
with simple_keys as (select
nspname as target_schema,
m.relname as target_table,
(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
inner join pg_class m on m.oid = o.conrelid
where o.contype in ('p','u')
and o.conrelid in (select oid from pg_class c where c.relkind = 'r')
and cardinality(o.conkey)=1
and n.nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
uuid_columns AS (SELECT table_schema, table_name, column_name
FROM INFORMATION_SCHEMA.columns
WHERE data_type='uuid' AND
(table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
missing_keys AS (SELECT table_schema, table_name, column_name
FROM uuid_columns
EXCEPT SELECT target_schema, target_table, column_name
FROM simple_keys)
SELECT format('ALTER TABLE %1$I.%2$I ADD CONSTRAINT %2$I_pkey PRIMARY KEY (%3$I);', table_schema, table_name, column_name) AS statements
FROM missing_keys
ORDER BY table_schema, table_name;
Declare the primary key.
Collections
This query belongs to the following collections:
Name
Description
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
Data types
Queries of this category provide information about the data types 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).