Обсуждение: Index problem

Поиск
Список
Период
Сортировка

Index problem

От
David Mitchell
Дата:
I'm totally baffled as to why postgres won't use this index. I have a
table "point" with an index on it as so:

CREATE INDEX unit_point
   ON point
   USING btree
   (unit_id, time);

When I try the following query, it insists on using a seqscan:

SELECT time FROM point
WHERE unit_id = 95501 and flags & 64 = 64
ORDER BY time DESC LIMIT 1;

If I enable_seqscan to off, then it uses the index. I have timed both
options and using the index is about 3 times faster. I have run vacuum
analyze on this table.  Here is the explain output:

seqscan = on:
Limit  (cost=12883.87..12883.87 rows=1 width=8)
   ->  Sort  (cost=12883.87..12883.99 rows=46 width=8)
         Sort Key: "time"
         ->  Seq Scan on point  (cost=0.00..12882.60 rows=46 width=8)
               Filter: ((unit_id = 95501::oid) AND (((flags)::integer &
64) = 64))

seqscan = off:
Limit  (cost=19710.90..19710.90 rows=1 width=8)
   ->  Sort  (cost=19710.90..19711.01 rows=46 width=8)
         Sort Key: "time"
         ->  Index Scan using unit_point on point  (cost=0.00..19709.63
rows=46 width=8)
               Index Cond: (unit_id = 95501::oid)
               Filter: (((flags)::integer & 64) = 64)

Can somebody please help?
--
David Mitchell
Software Engineer
Telogis

NOTICE:
This message (including any attachments) contains CONFIDENTIAL
INFORMATION intended for a specific individual and purpose, and
is protected by law.  If you are not the intended recipient,
you should delete this message and are hereby notified that any
disclosure, copying, or distribution of this message, or the
taking of any action based on it, is strictly prohibited.

Re: Index problem

От
Bruno Wolff III
Дата:
On Tue, Jun 14, 2005 at 08:37:38 +1200,
  David Mitchell <david.mitchell@telogis.com> wrote:
> I'm totally baffled as to why postgres won't use this index. I have a
> table "point" with an index on it as so:
>
> CREATE INDEX unit_point
>   ON point
>   USING btree
>   (unit_id, time);
>
> When I try the following query, it insists on using a seqscan:
>
> SELECT time FROM point
> WHERE unit_id = 95501 and flags & 64 = 64
> ORDER BY time DESC LIMIT 1;

This is spooky. There has been a rash of questions all with the same issue
over the last several days. It must be a sign that an improvement should
get added to 8.1 before feature freeze.

Anyway, you need to rewrite the query to help out the planner:
SELECT time FROM point
WHERE unit_id = 95501 and flags & 64 = 64
ORDER BY unit_id DESC, time DESC LIMIT 1;

Currently the planner can't tell that the unit_id being constant allows
it to use the index when ordering by time. Adding it explicitly to the
order by clause is equivalent but will allow the planner to see that it can
use the index. Note that you need to match directions as well.