Re: Poor OFFSET performance in PostgreSQL 9.1.6 - Mailing list pgsql-performance

From Merlin Moncure
Subject Re: Poor OFFSET performance in PostgreSQL 9.1.6
Date
Msg-id CAHyXU0yUzyX1UF_Ec8LrR_4c_NkhM1k8TPffBaFzrKPq_tgyDg@mail.gmail.com
Whole thread Raw
In response to Poor OFFSET performance in PostgreSQL 9.1.6  (<fburgess@radiantblue.com>)
List pgsql-performance
On Wed, Aug 28, 2013 at 3:39 PM,  <fburgess@radiantblue.com> wrote:
> Can anyone offer suggestions on how I can optimize a query that contains the
> LIMIT OFFSET clause?
>
> The explain plan of the query is included in the notepad attachment.

OFFSET is working as designed (that is, slowly).  Managing pagination
with OFFSET is essentially a hack and will not scale to even medium
sized tables.   You have some SQL alternatives.  One is cursors as
greg mentioned.   Another is client side pagination:

Select * from labor_task_report this_
inner join labor_tasks labor1_ on this_.labor_UID=20178
order by
  labor1_START_TIME asc,
  this_.work_DATE_TIME asc,
  this_.work_UID asc,
  this_.task_REPORT_UID
limit 10000 offset 940000;

could become

Select * from labor_task_report this_
inner join labor_tasks labor1_ on this_.labor_UID=20178
where (
  labor1_START_TIME,
  this_.work_DATE_TIME asc,
  this_.work_UID asc,
  this_.task_REPORT_UID) >
  ($1, $2, $3, $4)
order by
  labor1_START_TIME asc,
  this_.work_DATE_TIME asc,
  this_.work_UID asc,
  this_.task_REPORT_UID
limit 10000;


where $1-$4 are the corresponding fields of the last row you read from
the last fetch.

merlin


pgsql-performance by date:

Previous
From:
Date:
Subject: Re: Poor OFFSET performance in PostgreSQL 9.1.6
Next
From: David Rowley
Date:
Subject: Re: Poor OFFSET performance in PostgreSQL 9.1.6