If pkey_id truly is a primary key in the database sense of the term, and thus unique, then IIUC there is no circumstance in which your composite index would ever even get used ... all it's doing is slowing down writes :-) If the query is sufficiently selective on pkey_id to merit using an index, then the planner will use the primary key index, because it's narrower; if not, then the only other option is to do a full table scan because there is no index of which another_id is a prefix.
There are only three options which make sense:
1. No additional indexes, just the primary key
2. An additional index on (another_id)
3. An additional index on (another_id, pkey_id)
4. Both 2. and 3.
Choosing between these depends on a lot of variables of the query mix in practice ... you could set up both 2. and 3. and then see which indexes the planner actually uses in practice and then decide which to keep.
The value in having pkey_id in the index in 3. is for queries whose primary selectivity is on another_id, but which also have some selectivity on pkey_id .... the planner can use an index scan to filter candidate rows / blocks to look at. This is especially helpful if another_id is not very selective and / or the rows are quite wide.
On gut feel, it seems unlikely that you'd have a real-world circumstance in which it makes sense to choose option 4. but it can't be ruled out without further context.
Cheers
Dave
On Tue, Oct 11, 2011 at 7:52 PM, Claudio Freire <klaussfreire@xxxxxxxxx> wrote:
On Tue, Oct 11, 2011 at 5:16 PM, Carlo StonebanksMulticolumn indices on (c1, c2, ..., cn) can only be used on where
<stonec.register@xxxxxxxxxxxx> wrote:
> Question 2) Regardless of the answer to Question 1 - if another_id is not
> guaranteed to be unique, whereas pkey_id is – there any value to changing
> the order of declaration (more generally, is there a performance impact for
> column ordering in btree composite keys?)
clauses involving c1..ck with k<n.
So, an index on (a,b) does *not* help for querying on b.
Furthermore, if a is unique, querying on a or querying on a and b is
equally selective. b there is just consuming space and cpu cycles.
I'd say, although it obviously depends on the queries you issue, you
only need an index on another_id.
--
Sent via pgsql-performance mailing list (pgsql-performance@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance