Re: Replacing Cursors with Temporary Tables

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



That's a good point. However, even after changing it, it is still 12ms with the function call verses 6ms without the extra function call. Though, it is worth noting that if you can make the function call be guaranteed to return the same results when used with the same input parameters, it ends up being faster (roughly 3ms in my test case) due to caching -- at least when executing it multiple times in a row like this. Unfortunately, I cannot take advantage of that, because in my particular use case, the chances of it being called again with the same input values within the cache lifetime of the results is close to zero. Add to that the fact that the function queries tables that could change between transactions (meaning the function is volatile) and it's a moot point. However, it is worth noting that for those people using a non-volatile function call multiple times in the same transaction with the same input values, there is no need to inline the function call.


On Fri, Apr 23, 2010 at 5:01 PM, Merlin Moncure <mmoncure@xxxxxxxxx> wrote:
On Fri, Apr 23, 2010 at 4:42 PM, Eliot Gable
> To answer the question of whether calling a stored procedure adds any
> significant overhead, I built a test case and the short answer is that it
> seems that it does:
>
> CREATE OR REPLACE FUNCTION Test1() RETURNS INTEGER AS
> $BODY$
> DECLARE
>     temp INTEGER;
> BEGIN
>     FOR i IN 1..1000 LOOP
>         SELECT 1 AS id INTO temp;
>     END LOOP;
>     RETURN 1;
> END;
> $BODY$
> LANGUAGE plpgsql;
>
> CREATE OR REPLACE FUNCTION Test2A() RETURNS SETOF INTEGER AS
> $BODY$
> DECLARE
> BEGIN
>     RETURN QUERY SELECT 1 AS id;
> END;
> $BODY$
> LANGUAGE plpgsql;
>
> CREATE OR REPLACE FUNCTION Test2B() RETURNS INTEGER AS
> $BODY$
> DECLARE
>     temp INTEGER;
> BEGIN
>     FOR i IN 1..1000 LOOP
>         temp := Test2A();
>     END LOOP;
>     RETURN 1;
> END;
> $BODY$
> LANGUAGE plpgsql;
>
>
> EXPLAIN ANALYZE SELECT * FROM Test1();
> "Function Scan on test1  (cost=0.00..0.26 rows=1 width=4) (actual
> time=6.568..6.569 rows=1 loops=1)"
> "Total runtime: 6.585 ms"
>
>
> EXPLAIN ANALYZE SELECT * FROM Test2B();
> "Function Scan on test2b  (cost=0.00..0.26 rows=1 width=4) (actual
> time=29.006..29.007 rows=1 loops=1)"
> "Total runtime: 29.020 ms"

That's not a fair test.  test2a() is a SRF which has higher overhead
than regular function.  Try it this way and the timings will level
out:

CREATE OR REPLACE FUNCTION Test2A() RETURNS  INTEGER AS
$BODY$
DECLARE
BEGIN
   RETURN  1 ;
END;
$BODY$
LANGUAGE plpgsql ;

merlin



--
Eliot Gable

"We do not inherit the Earth from our ancestors: we borrow it from our children." ~David Brower

"I decided the words were too conservative for me. We're not borrowing from our children, we're stealing from them--and it's not even considered to be a crime." ~David Brower

"Esse oportet ut vivas, non vivere ut edas." (Thou shouldst eat to live; not live to eat.) ~Marcus Tullius Cicero

[Postgresql General]     [Postgresql PHP]     [PHP Users]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Yosemite]

  Powered by Linux