Thread: Update Returning as subquery
Hi, I want to update some values in a table, and need to count the number of values actually changed; but ROW_COUNT returns thenumber of total rows touched. But this gives a syntax error: SELECT count(*) INTO my_count FROM ( UPDATE stuff SET value = maybe_null(key) --^ WHERE value IS NULL RETURNING value ) AS t WHERE value IS NOT NULL; Why is that forbidden? Isn't the purpose of a RETURNING clause to return values like a SELECT statement would, and shouldn'tit therefore be allowed to occur in the same places? I switched it around using a CTE in this case: WITH new_values AS ( SELECT key, maybe_null(key) AS value FROM stuff WHERE value IS NULL) UPDATE stuff AS s SET value = n.value FROM new_values AS n WHERE n.key = s.key AND n.value IS NOT NULL; Which only touches rows that will be changed and returns a useful ROW_COUNT, but needs a join. Cheers, -- Pascal Germroth
pascal+postgres wrote > Hi, > > I want to update some values in a table, and need to count the number of > values actually changed; but ROW_COUNT returns the number of total rows > touched. > > But this gives a syntax error: > > SELECT count(*) INTO my_count > FROM ( > UPDATE stuff > SET value = maybe_null(key) > --^ > WHERE value IS NULL > RETURNING value ) AS t > WHERE value IS NOT NULL; > > Why is that forbidden? Isn't the purpose of a RETURNING clause to return > values like a SELECT statement would, and shouldn't it therefore be > allowed to occur in the same places? > > > > I switched it around using a CTE in this case: > > WITH new_values AS ( > SELECT key, maybe_null(key) AS value > FROM stuff WHERE value IS NULL) > UPDATE stuff AS s > SET value = n.value > FROM new_values AS n > WHERE n.key = s.key > AND n.value IS NOT NULL; > > Which only touches rows that will be changed and returns a useful > ROW_COUNT, but needs a join. > > Cheers, The following should work... WITH do_uodate AS ( UPDATE ... WHERE value IS NULL RETURNING value ) SELECT count(*) FROM do_update WHERE value IS NOT NULL I don't know why it doesn't work in subquery form but other than syntax this and your first form are equivalent. David J. -- View this message in context: http://postgresql.1045698.n5.nabble.com/Update-Returning-as-subquery-tp5814366p5814370.html Sent from the PostgreSQL - sql mailing list archive at Nabble.com.
pascal+postgres@ensieve.org writes: > Why is that forbidden? Isn't the purpose of a RETURNING clause to return values like a SELECT statement would, and shouldn'tit therefore be allowed to occur in the same places? An INSERT/UPDATE/DELETE RETURNING can be used as a CTE, not as a sub-select. Sub-selects aren't sufficiently independent of the outer query, eg they might be evaluated more than once, or not at all, or only partially. regards, tom lane