Re: Cursors

From: Laurenz Albe <laurenz(dot)albe(at)cybertec(dot)at>
To: Natalie Wenz <nataliewenz(at)gmail(dot)com>, pgsql-admin(at)lists(dot)postgresql(dot)org
Subject: Re: Cursors
Date: 2018-08-16 10:49:38
Message-ID: 1534416578.3084.23.camel@cybertec.at
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Natalie Wenz wrote:
> I have a couple of general questions regarding cursors.
>
> First, does something like this hold open one transaction, or is each fetch a separate transaction?
> As a dba I'm wondering if this would interfere with maintenance operations
> (xid rolling via autovacuum, attaching/detaching partitions, etc).

Unless a cursor is declared WITH HOLD, its life time is limited
to one database transaction.

Using a cursor does not keep a transaction open: if you close the
transaction, the cursor is implicitly closed, and subsequent attempts
to fetch from it will fail.

> Secondly, on this particular thing (it's a three-table join, with one of those tables being
> very "wide", so there's definitely a pg_toast table that's involved besides), it seems to
> perform pretty terribly. What are the advantages of gathering records this way compared to
> doing a series of queries with a range (record number >= x and record number < y)?

You should compare the execution plans.
By default, "cursor_tuple_fraction" is set to 0.1, meaning that PostgreSQL
assumes that only 10% of all rows will be fetched. In this case, a plan
that delivers the first rows will be preferred, while the execution time
if you fetch all rows may suffer.

Set "cursor_tuple_fraction" to 1.0 if you plan to fetch all rows.

The advantage of fetching a large result set with a cursor over fetching
parts of it with several queries is that the query has to be planned
and executed only once.

Moreover, if you use LIMIT and OFFSET for retrieving parts of the query in chunks,
you will suffer because processing for large OFFSET values is inherently inefficient:
it has to fetch and descard all rows until the OFFSET is reached.
So you may end up selecting the same first rows over and over, only to discard them.

Yours,
Laurenz Albe
--
Cybertec | https://www.cybertec-postgresql.com

In response to

  • Cursors at 2018-08-15 21:21:00 from Natalie Wenz

Browse pgsql-admin by date

  From Date Subject
Next Message Evgeniy Losev 2018-08-16 11:28:11 'autovacuum with lots of open file references to deleted files' back from 2012
Previous Message Evan Bauer 2018-08-15 23:08:37 Re: How to revoke privileged from PostgreSQL's superuser