Thread: extension for sql update
Hi, here is a patch that extends update syntax following the sql standard. The patch includes sgml documentation, too. For example: UPDATE table SET (col1, col2, ...) = (val1, val2, ...), (colm, coln, ...) = (valm, valn, ...), ...; Susanne
Attachment
Susanne Ebrecht <miracee@miracee.de> writes: > here is a patch that extends update syntax following the sql standard. > The patch includes sgml documentation, too. > UPDATE table SET (col1, col2, ...) = (val1, val2, ...), > (colm, coln, ...) = (valm, valn, ...), ...; This is a cute hack, but it does only a small part of what I think the spec says. In the first place, the SQL syntax is pretty clear that you can combine simple and multiple assignment in the same UPDATE: <update statement: searched> ::= UPDATE <target table> SET <set clause list> [ WHERE <search condition> ] <set clause list> ::= <set clause> [ { <comma> <set clause> }... ] <set clause> ::= <multiple column assignment> | <set target> <equals operator> <update source> <multiple column assignment> ::= <set target list> <equals operator> <assigned row> <set target list> ::= <left paren> <set target> [ { <comma> <set target> } ... ] <right paren> The patch doesn't do that, but it wouldn't be too hard to fix. The more serious problem is that <assigned row> ::= <contextually typed row value expression> and <contextually typed row value expression> is supposed to be pretty much anything that can generate a row. The patch as you have it provides nothing more than syntactic sugar for something people can do anyway. The reason people want this syntax is that they expect to be able to write, say, UPDATE mytab SET (foo, bar, baz) = (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); and with something like that you can't break apart the row-valued expression in the grammar. So in reality the feature has to propagate much further into the backend than this. regards, tom lane
Am Mittwoch, den 26.07.2006, 16:58 -0400 schrieb Tom Lane: > Susanne Ebrecht <miracee@miracee.de> writes: > This is a cute hack, but it does only a small part of what I think the > spec says. Thank you for compliment. > > In the first place, the SQL syntax is pretty clear that you can combine > simple and multiple assignment in the same UPDATE: Ups, I asked about mixed syntax and I missunderstood the answer (I thougt there is nothing spezified about mixed syntax). But fixing this, seems not to be difficult. > The patch doesn't do that, but it wouldn't be too hard to fix. The more > serious problem is that > > <assigned row> ::= <contextually typed row value expression> > > and <contextually typed row value expression> is supposed to be pretty > much anything that can generate a row. The patch as you have it > provides nothing more than syntactic sugar for something people can do > anyway. The reason people want this syntax is that they expect to be > able to write, say, > > UPDATE mytab SET (foo, bar, baz) = > (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > and with something like that you can't break apart the row-valued > expression in the grammar. So in reality the feature has to propagate > much further into the backend than this. This seems to be difficult and I'm not sure this could be done until feature freeze. We could provide the mixed update syntax and leave the typed row value expression for the next release. Do you agree? regards Susanne Ebrecht
Attachment
Susanne Ebrecht <miracee@miracee.de> writes: > ... We could provide the mixed update syntax and leave the > typed row value expression for the next release. Do you agree? I don't really see the point --- the patch won't provide any new functionality in anything like its current form, because you can always just write the separate expressions in the simple one to one way. If we do offer the row-on-the-left syntax then people will try to put sub-selects on the right, and won't get anything beyond an unhelpful "syntax error" message. So my vote would be to leave it alone until we have a more complete implementation. regards, tom lane
Tom Lane wrote: > much anything that can generate a row. The patch as you have it > provides nothing more than syntactic sugar for something people can do > anyway. The reason people want this syntax is that they expect to be > able to write, say, > > UPDATE mytab SET (foo, bar, baz) = > (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > and with something like that you can't break apart the row-valued > expression in the grammar. So in reality the feature has to propagate > much further into the backend than this. That UPDATE example is interesting because I remember when using Informix that I had to do a separate SELECT statement for each UPDATE column I wanted to update. I didn't realize that you could group columns and assign them from a single select --- clearly that is a powerful syntax we should support some day. -- Bruce Momjian bruce@momjian.us EnterpriseDB http://www.enterprisedb.com + If your life is a hard drive, Christ can be your backup. +
Bruce Momjian <bruce@momjian.us> writes: > Tom Lane wrote: >> UPDATE mytab SET (foo, bar, baz) = >> (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > That UPDATE example is interesting because I remember when using > Informix that I had to do a separate SELECT statement for each UPDATE > column I wanted to update. I didn't realize that you could group > columns and assign them from a single select --- clearly that is a > powerful syntax we should support some day. No question. The decision at hand is whether we want to look like we support it, when we don't yet. I'd vote not, because I think the main use-case for the row-on-the-left syntax is exactly this, and so I fear people will just get frustrated if they see it in the syntax synopsis and try to use it. regards, tom lane
Tom Lane wrote: > Bruce Momjian <bruce@momjian.us> writes: > > Tom Lane wrote: > >> UPDATE mytab SET (foo, bar, baz) = > >> (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > > That UPDATE example is interesting because I remember when using > > Informix that I had to do a separate SELECT statement for each UPDATE > > column I wanted to update. I didn't realize that you could group > > columns and assign them from a single select --- clearly that is a > > powerful syntax we should support some day. > > No question. The decision at hand is whether we want to look like > we support it, when we don't yet. I'd vote not, because I think the > main use-case for the row-on-the-left syntax is exactly this, and > so I fear people will just get frustrated if they see it in the > syntax synopsis and try to use it. Agreed. My guess is that a soluion that allows SELECT to return multiple values is going to be in another area of the code, and will require us to remove this code once that is done. -- Bruce Momjian bruce@momjian.us EnterpriseDB http://www.enterprisedb.com + If your life is a hard drive, Christ can be your backup. +
On Jul 27, 2006, at 7:30 AM, Tom Lane wrote: > Susanne Ebrecht <miracee@miracee.de> writes: >> ... We could provide the mixed update syntax and leave the >> typed row value expression for the next release. Do you agree? > > I don't really see the point --- the patch won't provide any new > functionality in anything like its current form, because you can > always just write the separate expressions in the simple one to > one way. If we do offer the row-on-the-left syntax then people > will try to put sub-selects on the right, and won't get anything > beyond an unhelpful "syntax error" message. So my vote would be > to leave it alone until we have a more complete implementation. While the patch doesn't provide any new functionality, I would still welcome it simply because I find it a lot easier and cleaner to group fields together when updating multiple fields at once. Even if we would have to rip this patch back out in order to fully support the spec, we've got a (mostly) working patch right now, and it sounds like it would take minimal effort to finish it. In any case, it sounds like there should be a TODO item out of this. -- Jim C. Nasby, Sr. Engineering Consultant jnasby@pervasive.com Pervasive Software http://pervasive.com work: 512-231-6117 vcard: http://jim.nasby.net/pervasive.vcf cell: 512-569-9461
Tom Lane wrote: > Susanne Ebrecht <miracee@miracee.de> writes: >> ... We could provide the mixed update syntax and leave the >> typed row value expression for the next release. Do you agree? > > I don't really see the point --- the patch won't provide any new > functionality in anything like its current form, because you can > always just write the separate expressions in the simple one to > one way. If we do offer the row-on-the-left syntax then people > will try to put sub-selects on the right, and won't get anything > beyond an unhelpful "syntax error" message. So my vote would be > to leave it alone until we have a more complete implementation. It has the advantage that inserts and updates look more "alike". If your sql statements are generated by code, then that removes the need of a special case for updates. greetings, Florian Pflug
Jim Nasby wrote: > On Jul 27, 2006, at 7:30 AM, Tom Lane wrote: > > Susanne Ebrecht <miracee@miracee.de> writes: > >> ... We could provide the mixed update syntax and leave the > >> typed row value expression for the next release. Do you agree? > > > > I don't really see the point --- the patch won't provide any new > > functionality in anything like its current form, because you can > > always just write the separate expressions in the simple one to > > one way. If we do offer the row-on-the-left syntax then people > > will try to put sub-selects on the right, and won't get anything > > beyond an unhelpful "syntax error" message. So my vote would be > > to leave it alone until we have a more complete implementation. > > While the patch doesn't provide any new functionality, I would still > welcome it simply because I find it a lot easier and cleaner to group > fields together when updating multiple fields at once. > > Even if we would have to rip this patch back out in order to fully > support the spec, we've got a (mostly) working patch right now, and > it sounds like it would take minimal effort to finish it. > > In any case, it sounds like there should be a TODO item out of this. We already had it on the TODO list, but I didn't realize about the subselect issue. I added a sentence to clarify that: o Allow UPDATE tab SET ROW (col, ...) = (...) for updating multiple columns new--> A subselect can also be used as the value source. -- Bruce Momjian bruce@momjian.us EnterpriseDB http://www.enterprisedb.com + If your life is a hard drive, Christ can be your backup. +
Am Donnerstag, den 27.07.2006, 08:30 -0400 schrieb Tom Lane: > Susanne Ebrecht <miracee@miracee.de> writes: > > ... We could provide the mixed update syntax and leave the > > typed row value expression for the next release. Do you agree? > > I don't really see the point --- the patch won't provide any new > functionality in anything like its current form, because you can > always just write the separate expressions in the simple one to > one way. If we do offer the row-on-the-left syntax then people > will try to put sub-selects on the right, and won't get anything > beyond an unhelpful "syntax error" message. So my vote would be > to leave it alone until we have a more complete implementation. Look at my intention, why I wrote this patch: In recent years I migrated many customers applications from oracle or informix to postgresql. Every time it was a very painful and annoying job to grep through the code of functions and the whole software, to find all updates and change them manually. Far ago at university, I learned both syntax as standard syntax. Example: set a=1, b=2, c=3 and set (a,b,c)=(1,2,3) I admit, I prefered the second form, too, when I only used informix and it seems also my customers do so. Still now, I never found this syntax with select statement. I am not sure if this is possible with informix or oracle. regards Susanne > > regards, tom lane
Attachment
On Thursday 27 July 2006 09:28, Bruce Momjian wrote: > Tom Lane wrote: > > Bruce Momjian <bruce@momjian.us> writes: > > > Tom Lane wrote: > > >> UPDATE mytab SET (foo, bar, baz) = > > >> (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > > > > > That UPDATE example is interesting because I remember when using > > > Informix that I had to do a separate SELECT statement for each UPDATE > > > column I wanted to update. I didn't realize that you could group > > > columns and assign them from a single select --- clearly that is a > > > powerful syntax we should support some day. > > > > No question. The decision at hand is whether we want to look like > > we support it, when we don't yet. I'd vote not, because I think the > > main use-case for the row-on-the-left syntax is exactly this, and > > so I fear people will just get frustrated if they see it in the > > syntax synopsis and try to use it. > I'm not a big fan of implementing partial solutions (remember "left-joins are not implemented messages" :-) way back when) , however in my experience with this form of the update command, the primary usage is not to use a subselect to derive the values, but to make it easier to generate sql, using a single update statement, based on an array of passed in values (in languages like perl/php/etc...). This solution would solve that problem for us, so I would lean toward including it. I would be interested in hearing from actual users who really need the subselect version though, but right now my thinking is that group is a small minority of who would benefit from this version of the update command. -- Robert Treat Build A Brighter LAMP :: Linux Apache {middleware} PostgreSQL
On Sun, 2006-07-30 at 20:20 -0400, Robert Treat wrote: > On Thursday 27 July 2006 09:28, Bruce Momjian wrote: > > Tom Lane wrote: > > > Bruce Momjian <bruce@momjian.us> writes: > > > > Tom Lane wrote: > > > >> UPDATE mytab SET (foo, bar, baz) = > > > >> (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > > > > > > > That UPDATE example is interesting because I remember when using > > > > Informix that I had to do a separate SELECT statement for each UPDATE > > > > column I wanted to update. I didn't realize that you could group > > > > columns and assign them from a single select --- clearly that is a > > > > powerful syntax we should support some day. > > > > > > No question. The decision at hand is whether we want to look like > > > we support it, when we don't yet. I'd vote not, because I think the > > > main use-case for the row-on-the-left syntax is exactly this, and > > > so I fear people will just get frustrated if they see it in the > > > syntax synopsis and try to use it. > > > > I'm not a big fan of implementing partial solutions (remember "left-joins are > not implemented messages" :-) way back when) , however in my experience with > this form of the update command, the primary usage is not to use a subselect > to derive the values, but to make it easier to generate sql, using a single I disagree. UPDATE mytab SET (foo, bar, baz) =(SELECT ...) is the specifications way of doing an update with a join. That is its primary purpose. UPDATE ... FROM is a PostgreSQL alternative to the above. --
On Sun, Jul 30, 2006 at 08:38:30PM -0400, Rod Taylor wrote: > On Sun, 2006-07-30 at 20:20 -0400, Robert Treat wrote: > > On Thursday 27 July 2006 09:28, Bruce Momjian wrote: > > > Tom Lane wrote: > > > > Bruce Momjian <bruce@momjian.us> writes: > > > > > Tom Lane wrote: > > > > >> UPDATE mytab SET (foo, bar, baz) = > > > > >> (SELECT alpha, beta, gamma FROM othertab WHERE key = mytab.key); > > > > > > > > > > That UPDATE example is interesting because I remember when using > > > > > Informix that I had to do a separate SELECT statement for each UPDATE > > > > > column I wanted to update. I didn't realize that you could group > > > > > columns and assign them from a single select --- clearly that is a > > > > > powerful syntax we should support some day. > > > > > > > > No question. The decision at hand is whether we want to look like > > > > we support it, when we don't yet. I'd vote not, because I think the > > > > main use-case for the row-on-the-left syntax is exactly this, and > > > > so I fear people will just get frustrated if they see it in the > > > > syntax synopsis and try to use it. > > > > > > > I'm not a big fan of implementing partial solutions (remember "left-joins are > > not implemented messages" :-) way back when) , however in my experience with > > this form of the update command, the primary usage is not to use a subselect > > to derive the values, but to make it easier to generate sql, using a single > > I disagree. UPDATE mytab SET (foo, bar, baz) =(SELECT ...) is the > specifications way of doing an update with a join. That is its primary > purpose. > > UPDATE ... FROM is a PostgreSQL alternative to the above. An alternative that people have been using without complaint for years (probably because a number of other databases do the same thing). Perhaps a good compromise would be to allow UPDATE ... (SELECT) where it would meet the current requirements for UPDATE ... FROM. -- Jim C. Nasby, Sr. Engineering Consultant jnasby@pervasive.com Pervasive Software http://pervasive.com work: 512-231-6117 vcard: http://jim.nasby.net/pervasive.vcf cell: 512-569-9461