Re: Strange choice of general index over partial index - Mailing list pgsql-performance

From Tom Lane
Subject Re: Strange choice of general index over partial index
Date
Msg-id 4423.1421372904@sss.pgh.pa.us
Whole thread Raw
In response to Strange choice of general index over partial index  (Josh Berkus <josh@agliodbs.com>)
List pgsql-performance
Josh Berkus <josh@agliodbs.com> writes:
> index file_state on (state)
>     (35GB in size)
> index file_in_flight_state (state) where state in (
> 'waiting','assigning', 'processing' )
>     (600MB in size)
> ... 10 more indexes

> More important facts:
> * state = 'done' 95% of the time.  thereform the partial index
> represents only 5% of the table
> * all indexes and the table are very bloated
> * server has 128GB RAM
> * Version 9.2.

9.2.what?  And how much of the table is 'waiting' state?

> What am I missing?  Or is this potentially a planner bug for costing?

The only real difference between the two cases is index descent costs:
the number of heap pages visited will be the same whichever index is
used, and the number of index leaf pages visited is probably about the
same too.  9.3 is the first release that makes any real attempt to
model index descent costs realistically.  Before that there were some
dubious fudge factors, which we're unlikely to change in long-stable
branches no matter how badly the results might suck in specific instances.

Having said that, though, I'd have thought that the old fudge factors
would strongly prefer the smaller index given such a large difference in
index size.  Have you neglected to mention some nondefault planner cost
settings?

            regards, tom lane


pgsql-performance by date:

Previous
From: Ivan Schneider
Date:
Subject: Autocompletion with full text search
Next
From: Mark Kirkwood
Date:
Subject: Re: Strange choice of general index over partial index