Re: Partial Index [WHERE col IN ('A','B')] Planner Anomalies

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "David Johnston" <polobo(at)yahoo(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Partial Index [WHERE col IN ('A','B')] Planner Anomalies
Date: 2011-04-26 22:00:29
Message-ID: 23048.1303855229@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

"David Johnston" <polobo(at)yahoo(dot)com> writes:
> If I explain the above query multiple times (without any data changes) I get
> either of the two query plans / the Bitmap Heap one more often. If I
> analyze the table I immediately get the "Index Scan" plan first but
> subsequent explains revert to switching between the two However, if I run
> any other query but the three-criteria query then the flipping behavior
> observed stops and the "Bitmap Heap" plan becomes the dominant plan. The

Hmmm ... I'm seeing some very odd behavior here too. I suspect there is
some use-of-uninitialized-memory in there. After several false starts
I have a script that reliably reproduces the change of behavior in
(debug builds of) both HEAD and 9.0:

drop table if exists taskinstance;

create table taskinstance (ti_status varchar, ti_creationtimestamp timestamptz);
create index ti_sortedstatus on taskinstance (ti_status, ti_creationtimestamp);
create index ti_active on taskinstance (ti_status) WHERE ti_status IN ('ACTIVE', 'DISPATCHED', 'FAILURE');

vacuum taskinstance;

\c -

EXPLAIN SELECT * FROM taskinstance WHERE ti_status IN ('ACTIVE', 'DISPATCHED', 'FAILURE');
EXPLAIN SELECT * FROM taskinstance WHERE ti_status IN ('ACTIVE', 'DISPATCHED', 'FAILURE');
EXPLAIN SELECT * FROM taskinstance WHERE ti_status IN ('ACTIVE', 'DISPATCHED', 'FAILURE');

The first two EXPLAINs give a sane plan, the third one not so much.
Poking at it now.

regards, tom lane

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message luda posch 2011-04-26 22:24:28 Feature Request, aggregate functions distinct on
Previous Message Carlos Mennens 2011-04-26 20:41:19 Re: Switching Database Engines