Thread: function slower than the same code in an sql file

function slower than the same code in an sql file

From
CS DBA
Date:
Hi All ;

I have code that drops a table, re-create's it (based on a long set of
joins) and then re-creates the indexes.

It runs via psql in about 10 seconds.  I took the code and simply
wrapped it into a plpgsql function and the function version takes almost
60 seconds to run.

I always thought that functions should run faster than psql... am I wrong?

Thanks in advance

--
---------------------------------------------
Kevin Kempter       -       Constent State
A PostgreSQL Professional Services Company
           www.consistentstate.com
---------------------------------------------


Re: function slower than the same code in an sql file

From
Tom Lane
Date:
CS DBA <cs_dba@consistentstate.com> writes:
> I have code that drops a table, re-create's it (based on a long set of
> joins) and then re-creates the indexes.

> It runs via psql in about 10 seconds.  I took the code and simply
> wrapped it into a plpgsql function and the function version takes almost
> 60 seconds to run.

> I always thought that functions should run faster than psql... am I wrong?

Did you really just put the identical queries into a function, or did
you parameterize them with values passed to the function?

Parameterized queries are often slower due to the planner not knowing
the specific constant values that are used in the actual calls.  There's
some work done for 9.2 to improve that, but in existing releases you
typically have to construct dynamic queries and EXECUTE them if you run
into this problem.

            regards, tom lane

Re: function slower than the same code in an sql file

From
Pavel Stehule
Date:
Hello

plpgsql uses a cached prepared plans for queries - where optimizations
is based on expected values - not on real values. This feature can do
performance problems some times. When you have these problems, then
you have to use a dynamic SQL instead.  This generate plans for only
one usage and then there optimization can be more exact (but it repeat
a plan generation)

http://www.postgresql.org/docs/8.4/static/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN

Regards

Pavel Stehule

2011/10/28 CS DBA <cs_dba@consistentstate.com>:
> Hi All ;
>
> I have code that drops a table, re-create's it (based on a long set of
> joins) and then re-creates the indexes.
>
> It runs via psql in about 10 seconds.  I took the code and simply wrapped it
> into a plpgsql function and the function version takes almost 60 seconds to
> run.
>
> I always thought that functions should run faster than psql... am I wrong?
>
> Thanks in advance
>
> --
> ---------------------------------------------
> Kevin Kempter       -       Constent State
> A PostgreSQL Professional Services Company
>          www.consistentstate.com
> ---------------------------------------------
>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance
>

Re: function slower than the same code in an sql file

From
CS DBA
Date:
On 10/27/2011 11:10 PM, Tom Lane wrote:
CS DBA <cs_dba@consistentstate.com> writes:
I have code that drops a table, re-create's it (based on a long set of 
joins) and then re-creates the indexes.
It runs via psql in about 10 seconds.  I took the code and simply 
wrapped it into a plpgsql function and the function version takes almost 
60 seconds to run.
I always thought that functions should run faster than psql... am I wrong?
Did you really just put the identical queries into a function, or did
you parameterize them with values passed to the function?

Parameterized queries are often slower due to the planner not knowing
the specific constant values that are used in the actual calls.  There's
some work done for 9.2 to improve that, but in existing releases you
typically have to construct dynamic queries and EXECUTE them if you run
into this problem.
		regards, tom lane


No parameters,  one of them looks like this:


CREATE or REPLACE FUNCTION refresh_xyz_view_m() RETURNS TRIGGER  AS $$                                                                             
BEGIN                                                                          
                                                                               
DROP TABLE xyz_view_m ;                                            
CREATE TABLE xyz_view_m AS                                         
SELECT                                                                         
        pp.id, pp.name, pp.description, pp.tariff_url, ppe.account_id, pp.active, ppe.time_zone                                                                
FROM                                                                           
        tab1 pp, enrollment ppe                     
WHERE                                                                          
        ((pp.id = ppe.pp_id) AND pp.active);                      
                                                                               
create index xyz_m_id_idx on xyx_view_m(id);          
                                                               
                                                                               
analyze xyz_view_m;                                                
                                                                               
RETURN NULL;                                                                   
END                                                                            
$$                                                                             
LANGUAGE plpgsql;

-- 
---------------------------------------------
Kevin Kempter       -       Constent State 
A PostgreSQL Professional Services Company         www.consistentstate.com
---------------------------------------------

Re: function slower than the same code in an sql file

From
Robert Haas
Date:
On Fri, Oct 28, 2011 at 9:39 AM, CS DBA <cs_dba@consistentstate.com> wrote:
> No parameters,  one of them looks like this:
>
> [ code snippet ]

It's hard to believe this is the real code, because SELECT without
INTO will bomb out inside a PL/pgsql function, won't it?

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

Re: function slower than the same code in an sql file

From
Rodrigo Gonzalez
Date:
El 03/11/11 11:42, Robert Haas escribió:
On Fri, Oct 28, 2011 at 9:39 AM, CS DBA <cs_dba@consistentstate.com> wrote:
No parameters,  one of them looks like this:

[ code snippet ]
It's hard to believe this is the real code, because SELECT without
INTO will bomb out inside a PL/pgsql function, won't it?

But he's using CREATE TABLE xyz_view_m AS

So it seems correct to me

Regards

Rodrigo

Re: function slower than the same code in an sql file

From
Robert Haas
Date:
On Thu, Nov 3, 2011 at 11:31 AM, Rodrigo Gonzalez
<rjgonzale@estrads.com.ar> wrote:
> El 03/11/11 11:42, Robert Haas escribió:
>
> On Fri, Oct 28, 2011 at 9:39 AM, CS DBA <cs_dba@consistentstate.com> wrote:
>
> No parameters,  one of them looks like this:
>
> [ code snippet ]
>
> It's hard to believe this is the real code, because SELECT without
> INTO will bomb out inside a PL/pgsql function, won't it?
>
> But he's using CREATE TABLE xyz_view_m AS
>
> So it seems correct to me

Oh, right, I missed that.

That seems pretty mysterious then.  But is it possible the function is
getting called more times than it should?  I notice that it's set up
as a trigger; is it FOR EACH ROW when it should be a statement-level
trigger or something like that?  Maybe run EXPLAIN ANALYZE on the
query that's invoking the trigger to get some more detail on what's
going on?

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

Re: function slower than the same code in an sql file

From
CS DBA
Date:
On 11/03/2011 09:40 AM, Robert Haas wrote:
> On Thu, Nov 3, 2011 at 11:31 AM, Rodrigo Gonzalez
> <rjgonzale@estrads.com.ar>  wrote:
>> El 03/11/11 11:42, Robert Haas escribió:
>>
>> On Fri, Oct 28, 2011 at 9:39 AM, CS DBA<cs_dba@consistentstate.com>  wrote:
>>
>> No parameters,  one of them looks like this:
>>
>> [ code snippet ]
>>
>> It's hard to believe this is the real code, because SELECT without
>> INTO will bomb out inside a PL/pgsql function, won't it?
>>
>> But he's using CREATE TABLE xyz_view_m AS
>>
>> So it seems correct to me
> Oh, right, I missed that.
>
> That seems pretty mysterious then.  But is it possible the function is
> getting called more times than it should?  I notice that it's set up
> as a trigger; is it FOR EACH ROW when it should be a statement-level
> trigger or something like that?  Maybe run EXPLAIN ANALYZE on the
> query that's invoking the trigger to get some more detail on what's
> going on?

I'll give it a shot ...




--
---------------------------------------------
Kevin Kempter       -       Constent State
A PostgreSQL Professional Services Company
           www.consistentstate.com
---------------------------------------------