From: | Bruno Wolff III <bruno(at)wolff(dot)to> |
---|---|
To: | Graham Davis <gdavis(at)refractions(dot)net> |
Cc: | pgsql-bugs(at)postgresql(dot)org, pgsql-performance(at)postgresql(dot)org |
Subject: | Re: BUG #2658: Query not using index |
Date: | 2006-10-03 00:01:47 |
Message-ID: | 20061003000147.GA31475@wolff.to |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-bugs pgsql-performance |
This shouldn't have been submitted to the bugs list, as it isn't a bug.
The best spot for this kind of question is the performance list so I am
copying it there and redirecting followups there.
On Wed, Sep 27, 2006 at 20:56:32 +0000,
Graham Davis <gdavis(at)refractions(dot)net> wrote:
>
> SELECT assetid, max(ts) AS ts
> FROM asset_positions
> GROUP BY assetid;
>
> I have an index on (ts), another index on (assetid) and a multikey index on
> (assetid, ts). I know the assetid index is pointless since the multikey one
> takes its place, but I put it there while testing just to make sure. The
> ANALYZE EXPLAIN for this query is:
>
> QUERY PLAN
> ----------------------------------------------------------------------------
> -------------------------------------------------------------
> HashAggregate (cost=125423.96..125424.21 rows=20 width=12) (actual
> time=39693.995..39694.036 rows=20 loops=1)
> -> Seq Scan on asset_positions (cost=0.00..116654.64 rows=1753864
> width=12) (actual time=20002.362..34724.896 rows=1738693 loops=1)
> Total runtime: 39694.245 ms
> (3 rows)
>
> You can see it is doing a sequential scan on the table when it should be
> using the (assetid, ts) index, or at the very least the (ts) index. This
> query takes about 40 seconds to complete with a table of 1.7 million rows.
> I tested running the query without the group by as follows:
> SELECT DISTINCT ON (assetid) assetid, ts
> FROM asset_positions
> ORDER BY assetid, ts DESC;
This is almost what you want to do to get an alternative plan. But you
need to ORDER BY assetid DESC, ts DESC to make use of the multicolumn
index. If you really need the other output order, reverse it in your
application or use the above as a subselect in another query that orders
by assetid ASC.
From | Date | Subject | |
---|---|---|---|
Next Message | Bruce Momjian | 2006-10-03 00:54:56 | Re: BUG #2665: VC++ 8 (Visual Studio 2005) |
Previous Message | pgsql-bugs | 2006-10-02 22:29:10 | Mail Delivery (failure ginarojas@bhd.com.do) |
From | Date | Subject | |
---|---|---|---|
Next Message | Jim Nasby | 2006-10-03 01:49:49 | Re: selecting data from information_schema.columns |
Previous Message | Steve Martin | 2006-10-02 23:31:13 | Re: selecting data from information_schema.columns |