Close cursors
One my customer reported very problematic memory issues of currently tested code freshly ported from Oracle's PL/SQL to PL/pgSQL. He rewrites very big application based on usage of thousands stored procedures and functions, and views. This application is ported to Postgres by ora2pg. It is working pretty well, but some patterns has different overhead, and some patterns can be fatal.
In your application he often (100 000x) call code (in long transaction):
OPEN qNAJUPOSPL FOR EXECUTE
mSqNAJUPOSPL;
LOOP
FETCH qNAJUPOSPL INTO mID_NAJVUPOSPL , mID_NAJDATSPLT ,
mID_PREDPIS;
EXIT WHEN NOT FOUND; /* apply on qNAJUPOSPL */
END LOOP;
The problem is undisclosed cursor there. PLpgSQL cursors are just references to SQL cursors. The lifecycle of cursor variable is defined by scope, but lifecycle of SQL cursor is limited by transaction. Any active cursor can have allocated lot of resources (it is "snapshot" of active query). Unfortunately, after leaving of scope of cursor's variable, the related cursor is not closed automatically (and there is not some garbage collector too). Inside large application is not easy to find this issue, mainly when you don't know what you should to find. So, I wrote new warning to plpgsql_check (2.7.0). This warning is enabled by default.
Default check is designed to check previously opened cursor when cursor is opening.
CREATE OR REPLACE FUNCTION public.test() RETURNS void LANGUAGE plpgsql AS $function$ declare c refcursor; q text; r record; begin q := 'select * from pg_class limit 10'; open c for execute q; loop fetch c into r; exit when not found; raise notice '%', r; end loop; end; $function$ do $$ begin perform test(); perform test(); end; $$; NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) DOWhen plpgsql_check is loaded, then the warning is displayed:
(2023-12-06 09:07:32) postgres=# load 'plpgsql_check'; LOAD (2023-12-06 09:07:51) postgres=# do $$ begin perform test(); perform test(); end; $$; NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) WARNING: cursor is not closed DETAIL: PL/pgSQL function test() line 8 at OPEN SQL statement "SELECT test()" PL/pgSQL function inline_code_block line 4 at PERFORM NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) DOThere is possible to set strict mode, and then the cursors are checked at the function's exit:
(2023-12-06 09:07:52) postgres=# set plpgsql_check.strict_cursors_leaks to on; SET (2023-12-06 09:09:56) postgres=# do $$ begin perform test(); perform test(); end; $$; NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) WARNING: cursor is not closed DETAIL: PL/pgSQL function test() during function exit SQL statement "SELECT test()" PL/pgSQL function inline_code_block line 3 at PERFORM NOTICE: (2619,pg_statistic,11,10029,0,10,2,2619,0,19,410,19,2840,t,f,p,r,31,0,f,f,f,f,f,t,n,f,0,728,1,{postgres=arwdDxt/postgres},,) WARNING: cursor is not closed DETAIL: PL/pgSQL function test() during function exit SQL statement "SELECT test()" PL/pgSQL function inline_code_block line 4 at PERFORM DO
1 Comments:
SUPERB, thanks!
Post a Comment
Subscribe to Post Comments [Atom]
<< Home