Thread: WG: sql-porting-problem oracle to postgresql with UPDATE/IS NOT NULL
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; or in very simplified form: UPDATE table t1SET (t1.id)=(SELECT expression)WHERE (SELECT expression) IS NOT NULL; The SELECT expressions are identical. this syntax is allowed on postgresql? the solution brought by Daryl Richter has no effect. Regards, Hans -----Ursprüngliche Nachricht----- Von: nha [mailto:lyondif02@free.fr] Gesendet: Dienstag, 28. Juli 2009 23:11 An: Gau, Hans-Jürgen Cc: PgSQL-sql Betreff: Re: [SQL] sql-porting-problem oracle to postgresql with UPDATE/IS NOT NULL Hello, Le 28/07/09 14:25, Daryl Richter a écrit : > > On Jul 28, 2009, at 5:58 AM, Gau, Hans-Jürgen wrote: > >> hello list, >> i have some problems with an sql-statement which runs on oracle but >> not on postgresql (i want update only if result of SELECT is not >> empty, the SELECT-queries are identical): >> >> UPDATE table1 t1 >> SET (t1.id) = >> (SELECT h.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 h.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; >> > Try this: > > UPDATE table1 t1 [...] > WHERE > EXISTS (SELECT 1 FROM table2 t2,table3 t3, table1 t1 > WHERE t3.field = t2.field > AND t2.id = t1.id > AND t1.id <> t3.id > > AND h.id IS NOT NULL); > Beyond the solution brought by Daryl Richter, it seems that "h" is an unbound alias in the original (and also in the suggested) query. Some clarification would be helpful for further investigation. Regards. -- nha / Lyon / France.
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; > > or in very simplified form: > > UPDATE table t1 > SET (t1.id)=(SELECT expression) > WHERE (SELECT expression) IS NOT NULL; > > The SELECT expressions are identical. > > this syntax is allowed on postgresql? > > the solution brought by Daryl Richter has no effect. > > Regards, Hans > [...] There is one mistake syntactically speaking and according to PostgreSQL specification for UPDATE statement: column specified in the SET part cannot be qualified with an existing alias for the updated table. See also: http://www.postgresql.org/docs/8.4/interactive/sql-update.html Except this point, the query is valid although I am not sure the result is always what you may expect because there is no relation between any field of the updated table and the SELECT expression in the WHERE clause; table1 is called (in fact, a copy of this table is implied) but no column of this table is bound to one or more of the current updated table1. I may mistake... Regards. -- nha / Lyon / France.
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.