Skip to content

Commit

Permalink
Fix error
Browse files Browse the repository at this point in the history
  • Loading branch information
mfvanek committed Dec 9, 2024
1 parent 73feee1 commit a225b82
Showing 1 changed file with 49 additions and 32 deletions.
81 changes: 49 additions & 32 deletions sql/columns_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,38 +9,55 @@
-- 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,
col.attname::text as column_name,
col.attnotnull as column_not_null,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
left join lateral (
select sum(case when c.contype = 'p' then +1 else -1 end) as res
from pg_constraint c
with
t as (
select
col.attrelid::regclass::text as table_name,
col.attname::text as column_name,
col.attnotnull as column_not_null,
nsp.nspname as schema_name,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_expr(ad.adbin, ad.adrelid) as column_default_value,
case
when has_schema_privilege(nsp.oid, 'create,usage'::text) then pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)
else null::text
end as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = 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
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
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.res is null or c.res <= 0) and
nsp.nspname = :schema_name_param::text
)

select
table_name,
column_name,
column_not_null,
column_type,
case when schema_name = 'public'::text then replace(sequence_name, 'public.', '') else sequence_name end as sequence_name
from t
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.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
sequence_name is not null and
column_default_value = 'nextval(''' || sequence_name::regclass || '''::regclass)'
order by table_name, column_name;

0 comments on commit a225b82

Please sign in to comment.