Re: Re: a plpgsql bug

From: "daidewei(at)highgo(dot)com" <daidewei(at)highgo(dot)com>
To: "Tom Lane" <tgl(at)sss(dot)pgh(dot)pa(dot)us>, "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>
Cc: "pgsql-bugs(at)lists(dot)postgresql(dot)org" <pgsql-bugs(at)lists(dot)postgresql(dot)org>
Subject: Re: Re: a plpgsql bug
Date: 2023-09-21 01:22:33
Message-ID: 202309210922334569481@highgo.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs

maybe when function compiling,swith to its owner

daidewei(at)highgo(dot)com

From: daidewei(at)highgo(dot)com
Date: 2023-09-20 14:34
To: Tom Lane; David G. Johnston
CC: pgsql-bugs(at)lists(dot)postgresql(dot)org
Subject: Re: Re: a plpgsql bug
I find another example which doesn't change search_path,but use function 'SECURITY DEFINER'

1 create a user
./psql -dpostgres
create user test_user;
grant all on database postgres to test_user;

2 use the new user to logon and create function
./psql -dpostgres -U test_user

create schema test_user;

create or replace function test_user.test_m(id integer) returns integer as
$$
declare
var2 integer := 1;
begin
if id % 4 = 1 then
return var2 + 2;
elseif id % 4 = 2 then
return var2 + 3;
elseif id % 4 = 3 then
return var2 + 4;
else
return var2;
end if;
end; $$ language plpgsql;

create or replace function test_user.test_f(id integer) returns integer SECURITY DEFINER as
$$
declare
var1 integer := 1;
begin
var1 := test_user.test_m(23);
return var1;
end; $$ language plpgsql;

3 execute
./psql -dpostgres

do $$
declare
var1 integer;
begin
for id in 1 .. 10000000 LOOP
var1 = test_user.test_m(id);
var1 = test_user.test_f(id);
end loop;
end; $$ language plpgsql;
daidewei(at)highgo(dot)com

From: Tom Lane
Date: 2023-09-20 00:12
To: David G. Johnston
CC: daidewei(at)highgo(dot)com; pgsql-bugs(at)lists(dot)postgresql(dot)org
Subject: Re: a plpgsql bug
"David G. Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com> writes:
> On Mon, Sep 18, 2023 at 11:46 PM daidewei(at)highgo(dot)com <daidewei(at)highgo(dot)com>
> wrote:
>> I found a problem in plpgsql. When there is a large loop in plpgsql,
>> it is found that the change of search_path will cause memory exhaustion and
>> thus disconnect the connection.

> It is impossible to prevent queries from exhausting memory so the fact that
> this one does isn't an indication of a bug on its own. I'm having trouble
> imagining a reasonable use case for this pattern of changing search_path
> frequently in a loop within a single execution of a function. That said,
> I'm not in a position to judge how easy or difficult an improvement in this
> area may be.

I poked into this a bit with valgrind. It seems that the problem
is that the changes to search_path thrash the "simple expression"
mechanism in plpgsql, such that it has to re-plan the various
expressions in the called function each time through. It's good about
tracking the actual cached plans and not leaking those, but what is
getting leaked into transaction-lifespan memory is the data structures
made by

expr->expr_simple_state =
ExecInitExprWithParams(expr->expr_simple_expr,
econtext->ecxt_param_list_info);

We could conceivably reclaim that data if we were willing to set up
yet another per-expression memory context to hold it. That seems
like rather a high overhead though.

The given test case is obviously a bit artificial, but I think it
may be a simplification of fairly plausible use-cases. The triggering
condition is that the same textual expression in a plpgsql function
gets executed repeatedly with different search_path settings, which
doesn't seem that unreasonable.

Perhaps another approach could be to assume that only a small number
of distinct search_path settings will be used in any one transaction,
and cache a separate plan and estate for each one. That would have
the nice side-effect of avoiding the replanning overhead, but then
we'd have to figure out how to manage the cache and keep it from
blowing out.

regards, tom lane

In response to

Browse pgsql-bugs by date

  From Date Subject
Next Message Peter Geoghegan 2023-09-21 04:58:10 Re: group by true now errors with non-integer constant in GROUP BY
Previous Message Michael Paquier 2023-09-20 23:24:49 Re: BUG #18057: unaccent removes intentional spaces