Thread: BUG #14173: Not using partitions with ANY(ARRAY[...])

BUG #14173: Not using partitions with ANY(ARRAY[...])

From
furstenheim@gmail.com
Date:
VGhlIGZvbGxvd2luZyBidWcgaGFzIGJlZW4gbG9nZ2VkIG9uIHRoZSB3ZWJz
aXRlOgoKQnVnIHJlZmVyZW5jZTogICAgICAxNDE3MwpMb2dnZWQgYnk6ICAg
ICAgICAgIEdhYnJpZWwgZgpFbWFpbCBhZGRyZXNzOiAgICAgIGZ1cnN0ZW5o
ZWltQGdtYWlsLmNvbQpQb3N0Z3JlU1FMIHZlcnNpb246IDkuNS4yCk9wZXJh
dGluZyBzeXN0ZW06ICAgVWJ1bnR1IDY0Yml0CkRlc2NyaXB0aW9uOiAgICAg
ICAgCgpodHRwOi8vc3RhY2tvdmVyZmxvdy5jb20vcXVlc3Rpb25zLzM0NzY2
NjcxL2hvdy10by1xdWVyeS1hZ2FpbnN0LXNldmVyYWwtdGFibGVzLWZyb20t
YS1wYXJ0aXRpb24taW4tcG9zdGdyZXNxbA0KDQpJJ20gcXVlcnlpbmcgYSB0
YWJsZSBwYXJ0aXRpb25lZCB3cnQgdG8gc29tZSB2YXJpYWJsZSwgc2F5IG12
YXIuIElmIEkgZG86DQoNCmV4cGxhaW4gc2VsZWN0ICogZnJvbSBtdGFibGUg
d2hlcmUgbXZhciA9ICdhJyBvciBtdmFyID0gJ2InDQoNCnRoZW4gdGhlIHF1
ZXJ5IHBsYW5uZXIgZ29lcyBvbmx5IGludG8gdGhlIHR3byBzdWJ0YWJsZXMg
cmVsYXRlZCB0byAnYScgYW5kCidiJy4NClRoZSBzYW1lIHdvcmtzIHdpdGgg
dGhlIHN0YXRpYyBpbg0KDQpzZWxlY3QgKiBmcm9tIG10YWJsZSB3aGVyZSBt
dmFyIElOICgnYScsICdiJykNCg0KSG93ZXZlciwgaXQgZG9lcyBub3Qgd29y
ayBpZiBJIHVzZSBhcnJheQ0KDQpzZWxlY3QgKiBmcm9tIG10YWJsZSB3aGVy
ZSBtdmFyID0gQU5ZKEFSUkFZWydhJywnYiddKQ0KDQp0aGUgcXVlcnkgcGxh
bm5lciBzY2hlZHVsZXMgYWxsIHN1YnRhYmxlcyBvZiB0aGUgcGFydGl0aW9u
Lg0KDQpJJ3ZlIHNlZW4gdGhlIGVycm9yIGJvdGggaW4gOS40IGFuZCBpbiA5
LjUuMi4gSG93ZXZlciwgYWNjb3JkaW5nIHRvIHNvbWUKY29tbWVudCBpbiB0
aGUgcHJvdmlkZWQgbGluayBpdCBkaWQgd29yayBwcm9wZXJseSB3aXRoIDku
Mw0KDQpUaGFua3MgCgo=

Re: BUG #14173: Not using partitions with ANY(ARRAY[...])

From
Tom Lane
Date:
furstenheim@gmail.com writes:
> I'm querying a table partitioned wrt to some variable, say mvar. If I do:
> explain select * from mtable where mvar = 'a' or mvar = 'b'
> then the query planner goes only into the two subtables related to 'a' and
> 'b'.
> The same works with the static in
> select * from mtable where mvar IN ('a', 'b')
> However, it does not work if I use array
> select * from mtable where mvar = ANY(ARRAY['a','b'])
> the query planner schedules all subtables of the partition.

Works for me:

regression=# create table mtable (mvar int);
CREATE TABLE
regression=# create table c1 (check (mvar > 0 and mvar <= 10)) inherits(mtable);
CREATE TABLE
regression=# create table c2 (check (mvar > 10 and mvar <= 20)) inherits(mtable);
CREATE TABLE
regression=# explain select * from mtable where mvar = 3 or mvar = 4;
                         QUERY PLAN
------------------------------------------------------------
 Append  (cost=0.00..48.25 rows=26 width=4)
   ->  Seq Scan on mtable  (cost=0.00..0.00 rows=1 width=4)
         Filter: ((mvar = 3) OR (mvar = 4))
   ->  Seq Scan on c1  (cost=0.00..48.25 rows=25 width=4)
         Filter: ((mvar = 3) OR (mvar = 4))
(5 rows)

regression=# explain select * from mtable where mvar in (3, 4);
                         QUERY PLAN
------------------------------------------------------------
 Append  (cost=0.00..41.88 rows=27 width=4)
   ->  Seq Scan on mtable  (cost=0.00..0.00 rows=1 width=4)
         Filter: (mvar = ANY ('{3,4}'::integer[]))
   ->  Seq Scan on c1  (cost=0.00..41.88 rows=26 width=4)
         Filter: (mvar = ANY ('{3,4}'::integer[]))
(5 rows)

regression=# explain select * from mtable where mvar = any (array[3,4]);
                         QUERY PLAN
------------------------------------------------------------
 Append  (cost=0.00..41.88 rows=27 width=4)
   ->  Seq Scan on mtable  (cost=0.00..0.00 rows=1 width=4)
         Filter: (mvar = ANY ('{3,4}'::integer[]))
   ->  Seq Scan on c1  (cost=0.00..41.88 rows=26 width=4)
         Filter: (mvar = ANY ('{3,4}'::integer[]))
(5 rows)

regression=# explain select * from mtable where mvar = any (array[13,14]);
                         QUERY PLAN
------------------------------------------------------------
 Append  (cost=0.00..41.88 rows=27 width=4)
   ->  Seq Scan on mtable  (cost=0.00..0.00 rows=1 width=4)
         Filter: (mvar = ANY ('{13,14}'::integer[]))
   ->  Seq Scan on c2  (cost=0.00..41.88 rows=26 width=4)
         Filter: (mvar = ANY ('{13,14}'::integer[]))
(5 rows)

I speculate that you've got some sort of datatype mismatch problem, but
without seeing an exact example it's hard to diagnose.

            regards, tom lane