WG: WG: sql-porting-problem oracle to postgresql with UPDAT E/IS NOT NULL

From: "Gau, Hans-Jürgen" <Hans-Juergen(dot)Gau(at)LGN(dot)Niedersachsen(dot)de>
To: pgsql-sql(at)postgresql(dot)org
Subject: WG: WG: sql-porting-problem oracle to postgresql with UPDAT E/IS NOT NULL
Date: 2009-07-29 16:08:15
Message-ID: 670F563845D6B34189933C9C7322B4872C0A07@LV-MX-00002-V02.LV.ads.niedersachsen.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

it runs without alias t1. before fieldname id after SET, so:

UPDATE table1 t1
SET id =
(SELECT t3.id FROM table2 t2,table3 t3, table1 t1
WHERE t3.field = t2.field
AND t2.id = t1.id
AND t1.id <> t3.id)
WHERE
(SELECT t3.id FROM table2 t2,table3 t3, table1 t1
WHERE t3.field = t2.field
AND t2.id = t1.id
AND t1.id <> t3.id) IS NOT NULL;

Of course, simply...

Thanks for the help!

-----Ursprüngliche Nachricht-----
Von: nha [mailto:lyondif02(at)free(dot)fr]
Gesendet: Mittwoch, 29. Juli 2009 13:04
An: Gau, Hans-Jürgen
Cc: PgSQL-sql
Betreff: Re: WG: [SQL] sql-porting-problem oracle to postgresql with
UPDATE/IS NOT NULL

Hello again,

Le 29/07/09 12:21, nha a écrit :
> Hello,
>
> Le 29/07/09 11:48, Gau, Hans-Jürgen a écrit :
>> Sorry, it's a lapse by copying and simplification the original version.
that
>> is correct:
>>
>> UPDATE table1 t1
>> SET (t1.id) =
>> (SELECT t3.id FROM table2 t2,table3 t3, table1 t1
>> WHERE t3.field = t2.field
>> AND t2.id = t1.id
>> AND t1.id <> t3.id)
>> WHERE
>> (SELECT t3.id FROM table2 t2,table3 t3, table1 t1
>> WHERE t3.field = t2.field
>> AND t2.id = t1.id
>> AND t1.id <> t3.id) IS NOT NULL;
>> [...]
>> the solution brought by Daryl Richter has no effect.
>
> There is one mistake [...]

To be concrete, a valid version would be:
UPDATE table1 t1
SET id = (something)
WHERE (anotherthing);

> Except this point, the query is valid although I am not sure the result
> is always what you may expect [...]

To "join" table1 column (assumed: id) to the subquery (sub-select here)
expression, table1 recall is not relevant in the subquery. Moreover an
alias "t1" is already defined to table1 (at the beginning of the statement).

A more suitable version would be:
UPDATE table1 t1
SET id = (SELECT t3.id FROM table2 t2, table3 t3
WHERE t3.field = t2.field AND t2.id = t1.id AND t1.id <> t3.id)
WHERE (SELECT t3.id FROM table2 t2, table3 t3
WHERE t3.field = t2.field AND t2.id = t1.id AND t1.id <> t3.id) IS NOT
NULL;

A PostgreSQL-compliant version could also be:
UPDATE table1 t1
SET id = t3.id
FROM table2 t2, table3 t3
WHERE t3.field = t2.field AND t2.id = t1.id AND t1.id <> t3.id AND
t3.id IS NOT NULL;

A PostgreSQL-compliant and faster version may be:
UPDATE table1 t1
SET id = t3.id
FROM table2 t2
INNER JOIN
(SELECT t.id, t.field FROM table3 t WHERE t.id IS NOT NULL) t3
ON t3.field = t2.field
WHERE t2.id = t1.id AND t3.id <> t1.id;

Hoping a satisfying solution is up.

--
nha / Lyon / France.

Browse pgsql-sql by date

  From Date Subject
Next Message Kjell Rune Skaaraas 2009-07-29 20:16:54 Foreign keys and fixed values...
Previous Message Daryl Richter 2009-07-29 13:44:37 Re: sql-porting-problem oracle to postgresql with UPDATE/IS NOT NULL