Thread: Query slow as Function

Query slow as Function

From
Steve Horn
Date:
Hello all!

I have a very simple query that I am trying to wrap into a function:

SELECT gs.geo_shape_id AS gid,
gs.geocode
FROM geo_shapes gs
WHERE gs.geocode = 'xyz'
AND geo_type = 1 
GROUP BY gs.geography, gs.geo_shape_id, gs.geocode;

This query runs in about 10 milliseconds.

Now my goal is to wrap the query in a function:

I create a return type:
CREATE TYPE geocode_carrier_route_by_geocode_result AS
   (gid integer,
    geocode character varying(9));
ALTER TYPE geocode_carrier_route_by_geocode_result
  OWNER TO root;

..and the function
CREATE OR REPLACE FUNCTION geocode_carrier_route_by_geocode(geo_code character(9))
  RETURNS SETOF geocode_carrier_route_by_geocode_result AS
$BODY$

BEGIN

RETURN QUERY EXECUTE
'SELECT  gs.geo_shape_id AS gid,
gs.geocode
FROM geo_shapes gs
WHERE gs.geocode = $1
AND geo_type = 1 
GROUP BY gs.geography, gs.geo_shape_id, gs.geocode'
USING geo_code;

END;

$BODY$
  LANGUAGE plpgsql STABLE;
ALTER FUNCTION geocode_carrier_route_by_geocode(character)
  OWNER TO root;

Execute the function: select * from geocode_carrier_route_by_geocode('xyz');

This query takes 500 milliseconds to run. My question of course is why?

Related: If I create a function and assign LANGUAGE 'sql', my function runs in the expected 10 milliseconds. Is there some overhead to using the plpgsql language?

Thanks for any help in clarifying my understanding!

Re: Query slow as Function

From
Andreas Kretschmer
Date:
Steve Horn <steve@stevehorn.cc> wrote:

> Execute the function: select * from geocode_carrier_route_by_geocode('xyz');
>
> This query takes 500 milliseconds to run. My question of course is why?

Wild guess:

The planner doesn't know the actual value of the input-parameter, so the
planner doesn't use the Index.

>
> Related: If I create a function and assign LANGUAGE 'sql', my function runs in
> the expected 10 milliseconds. Is there some overhead to using the plpgsql
> language?

The planner, in this case, knows the actual value.

>
> Thanks for any help in clarifying my understanding!

You can check the plan with the auto_explain - Extension, and you can
force the planner to create a plan based on the actual input-value by
using dynamic SQL (EXECUTE 'your query string' inside the function)


As i said, wild guess ...


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°

Re: Query slow as Function

From
Tom Lane
Date:
Andreas Kretschmer <akretschmer@spamfence.net> writes:
> You can check the plan with the auto_explain - Extension, and you can
> force the planner to create a plan based on the actual input-value by
> using dynamic SQL (EXECUTE 'your query string' inside the function)

Steve *is* using EXECUTE, so that doesn't seem to be the answer.  I'm
wondering about datatype mismatches myself --- the function form is
forcing the parameter to be char(9), which is not a constraint imposed
in the written-out query.  There are lots of other possibilities
though.  It would be hard to say much without a self-contained example
to try.

            regards, tom lane

Re: Query slow as Function

From
Andrew Dunstan
Date:

On 02/18/2012 11:37 AM, Tom Lane wrote:
> Andreas Kretschmer<akretschmer@spamfence.net>  writes:
>> You can check the plan with the auto_explain - Extension, and you can
>> force the planner to create a plan based on the actual input-value by
>> using dynamic SQL (EXECUTE 'your query string' inside the function)
> Steve *is* using EXECUTE, so that doesn't seem to be the answer.  I'm
> wondering about datatype mismatches myself --- the function form is
> forcing the parameter to be char(9), which is not a constraint imposed
> in the written-out query.  There are lots of other possibilities
> though.  It would be hard to say much without a self-contained example
> to try.
>
>

He's using EXECUTE ... USING. Does that plan with the used parameter?

cheers

andrew

Re: Query slow as Function

From
Steve Horn
Date:
Tom,
Thank you for your thoughts as it lead me to the solution. My column "geocode" is defined as character varying (9), and my function parameter as character(9). Changing the input parameter type to match the column definition caused my procedure to execute in 10 milliseconds. 

I was even able to refactor the method to a non-dynamic SQL call (allowing me to take the SQL out of a string and dropping the EXECUTE):

RETURN QUERY
SELECT gs.geo_shape_id AS gid,
gs.geocode
FROM geo_shapes gs
WHERE gs.geocode = geo_code
AND geo_type = 1 
GROUP BY gs.geography, gs.geo_shape_id, gs.geocode;

Thanks for your help!

On Sat, Feb 18, 2012 at 11:37 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
Andreas Kretschmer <akretschmer@spamfence.net> writes:
> You can check the plan with the auto_explain - Extension, and you can
> force the planner to create a plan based on the actual input-value by
> using dynamic SQL (EXECUTE 'your query string' inside the function)

Steve *is* using EXECUTE, so that doesn't seem to be the answer.  I'm
wondering about datatype mismatches myself --- the function form is
forcing the parameter to be char(9), which is not a constraint imposed
in the written-out query.  There are lots of other possibilities
though.  It would be hard to say much without a self-contained example
to try.

                       regards, tom lane



--
Steve Horn
http://www.stevehorn.cc
steve@stevehorn.cc
http://twitter.com/stevehorn
740-503-2300

Re: Query slow as Function

From
Tom Lane
Date:
Andrew Dunstan <andrew@dunslane.net> writes:
> He's using EXECUTE ... USING. Does that plan with the used parameter?

Yeah, it's supposed to.  One of the open possibilities is that that's
malfunctioning for some reason, but without a test case to trace through
I wouldn't jump to that as the most likely possibility.

            regards, tom lane

Re: Query slow as Function

From
Andreas Kretschmer
Date:
Tom Lane <tgl@sss.pgh.pa.us> wrote:

> Andreas Kretschmer <akretschmer@spamfence.net> writes:
> > You can check the plan with the auto_explain - Extension, and you can
> > force the planner to create a plan based on the actual input-value by
> > using dynamic SQL (EXECUTE 'your query string' inside the function)
>
> Steve *is* using EXECUTE, so that doesn't seem to be the answer.  I'm

Ohhh yes, my fault, sorry...


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°