Commit 29b39e7a authored by Mattias Jonsson's avatar Mattias Jonsson

Bug#51830: Incorrect partition pruning on range partition

(regression)

Problem was that partition pruning did not exclude the
last partition if the range was beyond it
(i.e. not using MAXVALUE)

Fix was to not include the last partition if the
partitioning function value was not within the partition
range.

mysql-test/r/partition_innodb.result:
  Bug#51830: Incorrect partition pruning on range partition
  (regression)
  
  Updated result
mysql-test/r/partition_pruning.result:
  Bug#51830: Incorrect partition pruning on range partition
  (regression)
  
  Updated result
mysql-test/t/partition_innodb.test:
  Bug#51830: Incorrect partition pruning on range partition
  (regression)
  
  Added test for pruning in InnoDB, since it does not show
  for MyISAM due to 'Impossible WHERE noticed after reading
  const tables'.
mysql-test/t/partition_pruning.test:
  Bug#51830: Incorrect partition pruning on range partition
  (regression)
  
  Added test
sql/sql_partition.cc:
  Bug#51830: Incorrect partition pruning on range partition
  (regression)
  
  Also increase the partition id if not inside the last partition
  (and no MAXVALUE is defined).
  
  Added comments and DBUG_ASSERT.
parent 25a9f5e0
drop table if exists t1;
#
# Bug#51830: Incorrect partition pruning on range partition (regression)
#
CREATE TABLE t1 (a INT NOT NULL)
ENGINE = InnoDB
PARTITION BY RANGE(a)
(PARTITION p10 VALUES LESS THAN (10),
PARTITION p30 VALUES LESS THAN (30),
PARTITION p50 VALUES LESS THAN (50),
PARTITION p70 VALUES LESS THAN (70),
PARTITION p90 VALUES LESS THAN (90));
INSERT INTO t1 VALUES (10),(30),(50);
INSERT INTO t1 VALUES (70);
INSERT INTO t1 VALUES (80);
INSERT INTO t1 VALUES (89);
INSERT INTO t1 VALUES (90);
ERROR HY000: Table has no partition for value 90
INSERT INTO t1 VALUES (100);
ERROR HY000: Table has no partition for value 100
insert INTO t1 VALUES (110);
ERROR HY000: Table has no partition for value 110
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p90 ALL NULL NULL NULL NULL 7 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p90 ALL NULL NULL NULL NULL 7 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 100;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 100;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 100;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
DROP TABLE t1;
create table t1 (a int not null,
b datetime not null,
primary key (a,b))
......
......@@ -2101,6 +2101,21 @@ insert into t7 values (10),(30),(50);
explain partitions select * from t7 where a < 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a < 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a <= 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a = 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a >= 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a > 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a < 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......@@ -2110,9 +2125,33 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
explain partitions select * from t7 where a = 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30 system NULL NULL NULL NULL 1
explain partitions select * from t7 where a >= 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a > 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a < 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a <= 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a = 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a >= 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a < 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a <= 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a = 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......@@ -2122,6 +2161,9 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
explain partitions select * from t7 where a >= 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 91;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 11 and a < 29;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......@@ -2137,6 +2179,21 @@ insert into t7 values (10),(30),(50);
explain partitions select * from t7 where a < 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a < 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a <= 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a = 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a >= 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a > 9;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a < 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......@@ -2146,9 +2203,33 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
explain partitions select * from t7 where a = 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30 system NULL NULL NULL NULL 1
explain partitions select * from t7 where a >= 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a > 10;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a < 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a <= 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a = 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a >= 89;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a < 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a <= 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t7 p10,p30,p50,p70,p90 ALL NULL NULL NULL NULL 3 Using where
explain partitions select * from t7 where a = 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......@@ -2158,6 +2239,9 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
explain partitions select * from t7 where a >= 90;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 91;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
explain partitions select * from t7 where a > 11 and a < 29;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
......
......@@ -7,6 +7,38 @@ drop table if exists t1;
let $MYSQLD_DATADIR= `SELECT @@datadir`;
--echo #
--echo # Bug#51830: Incorrect partition pruning on range partition (regression)
--echo #
CREATE TABLE t1 (a INT NOT NULL)
ENGINE = InnoDB
PARTITION BY RANGE(a)
(PARTITION p10 VALUES LESS THAN (10),
PARTITION p30 VALUES LESS THAN (30),
PARTITION p50 VALUES LESS THAN (50),
PARTITION p70 VALUES LESS THAN (70),
PARTITION p90 VALUES LESS THAN (90));
INSERT INTO t1 VALUES (10),(30),(50);
INSERT INTO t1 VALUES (70);
INSERT INTO t1 VALUES (80);
INSERT INTO t1 VALUES (89);
--error ER_NO_PARTITION_FOR_GIVEN_VALUE
INSERT INTO t1 VALUES (90);
--error ER_NO_PARTITION_FOR_GIVEN_VALUE
INSERT INTO t1 VALUES (100);
--error ER_NO_PARTITION_FOR_GIVEN_VALUE
insert INTO t1 VALUES (110);
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 90;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 90;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 90;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 89;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 89;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 89;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 100;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 100;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 100;
DROP TABLE t1;
#
# Bug#47029: Crash when reorganize partition with subpartition
#
......
......@@ -702,15 +702,29 @@ insert into t7 values (10),(30),(50);
# leftmost intervals
explain partitions select * from t7 where a < 5;
explain partitions select * from t7 where a < 9;
explain partitions select * from t7 where a <= 9;
explain partitions select * from t7 where a = 9;
explain partitions select * from t7 where a >= 9;
explain partitions select * from t7 where a > 9;
explain partitions select * from t7 where a < 10;
explain partitions select * from t7 where a <= 10;
explain partitions select * from t7 where a = 10;
explain partitions select * from t7 where a >= 10;
explain partitions select * from t7 where a > 10;
#rightmost intervals
explain partitions select * from t7 where a < 89;
explain partitions select * from t7 where a <= 89;
explain partitions select * from t7 where a = 89;
explain partitions select * from t7 where a > 89;
explain partitions select * from t7 where a >= 89;
explain partitions select * from t7 where a < 90;
explain partitions select * from t7 where a <= 90;
explain partitions select * from t7 where a = 90;
explain partitions select * from t7 where a > 90;
explain partitions select * from t7 where a >= 90;
explain partitions select * from t7 where a > 91;
# misc intervals
explain partitions select * from t7 where a > 11 and a < 29;
......@@ -728,15 +742,29 @@ insert into t7 values (10),(30),(50);
# leftmost intervals
explain partitions select * from t7 where a < 5;
explain partitions select * from t7 where a < 9;
explain partitions select * from t7 where a <= 9;
explain partitions select * from t7 where a = 9;
explain partitions select * from t7 where a >= 9;
explain partitions select * from t7 where a > 9;
explain partitions select * from t7 where a < 10;
explain partitions select * from t7 where a <= 10;
explain partitions select * from t7 where a = 10;
explain partitions select * from t7 where a >= 10;
explain partitions select * from t7 where a > 10;
#rightmost intervals
explain partitions select * from t7 where a < 89;
explain partitions select * from t7 where a <= 89;
explain partitions select * from t7 where a = 89;
explain partitions select * from t7 where a > 89;
explain partitions select * from t7 where a >= 89;
explain partitions select * from t7 where a < 90;
explain partitions select * from t7 where a <= 90;
explain partitions select * from t7 where a = 90;
explain partitions select * from t7 where a > 90;
explain partitions select * from t7 where a >= 90;
explain partitions select * from t7 where a > 91;
# misc intervals
explain partitions select * from t7 where a > 11 and a < 29;
......
......@@ -2876,6 +2876,7 @@ int get_partition_id_range(partition_info *part_info,
*func_value= part_func_value;
if (unsigned_flag)
part_func_value-= 0x8000000000000000ULL;
/* Search for the partition containing part_func_value */
while (max_part_id > min_part_id)
{
loc_part_id= (max_part_id + min_part_id) / 2;
......@@ -3015,11 +3016,17 @@ uint32 get_partition_id_range_for_endpoint(partition_info *part_info,
part_end_val= range_array[loc_part_id];
if (left_endpoint)
{
DBUG_ASSERT(part_func_value > part_end_val ?
(loc_part_id == max_partition &&
!part_info->defined_max_value) :
1);
/*
In case of PARTITION p VALUES LESS THAN MAXVALUE
the maximum value is in the current partition.
the maximum value is in the current (last) partition.
If value is equal or greater than the endpoint,
the range starts from the next partition.
*/
if (part_func_value == part_end_val &&
if (part_func_value >= part_end_val &&
(loc_part_id < max_partition || !part_info->defined_max_value))
loc_part_id++;
}
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment