Re: Index problem

From: Bruno Wolff III <bruno(at)wolff(dot)to>
To: David Mitchell <david(dot)mitchell(at)telogis(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Index problem
Date: 2005-06-13 20:56:08
Message-ID: 20050613205608.GC1346@wolff.to
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Tue, Jun 14, 2005 at 08:37:38 +1200,
David Mitchell <david(dot)mitchell(at)telogis(dot)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.

In response to

Browse pgsql-general by date

  From Date Subject
Next Message martin 2005-06-13 21:05:02 suse 9.2
Previous Message Bruno Wolff III 2005-06-13 20:50:45 Re: PG 8.0.1 is getting slow in 24 hours. Only daily VACUUM FULL helps