Re: limit order by performance issue - Mailing list pgsql-performance

From Shaun Thomas
Subject Re: limit order by performance issue
Date
Msg-id 507DB54F.7000005@optionshouse.com
Whole thread Raw
In response to limit order by performance issue  (Pedro Jiménez <p.jimenez@ismsolar.com>)
List pgsql-performance
On 10/15/2012 12:44 PM, Pedro Jiménez wrote:

> select var_value from ism_floatvalues where id_signal = 29660 order by
> time_stamp desc limit 1;

Well, we'd have to see an EXPLAIN plan to really know what's going on
here, but it often boils down to the planner being overly optimistic
when low limits are specified. I bet you have an index on time_stamp,
don't you?

In that case, the planner would reverse index-scan that index,
estimating that the chances of it finding ID 29660 are less expensive
than fetching all of the rows that match the ID directly, and throwing
away all but 1 row. Remember, it would have to read all of those values
to know which is the most recent.

You can fix this a couple of ways:

1. Put a two-column index on these values:

CREATE INDEX idx_ordered_signal
     ON ism_floatvalues (id_signal, time_stamp DESC);

Which turns any request for that particular combo into a single index fetch.

2. You can trick the planner by introducing an optimization fence:

SELECT var_value
   FROM (
          SELECT var_value, time_stamp
            FROM ism_floatvalues
           WHERE id_signal = 29660
          OFFSET 0
        )
  ORDER BY time_stamp DESC
  LIMIT 1;

Quite a few people will probably grouse at me for giving you that as an
option, but it does work better than LIMIT 1 more often than it probably
should.


--
Shaun Thomas
OptionsHouse | 141 W. Jackson Blvd. | Suite 500 | Chicago IL, 60604
312-444-8534
sthomas@optionshouse.com

______________________________________________

See http://www.peak6.com/email_disclaimer/ for terms and conditions related to this email


pgsql-performance by date:

Previous
From: Pavel Stehule
Date:
Subject: Re: limit order by performance issue
Next
From: Karl Denninger
Date:
Subject: Re: limit order by performance issue