From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | "Gavin M(dot) Roy" <gmr(at)myyearbook(dot)com> |
Cc: | pgsql-performance(at)postgresql(dot)org |
Subject: | Re: SQL Function Slowness, 8.3.0 |
Date: | 2008-04-16 20:24:32 |
Message-ID: | 18099.1208377472@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
"Gavin M. Roy" <gmr(at)myyearbook(dot)com> writes:
> After detailed examination of pg_stat_user_indexes usage, it's clear that
> the functions don't use the same indexes. I've casted everything to match
> the indexes in the SQL function, to no success. Any suggestions on next
> steps? Maybe for 8.4 we could find a way to explain analyze function
> internals ;-)
Yeah, this could be easier, but it's certainly possible to examine the
plan generated for a function's parameterized statement. For instance,
say you're wondering about the plan for
create function foo(int, text) ... as
$$ select * from bar where f1 = $1 and f2 = $2 $$
language sql
What you do is
prepare p(int, text) as select * from bar where f1 = $1 and f2 = $2 ;
explain analyze execute p(42, 'hello world');
It works exactly the same for statements in plpgsql functions,
remembering that both parameters and local variables of the function
have to become $n placeholders. Remember to make the parameters
of the prepared statement have the same declared types as the
function's parameters and variables.
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Jeffrey Baker | 2008-04-16 20:37:32 | Re: Anybody using the Dell Powervault MD3000 array? |
Previous Message | Joshua D. Drake | 2008-04-16 20:20:22 | Re: Anybody using the Dell Powervault MD3000 array? |