From: | Craig Ringer <ringerc(at)ringerc(dot)id(dot)au> |
---|---|
To: | Mike Broers <mbroers(at)gmail(dot)com> |
Cc: | pgsql-admin(at)postgresql(dot)org |
Subject: | Re: bumping all sequence ids in a schema |
Date: | 2012-11-08 02:39:25 |
Message-ID: | 509B1B5D.5010503@ringerc.id.au |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-admin |
On 11/08/2012 04:42 AM, Mike Broers wrote:
> I would like to bump all sequences in a schema by a specified
> increment. Is there a stored proc or some method that is recommended?
> Currently I have sql that generates scripts to do this, but it seems
> to be an inelegant approach and before I rework it from the ground up
> I want to see if anyone has already done this kind of work or thinks
> its a wasteful pursuit for some other reason I'm overlooking.
I'd use a PL/PgSQL `DO` block, myself.
DO
$$
DECLARE
seqname text;
nspname text;
seqval bigint;
BEGIN
FOR nspname, seqname IN select n.nspname, c.relname FROM
pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid)
WHERE c.relkind = 'S' AND n.nspname = 'public' LOOP
EXECUTE format('SELECT last_value FROM %I.%I', nspname,
seqname) INTO seqval;
PERFORM setval(
quote_ident(nspname)||'.'||quote_ident(seqname), seqval + 0);
END LOOP;
END;
$$ LANGUAGE plpgsql;
Change "+ 0" to whatever your increment is.
--
Craig Ringer
From | Date | Subject | |
---|---|---|---|
Next Message | Baptiste LHOSTE | 2012-11-08 08:54:19 | Re: Autoanalyze of the autovacuum daemon ... |
Previous Message | Lonni J Friedman | 2012-11-07 21:17:33 | Re: pg_upgrade from 9.1 to 9.2 takes a really long time (compared to previous versions)? |