Re: Minor buglet in update...from (I think)

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
Cc: Philip Warner <pjw(at)rhyme(dot)com(dot)au>, pgsql-hackers(at)postgresql(dot)org
Subject: Re: Minor buglet in update...from (I think)
Date: 2001-11-27 00:51:13
Message-ID: 16381.1006822273@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us> writes:
> I thought the aggregate would be generated on all rows in the table in
> the pre-transaction version of the table, so in this example:
> regression=# update t2 set f2 = min(f1) from t1;
> It places the minimum value of t1.f1 in all t2.f2 rows.

This actually is not the most interesting example, because the aggregate
doesn't depend at all on t2. Try this instead:

regression=# create table t1(f1 int);
CREATE
regression=# create table t2(f1 int);
CREATE
regression=# insert into t1 values(-1);
INSERT 400599 1
regression=# insert into t1 values(-2);
INSERT 400600 1
regression=# insert into t1 values(-3);
INSERT 400601 1
regression=# insert into t2 values(-1);
INSERT 400602 1
regression=# insert into t2 values(-2);
INSERT 400603 1
regression=# insert into t2 values(-3);
INSERT 400604 1
regression=# update t2 set f1 = count(*) from t1;
UPDATE 1
regression=# select * from t2;
f1
----
-2
-3
9
(3 rows)

regression=#

This is certainly broken, but what's the correct behavior?
Or how about this, which doesn't even use an aggregate:

regression=# update t2 set f1 = t1.f1 from t1;
UPDATE 3
regression=# select * from t2;
f1
----
-1
-1
-1
(3 rows)

regression=#

That's surprising too, perhaps, but what would you have expected
and why?

There's a reason why SQL99 forbids joins and aggregates in UPDATE ...
they're not always well-defined.

I had a proposal (GROUP BY ctid) in the older thread for fixing the
aggregate misbehavior, but it doesn't solve the more general problem
of a join that produces multiple matches for the same target row.
Seems like that probably ought to draw an error.

regards, tom lane

In response to

Responses

Browse pgsql-hackers by date

  From Date Subject
Next Message Bruce Momjian 2001-11-27 00:58:06 Re: Minor buglet in update...from (I think)
Previous Message Stuart Robinson 2001-11-27 00:39:54 Re: insert/update/delete statements returning a query