Thread: AW: partial index

AW: partial index

From
"Zeugswetter Andreas SB SD"
Date:
> Tatsuo Ishii <t-ishii@sra.co.jp> writes:
> > test=# create index myindex on accounts(aid) where bid <> 0;

Hmm ? Am I reading correctly ? a restriction that is on a field, that 
is not in the index ? Does that make sense ? (aid --> bid)

> The original implementation would have refused to let you create a
> partial index with such a WHERE clause, since <> isn't a
btree-indexable
> operator.

But that is sad, since it would be a rather important use. Couldn't it
be 
rewritten to: (aid < 0 or aid > 0) ? (I assume you meant aid) 

Andreas


Re: AW: partial index

From
Tom Lane
Date:
"Zeugswetter Andreas SB SD" <ZeugswetterA@spardat.at> writes:
>> Tatsuo Ishii <t-ishii@sra.co.jp> writes:
> test=# create index myindex on accounts(aid) where bid <> 0;

> Hmm ? Am I reading correctly ? a restriction that is on a field, that 
> is not in the index ? Does that make sense ?

Yes it does, and in fact it's one of the more important applications of
partial indexes.  It's the only way that a partial index can be cheaper
to scan than a full index.  Consider:
create index foofull on foo (f1);
create index foopartial on foo (f1) where f1 < 100;
create index foopartial2 on foo (f1) where f2 > 100;

Now
select * from foo where f1 < 200;

cannot use either of the partial indexes, it will have to use foofull
or a seqscan.
select * from foo where f1 < 50;

can use foopartial, but the number of rows retrieved using the index
will be just the same as if it used foofull.  Cost savings will be
marginal at best.
select * from foo where f1 < 50 and f2 > 200;

can use foopartial2, and since some of the rows have already been
filtered from the index on the basis of f2, this will be cheaper than
using either of the other indexes.

When I was testing the partial-index additions awhile back, at first
I thought it was a bug that the planner didn't show a preference for the
partial index in a case like #2.  But it was right; the indexscan will
cover the same number of rows and indexentries with either index.  If
the partial index is much smaller than the full index, you might save
one or two disk reads during the initial btree descent --- but that's
all.  So a partial index constructed along the lines of foopartial might
save work at insert/update time (if it's much smaller than a full index)
but it's no better for selecting.  The only way that having both full
and partial indexes on a column could make sense is if the partial
index's predicate mentions another column.

See also the previous discussion about using predicates with UNIQUE
indexes.
        regards, tom lane


RE: AW: partial index

From
"Zeugswetter Andreas SB SD"
Date:
> > test=# create index myindex on accounts(aid) where bid <> 0;
> 
> > Hmm ? Am I reading correctly ? a restriction that is on a field,
that 
> > is not in the index ? Does that make sense ?
> 
> Yes it does, and in fact it's one of the more important applications
of
> partial indexes.  It's the only way that a partial index can be
cheaper
> to scan than a full index.

Ok, yes, sounds great, but then back to Tatsuo's question:
Why is the index atestpartial not used (instead DEBUG) ?
create table atest (aid int, bid int);create index atestpartial on atest (aid) where bid <> 0;select * from atest where
aid=1and bid <> 0;
 

and instead seq scan for 1 mio rows 2 rows where bid <> 0

Since bid is not in an index the evaluation of usability obviously 
should not be based on index ops ?

Andreas


Re: AW: partial index

From
Tom Lane
Date:
"Zeugswetter Andreas SB SD" <ZeugswetterA@spardat.at> writes:
> Since bid is not in an index the evaluation of usability obviously 
> should not be based on index ops ?

Feel free to reimplement the theorem-prover, taking special care to
be able to prove things about operators that you have zero information
about the semantics of.

The reason the prover works with btree-indexable operators is that
it can infer a lot of semantics from the index opclass relationships.
This has nothing to do with whether the index itself is btree or not,
let alone whether the variables used in the predicate are in the index.
It's just a way to do something useful within a reasonable amount of
code.
        regards, tom lane


Re: AW: partial index

From
Tom Lane
Date:
"Zeugswetter Andreas SB SD" <ZeugswetterA@spardat.at> writes:
>> Since bid is not in an index the evaluation of usability obviously 
>> should not be based on index ops ?

Actually, now that I think about it, there's no reason that the prover
couldn't try a simple equal() on a WHERE clause and predicate clause
before moving on to the btree-semantics-based tests.  If the clauses
are statically identical then one implies the other, no?  This would
work nicely for clauses like IS [NOT] NULL, and would give us at least a
little bit of ability to deal with non-btree operator clauses.
        regards, tom lane