Re: Getting the currently used sequence for a SERIAL column - Mailing list pgsql-general

From Thomas Kellerer
Subject Re: Getting the currently used sequence for a SERIAL column
Date
Msg-id nu7ebq$a2h$1@blaine.gmane.org
Whole thread Raw
In response to Re: Getting the currently used sequence for a SERIAL column  (Hanne Moa <hanne.moa@gmail.com>)
List pgsql-general
Hanne Moa schrieb am 19.10.2016 um 10:31:
>> You can use the following statement to find the sequences that a table uses:
>>
> Thanks. This assumes that there is only one nextval per table though.
> While this holds for the database we need this on right now, it's not a
> sufficiently generic solution. How do I, for the sake of paranoia,
> specify a column?

No, it will return that for all columns in that table that have a sequence default
If you add "col.attname" to the select list you can see each column.

    create sequence s1;
    create sequence s2;
    create table t1 (id1 integer default nextval('s1'), id2 integer default nextval('s2'), id3 integer default
nextval('s2'));

    select sn.nspname as sequence_schema, s.relname as sequence_name, col.attname
    from pg_class s
      join pg_namespace sn on sn.oid = s.relnamespace
      join pg_depend d on d.refobjid = s.oid and d.refclassid='pg_class'::regclass
      join pg_attrdef ad on ad.oid = d.objid and d.classid = 'pg_attrdef'::regclass
      join pg_attribute col on col.attrelid = ad.adrelid and col.attnum = ad.adnum
      join pg_class tbl on tbl.oid = ad.adrelid
      join pg_namespace n on n.oid = tbl.relnamespace
    where s.relkind = 'S'
      and d.deptype in ('a', 'n')
      and n.nspname = 'public'
      and tbl.relname = 't1'

Returns

    sequence_schema | sequence_name | attname
    ----------------+---------------+--------
    public          | s1            | id1
    public          | s2            | id2
    public          | s2            | id3


Thomas

pgsql-general by date:

Previous
From: Hanne Moa
Date:
Subject: Re: Getting the currently used sequence for a SERIAL column
Next
From: Karsten Hilbert
Date:
Subject: Re: pg_sample