Find surrogate keys where the generator can output the same value more than once. Key values must be unique, i.e., at some point the generator will prevent adding new rows to the table.
Notes
The query takes into account a possibility that a column may be associated with a sequence generator through a domain.
Type
Problem detection (Each row in the result could represent a flaw in the design)
with keys as (select
o.conname,
(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 in ('u', 'p') ),
keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
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
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)
SELECT c.table_schema, c.table_name , c.column_name, se.sequence_schema, se.sequence_name, se.increment, CASE WHEN se.increment::integer<0 THEN se.minimum_value ELSE se.maximum_value END AS limit
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, INFORMATION_SCHEMA.sequences se
WHERE (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%' || se.sequence_name || '%')
AND (se.cycle_option='YES')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres')
AND EXISTS (SELECT *
FROM keys_with_names AS k
WHERE k.key_schema=c.table_schema
AND k.key_table=c.table_name
AND k.key_col=c.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 keys as (select
(select nspname from pg_namespace where oid=m.relnamespace) as key_schema,
m.relname as key_table,
m.oid as key_table_oid,
o.conkey AS key_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 in ('p','u') and o.conrelid in (select oid from pg_class c where c.relkind = 'r')),
keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
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
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),
sequences AS (SELECT DISTINCT se.sequence_schema, se.sequence_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, INFORMATION_SCHEMA.sequences se
WHERE ((coalesce (c.column_default, d.domain_default) LIKE 'nextval(%' || se.sequence_name || '%') OR (coalesce (c.column_default, d.domain_default) LIKE 'nextval(%' || se.sequence_schema || '.' || se.sequence_name || '%'))
AND (se.cycle_option='YES')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres')
AND EXISTS (SELECT *
FROM keys_with_names AS k
WHERE k.key_schema=c.table_schema
AND k.key_table=c.table_name
AND k.key_col=c.column_name))
SELECT format ('ALTER SEQUENCE %1$I.%2$I NO CYCLE;', sequence_schema, sequence_name) AS statements
FROM sequences
ORDER BY sequence_schema, sequence_name;
Remove the CYCLE option.
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
Comfortability of data management
Queries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
Sequence generators
Queries of this category provide information about sequence generators and their usage.