Re: Multiple-index optimization not working for = ANY operator

From: Andrew - Supernews <andrew+nonews(at)supernews(dot)com>
To: pgsql-general(at)postgresql(dot)org
Subject: Re: Multiple-index optimization not working for = ANY operator
Date: 2006-02-16 00:25:37
Message-ID: slrndv7hk1.2i3v.andrew+nonews@atlantis.supernews.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 2006-02-15, "Jimmy Choi" <JCHOI(at)altera(dot)com> wrote:
> I find that it doesn't work (i.e. index is not used and a sequential
> scan is needed), if I have the following instead:
>
> SELECT * FROM foo WHERE id = ANY (ARRAY[1,2]);
>
> Is this expected? The reason I would like the last case to work is that
> my plpgsql function takes as input an array of IDs, and so I cannot
> write my query using the first two forms above.
>
> Any idea on how I can get around this is greatly appreciated.

The workaround (for versions 7.4 - 8.1) is:

select * from foo
where id in (select myarray[i]
from generate_series(array_lower(myarray,1),
array_upper(myarray,1)) as s(i));

This typically plans out as a nestloop join with an aggregate over the
function scan as the outer path, and an index lookup on foo.id as the
inner path. Execution times for 8.1 are usually very slightly worse than
the equivalent IN (a,b,c,...) with literal values, but the plan time is
shorter.

--
Andrew, Supernews
http://www.supernews.com - individual and corporate NNTP services

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Christopher Browne 2006-02-16 01:07:37 Re: I see this as the end of BDB in MySQL without a doubt.
Previous Message Reid Thompson 2006-02-16 00:04:34 Oracle tried to buy MySQL