Re: Performant queries on table with many boolean columns - Mailing list pgsql-performance

From Rob Imig
Subject Re: Performant queries on table with many boolean columns
Date
Msg-id CANcrS5oP6+CRucJD9R59E2V9NoY4ZrAbW91pxj2eoivGfsz_ng@mail.gmail.com
Whole thread Raw
In response to Re: Performant queries on table with many boolean columns  (Rob Imig <rimig88@gmail.com>)
Responses Re: Performant queries on table with many boolean columns
List pgsql-performance
Just to followup where I'm at, I've constructed a new column which is a 100 bit bitstring representing all the flags. Created a b-tree index on that column and can now do super fast lookups (2) for specific scenarios however getting the behavior I need would require a huge amount of OR conditions (as Rick mentioned earlier). Another option is to do bitwiser operators (3) but that seems really slow. Not sure how I can speed that up.

For my specific use-case I think we are going to be able to shard by a category so performance will be acceptable, so this is turning into an educational exercise.

1. SELECT..WHERE on each boolean property

rimig=# explain analyze select bitstr from bloomtest_bi where prop0 AND prop1 AND prop2 AND prop3 AND prop4 AND prop5 AND prop6 AND prop7 AND prop8 AND prop9 AND prop10 AND prop11 AND prop12 AND prop13 AND prop14 AND prop15 AND prop16 AND prop17 AND prop18 AND prop19 AND prop20 AND prop21 AND prop22 AND prop23 AND prop24 AND prop25 AND prop26 AND prop27 AND prop28 AND prop29 AND prop30 AND prop31 AND prop32 AND prop33 AND prop34 AND prop35 AND prop36 AND prop37 AND prop38 AND prop39 AND prop40 AND prop41 AND prop42 AND prop43 AND prop44 AND prop45 AND prop46 AND prop47 AND prop48 AND prop49 AND prop50 AND prop51 AND prop52 AND prop53 AND prop54 AND prop55 AND prop56 AND prop57 AND prop58 AND prop59 AND prop60 AND prop61 AND prop62 AND prop63 AND prop64;

                                                                                                                                                                                                                                                                                                                                                                QUERY PLAN                                                                                                                                                                                                                                                                                                                                                                

------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

 Seq Scan on bloomtest_bi  (cost=0.00..350770.00 rows=6 width=18) (actual time=229.365..2576.391 rows=9 loops=1)

   Filter: (prop0 AND prop1 AND prop2 AND prop3 AND prop4 AND prop5 AND prop6 AND prop7 AND prop8 AND prop9 AND prop10 AND prop11 AND prop12 AND prop13 AND prop14 AND prop15 AND prop16 AND prop17 AND prop18 AND prop19 AND prop20 AND prop21 AND prop22 AND prop23 AND prop24 AND prop25 AND prop26 AND prop27 AND prop28 AND prop29 AND prop30 AND prop31 AND prop32 AND prop33 AND prop34 AND prop35 AND prop36 AND prop37 AND prop38 AND prop39 AND prop40 AND prop41 AND prop42 AND prop43 AND prop44 AND prop45 AND prop46 AND prop47 AND prop48 AND prop49 AND prop50 AND prop51 AND prop52 AND prop53 AND prop54 AND prop55 AND prop56 AND prop57 AND prop58 AND prop59 AND prop60 AND prop61 AND prop62 AND prop63 AND prop64)

   Rows Removed by Filter: 11999991

 Total runtime: 2576.420 ms

(4 rows)


Time: 2577.160 ms



2. SELECT..WHERE on exact bitstring match (standard b-tree index on bitstr so obviously fast here)

This would mean I'd have to OR all the conditions which is a bit gnarly.


rimig=# explain analyze select bitstr from bloomtest_bi where bitstr = '11111111111111111111111111111111111111111111111111111111111111111011011101110011111100110001101000111';

                                                                   QUERY PLAN                                                                   

------------------------------------------------------------------------------------------------------------------------------------------------

 Index Only Scan using i_gist on bloomtest_bi  (cost=0.56..8.58 rows=1 width=18) (actual time=0.040..0.040 rows=1 loops=1)

   Index Cond: (bitstr = B'11111111111111111111111111111111111111111111111111111111111111111011011101110011111100110001101000111'::bit varying)

   Heap Fetches: 1

 Total runtime: 0.056 ms

(4 rows)


Time: 0.443 ms


3. SELECT..WHERE using bitwise operator 

This gets all the results I need however it's slow. 

rimig=# explain analyze select bitstr from bloomtest_bi where (bitstr & '11111111111111111111111111111111111111111111111111111111111111111000000000000000000000000000000000000' ) = '11111111111111111111111111111111111111111111111111111111111111111000000000000000000000000000000000000';

                                                                                                                            QUERY PLAN                                                                                                                             

-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

 Seq Scan on bloomtest_bi  (cost=0.00..410770.00 rows=60000 width=18) (actual time=856.595..9359.566 rows=9 loops=1)

   Filter: (((bitstr)::"bit" & B'11111111111111111111111111111111111111111111111111111111111111111000000000000000000000000000000000000'::"bit") = B'11111111111111111111111111111111111111111111111111111111111111111000000000000000000000000000000000000'::"bit")

   Rows Removed by Filter: 11999991

 Total runtime: 9359.593 ms

(4 rows)


Time: 9360.072 ms



On Thu, Apr 21, 2016 at 3:34 PM, Rob Imig <rimig88@gmail.com> wrote:
Hey all,

Lots of interesting suggestions! I'm loving it.

Just came back to this a bit earlier today and made a sample table to see what non-index performance would be. Constructed data just like above (used 12M rows and 80% true for all 100 boolean columns)

Here's an analyze for what I'd expect to be the types of queries that I'll be handling from the frontend. I would expect around 40-70 properties per query.

Now I'm going to start experimenting with some ideas above and other tuning. This isn't as bad as I thought it would be, though would like to get this under 200ms.

rimig=# explain analyze select count(*) from bloomtest where prop0 AND prop1 AND prop2 AND prop3 AND prop4 AND prop5 AND prop6 AND prop7 AND prop8 AND prop9 AND prop10 AND prop11 AND prop12 AND prop13 AND prop14 AND prop15 AND prop16 AND prop17 AND prop18 AND prop19 AND prop20 AND prop21 AND prop22 AND prop23 AND prop24 AND prop25 AND prop26 AND prop27 AND prop28 AND prop29 AND prop30 AND prop31 AND prop32 AND prop33 AND prop34 AND prop35 AND prop36 AND prop37 AND prop38 AND prop39 AND prop40 AND prop41 AND prop42 AND prop43 AND prop44 AND prop45 AND prop46 AND prop47 AND prop48 AND prop49 AND prop50 AND prop51 AND prop52 AND prop53 AND prop54 AND prop55 AND prop56 AND prop57 AND prop58 AND prop59 AND prop60 AND prop61 AND prop62 AND prop63 AND prop64;

 Aggregate  (cost=351563.03..351563.04 rows=1 width=0) (actual time=2636.829..2636.829 rows=1 loops=1)

   ->  Seq Scan on bloomtest  (cost=0.00..351563.02 rows=3 width=0) (actual time=448.200..2636.811 rows=9 loops=1)

         Filter: (prop0 AND prop1 AND prop2 AND prop3 AND prop4 AND prop5 AND prop6 AND prop7 AND prop8 AND prop9 AND prop10 AND prop11 AND prop12 AND prop13 AND prop14 AND prop15 AND prop16 AND prop17 AND prop18 AND prop19 AND prop20 AND prop21 AND prop22 AND prop23 AND prop24 AND prop25 AND prop26 AND prop27 AND prop28 AND prop29 AND prop30 AND prop31 AND prop32 AND prop33 AND prop34 AND prop35 AND prop36 AND prop37 AND prop38 AND prop39 AND prop40 AND prop41 AND prop42 AND prop43 AND prop44 AND prop45 AND prop46 AND prop47 AND prop48 AND prop49 AND prop50 AND prop51 AND prop52 AND prop53 AND prop54 AND prop55 AND prop56 AND prop57 AND prop58 AND prop59 AND prop60 AND prop61 AND prop62 AND prop63 AND prop64)

         Rows Removed by Filter: 11999991

 Total runtime: 2636.874 ms


On Thu, Apr 21, 2016 at 12:45 PM, Jeff Janes <jeff.janes@gmail.com> wrote:
On Wed, Apr 20, 2016 at 11:54 AM, Teodor Sigaev <teodor@sigaev.ru> wrote:
>>
>> The obvious thing seems to make a table with ~100 columns, with 1 column
>> for each boolean property. Though, what type of indexing strategy would
>> one use on that table? Doesn't make sense to do BTREE. Is there a better
>> way to structure it?
>>
> looks like a deal for contrib/bloom index in upcoming 9.6 release

Not without doing a custom compilation with an increased INDEX_MAX_KEYS:

ERROR:  cannot use more than 32 columns in an index

But even so, I'm skeptical this would do better than a full scan.  It
would be interesting to test that.

Cheers,

Jeff


pgsql-performance by date:

Previous
From: Rob Imig
Date:
Subject: Re: Performant queries on table with many boolean columns
Next
From: Merlin Moncure
Date:
Subject: Re: Performance problems with postgres and null Values?