Thread: Re: [GENERAL] Bug with sequence
On Wed, 2002-11-20 at 21:35, Robert Treat wrote: > On Wed, 2002-11-20 at 03:53, Oliver Elphick wrote: > > On Mon, 2002-11-18 at 15:45, Thomas Aichinger wrote: > > > Hi, > > > > > > I recently installed pg 7.2.3 on my linux box and discovered that > > > there are some problems with datatype serial and sequence. > > > > > > 1.) If you create a table with a datatype serial, the corrsponding > > > sequence will be created, but if you drop the table the sequence is > > > not dropped. > > > > This is fixed in 7.3 > > > > out of curiosity, do you know the logic that implements this fix? I have > a couple of tables that use the same sequence; I'm wondering if dropping > one of the tables removes the sequence or if I have to drop all tables > before the sequence is removed I just tried it. I created a sequence using SERIAL when I created a table. I used the same sequence for another table by setting a column default to nextval(sequence). I deleted the first table. The sequence was deleted too, leaving the default of the second table referring to a non-existent sequence. Could this be a TODO item in 7.4, to add a dependency check when a sequence is set as the default without being created at the same time? -- Oliver Elphick Oliver.Elphick@lfix.co.uk Isle of Wight, UK http://www.lfix.co.uk/oliver GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839 932A 614D 4C34 3E1D 0C1C ======================================== "If my people, which are called by my name, shall humble themselves, andpray, and seek my face, and turn from their wicked ways; then will I hear from heaven, and will forgive theirsin, and will heal their land." II Chronicles 7:14
This requires changing the nextval() function to be an attribute of the sequence. ie. sequence.nextval and sequence.currval to deal with the sequence. It should also be on the todo list. On Wed, 2002-11-20 at 17:12, Oliver Elphick wrote: > On Wed, 2002-11-20 at 21:35, Robert Treat wrote: > > On Wed, 2002-11-20 at 03:53, Oliver Elphick wrote: > > > On Mon, 2002-11-18 at 15:45, Thomas Aichinger wrote: > > > > Hi, > > > > > > > > I recently installed pg 7.2.3 on my linux box and discovered that > > > > there are some problems with datatype serial and sequence. > > > > > > > > 1.) If you create a table with a datatype serial, the corrsponding > > > > sequence will be created, but if you drop the table the sequence is > > > > not dropped. > > > > > > This is fixed in 7.3 > > > > > > > out of curiosity, do you know the logic that implements this fix? I have > > a couple of tables that use the same sequence; I'm wondering if dropping > > one of the tables removes the sequence or if I have to drop all tables > > before the sequence is removed > > I just tried it. > > I created a sequence using SERIAL when I created a table. I used the > same sequence for another table by setting a column default to > nextval(sequence). > > I deleted the first table. The sequence was deleted too, leaving the > default of the second table referring to a non-existent sequence. > > > Could this be a TODO item in 7.4, to add a dependency check when a > sequence is set as the default without being created at the same time? -- Rod Taylor <rbt@rbt.ca>
Oliver Elphick wrote: > > On Wed, 2002-11-20 at 21:35, Robert Treat wrote: > > On Wed, 2002-11-20 at 03:53, Oliver Elphick wrote: > > > On Mon, 2002-11-18 at 15:45, Thomas Aichinger wrote: > > > > Hi, > > > > > > > > I recently installed pg 7.2.3 on my linux box and discovered that > > > > there are some problems with datatype serial and sequence. > > > > > > > > 1.) If you create a table with a datatype serial, the corrsponding > > > > sequence will be created, but if you drop the table the sequence is > > > > not dropped. > > > > > > This is fixed in 7.3 > > > > > > > out of curiosity, do you know the logic that implements this fix? I have > > a couple of tables that use the same sequence; I'm wondering if dropping > > one of the tables removes the sequence or if I have to drop all tables > > before the sequence is removed > > I just tried it. > > I created a sequence using SERIAL when I created a table. I used the > same sequence for another table by setting a column default to > nextval(sequence). > > I deleted the first table. The sequence was deleted too, leaving the > default of the second table referring to a non-existent sequence. This sounds like a serious bug in our behaviour, and not something we'd like to release. Specifically in relation to people's existing scripts, and also to people who are doing dump/restore of specific tables (it'll kill the sequences that other tables depend on too!) No real issue with the nicety for newbies, but am very concerned about the lack of a dependancy check here. :-/ Regards and best wishes, Justin Clift > Could this be a TODO item in 7.4, to add a dependency check when a > sequence is set as the default without being created at the same time? > > -- > Oliver Elphick Oliver.Elphick@lfix.co.uk > Isle of Wight, UK > http://www.lfix.co.uk/oliver > GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839 932A 614D 4C34 3E1D 0C1C > ======================================== > "If my people, which are called by my name, shall > humble themselves, and pray, and seek my face, and > turn from their wicked ways; then will I hear from > heaven, and will forgive their sin, and will heal > their land." II Chronicles 7:14 > > ---------------------------(end of broadcast)--------------------------- > TIP 3: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly -- "My grandfather once told me that there are two kinds of people: those who work and those who take the credit. He told me to try to be in the first group; there was less competition there." - Indira Gandhi
Justin Clift <justin@postgresql.org> writes: > This sounds like a serious bug in our behaviour, and not something > we'd like to release. It's not ideal, I agree, but I *definately* don't think this is grounds for changing the release schedule. > No real issue with the nicety for newbies, but am very concerned > about the lack of a dependancy check here. Well, how would you suggest we fix this? ISTM this is partially a result of the fact that we don't produce dependancy information for function bodies. While it might be possible to do so (in 7.4) for certain types of functions (e.g. for functions defined in SQL, PL/PgSQL, etc.), I can't see a general solution (e.g. for functions defined in C). And adding random hacks to get specific functions (e.g. nextval()) to work does not strike me as a very good idea. Cheers, Neil -- Neil Conway <neilc@samurai.com> || PGP Key ID: DB3C29FC
Neil Conway wrote: > > Justin Clift <justin@postgresql.org> writes: > > This sounds like a serious bug in our behaviour, and not something > > we'd like to release. > > It's not ideal, I agree, but I *definately* don't think this is > grounds for changing the release schedule. Hey, I'm no fan of slowing the release schedule either. Bug this is definitely sounding like a bug. > > No real issue with the nicety for newbies, but am very concerned > > about the lack of a dependancy check here. > > Well, how would you suggest we fix this? ISTM this is partially a > result of the fact that we don't produce dependancy information for > function bodies. While it might be possible to do so (in 7.4) for > certain types of functions (e.g. for functions defined in SQL, > PL/PgSQL, etc.), I can't see a general solution (e.g. for functions > defined in C). Absolutely *no* idea. > And adding random hacks to get specific functions (e.g. nextval()) to > work does not strike me as a very good idea. Agreed. Random hacks aren't always a good approach. Regards and best wishes, Justin Clift > Cheers, > > Neil > > -- > Neil Conway <neilc@samurai.com> || PGP Key ID: DB3C29FC -- "My grandfather once told me that there are two kinds of people: those who work and those who take the credit. He told me to try to be in the first group; there was less competition there." - Indira Gandhi
Justin Clift <justin@postgresql.org> writes: > Oliver Elphick wrote: >> I created a sequence using SERIAL when I created a table. I used the >> same sequence for another table by setting a column default to >> nextval(sequence). >> >> I deleted the first table. The sequence was deleted too, leaving the >> default of the second table referring to a non-existent sequence. > This sounds like a serious bug in our behaviour, and not something we'd > like to release. We will be releasing it whether we like it or not, because nextval('foo') doesn't expose any visible dependency on sequence foo. (If you think it should, how about nextval('fo' || 'o')? If you think that's improbable, consider nextval('table' || '_' || 'col' || '_seq').) The long-term answer is to do what Rod alluded to: support the Oracle-style syntax foo.nextval, so that the sequence reference is honestly part of the parsetree and not buried inside a string expression. In the meantime, I consider that Oliver was misusing the SERIAL feature. If you want multiple tables fed by the same sequence object, you should create the sequence as a separate object and then create the tables using explicit "DEFAULT nextval('foo')" clauses. Doing what he did amounts to sticking his fingers under the hood of the SERIAL implementation; if he gets his fingers burnt, it's his problem. > Specifically in relation to people's existing scripts, and also to > people who are doing dump/restore of specific tables (it'll kill the > sequences that other tables depend on too!) 7.3 breaks no existing schemas, because older schemas will be dumped as separate CREATE SEQUENCE and CREATE TABLE ... DEFAULT nextval() commands. regards, tom lane
Tom Lane wrote: > > Justin Clift <justin@postgresql.org> writes: > > Oliver Elphick wrote: > >> I created a sequence using SERIAL when I created a table. I used the > >> same sequence for another table by setting a column default to > >> nextval(sequence). > >> > >> I deleted the first table. The sequence was deleted too, leaving the > >> default of the second table referring to a non-existent sequence. > > > This sounds like a serious bug in our behaviour, and not something we'd > > like to release. > > We will be releasing it whether we like it or not, because > nextval('foo') doesn't expose any visible dependency on sequence foo. Awww rats. <snip> > 7.3 breaks no existing schemas, because older schemas will be dumped > as separate CREATE SEQUENCE and CREATE TABLE ... DEFAULT nextval() > commands. Ok. Thanks Tom. :) Regards and best wishes, Justin Clift > regards, tom lane -- "My grandfather once told me that there are two kinds of people: those who work and those who take the credit. He told me to try to be in the first group; there was less competition there." - Indira Gandhi
It seems worth pointing out, too, that some SQL purists propose not relying on product-specific methods of auto-incrementing. I.e., it is possible to do something like: insert into foo( col, ... ) values( coalesce( ( select max( col ) from foo ), 0 ) + 1, ... ); and this is easily placed in a trigger. -tfo In article <7017.1037851915@sss.pgh.pa.us>,tgl@sss.pgh.pa.us (Tom Lane) wrote: > Justin Clift <justin@postgresql.org> writes: > > Oliver Elphick wrote: > >> I created a sequence using SERIAL when I created a table. I used the > >> same sequence for another table by setting a column default to > >> nextval(sequence). > >> > >> I deleted the first table. The sequence was deleted too, leaving the > >> default of the second table referring to a non-existent sequence. > > > This sounds like a serious bug in our behaviour, and not something we'd > > like to release. > > We will be releasing it whether we like it or not, because > nextval('foo') doesn't expose any visible dependency on sequence foo. > > (If you think it should, how about nextval('fo' || 'o')? If you think > that's improbable, consider nextval('table' || '_' || 'col' || '_seq').) > > The long-term answer is to do what Rod alluded to: support the > Oracle-style syntax foo.nextval, so that the sequence reference is > honestly part of the parsetree and not buried inside a string > expression. > > In the meantime, I consider that Oliver was misusing the SERIAL > feature. If you want multiple tables fed by the same sequence object, > you should create the sequence as a separate object and then create > the tables using explicit "DEFAULT nextval('foo')" clauses. Doing what > he did amounts to sticking his fingers under the hood of the SERIAL > implementation; if he gets his fingers burnt, it's his problem. > > > Specifically in relation to people's existing scripts, and also to > > people who are doing dump/restore of specific tables (it'll kill the > > sequences that other tables depend on too!) > > 7.3 breaks no existing schemas, because older schemas will be dumped > as separate CREATE SEQUENCE and CREATE TABLE ... DEFAULT nextval() > commands. > > regards, tom lane
Of course, those would be SQL purists who _don't_ understand concurrency issues. ;-) --------------------------------------------------------------------------- Thomas O'Connell wrote: > It seems worth pointing out, too, that some SQL purists propose not > relying on product-specific methods of auto-incrementing. > > I.e., it is possible to do something like: > > insert into foo( col, ... ) > values( coalesce( ( select max( col ) from foo ), 0 ) + 1, ... ); > > and this is easily placed in a trigger. > > -tfo > > In article <7017.1037851915@sss.pgh.pa.us>, > tgl@sss.pgh.pa.us (Tom Lane) wrote: > > > Justin Clift <justin@postgresql.org> writes: > > > Oliver Elphick wrote: > > >> I created a sequence using SERIAL when I created a table. I used the > > >> same sequence for another table by setting a column default to > > >> nextval(sequence). > > >> > > >> I deleted the first table. The sequence was deleted too, leaving the > > >> default of the second table referring to a non-existent sequence. > > > > > This sounds like a serious bug in our behaviour, and not something we'd > > > like to release. > > > > We will be releasing it whether we like it or not, because > > nextval('foo') doesn't expose any visible dependency on sequence foo. > > > > (If you think it should, how about nextval('fo' || 'o')? If you think > > that's improbable, consider nextval('table' || '_' || 'col' || '_seq').) > > > > The long-term answer is to do what Rod alluded to: support the > > Oracle-style syntax foo.nextval, so that the sequence reference is > > honestly part of the parsetree and not buried inside a string > > expression. > > > > In the meantime, I consider that Oliver was misusing the SERIAL > > feature. If you want multiple tables fed by the same sequence object, > > you should create the sequence as a separate object and then create > > the tables using explicit "DEFAULT nextval('foo')" clauses. Doing what > > he did amounts to sticking his fingers under the hood of the SERIAL > > implementation; if he gets his fingers burnt, it's his problem. > > > > > Specifically in relation to people's existing scripts, and also to > > > people who are doing dump/restore of specific tables (it'll kill the > > > sequences that other tables depend on too!) > > > > 7.3 breaks no existing schemas, because older schemas will be dumped > > as separate CREATE SEQUENCE and CREATE TABLE ... DEFAULT nextval() > > commands. > > > > regards, tom lane > > ---------------------------(end of broadcast)--------------------------- > TIP 3: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly > -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
Oliver Elphick wrote: > I deleted the first table. The sequence was deleted too, leaving the > default of the second table referring to a non-existent sequence. > > > Could this be a TODO item in 7.4, to add a dependency check when a > sequence is set as the default without being created at the same time? Added to TODO: * Have sequence dependency track use of DEFAULT sequences, seqname.nextval -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
On Thu, 2002-11-21 at 14:11, Bruce Momjian wrote: > Of course, those would be SQL purists who _don't_ understand > concurrency issues. ;-) Or they're the kind that locks the entire table for any given insert. -- Rod Taylor <rbt@rbt.ca>
"Thomas O'Connell" <tfo@monsterlabs.com> writes: > It seems worth pointing out, too, that some SQL purists propose not > relying on product-specific methods of auto-incrementing. > I.e., it is possible to do something like: > insert into foo( col, ... ) > values( coalesce( ( select max( col ) from foo ), 0 ) + 1, ... ); > and this is easily placed in a trigger. ... but that approach is entirely unworkable if you want any concurrency of insert operations. (Triggers are a tad product-specific, too :-() regards, tom lane
On 21 Nov 2002, Rod Taylor wrote: > On Thu, 2002-11-21 at 14:11, Bruce Momjian wrote: > > Of course, those would be SQL purists who _don't_ understand > > concurrency issues. ;-) > > Or they're the kind that locks the entire table for any given insert. Isn't that what Bruce just said? ;^)
On Thu, 2002-11-21 at 15:09, scott.marlowe wrote: > On 21 Nov 2002, Rod Taylor wrote: > > > On Thu, 2002-11-21 at 14:11, Bruce Momjian wrote: > > > Of course, those would be SQL purists who _don't_ understand > > > concurrency issues. ;-) > > > > Or they're the kind that locks the entire table for any given insert. > > Isn't that what Bruce just said? ;^) I suppose so. I took what Bruce said to be that multiple users could get the same ID. I keep having developers want to make their own table for a sequence, then use id = id + 1 -- so they hold a lock on it for the duration of the transaction. -- Rod Taylor <rbt@rbt.ca>
On 21 Nov 2002, Rod Taylor wrote: > On Thu, 2002-11-21 at 15:09, scott.marlowe wrote: > > On 21 Nov 2002, Rod Taylor wrote: > > > > > On Thu, 2002-11-21 at 14:11, Bruce Momjian wrote: > > > > Of course, those would be SQL purists who _don't_ understand > > > > concurrency issues. ;-) > > > > > > Or they're the kind that locks the entire table for any given insert. > > > > Isn't that what Bruce just said? ;^) > > I suppose so. I took what Bruce said to be that multiple users could > get the same ID. > > I keep having developers want to make their own table for a sequence, > then use id = id + 1 -- so they hold a lock on it for the duration of > the transaction. I was just funnin' with ya, but the point behind it was that either way (with or without a lock) that using something other than a sequence is probably a bad idea. Either way, under parallel load, you have data consistency issues, or you have poor performance issues.
scott.marlowe@ihs.com ("scott.marlowe") wrote in message news:<Pine.LNX.4.33.0211211450100.23804-100000@css120.ihs.com>... > On 21 Nov 2002, Rod Taylor wrote: > > > On Thu, 2002-11-21 at 15:09, scott.marlowe wrote: > > > On 21 Nov 2002, Rod Taylor wrote: > > > > > > > On Thu, 2002-11-21 at 14:11, Bruce Momjian wrote: > > > > > Of course, those would be SQL purists who _don't_ understand > > > > > concurrency issues. ;-) > > > > > > > > Or they're the kind that locks the entire table for any given insert. > > > > > > Isn't that what Bruce just said? ;^) > > > > I suppose so. I took what Bruce said to be that multiple users could > > get the same ID. > > > > I keep having developers want to make their own table for a sequence, > > then use id = id + 1 -- so they hold a lock on it for the duration of > > the transaction. > > I was just funnin' with ya, but the point behind it was that either way > (with or without a lock) that using something other than a sequence is > probably a bad idea. Either way, under parallel load, you have data > consistency issues, or you have poor performance issues. > > I'm not familiar with these "SQL purists" (perhaps the reference is to J. Celko?) but the fact is that it's hard to call SEQUENCE product-specific now that it's in Oracle, DB2, and SQL:2003. The syntaxes do differ a little, usually due to choice of abbreviation, but as far as I can tell the internals are similar across implementations. Peter Gulutzan Author of "Sequences And Identity Columns" (http://dbazine.com/gulutzan4.html)