On Tue, Aug 21, 2012 at 2:03 PM, Scott Marlowe <scott.marlowe@xxxxxxxxx> wrote: > On Tue, Aug 21, 2012 at 9:32 AM, Craig James <cjames@xxxxxxxxxxxxxx> wrote: >> On Mon, Aug 20, 2012 at 5:10 PM, Tom Lane <tgl@xxxxxxxxxxxxx> wrote: >>> Craig James <cjames@xxxxxxxxxxxxxx> writes: >>>> I want to do this: >>> >>>> select setval('object_id_seq', nextval('object_id_seq') + 1000, false); >>> >>>> Now suppose two processes do this simultaneously. Maybe they're in >>>> transactions, maybe they're not. Are they guaranteed to get distinct >>>> blocks of IDs? >>> >>> No, because the setval and the nextval are not indivisible. >>> >>>> Or is it possible that each will execute nextval() and >>>> get N and N+1 respectively, and then do setval() to N+1000 and N+1001, >>>> resulting in two overlapping blocks. >>> >>> Exactly. >>> >>>> If the answer is, "This won't work," then what's a better way to do this? >>> >>> AFAIK the only way at the moment is >>> >>> * acquire some advisory lock that by convention you use for this sequence >>> * advance the sequence >>> * release advisory lock >>> >>> There have been previous discussions of this type of problem, eg >>> http://archives.postgresql.org/pgsql-hackers/2011-09/msg01031.php >>> but the topic doesn't seem to have come up quite often enough to >>> motivate anybody to do anything about it. Your particular case could be >>> handled by a variant of nextval() with a number-of-times-to-advance >>> argument, but I'm not sure if that's enough for other scenarios. >>> >>> regards, tom lane >> >> So here's what I came up with. I'm no PLPGSQL guru, but it seemed >> pretty straightforward. >> >> create or replace function nextval_block(bsize integer default 1) >> returns bigint as $nextval_block$ >> declare >> bstart bigint; >> begin >> perform pg_advisory_lock(1); >> select into bstart nextval('my_seq'); >> perform setval('my_seq', bstart + bsize, false); >> perform pg_advisory_unlock(1); >> return bstart; >> end; >> $nextval_block$ language plpgsql; > > That seems unnecessarily complex. how about this: > > create sequence s; > select array_agg (a.b) from (select nextval('s') as b from > generate_series(1,1000)) as a; > > Then you just iterate that array for the ids you need. If you want it in a comma delimited formate: select array_to_string(array_agg (a.b),',') from (select nextval('s') as b from generate_series(1,1000)) as a; -- Sent via pgsql-performance mailing list (pgsql-performance@xxxxxxxxxxxxxx) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-performance