Thread: BUG #15906: Insert ops within a branch of "RETURN QUERY WITH" are not seen by a subsequent SELECT
BUG #15906: Insert ops within a branch of "RETURN QUERY WITH" are not seen by a subsequent SELECT
From
PG Bug reporting form
Date:
The following bug has been logged on the website: Bug reference: 15906 Logged by: Hugo Mildenberger Email address: px812@mailbox.org PostgreSQL version: 11.4 Operating system: Gentoo Linux Description: -- 13.2.1. Read Committed Isolation Level -- -- [...] However, SELECT does see the effects of previous updates executed within -- its own transaction, even though they are not yet committed. [...] -- Source: https://www.postgresql.org/docs/11/transaction-iso.html -- Assuming the term "previous updates" as cited above also includes insert operations, the -- following example shows that SELECT actually does NOT see uncommitted data within -- its own transaction. CREATE TABLE xtmp( name TEXT); CREATE OR REPLACE FUNCTION itest1( aName Text) RETURNS SETOF xtmp AS $$ BEGIN RETURN QUERY WITH ix AS ( INSERT INTO xtmp(name) VALUES(aName) RETURNING * ) SELECT * FROM xtmp WHERE name = (SELECT name from ix); -- Same result as with -- ) SELECT * FROM xtmp; -- ) SELECT * FROM xtmp WHERE name = aName; END $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION itest2( aName Text) RETURNS SETOF xtmp AS $$ BEGIN INSERT INTO xtmp(name) VALUES(aName); RETURN QUERY SELECT * FROM xtmp WHERE name = aName; END $$ LANGUAGE plpgsql; -- Test log: -- -- opk=# begin; -- opk=# select * from itest1('hello'); -- name -- ------ -- (0 rows) -- -- opk=# select * from itest1('hello'); -- name -- ------- -- hello -- (1 row) -- -- opk=# select * from xtmp; -- name -- ------- -- hello -- hello -- (2 rows) -- -- opk=# commit; -- -- opk=# delete from xtmp; -- DELETE 2 -- -- opk=# begin; -- opk=# select * from itest2('hello'); -- name -- ------- -- hello -- (1 row) -- -- opk=# select * from itest2('hello'); -- name -- ------- -- hello -- hello -- (2 rows) -- -- opk=# select * from xtmp; -- name -- ------- -- hello -- hello -- (2 rows) -- -- opk=# commit;
Re: BUG #15906: Insert ops within a branch of "RETURN QUERY WITH" are not seen by a subsequent SELECT
From
Andrew Gierth
Date:
>>>>> "PG" == PG Bug reporting form <noreply@postgresql.org> writes: PG> CREATE OR REPLACE FUNCTION itest1( aName Text) RETURNS SETOF xtmp AS $$ PG> BEGIN PG> RETURN QUERY PG> WITH ix AS ( PG> INSERT INTO xtmp(name) VALUES(aName) RETURNING * PG> ) SELECT * FROM xtmp WHERE name = (SELECT name from ix); PG> -- Same result as with PG> -- ) SELECT * FROM xtmp; PG> -- ) SELECT * FROM xtmp WHERE name = aName; PG> END PG> $$ LANGUAGE plpgsql; I think the point that you're missing here is that a SELECT (or indeed any other statement) sees only the effects of _previously started_ modification statements, while the INSERT in the WITH is part of the _same_ statement as the final SELECT and therefore its effects are not visible. This is explicitly documented at: https://www.postgresql.org/docs/11/queries-with.html#QUERIES-WITH-MODIFYING If you want to return the inserted value then you must do so by querying the CTE ("ix" in this example), using UNION ALL if necessary. -- Andrew (irc:RhodiumToad)