Thread: HINTing on UPDATE foo SET foo.bar = ..;

HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
Hi,

A common mistake is to try and qualify column references on the LHS of
SET in UPDATE.  The error message can be a bit cryptic at times, too.
I've attached a patch to try and improve the situation a bit:

=# create table foo(bar int);
CREATE TABLE

=# update foo set foo.bar = 1;
ERROR:  column "foo" of relation "foo" does not exist
LINE 1: update foo set foo.bar = 1;
                        ^
HINT:  Target column references in UPDATE must not be qualified

=# update foo set notfoo.bar = 1; -- no hint
ERROR:  column "notfoo" of relation "foo" does not exist
LINE 1: update foo set notfoo.bar = 1;
                        ^

=# update foo set foo.bar[1] = 1;
ERROR:  column "foo" of relation "foo" does not exist
LINE 1: update foo set foo.bar[1] = 1;
                        ^
HINT:  Target column references in UPDATE must not be qualified


I'll add this to the next CF, but feel free to bash it before that.


.marko

Attachment

Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Peter Geoghegan
Date:
On Fri, Nov 21, 2014 at 7:49 PM, Marko Tiikkaja <marko@joh.to> wrote:
> A common mistake is to try and qualify column references on the LHS of SET
> in UPDATE.

I think that this is a good idea, but as written the patch doesn't
handle aliases correctly:

postgres=# create table foo (val text);
CREATE TABLE
postgres=# update foo f set val = 'bar' where f.val != 'fd';
UPDATE 0
postgres=# update foo f set f.val = 'bar' where f.val != 'fd';
ERROR:  42703: column "f" of relation "foo" does not exist
LINE 1: update foo f set f.val = 'bar' where f.val != 'fd';                        ^
LOCATION:  transformUpdateStmt, analyze.c:2015

-- 
Peter Geoghegan



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
On 2014-11-22 05:11, Peter Geoghegan wrote:
> On Fri, Nov 21, 2014 at 7:49 PM, Marko Tiikkaja <marko@joh.to> wrote:
>> A common mistake is to try and qualify column references on the LHS of SET
>> in UPDATE.
>
> I think that this is a good idea, but as written the patch doesn't
> handle aliases correctly:
>
> postgres=# create table foo (val text);
> CREATE TABLE
> postgres=# update foo f set val = 'bar' where f.val != 'fd';
> UPDATE 0
> postgres=# update foo f set f.val = 'bar' where f.val != 'fd';
> ERROR:  42703: column "f" of relation "foo" does not exist
> LINE 1: update foo f set f.val = 'bar' where f.val != 'fd';
>                           ^
> LOCATION:  transformUpdateStmt, analyze.c:2015

Good point!  Changed in v2, attached.


.marko

Attachment

Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Tom Lane
Date:
Marko Tiikkaja <marko@joh.to> writes:
> A common mistake is to try and qualify column references on the LHS of 
> SET in UPDATE.  The error message can be a bit cryptic at times, too. 

Perhaps, but this hint is not much of an improvement:

> HINT:  Target column references in UPDATE must not be qualified

because target column references *can* be "qualified", for example
if you have a composite column datatype you can assign directly to
one of its fields.  (This ambiguity is exactly why we don't simply
allow the case.)  So I don't think that "qualified" is a sufficiently
precise phrase to be helpful.  Possibly something along the lines of

HINT:  Do not qualify an UPDATE target column with the name of the table.

Also, the coding technique used here is poor, because the hint text
will not be exposed for translation.  The usual pattern is
    need_hint ? errhint("Message text here.") : 0

Also, as far as Peter's point goes, it would likely make sense to
issue this hint if the column basename is *either* the alias name
or the underlying table name.
        regards, tom lane



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
On 2014-11-22 18:02, Tom Lane wrote:
> Marko Tiikkaja <marko@joh.to> writes:
>> A common mistake is to try and qualify column references on the LHS of
>> SET in UPDATE.  The error message can be a bit cryptic at times, too.
>
> Perhaps, but this hint is not much of an improvement:
>
>> HINT:  Target column references in UPDATE must not be qualified
>
> because target column references *can* be "qualified", for example
> if you have a composite column datatype you can assign directly to
> one of its fields.  (This ambiguity is exactly why we don't simply
> allow the case.)  So I don't think that "qualified" is a sufficiently
> precise phrase to be helpful.  Possibly something along the lines of
>
> HINT:  Do not qualify an UPDATE target column with the name of the table.

Sounds good to me.  I didn't expect anyone to like the wording of the 
hint in the first place ;-)

> Also, the coding technique used here is poor, because the hint text
> will not be exposed for translation.  The usual pattern is
>
>       need_hint ? errhint("Message text here.") : 0

Oops.  I just copied what the first relevant grep of errhint did, which 
was from postgres_fdw.  But its hints will already have been translated.  Will fix.

> Also, as far as Peter's point goes, it would likely make sense to
> issue this hint if the column basename is *either* the alias name
> or the underlying table name.

Yeah, I thought about that too, but I thought that might be weird if 
there's an alias in FROM with the name of the table, e.g:
  UPDATE foo f1 SET foo.a = 1 FROM foo;

But I don't really care too much either way.


.marko



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Alvaro Herrera
Date:
We're waiting for an updated version here, right?

-- 
Álvaro Herrera                http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
On 1/7/15 6:22 PM, Alvaro Herrera wrote:
> We're waiting for an updated version here, right?

Yeah.  (The CF entry is also set to Waiting on Author, which seems 
appropriate.)


.marko



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Michael Paquier
Date:
On Thu, Jan 8, 2015 at 2:28 AM, Marko Tiikkaja <marko@joh.to> wrote:
> Yeah.  (The CF entry is also set to Waiting on Author, which seems
> appropriate.)
Seeing nothing happening here for quite some time, marked as returned
with feedback..
-- 
Michael



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
Hi,

Hopefully nobody minds if I slip this to the commit fest that started
today?  The attached patch should address all the comments from the 9.5
cycle.


.m

Attachment

Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Marko Tiikkaja
Date:
On 2015-09-01 23:19, I wrote:
> Hopefully nobody minds if I slip this to the commit fest that started
> today?  The attached patch should address all the comments from the 9.5
> cycle.

Apparently the CF app will.  Meh.  Whatever.  Ignore then, I guess.


.m



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Michael Paquier
Date:
<div dir="ltr"><br /><div class="gmail_extra"><br /><div class="gmail_quote">On Wed, Sep 2, 2015 at 6:19 AM, Marko
Tiikkaja<span dir="ltr"><<a href="mailto:marko@joh.to" target="_blank">marko@joh.to</a>></span> wrote:<br
/><blockquoteclass="gmail_quote" style="margin:0 0 0 .8ex;border-left:1px #ccc solid;padding-left:1ex">Hopefully nobody
mindsif I slip this to the commit fest that started today?  The attached patch should address all the comments from the
9.5cycle.<span class="HOEnZb"><font color="#888888"><br /></font></span></blockquote></div><br /></div><div
class="gmail_extra">Allthe previous comments have been addressed. Perhaps some regression tests would have some
value?<br/>-- <br /><div class="gmail_signature">Michael<br /></div></div></div> 

Re: HINTing on UPDATE foo SET foo.bar = ..;

From
Michael Paquier
Date:
On Mon, Dec 7, 2015 at 9:14 PM, Michael Paquier
<michael.paquier@gmail.com> wrote:
>
>
> On Wed, Sep 2, 2015 at 6:19 AM, Marko Tiikkaja <marko@joh.to> wrote:
>>
>> Hopefully nobody minds if I slip this to the commit fest that started
>> today?  The attached patch should address all the comments from the 9.5
>> cycle.
>
>
> All the previous comments have been addressed. Perhaps some regression tests
> would have some value?

This thread has been stalling for a couple of weeks now. I have marked
it as "returned with feedback". Marko, if you are still working on
this patch, could you add some regression tests and then move it to
the next CF?
-- 
Michael



Re: HINTing on UPDATE foo SET foo.bar = ..;

From
David Steele
Date:
On 12/23/15 9:15 PM, Michael Paquier wrote:
> On Mon, Dec 7, 2015 at 9:14 PM, Michael Paquier
> <michael.paquier@gmail.com> wrote:
>> On Wed, Sep 2, 2015 at 6:19 AM, Marko Tiikkaja <marko@joh.to> wrote:
>>> Hopefully nobody minds if I slip this to the commit fest that started
>>> today?  The attached patch should address all the comments from the 9.5
>>> cycle.
>> All the previous comments have been addressed. Perhaps some regression tests
>> would have some value?
> This thread has been stalling for a couple of weeks now. I have marked
> it as "returned with feedback". Marko, if you are still working on
> this patch, could you add some regression tests and then move it to
> the next CF?
This was submitted to the 2016-03 CF but no new patch was supplied and 
there's been no activity on the thread for months.  I'm marking it as 
"returned with feedback."

Marko, if can address Michael's concerns or supply a new patch I'll be 
happy to open the CF entry again.

Thanks,

-- 
-David
david@pgmasters.net