From 9ab0b380ee32ed56c14588f4c836be9c9a899004 Mon Sep 17 00:00:00 2001 From: Ivan Vakhrushev Date: Thu, 22 Sep 2022 23:24:33 +0300 Subject: [PATCH] Fixed wrong detection for columns with multiple constraints --- ...non_primary_key_columns_with_serial_types.sql | 16 ++++++++++++---- 1 file changed, 12 insertions(+), 4 deletions(-) diff --git a/sql/non_primary_key_columns_with_serial_types.sql b/sql/non_primary_key_columns_with_serial_types.sql index bfd7b6f..019ceb6 100644 --- a/sql/non_primary_key_columns_with_serial_types.sql +++ b/sql/non_primary_key_columns_with_serial_types.sql @@ -5,7 +5,8 @@ * Licensed under the Apache License 2.0 */ --- Finds columns of serial types (smallserial/serial/bigserial) that are not primary keys. +-- Finds columns of serial types (smallserial/serial/bigserial) +-- that are not primary keys (or primary and foreign keys at the same time). -- Based on https://dba.stackexchange.com/questions/90555/postgresql-select-primary-key-as-serial-or-bigserial/ select col.attrelid::regclass::text as table_name, @@ -21,14 +22,21 @@ from join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace join pg_catalog.pg_attribute col on col.attrelid = t.oid join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum - left join pg_constraint c on c.conrelid = col.attrelid and c.conkey[1] = col.attnum + left join lateral ( + select sum(case when c.contype = 'p' then +1 else -1 end) as res + from pg_constraint c + where + c.conrelid = col.attrelid and + c.conkey[1] = col.attnum and + c.contype in ('p', 'f') and /* primary or foreign key */ + array_length(c.conkey, 1) = 1 /* single column */ + group by c.conrelid, c.conkey[1]) c on true where t.relkind = 'r' and col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */ not col.attisdropped and col.atttypid = any('{int,int8,int2}'::regtype[]) and - (c.contype is null or (c.contype != 'p' and /* not primary key */ - array_length(c.conkey, 1) = 1)) and /* single column */ + (c.res is null or c.res <= 0) and /* column default value = nextval from owned sequence */ pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || (pg_get_serial_sequence(col.attrelid::regclass::text, col.attname))::regclass || '''::regclass)' and nsp.nspname = :schema_name_param::text