Problem with accessing OTAST data in stored procedures

From: Konstantin Knizhnik <k(dot)knizhnik(at)postgrespro(dot)ru>
To: pgsql-bugs(at)lists(dot)postgresql(dot)org
Subject: Problem with accessing OTAST data in stored procedures
Date: 2020-06-02 08:24:59
Message-ID: 5d335911-fb25-60cd-4aa7-a5bd0954aea0@postgrespro.ru
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs

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

Attachment Content-Type Size
plpgsql_stored_procedures.patch text/x-patch 18.5 KB

Browse pgsql-bugs by date

  From Date Subject
Next Message Fabien COELHO 2020-06-02 11:27:48 Re: pgbench bug / limitation
Previous Message Kyotaro Horiguchi 2020-06-02 06:20:56 Re: BUG #16473: Marked as broken because of SQLSTATE(08006),ErrorCode(0)