Thread: Atomic query and update of sequence generators
If I want to allocate a block of adjacent values from a sequence generator, is the following statement atomic with respect to the time between when the call to nextval() and setval()? SELECT setval('foo', nextval()+20) ... The goal is to get a sequence of 20 values that are all +1 from each other. If the above isn't safe in concurrent environments, is there something else I can do to achieve the effect safely? I saw a similar unanswered question on one of the PostgreSQL newsgroups, and have a need to do the same thing from my JDBC app. Tips appreciated.
Jeffrey Tenny <jeffrey.tenny@comcast.net> writes: > If I want to allocate a block of adjacent values from a sequence generator, > is the following statement atomic with respect to the time between > when the call to nextval() and setval()? > SELECT setval('foo', nextval()+20) ... Nope. > The goal is to get a sequence of 20 values that are all +1 from each other. Do you always want to pull exactly 20 values? If so you could set the sequence's "cache" parameter to 20 (see the CREATE SEQUENCE man page for details). I don't think there's any way at present to get varying sizes of consecutively-allocated blocks. If you need that, it would likely not be real hard to implement a "next_n_vals(seq, n)" variant of nextval() to grab N consecutive values and return the first. But it's not there at the moment. regards, tom lane
-----BEGIN PGP SIGNED MESSAGE----- Hash: SHA1 > The goal is to get a sequence of 20 values that are > all +1 from each other. If you don't care about the rest of the values being +1 from each other, you could create the sequence with an INTERVAL of 20. Other than that, you would probably have to create your own "sequence" generator. Another alternative would be a function like this: get nextval as x set sequence to x+20 get nextval as y repeat if y != x+20 (i.e. someone else grabbed a value) - -- Greg Sabino Mullane greg@turnstep.com PGP Key: 0x14964AC8 200401150746 -----BEGIN PGP SIGNATURE----- iD8DBQFABovdvJuQZxSWSsgRAnxeAKCWK3tFCE3u8NfXG5LG3H0smDLyhACglrr7 08ke6k8B8MSKVipRb2aSWQg= =PSzM -----END PGP SIGNATURE-----
Hi all, I am using : PostgreSQL 7.2.3 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.2 20020903 (Red Hat Linux 8.0 3.2-7) I am facing strange problem.. I have created two tables: create table contact (id int constraint contact_pk primary key, name text ); create table address (id int constraint address_fk references contact(id) on delete cascade initially deferred, city text, pin text); Lets.. insert few data in it.. insert into contact values (1, 'Denis'); insert into contact values (2, 'Anand'); insert into contact values (3, 'Debatosh'); insert into contact values (4, 'Pradeep'); insert into address values (1,'Howrah','711102'); insert into address values (2,'Kolkata','700001'); insert into address values (3,'Jadavpur','700005'); insert into address values (4,'Mumbai','400002'); Now, below gives me the correct result. select * from contact; select * from address; acedg=> select * from contact; select * from address;id | name ----+---------- 1 | Denis 2 | Anand 3 | Debatosh 4 | Pradeep (4 rows) id | city | pin ----+----------+-------- 1 | Howrah | 711102 2 | Kolkata | 700001 3 | Jadavpur | 700005 4 | Mumbai | 400002 (4 rows) BUT, the problem starts when i issue the following set of DMLs in transaction: begin; delete from contact where id=1; insert into contact values (1, 'Denis'); delete from address where id=1; /* this is not required.. but my app.fires. Should not have any impact */ insert into address values (1,'Howrah','711102'); end; It gives me the result: acedg=> select * from contact; select * from address;id | name ----+---------- 2 | Anand 3 | Debatosh 4 | Pradeep 1 | Denis (4 rows) id | city | pin ----+----------+-------- 2 | Kolkata | 700001 3 | Jadavpur | 700005 4 | Mumbai | 400002 (3 rows) Where is my lastly inserted row ?? i.e. insert into address values (1,'Howrah','711102'); I have tested the same in ORACLE, and it works fine (i.e. both table has 4 records). It is BUG or !!! Pl. help. Thanx Denis