mirror of
https://github.com/postgres/postgres.git
synced 2025-07-15 19:21:59 +03:00
Fix partition pruning with IS [NOT] NULL clauses
The original code was unable to prune partitions that could not possibly contain NULL values, when the query specified less than all columns in a multicolumn partition key. Reorder the if-tests so that it is, and add more commentary and regression tests. Reported-by: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com> Co-authored-by: Dilip Kumar <dilipbalaut@gmail.com> Co-authored-by: Amit Langote <Langote_Amit_f8@lab.ntt.co.jp> Co-authored-by: Álvaro Herrera <alvherre@alvh.no-ip.org> Reviewed-by: Ashutosh Bapat <ashutosh.bapat@enterprisedb.com> Reviewed-by: amul sul <sulamul@gmail.com> Discussion: https://postgr.es/m/CAFjFpRc7qjLUfXLVBBC_HAnx644sjTYM=qVoT3TJ840HPbsTXw@mail.gmail.com
This commit is contained in:
@ -853,54 +853,60 @@ gen_partprune_steps_internal(GeneratePruningStepsContext *context,
|
|||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
/*
|
/*-----------
|
||||||
* If generate_opsteps is set to false it means no OpExprs were directly
|
* Now generate some (more) pruning steps. We have three strategies:
|
||||||
* present in the input list.
|
*
|
||||||
|
* 1) Generate pruning steps based on IS NULL clauses:
|
||||||
|
* a) For list partitioning, null partition keys can only be found in
|
||||||
|
* the designated null-accepting partition, so if there are IS NULL
|
||||||
|
* clauses containing partition keys we should generate a pruning
|
||||||
|
* step that gets rid of all partitions but that one. We can
|
||||||
|
* disregard any OpExpr we may have found.
|
||||||
|
* b) For range partitioning, only the default partition can contain
|
||||||
|
* NULL values, so the same rationale applies.
|
||||||
|
* c) For hash partitioning, we only apply this strategy if we have
|
||||||
|
* IS NULL clauses for all the keys. Strategy 2 below will take
|
||||||
|
* care of the case where some keys have OpExprs and others have
|
||||||
|
* IS NULL clauses.
|
||||||
|
*
|
||||||
|
* 2) If not, generate steps based on OpExprs we have (if any).
|
||||||
|
*
|
||||||
|
* 3) If this doesn't work either, we may be able to generate steps to
|
||||||
|
* prune just the null-accepting partition (if one exists), if we have
|
||||||
|
* IS NOT NULL clauses for all partition keys.
|
||||||
*/
|
*/
|
||||||
if (!generate_opsteps)
|
if (!bms_is_empty(nullkeys) &&
|
||||||
{
|
(part_scheme->strategy == PARTITION_STRATEGY_LIST ||
|
||||||
/*
|
part_scheme->strategy == PARTITION_STRATEGY_RANGE ||
|
||||||
* Generate one prune step for the information derived from IS NULL,
|
(part_scheme->strategy == PARTITION_STRATEGY_HASH &&
|
||||||
* if any. To prune hash partitions, we must have found IS NULL
|
bms_num_members(nullkeys) == part_scheme->partnatts)))
|
||||||
* clauses for all partition keys.
|
|
||||||
*/
|
|
||||||
if (!bms_is_empty(nullkeys) &&
|
|
||||||
(part_scheme->strategy != PARTITION_STRATEGY_HASH ||
|
|
||||||
bms_num_members(nullkeys) == part_scheme->partnatts))
|
|
||||||
{
|
|
||||||
PartitionPruneStep *step;
|
|
||||||
|
|
||||||
step = gen_prune_step_op(context, InvalidStrategy,
|
|
||||||
false, NIL, NIL, nullkeys);
|
|
||||||
result = lappend(result, step);
|
|
||||||
}
|
|
||||||
|
|
||||||
/*
|
|
||||||
* Note that for IS NOT NULL clauses, simply having step suffices;
|
|
||||||
* there is no need to propagate the exact details of which keys are
|
|
||||||
* required to be NOT NULL. Hash partitioning expects to see actual
|
|
||||||
* values to perform any pruning.
|
|
||||||
*/
|
|
||||||
if (!bms_is_empty(notnullkeys) &&
|
|
||||||
part_scheme->strategy != PARTITION_STRATEGY_HASH)
|
|
||||||
{
|
|
||||||
PartitionPruneStep *step;
|
|
||||||
|
|
||||||
step = gen_prune_step_op(context, InvalidStrategy,
|
|
||||||
false, NIL, NIL, NULL);
|
|
||||||
result = lappend(result, step);
|
|
||||||
}
|
|
||||||
}
|
|
||||||
else
|
|
||||||
{
|
{
|
||||||
PartitionPruneStep *step;
|
PartitionPruneStep *step;
|
||||||
|
|
||||||
/* Generate pruning steps from OpExpr clauses in keyclauses. */
|
/* Strategy 1 */
|
||||||
|
step = gen_prune_step_op(context, InvalidStrategy,
|
||||||
|
false, NIL, NIL, nullkeys);
|
||||||
|
result = lappend(result, step);
|
||||||
|
}
|
||||||
|
else if (generate_opsteps)
|
||||||
|
{
|
||||||
|
PartitionPruneStep *step;
|
||||||
|
|
||||||
|
/* Strategy 2 */
|
||||||
step = gen_prune_steps_from_opexps(part_scheme, context,
|
step = gen_prune_steps_from_opexps(part_scheme, context,
|
||||||
keyclauses, nullkeys);
|
keyclauses, nullkeys);
|
||||||
if (step != NULL)
|
if (step != NULL)
|
||||||
result = lappend(result, step);
|
result = lappend(result, step);
|
||||||
}
|
}
|
||||||
|
else if (bms_num_members(notnullkeys) == part_scheme->partnatts)
|
||||||
|
{
|
||||||
|
PartitionPruneStep *step;
|
||||||
|
|
||||||
|
/* Strategy 3 */
|
||||||
|
step = gen_prune_step_op(context, InvalidStrategy,
|
||||||
|
false, NIL, NIL, NULL);
|
||||||
|
result = lappend(result, step);
|
||||||
|
}
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Finally, results from all entries appearing in result should be
|
* Finally, results from all entries appearing in result should be
|
||||||
|
@ -993,6 +993,47 @@ explain (costs off) select * from mc2p where a = 1 and b > 1;
|
|||||||
Filter: ((b > 1) AND (a = 1))
|
Filter: ((b > 1) AND (a = 1))
|
||||||
(3 rows)
|
(3 rows)
|
||||||
|
|
||||||
|
-- all partitions but the default one should be pruned
|
||||||
|
explain (costs off) select * from mc2p where a = 1 and b is null;
|
||||||
|
QUERY PLAN
|
||||||
|
-------------------------------------------
|
||||||
|
Append
|
||||||
|
-> Seq Scan on mc2p_default
|
||||||
|
Filter: ((b IS NULL) AND (a = 1))
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
|
explain (costs off) select * from mc2p where a is null and b is null;
|
||||||
|
QUERY PLAN
|
||||||
|
-----------------------------------------------
|
||||||
|
Append
|
||||||
|
-> Seq Scan on mc2p_default
|
||||||
|
Filter: ((a IS NULL) AND (b IS NULL))
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
|
explain (costs off) select * from mc2p where a is null and b = 1;
|
||||||
|
QUERY PLAN
|
||||||
|
-------------------------------------------
|
||||||
|
Append
|
||||||
|
-> Seq Scan on mc2p_default
|
||||||
|
Filter: ((a IS NULL) AND (b = 1))
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
|
explain (costs off) select * from mc2p where a is null;
|
||||||
|
QUERY PLAN
|
||||||
|
--------------------------------
|
||||||
|
Append
|
||||||
|
-> Seq Scan on mc2p_default
|
||||||
|
Filter: (a IS NULL)
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
|
explain (costs off) select * from mc2p where b is null;
|
||||||
|
QUERY PLAN
|
||||||
|
--------------------------------
|
||||||
|
Append
|
||||||
|
-> Seq Scan on mc2p_default
|
||||||
|
Filter: (b IS NULL)
|
||||||
|
(3 rows)
|
||||||
|
|
||||||
-- boolean partitioning
|
-- boolean partitioning
|
||||||
create table boolpart (a bool) partition by list (a);
|
create table boolpart (a bool) partition by list (a);
|
||||||
create table boolpart_default partition of boolpart default;
|
create table boolpart_default partition of boolpart default;
|
||||||
|
@ -137,6 +137,13 @@ explain (costs off) select * from mc2p where a = 2 and b < 1;
|
|||||||
explain (costs off) select * from mc2p where a > 1;
|
explain (costs off) select * from mc2p where a > 1;
|
||||||
explain (costs off) select * from mc2p where a = 1 and b > 1;
|
explain (costs off) select * from mc2p where a = 1 and b > 1;
|
||||||
|
|
||||||
|
-- all partitions but the default one should be pruned
|
||||||
|
explain (costs off) select * from mc2p where a = 1 and b is null;
|
||||||
|
explain (costs off) select * from mc2p where a is null and b is null;
|
||||||
|
explain (costs off) select * from mc2p where a is null and b = 1;
|
||||||
|
explain (costs off) select * from mc2p where a is null;
|
||||||
|
explain (costs off) select * from mc2p where b is null;
|
||||||
|
|
||||||
-- boolean partitioning
|
-- boolean partitioning
|
||||||
create table boolpart (a bool) partition by list (a);
|
create table boolpart (a bool) partition by list (a);
|
||||||
create table boolpart_default partition of boolpart default;
|
create table boolpart_default partition of boolpart default;
|
||||||
|
Reference in New Issue
Block a user