Stored procedure allows to commit/rollback transaction inside its body.
Unfortunately it is not always correctly handled.
This fragment of code reports ERROR: no known snapshots
CREATE TABLE toasted(id serial primary key, data text);
INSERT INTO toasted(data) VALUES((SELECT string_agg(random()::text, ':') FROM generate_series(1, 1000)));
INSERT INTO toasted(data) VALUES((SELECT string_agg(random()::text, ':') FROM generate_series(1, 1000)));
DO $$ DECLARE v_r record; BEGIN FOR v_r in SELECT data FROM toasted LOOP INSERT INTO toasted(data) VALUES(v_r.data);COMMIT;END LOOP;END;$$;
I found out that code responsible for persisting portal correctly extracts TOAST data.
But pl_pgsql is using prefetch and so takes records form SPI_tuptable, not from stored tuplestore.
I didn't not find better solution rather than disabling prefetch when loop body contains COMMIT or ROLLBACK statements.
Unfortunately there is no existed walker for plpgsql statements tree, so I have to add such walker. I hope that it will be useful not only for this case.
But may be there are some other ways to fix this problem...
Please notice the following bug report which may be also related:
https://www.postgresql.org/message-id/20190904105618.j5l6fhyesmprmstf%40alap3.anarazel.de