When I explain a query using a partitioned table the result is the expected. That is, only the corrected partition is scanned. But when the query is inside a plpgsql function it takes forever to complete suggesting it is scanning all partitions.
create table p (c integer);
create table p1 (like p);
alter table p1 add constraint p1c check (c = 1);
create table p2 (like p);
alter table p2 add constraint p2c check (c = 2);
insert into p1 values (1);
insert into p2 values (2);
alter table p1 inherit p;
alter table p2 inherit p;
The explain shows the expected plan and the select is also very fast: (obviously the real query and table are more complex)
explain select c from p where c = 1;
A function like this takes very long to complete:
create or replace function pf() returns integer as
$body$
declare
v constant integer := 1;
begin
return (select c from p where c = v);
end
$body$
language plpgsql stable
cost 100;
Isn't the "constant" option to a variable declaration enough to the planner? Or else what is the limitation here? Is there some way to see the plan for a plpgsql function?
It seems that the only solution is to make the query dynamic:
create or replace function pf() returns integer as
$body$
declare
v constant integer := 1;
r integer;
begin
execute 'select c from p where c = $1' into r using v;
return r;
end
$body$
language plpgsql stable
cost 100;
Using the dynamic solution the actual function executes very fast.
Clodoaldo
create or replace function pf() returns integer as
$body$
declare
v constant integer := 1;
r integer;
begin
execute 'select c from p where c = $1' into r using v;
return r;
end
$body$
language plpgsql stable
cost 100;
Using the dynamic solution the actual function executes very fast.
Clodoaldo