Re: Cursor fetch performance issue

From: Pavel Stehule <pavel(dot)stehule(at)gmail(dot)com>
To: Tony Capobianco <tcapobianco(at)prospectiv(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Cursor fetch performance issue
Date: 2012-01-24 21:11:29
Message-ID: CAFj8pRCt75JUJ0s5ncNA60mXk2ZEMFkoJENZ0znXCVn4La4r_w@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

2012/1/24 Tony Capobianco <tcapobianco(at)prospectiv(dot)com>:
> Running just the sql of the function returns only 10 rows:
>
> pg=# SELECT m.memberid, m.websiteid, m.emailaddress,
> pg-#                m.firstname, m.lastname, m.regcomplete, m.emailok
> pg-#         FROM   members m
> pg-#         WHERE  m.emailaddress LIKE 'test(dot)email(at)hotmail(dot)com'
> pg-#         AND    m.changedate_id < 5868 ORDER BY m.emailaddress, m.websiteid;
>  memberid  | websiteid |    emailaddress        | firstname | lastname | regcomplete | emailok
> -----------+-----------+------------------------+-----------+----------+-------------+---------
>  247815829 |         1 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       1
>  300960335 |        62 | test(dot)email(at)hotmail(dot)com |           |          |           1 |       1
>  300959937 |       625 | test(dot)email(at)hotmail(dot)com |           |          |           1 |       1
>  260152830 |      1453 | test(dot)email(at)hotmail(dot)com |           |          |           1 |       1
>  300960163 |      1737 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       1
>  300960259 |      1824 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       1
>  300959742 |      1928 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       1
>  368122699 |      2457 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       1
>  403218613 |      2464 | test(dot)email(at)hotmail(dot)com | email     | test     |           1 |       0
>  378951994 |      2656 | test(dot)email(at)hotmail(dot)com |           |          |           1 |       1
> (10 rows)
>
> Time: 132.626 ms
>
> So, it would seem that's a small enough number of rows.  Unfortunately, issuing:
>
> set cursor_tuple_fraction to 1.0;
>
> Did not have an effect on performance.  Is it common to modify this
> cursor_tuple_fraction parameter each time we execute the function?
>

no, usually only before some strange query. Check execution plan,
please - but I don't think so your slow query depends on cursor usage.

postgres=# set cursor_tuple_fraction TO 1.0;
SET
postgres=# explain declare x cursor for select * from foo where a % 2
= 0 order by a;
QUERY PLAN
────────────────────────────────────────────────────────────────
Sort (cost=19229.19..19241.69 rows=5000 width=4)
Sort Key: a
-> Seq Scan on foo (cost=0.00..18922.00 rows=5000 width=4)
Filter: ((a % 2) = 0)
(4 rows)

postgres=# set cursor_tuple_fraction TO 1.0;
SET
postgres=# explain declare x cursor for select * from foo where a % 2
= 0 order by a;
QUERY PLAN
────────────────────────────────────────────────────────────────
Sort (cost=19229.19..19241.69 rows=5000 width=4)
Sort Key: a
-> Seq Scan on foo (cost=0.00..18922.00 rows=5000 width=4)
Filter: ((a % 2) = 0)
(4 rows)

postgres=# set cursor_tuple_fraction TO 0.1;
SET
postgres=# explain declare x cursor for select * from foo where a % 2
= 0 order by a;
QUERY PLAN
───────────────────────────────────────────────────────────────────────────
Index Scan using foo_pkey on foo (cost=0.00..32693.34 rows=5000 width=4)
Filter: ((a % 2) = 0)
(2 rows)

Regards

Pavel Stehule
>
> On Tue, 2012-01-24 at 21:47 +0100, Pavel Stehule wrote:
>> Hello
>>
>> 2012/1/24 Tony Capobianco <tcapobianco(at)prospectiv(dot)com>:
>> > We are migrating our Oracle warehouse to Postgres 9.
>> >
>> > This function responds well:
>> >
>> > pg=# select public.getMemberAdminPrevious_sp2(247815829, 1,'test(dot)email(at)hotmail(dot)com', 'email', 'test');
>> >  getmemberadminprevious_sp2
>> > ----------------------------
>> >  <unnamed portal 1>
>> > (1 row)
>> >
>> > Time: 7.549 ms
>> >
>> > However, when testing, this fetch takes upwards of 38 minutes:
>> >
>> > BEGIN;
>> > select public.getMemberAdminPrevious_sp2(247815829, 1,'test(dot)email(at)hotmail(dot)com', 'email', 'test');
>> > FETCH ALL IN "<unnamed portal 2>";
>> >
>> > How can I diagnose any performance issues with the fetch in the cursor?
>> >
>>
>> Cursors are optimized to returns small subset of result - if you plan
>> to read complete result, then set
>>
>> set cursor_tuple_fraction to 1.0;
>>
>> this is session config value, you can set it before selected cursors queries
>>
>> Regards
>>
>> Pavel Stehule
>>
>> > Thanks.
>> > Tony
>> >
>> >
>> > --
>> > Sent via pgsql-performance mailing list (pgsql-performance(at)postgresql(dot)org)
>> > To make changes to your subscription:
>> > http://www.postgresql.org/mailpref/pgsql-performance
>>
>
>

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Pavel Stehule 2012-01-24 21:17:11 Re: Cursor fetch performance issue
Previous Message Andy Colson 2012-01-24 21:11:22 Re: Cursor fetch performance issue