Skip to content

Commit 57d7439

Browse files
author
Commitfest Bot
committed
[CF 5656] Prune partitions by ScalarArrayOpExpr with an array parameter (partkey = ANY($1))
This branch was automatically generated by a robot using patches from an email thread registered at: https://commitfest.postgresql.org/patch/5656 The branch will be overwritten each time a new patch version is posted to the thread, and also periodically to check for bitrot caused by changes on the master branch. Patch(es): https://www.postgresql.org/message-id/[email protected] Author(s): Andrei Lepikhov
2 parents 5c8eda1 + 0a20b6a commit 57d7439

File tree

3 files changed

+311
-4
lines changed

3 files changed

+311
-4
lines changed

src/backend/partitioning/partprune.c

Lines changed: 67 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -2179,6 +2179,9 @@ match_clause_to_partition_key(GeneratePruningStepsContext *context,
21792179
List *elem_exprs,
21802180
*elem_clauses;
21812181
ListCell *lc1;
2182+
int strategy;
2183+
Oid lefttype,
2184+
righttype;
21822185

21832186
if (IsA(leftop, RelabelType))
21842187
leftop = ((RelabelType *) leftop)->arg;
@@ -2206,10 +2209,6 @@ match_clause_to_partition_key(GeneratePruningStepsContext *context,
22062209
negator = get_negator(saop_op);
22072210
if (OidIsValid(negator) && op_in_opfamily(negator, partopfamily))
22082211
{
2209-
int strategy;
2210-
Oid lefttype,
2211-
righttype;
2212-
22132212
get_op_opfamily_properties(negator, partopfamily,
22142213
false, &strategy,
22152214
&lefttype, &righttype);
@@ -2219,6 +2218,12 @@ match_clause_to_partition_key(GeneratePruningStepsContext *context,
22192218
else
22202219
return PARTCLAUSE_NOMATCH; /* no useful negator */
22212220
}
2221+
else
2222+
{
2223+
get_op_opfamily_properties(saop_op, partopfamily, false,
2224+
&strategy, &lefttype,
2225+
&righttype);
2226+
}
22222227

22232228
/*
22242229
* Only allow strict operators. This will guarantee nulls are
@@ -2365,6 +2370,64 @@ match_clause_to_partition_key(GeneratePruningStepsContext *context,
23652370
*/
23662371
elem_exprs = arrexpr->elements;
23672372
}
2373+
else if (IsA(rightop, Param))
2374+
{
2375+
Oid cmpfn;
2376+
PartClauseInfo *partclause;
2377+
2378+
if (righttype == part_scheme->partopcintype[partkeyidx])
2379+
cmpfn = part_scheme->partsupfunc[partkeyidx].fn_oid;
2380+
else
2381+
{
2382+
switch (part_scheme->strategy)
2383+
{
2384+
/*
2385+
* For range and list partitioning, we need the ordering
2386+
* procedure with lefttype being the partition key's type,
2387+
* and righttype the clause's operator's right type.
2388+
*/
2389+
case PARTITION_STRATEGY_LIST:
2390+
case PARTITION_STRATEGY_RANGE:
2391+
cmpfn =
2392+
get_opfamily_proc(part_scheme->partopfamily[partkeyidx],
2393+
part_scheme->partopcintype[partkeyidx],
2394+
righttype, BTORDER_PROC);
2395+
break;
2396+
2397+
/*
2398+
* For hash partitioning, we need the hashing procedure
2399+
* for the clause's type.
2400+
*/
2401+
case PARTITION_STRATEGY_HASH:
2402+
cmpfn =
2403+
get_opfamily_proc(part_scheme->partopfamily[partkeyidx],
2404+
righttype, righttype,
2405+
HASHEXTENDED_PROC);
2406+
break;
2407+
2408+
default:
2409+
elog(ERROR, "invalid partition strategy: %c",
2410+
part_scheme->strategy);
2411+
cmpfn = InvalidOid; /* keep compiler quiet */
2412+
break;
2413+
}
2414+
2415+
if (!OidIsValid(cmpfn))
2416+
return PARTCLAUSE_NOMATCH;
2417+
}
2418+
2419+
partclause = (PartClauseInfo *) palloc(sizeof(PartClauseInfo));
2420+
partclause->keyno = partkeyidx;
2421+
partclause->opno = saop_op;
2422+
partclause->op_is_ne = false;
2423+
partclause->op_strategy = strategy;
2424+
partclause->expr = rightop;
2425+
partclause->cmpfn = cmpfn;
2426+
2427+
*pc = partclause;
2428+
2429+
return PARTCLAUSE_MATCH_CLAUSE;
2430+
}
23682431
else
23692432
{
23702433
/* Give up on any other clause types. */

src/test/regress/expected/inherit.out

Lines changed: 180 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3856,3 +3856,183 @@ select * from tuplesest_tab join
38563856

38573857
drop table tuplesest_parted;
38583858
drop table tuplesest_tab;
3859+
--
3860+
-- Test the cases for partition pruning by an expression like:
3861+
-- partkey = ANY($1)
3862+
--
3863+
CREATE TABLE array_prune (id int)
3864+
PARTITION BY HASH(id);
3865+
CREATE TABLE array_prune_t0
3866+
PARTITION OF array_prune FOR VALUES WITH (modulus 2, remainder 0);
3867+
CREATE TABLE array_prune_t1
3868+
PARTITION OF array_prune FOR VALUES WITH (modulus 2, remainder 1);
3869+
CREATE FUNCTION array_prune_fn(oper text, arr text) RETURNS setof text
3870+
LANGUAGE plpgsql AS $$
3871+
DECLARE
3872+
line text;
3873+
query text;
3874+
BEGIN
3875+
query := format('EXPLAIN (COSTS OFF) SELECT * FROM array_prune WHERE id %s (%s)', $1, $2);
3876+
FOR line IN EXECUTE query
3877+
LOOP
3878+
RETURN NEXT line;
3879+
END LOOP;
3880+
END; $$;
3881+
SELECT array_prune_fn('= ANY', 'ARRAY[1]'); -- prune one partition
3882+
array_prune_fn
3883+
-----------------------------------------
3884+
Seq Scan on array_prune_t0 array_prune
3885+
Filter: (id = ANY ('{1}'::integer[]))
3886+
(2 rows)
3887+
3888+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2]'); -- prune one partition
3889+
array_prune_fn
3890+
-------------------------------------------
3891+
Seq Scan on array_prune_t0 array_prune
3892+
Filter: (id = ANY ('{1,2}'::integer[]))
3893+
(2 rows)
3894+
3895+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2,3]'); -- no pruning
3896+
array_prune_fn
3897+
---------------------------------------------------
3898+
Append
3899+
-> Seq Scan on array_prune_t0 array_prune_1
3900+
Filter: (id = ANY ('{1,2,3}'::integer[]))
3901+
-> Seq Scan on array_prune_t1 array_prune_2
3902+
Filter: (id = ANY ('{1,2,3}'::integer[]))
3903+
(5 rows)
3904+
3905+
SELECT array_prune_fn('= ANY', 'ARRAY[1, NULL]'); -- prune
3906+
array_prune_fn
3907+
----------------------------------------------
3908+
Seq Scan on array_prune_t0 array_prune
3909+
Filter: (id = ANY ('{1,NULL}'::integer[]))
3910+
(2 rows)
3911+
3912+
SELECT array_prune_fn('= ANY', 'ARRAY[3, NULL]'); -- prune
3913+
array_prune_fn
3914+
----------------------------------------------
3915+
Seq Scan on array_prune_t1 array_prune
3916+
Filter: (id = ANY ('{3,NULL}'::integer[]))
3917+
(2 rows)
3918+
3919+
SELECT array_prune_fn('= ANY', 'ARRAY[NULL, NULL]'); -- error
3920+
ERROR: operator does not exist: integer = text
3921+
LINE 1: ...IN (COSTS OFF) SELECT * FROM array_prune WHERE id = ANY (ARR...
3922+
^
3923+
HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
3924+
QUERY: EXPLAIN (COSTS OFF) SELECT * FROM array_prune WHERE id = ANY (ARRAY[NULL, NULL])
3925+
CONTEXT: PL/pgSQL function array_prune_fn(text,text) line 7 at FOR over EXECUTE statement
3926+
-- Check case of explicit cast
3927+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2]::numeric[]');
3928+
array_prune_fn
3929+
------------------------------------------------------------
3930+
Append
3931+
-> Seq Scan on array_prune_t0 array_prune_1
3932+
Filter: ((id)::numeric = ANY ('{1,2}'::numeric[]))
3933+
-> Seq Scan on array_prune_t1 array_prune_2
3934+
Filter: ((id)::numeric = ANY ('{1,2}'::numeric[]))
3935+
(5 rows)
3936+
3937+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::int]'); -- conversion to bigint
3938+
array_prune_fn
3939+
------------------------------------------
3940+
Seq Scan on array_prune_t0 array_prune
3941+
Filter: (id = ANY ('{1,2}'::bigint[]))
3942+
(2 rows)
3943+
3944+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::numeric]'); -- conversion to numeric
3945+
array_prune_fn
3946+
------------------------------------------------------------
3947+
Append
3948+
-> Seq Scan on array_prune_t0 array_prune_1
3949+
Filter: ((id)::numeric = ANY ('{1,2}'::numeric[]))
3950+
-> Seq Scan on array_prune_t1 array_prune_2
3951+
Filter: ((id)::numeric = ANY ('{1,2}'::numeric[]))
3952+
(5 rows)
3953+
3954+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::text]'); -- Error. XXX: slightly different error in comparison with the static case
3955+
ERROR: ARRAY types bigint and text cannot be matched
3956+
LINE 1: ...* FROM array_prune WHERE id = ANY (ARRAY[1::bigint,2::text])
3957+
^
3958+
QUERY: EXPLAIN (COSTS OFF) SELECT * FROM array_prune WHERE id = ANY (ARRAY[1::bigint,2::text])
3959+
CONTEXT: PL/pgSQL function array_prune_fn(text,text) line 7 at FOR over EXECUTE statement
3960+
SELECT array_prune_fn('<> ANY', 'ARRAY[1]'); -- no pruning
3961+
array_prune_fn
3962+
------------------------------------------------
3963+
Append
3964+
-> Seq Scan on array_prune_t0 array_prune_1
3965+
Filter: (id <> ANY ('{1}'::integer[]))
3966+
-> Seq Scan on array_prune_t1 array_prune_2
3967+
Filter: (id <> ANY ('{1}'::integer[]))
3968+
(5 rows)
3969+
3970+
DROP TABLE IF EXISTS array_prune CASCADE;
3971+
CREATE TABLE array_prune (id int)
3972+
PARTITION BY RANGE(id);
3973+
CREATE TABLE array_prune_t0
3974+
PARTITION OF array_prune FOR VALUES FROM (1) TO (10);
3975+
CREATE TABLE array_prune_t1
3976+
PARTITION OF array_prune FOR VALUES FROM (10) TO (20);
3977+
SELECT array_prune_fn('= ANY', 'ARRAY[10]'); -- prune
3978+
array_prune_fn
3979+
------------------------------------------
3980+
Seq Scan on array_prune_t1 array_prune
3981+
Filter: (id = ANY ('{10}'::integer[]))
3982+
(2 rows)
3983+
3984+
SELECT array_prune_fn('>= ANY', 'ARRAY[10]'); -- prune
3985+
array_prune_fn
3986+
-------------------------------------------
3987+
Seq Scan on array_prune_t1 array_prune
3988+
Filter: (id >= ANY ('{10}'::integer[]))
3989+
(2 rows)
3990+
3991+
SELECT array_prune_fn('>= ANY', 'ARRAY[9, 10]'); -- do not prune
3992+
array_prune_fn
3993+
---------------------------------------------------
3994+
Append
3995+
-> Seq Scan on array_prune_t0 array_prune_1
3996+
Filter: (id >= ANY ('{9,10}'::integer[]))
3997+
-> Seq Scan on array_prune_t1 array_prune_2
3998+
Filter: (id >= ANY ('{9,10}'::integer[]))
3999+
(5 rows)
4000+
4001+
DROP TABLE IF EXISTS array_prune CASCADE;
4002+
CREATE TABLE array_prune (id int)
4003+
PARTITION BY LIST(id);
4004+
CREATE TABLE array_prune_t0
4005+
PARTITION OF array_prune FOR VALUES IN ('1');
4006+
CREATE TABLE array_prune_t1
4007+
PARTITION OF array_prune FOR VALUES IN ('2');
4008+
SELECT array_prune_fn('= ANY', 'ARRAY[1,1]'); -- prune second
4009+
array_prune_fn
4010+
-------------------------------------------
4011+
Seq Scan on array_prune_t0 array_prune
4012+
Filter: (id = ANY ('{1,1}'::integer[]))
4013+
(2 rows)
4014+
4015+
SELECT array_prune_fn('>= ANY', 'ARRAY[1,2]'); -- do not prune
4016+
array_prune_fn
4017+
--------------------------------------------------
4018+
Append
4019+
-> Seq Scan on array_prune_t0 array_prune_1
4020+
Filter: (id >= ANY ('{1,2}'::integer[]))
4021+
-> Seq Scan on array_prune_t1 array_prune_2
4022+
Filter: (id >= ANY ('{1,2}'::integer[]))
4023+
(5 rows)
4024+
4025+
SELECT array_prune_fn('<> ANY', 'ARRAY[1]'); -- prune second
4026+
array_prune_fn
4027+
------------------------------------------
4028+
Seq Scan on array_prune_t1 array_prune
4029+
Filter: (id <> ANY ('{1}'::integer[]))
4030+
(2 rows)
4031+
4032+
SELECT array_prune_fn('<> ALL', 'ARRAY[1,2]'); -- prune both
4033+
array_prune_fn
4034+
--------------------------
4035+
Result
4036+
One-Time Filter: false
4037+
(2 rows)
4038+

src/test/regress/sql/inherit.sql

Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1589,3 +1589,67 @@ select * from tuplesest_tab join
15891589

15901590
drop table tuplesest_parted;
15911591
drop table tuplesest_tab;
1592+
1593+
--
1594+
-- Test the cases for partition pruning by an expression like:
1595+
-- partkey = ANY($1)
1596+
--
1597+
1598+
CREATE TABLE array_prune (id int)
1599+
PARTITION BY HASH(id);
1600+
1601+
CREATE TABLE array_prune_t0
1602+
PARTITION OF array_prune FOR VALUES WITH (modulus 2, remainder 0);
1603+
CREATE TABLE array_prune_t1
1604+
PARTITION OF array_prune FOR VALUES WITH (modulus 2, remainder 1);
1605+
1606+
CREATE FUNCTION array_prune_fn(oper text, arr text) RETURNS setof text
1607+
LANGUAGE plpgsql AS $$
1608+
DECLARE
1609+
line text;
1610+
query text;
1611+
BEGIN
1612+
query := format('EXPLAIN (COSTS OFF) SELECT * FROM array_prune WHERE id %s (%s)', $1, $2);
1613+
FOR line IN EXECUTE query
1614+
LOOP
1615+
RETURN NEXT line;
1616+
END LOOP;
1617+
END; $$;
1618+
1619+
SELECT array_prune_fn('= ANY', 'ARRAY[1]'); -- prune one partition
1620+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2]'); -- prune one partition
1621+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2,3]'); -- no pruning
1622+
SELECT array_prune_fn('= ANY', 'ARRAY[1, NULL]'); -- prune
1623+
SELECT array_prune_fn('= ANY', 'ARRAY[3, NULL]'); -- prune
1624+
SELECT array_prune_fn('= ANY', 'ARRAY[NULL, NULL]'); -- error
1625+
-- Check case of explicit cast
1626+
SELECT array_prune_fn('= ANY', 'ARRAY[1,2]::numeric[]');
1627+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::int]'); -- conversion to bigint
1628+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::numeric]'); -- conversion to numeric
1629+
SELECT array_prune_fn('= ANY', 'ARRAY[1::bigint,2::text]'); -- Error. XXX: slightly different error in comparison with the static case
1630+
1631+
SELECT array_prune_fn('<> ANY', 'ARRAY[1]'); -- no pruning
1632+
1633+
DROP TABLE IF EXISTS array_prune CASCADE;
1634+
CREATE TABLE array_prune (id int)
1635+
PARTITION BY RANGE(id);
1636+
CREATE TABLE array_prune_t0
1637+
PARTITION OF array_prune FOR VALUES FROM (1) TO (10);
1638+
CREATE TABLE array_prune_t1
1639+
PARTITION OF array_prune FOR VALUES FROM (10) TO (20);
1640+
1641+
SELECT array_prune_fn('= ANY', 'ARRAY[10]'); -- prune
1642+
SELECT array_prune_fn('>= ANY', 'ARRAY[10]'); -- prune
1643+
SELECT array_prune_fn('>= ANY', 'ARRAY[9, 10]'); -- do not prune
1644+
1645+
DROP TABLE IF EXISTS array_prune CASCADE;
1646+
CREATE TABLE array_prune (id int)
1647+
PARTITION BY LIST(id);
1648+
CREATE TABLE array_prune_t0
1649+
PARTITION OF array_prune FOR VALUES IN ('1');
1650+
CREATE TABLE array_prune_t1
1651+
PARTITION OF array_prune FOR VALUES IN ('2');
1652+
SELECT array_prune_fn('= ANY', 'ARRAY[1,1]'); -- prune second
1653+
SELECT array_prune_fn('>= ANY', 'ARRAY[1,2]'); -- do not prune
1654+
SELECT array_prune_fn('<> ANY', 'ARRAY[1]'); -- prune second
1655+
SELECT array_prune_fn('<> ALL', 'ARRAY[1,2]'); -- prune both

0 commit comments

Comments
 (0)