Re: Queries with conditions using bitand operator

From: Joe Conway <mail(at)joeconway(dot)com>
To: Elias Ghanem <e(dot)ghanem(at)acteos(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Queries with conditions using bitand operator
Date: 2010-07-14 01:07:50
Message-ID: 4C3D0DE6.8070003@joeconway.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On 07/13/2010 04:48 AM, Elias Ghanem wrote:
> Hi,
> I have table "ARTICLE" containing a String a field "STATUS" that
> represents a number in binary format (for ex: 10011101).
> My application issues queries with where conditions that uses BITAND
> operator on this field (for ex: select * from article where status & 4 =
> 4).
> Thus i'm facing performance problemes with these select queries: the
> queries are too slow.
> Since i'm using the BITAND operator in my conditions, creating an index
> on the status filed is useless
> and since the second operator variable (status & 4 = 4; status & 8 = 8;
> status & 16 = 16...) a functional index is also usless (because a
> functional index require the use of a function that accept only table
> column as input parameter: constants are not accepted).
> So is there a way to enhance the performance of these queries?

You haven't given a lot of info to help us help you, but would something
along these lines be useful to you?

drop table if exists testbit;
create table testbit(
id serial primary key,
article text,
status int
);

insert into testbit (article, status) select 'article ' ||
generate_series::text, generate_series % 256 from
generate_series(1,1000000);

create index idx1 on testbit(article) where status & 1 = 1;
create index idx2 on testbit(article) where status & 2 = 2;
create index idx4 on testbit(article) where status & 4 = 4;
create index idx8 on testbit(article) where status & 8 = 8;
create index idx16 on testbit(article) where status & 16 = 16;
create index idx32 on testbit(article) where status & 512 = 512;

update testbit set status = status + 512 where id in (42, 4242, 424242);
explain analyze select * from testbit where status & 512 = 512;
QUERY PLAN
------------------------------------------------------------------
Index Scan using idx32 on testbit (cost=0.00..4712.62 rows=5000
width=22) (actual time=0.080..0.085 rows=3 loops=1)
Total runtime: 0.170 ms

HTH,

Joe

--
Joe Conway
credativ LLC: http://www.credativ.us
Linux, PostgreSQL, and general Open Source
Training, Service, Consulting, & Support

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Scott Marlowe 2010-07-14 06:44:53 Re: Need help in performance tuning.
Previous Message Andy Colson 2010-07-13 23:26:09 Re: performance on new linux box