Re: Does setval(nextval()+N) generate unique blocks of IDs?

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



On Mon, Aug 20, 2012 at 6:59 PM, Scott Marlowe <scott.marlowe@xxxxxxxxx> wrote:
> On Mon, Aug 20, 2012 at 6: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.
>
> If the OP could live with large gaps in his sequence, he could set it
> to advance by say 1000 at a time, and then use the numbers in that gap
> freely.  Just a thought.

Better yet set cache = 1000;  here's an example:

create sequence a cache 1000;
T1: select nextval('a');
1
T2: select nextval('a');
1001
T1: select nextval('a');
2
T2: select nextval('a');
1002

and so on.

Now can he just select nextval('a'); 1000 times in a loop?  Or would
he prefer another method.

I guess I'm kind of wondering which problem he's trying to solve.


-- 
Sent via pgsql-performance mailing list (pgsql-performance@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


[Postgresql General]     [Postgresql PHP]     [PHP Users]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Yosemite]

  Powered by Linux