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 t1SET 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 t1SET 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)
ISNOT
NULL;
A PostgreSQL-compliant version could also be:
UPDATE table1 t1SET id = t3.idFROM table2 t2, table3 t3WHERE 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 t1SET id = t3.idFROM table2 t2 INNER JOIN (SELECT t.id, t.field FROM table3 t WHERE t.id IS NOT NULL) t3
ONt3.field = t2.field WHERE t2.id = t1.id AND t3.id <> t1.id;
Hoping a satisfying solution is up.
--
nha / Lyon / France.