On Mon, Aug 5, 2013 at 6:22 PM, Josh Berkus <josh@xxxxxxxxxxxx> wrote: >> Or, more generally, is there some set of circumstances under which the >> catastrophic scenario will happen? > > Yes: > > SELECT * FROM table ORDER BY id DESC LIMIT 10 OFFSET 100000 > > This is the "high offset" problem, and affects all databases which > support applications with paginated results, including non-relational > ones like SOLR. The basic problem is that you can't figure out what is > OFFSET 100000 without first sorting the first 100000 results. > > The easiest solution is to limit the number of pages your users can > "flip through". Generally anyone asking for page 10,000 is a bot > screen-scraping your site, anyway. In addition to Josh's answer I would like to mention that it might be worth to use partial index like this CREATE INDEX i_table_id_active ON table (is) WHERE active in this particular case SELECT * FROM table WHERE active ORDER BY id DESC LIMIT 10 OFFSET 10 so it will prevent from long filtering tons of rows in case of long "NOT active" gaps in the beginning of the scanning sequence. As an alternative solution for pagination (OFFSET) problem you might also use the "prev/next" technique, like SELECT * FROM table WHERE id > :current_last_id ORDER BY id LIMIT 10 for "next", and SELECT * FROM ( SELECT * FROM table WHERE id < :current_first_id ORDER BY id DESC LIMIT 10 ) AS sq ORDER BY id for "prev". It will be very fast. -- Kind regards, Sergey Konoplev PostgreSQL Consultant and DBA Profile: http://www.linkedin.com/in/grayhemp Phone: USA +1 (415) 867-9984, Russia +7 (901) 903-0499, +7 (988) 888-1979 Skype: gray-hemp Jabber: gray.ru@xxxxxxxxx -- Sent via pgsql-performance mailing list (pgsql-performance@xxxxxxxxxxxxxx) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-performance