Commit 94709df7 authored by Mattias Jonsson's avatar Mattias Jonsson

Bug#49742: Partition Pruning not working correctly for RANGE

Problem was when calculating the range of partitions for
pruning.

Solution was to get the calculation correct. I also simplified
it a bit for easier understanding.
parent 51d54db7
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9; drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9;
#
# Bug#49742: Partition Pruning not working correctly for RANGE
#
CREATE TABLE t1 (a INT PRIMARY KEY)
PARTITION BY RANGE (a) (
PARTITION p0 VALUES LESS THAN (1),
PARTITION p1 VALUES LESS THAN (2),
PARTITION p2 VALUES LESS THAN (3),
PARTITION p3 VALUES LESS THAN (4),
PARTITION p4 VALUES LESS THAN (5),
PARTITION p5 VALUES LESS THAN (6),
PARTITION max VALUES LESS THAN MAXVALUE);
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7),(8);
SELECT * FROM t1 WHERE a < 1;
a
-1
0
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0 index PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a < 2;
a
-1
0
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1 index PRIMARY PRIMARY 4 NULL 3 Using where; Using index
SELECT * FROM t1 WHERE a < 3;
a
-1
0
1
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2 index PRIMARY PRIMARY 4 NULL 4 Using where; Using index
SELECT * FROM t1 WHERE a < 4;
a
-1
0
1
2
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3 index PRIMARY PRIMARY 4 NULL 5 Using where; Using index
SELECT * FROM t1 WHERE a < 5;
a
-1
0
1
2
3
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4 index PRIMARY PRIMARY 4 NULL 6 Using where; Using index
SELECT * FROM t1 WHERE a < 6;
a
-1
0
1
2
3
4
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,p5 index PRIMARY PRIMARY 4 NULL 7 Using where; Using index
SELECT * FROM t1 WHERE a < 7;
a
-1
0
1
2
3
4
5
6
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 7;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max range PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 1;
a
-1
0
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1 index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a <= 2;
a
-1
0
1
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2 index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a <= 3;
a
-1
0
1
2
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3 index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a <= 4;
a
-1
0
1
2
3
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4 index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a <= 5;
a
-1
0
1
2
3
4
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,p5 index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a <= 6;
a
-1
0
1
2
3
4
5
6
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max range PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 7;
a
-1
0
1
2
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 7;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max range PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a = 1;
a
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p1 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 2;
a
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 3;
a
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 4;
a
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 5;
a
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p5 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 6;
a
6
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max const PRIMARY PRIMARY 4 const 1 Using index
SELECT * FROM t1 WHERE a = 7;
a
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 7;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max const PRIMARY PRIMARY 4 const 1 Using index
SELECT * FROM t1 WHERE a >= 1;
a
1
2
3
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p1,p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 2;
a
2
3
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 3;
a
3
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 4;
a
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 5;
a
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 6;
a
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a >= 7;
a
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 7;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a > 1;
a
2
3
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a > 2;
a
3
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a > 3;
a
4
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a > 4;
a
5
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a > 5;
a
6
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index
SELECT * FROM t1 WHERE a > 6;
a
7
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a > 7;
a
8
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 7;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
DROP TABLE t1;
CREATE TABLE t1 (a INT PRIMARY KEY)
PARTITION BY RANGE (a) (
PARTITION p0 VALUES LESS THAN (1),
PARTITION p1 VALUES LESS THAN (2),
PARTITION p2 VALUES LESS THAN (3),
PARTITION p3 VALUES LESS THAN (4),
PARTITION p4 VALUES LESS THAN (5),
PARTITION max VALUES LESS THAN MAXVALUE);
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7);
SELECT * FROM t1 WHERE a < 1;
a
-1
0
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0 index PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a < 2;
a
-1
0
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1 index PRIMARY PRIMARY 4 NULL 3 Using where; Using index
SELECT * FROM t1 WHERE a < 3;
a
-1
0
1
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2 index PRIMARY PRIMARY 4 NULL 4 Using where; Using index
SELECT * FROM t1 WHERE a < 4;
a
-1
0
1
2
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3 index PRIMARY PRIMARY 4 NULL 5 Using where; Using index
SELECT * FROM t1 WHERE a < 5;
a
-1
0
1
2
3
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4 index PRIMARY PRIMARY 4 NULL 6 Using where; Using index
SELECT * FROM t1 WHERE a < 6;
a
-1
0
1
2
3
4
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,max range PRIMARY PRIMARY 4 NULL 8 Using where; Using index
SELECT * FROM t1 WHERE a <= 1;
a
-1
0
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1 index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 2;
a
-1
0
1
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2 index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 3;
a
-1
0
1
2
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3 index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 4;
a
-1
0
1
2
3
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4 index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a <= 5;
a
-1
0
1
2
3
4
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,max range PRIMARY PRIMARY 4 NULL 8 Using where; Using index
SELECT * FROM t1 WHERE a <= 6;
a
-1
0
1
2
3
4
5
6
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p0,p1,p2,p3,p4,max range PRIMARY PRIMARY 4 NULL 8 Using where; Using index
SELECT * FROM t1 WHERE a = 1;
a
1
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p1 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 2;
a
2
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 3;
a
3
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 4;
a
4
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4 system PRIMARY NULL NULL NULL 1
SELECT * FROM t1 WHERE a = 5;
a
5
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max const PRIMARY PRIMARY 4 const 1 Using index
SELECT * FROM t1 WHERE a = 6;
a
6
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max const PRIMARY PRIMARY 4 const 1 Using index
SELECT * FROM t1 WHERE a >= 1;
a
1
2
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p1,p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a >= 2;
a
2
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a >= 3;
a
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a >= 4;
a
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a >= 5;
a
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a >= 6;
a
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a > 1;
a
2
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 1;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a > 2;
a
3
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 2;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a > 3;
a
4
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 3;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a > 4;
a
5
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 4;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index
SELECT * FROM t1 WHERE a > 5;
a
6
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 5;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
SELECT * FROM t1 WHERE a > 6;
a
7
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 6;
id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t1 max range PRIMARY PRIMARY 4 NULL 2 Using where; Using index
DROP TABLE t1;
# test of RANGE and index # test of RANGE and index
CREATE TABLE t1 (a DATE, KEY(a)) CREATE TABLE t1 (a DATE, KEY(a))
PARTITION BY RANGE (TO_DAYS(a)) PARTITION BY RANGE (TO_DAYS(a))
...@@ -1816,7 +2426,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra ...@@ -1816,7 +2426,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t2 p0,p4 ALL NULL NULL NULL NULL 910 Using where 1 SIMPLE t2 p0,p4 ALL NULL NULL NULL NULL 910 Using where
explain partitions select * from t2 where (a > 100 AND a < 600); explain partitions select * from t2 where (a > 100 AND a < 600);
id select_type table partitions type possible_keys key key_len ref rows Extra id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t2 p0,p1,p2,p3 ALL NULL NULL NULL NULL 910 Using where 1 SIMPLE t2 p0,p1,p2 ALL NULL NULL NULL NULL 910 Using where
explain partitions select * from t2 where b = 4; explain partitions select * from t2 where b = 4;
id select_type table partitions type possible_keys key key_len ref rows Extra id select_type table partitions type possible_keys key key_len ref rows Extra
1 SIMPLE t2 p0,p1,p2,p3,p4 ref b b 5 const 76 Using where 1 SIMPLE t2 p0,p1,p2,p3,p4 ref b b 5 const 76 Using where
......
...@@ -8,6 +8,166 @@ ...@@ -8,6 +8,166 @@
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9; drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9;
--enable_warnings --enable_warnings
--echo #
--echo # Bug#49742: Partition Pruning not working correctly for RANGE
--echo #
CREATE TABLE t1 (a INT PRIMARY KEY)
PARTITION BY RANGE (a) (
PARTITION p0 VALUES LESS THAN (1),
PARTITION p1 VALUES LESS THAN (2),
PARTITION p2 VALUES LESS THAN (3),
PARTITION p3 VALUES LESS THAN (4),
PARTITION p4 VALUES LESS THAN (5),
PARTITION p5 VALUES LESS THAN (6),
PARTITION max VALUES LESS THAN MAXVALUE);
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7),(8);
SELECT * FROM t1 WHERE a < 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 1;
SELECT * FROM t1 WHERE a < 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 2;
SELECT * FROM t1 WHERE a < 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 3;
SELECT * FROM t1 WHERE a < 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 4;
SELECT * FROM t1 WHERE a < 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 5;
SELECT * FROM t1 WHERE a < 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 6;
SELECT * FROM t1 WHERE a < 7;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 7;
SELECT * FROM t1 WHERE a <= 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
SELECT * FROM t1 WHERE a <= 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 2;
SELECT * FROM t1 WHERE a <= 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 3;
SELECT * FROM t1 WHERE a <= 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 4;
SELECT * FROM t1 WHERE a <= 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 5;
SELECT * FROM t1 WHERE a <= 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 6;
SELECT * FROM t1 WHERE a <= 7;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 7;
SELECT * FROM t1 WHERE a = 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 1;
SELECT * FROM t1 WHERE a = 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 2;
SELECT * FROM t1 WHERE a = 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 3;
SELECT * FROM t1 WHERE a = 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 4;
SELECT * FROM t1 WHERE a = 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 5;
SELECT * FROM t1 WHERE a = 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 6;
SELECT * FROM t1 WHERE a = 7;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 7;
SELECT * FROM t1 WHERE a >= 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 1;
SELECT * FROM t1 WHERE a >= 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 2;
SELECT * FROM t1 WHERE a >= 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 3;
SELECT * FROM t1 WHERE a >= 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 4;
SELECT * FROM t1 WHERE a >= 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 5;
SELECT * FROM t1 WHERE a >= 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 6;
SELECT * FROM t1 WHERE a >= 7;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 7;
SELECT * FROM t1 WHERE a > 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 1;
SELECT * FROM t1 WHERE a > 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 2;
SELECT * FROM t1 WHERE a > 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 3;
SELECT * FROM t1 WHERE a > 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 4;
SELECT * FROM t1 WHERE a > 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 5;
SELECT * FROM t1 WHERE a > 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 6;
SELECT * FROM t1 WHERE a > 7;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 7;
DROP TABLE t1;
CREATE TABLE t1 (a INT PRIMARY KEY)
PARTITION BY RANGE (a) (
PARTITION p0 VALUES LESS THAN (1),
PARTITION p1 VALUES LESS THAN (2),
PARTITION p2 VALUES LESS THAN (3),
PARTITION p3 VALUES LESS THAN (4),
PARTITION p4 VALUES LESS THAN (5),
PARTITION max VALUES LESS THAN MAXVALUE);
INSERT INTO t1 VALUES (-1),(0),(1),(2),(3),(4),(5),(6),(7);
SELECT * FROM t1 WHERE a < 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 1;
SELECT * FROM t1 WHERE a < 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 2;
SELECT * FROM t1 WHERE a < 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 3;
SELECT * FROM t1 WHERE a < 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 4;
SELECT * FROM t1 WHERE a < 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 5;
SELECT * FROM t1 WHERE a < 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 6;
SELECT * FROM t1 WHERE a <= 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1;
SELECT * FROM t1 WHERE a <= 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 2;
SELECT * FROM t1 WHERE a <= 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 3;
SELECT * FROM t1 WHERE a <= 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 4;
SELECT * FROM t1 WHERE a <= 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 5;
SELECT * FROM t1 WHERE a <= 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 6;
SELECT * FROM t1 WHERE a = 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 1;
SELECT * FROM t1 WHERE a = 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 2;
SELECT * FROM t1 WHERE a = 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 3;
SELECT * FROM t1 WHERE a = 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 4;
SELECT * FROM t1 WHERE a = 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 5;
SELECT * FROM t1 WHERE a = 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = 6;
SELECT * FROM t1 WHERE a >= 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 1;
SELECT * FROM t1 WHERE a >= 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 2;
SELECT * FROM t1 WHERE a >= 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 3;
SELECT * FROM t1 WHERE a >= 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 4;
SELECT * FROM t1 WHERE a >= 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 5;
SELECT * FROM t1 WHERE a >= 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= 6;
SELECT * FROM t1 WHERE a > 1;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 1;
SELECT * FROM t1 WHERE a > 2;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 2;
SELECT * FROM t1 WHERE a > 3;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 3;
SELECT * FROM t1 WHERE a > 4;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 4;
SELECT * FROM t1 WHERE a > 5;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 5;
SELECT * FROM t1 WHERE a > 6;
EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > 6;
DROP TABLE t1;
# #
# Bug#20577: Partitions: use of to_days() function leads to selection failures # Bug#20577: Partitions: use of to_days() function leads to selection failures
# #
......
...@@ -2878,16 +2878,13 @@ int get_partition_id_range(partition_info *part_info, ...@@ -2878,16 +2878,13 @@ int get_partition_id_range(partition_info *part_info,
part_func_value-= 0x8000000000000000ULL; part_func_value-= 0x8000000000000000ULL;
while (max_part_id > min_part_id) while (max_part_id > min_part_id)
{ {
loc_part_id= (max_part_id + min_part_id + 1) >> 1; loc_part_id= (max_part_id + min_part_id) / 2;
if (range_array[loc_part_id] <= part_func_value) if (range_array[loc_part_id] <= part_func_value)
min_part_id= loc_part_id + 1; min_part_id= loc_part_id + 1;
else else
max_part_id= loc_part_id - 1; max_part_id= loc_part_id;
} }
loc_part_id= max_part_id; loc_part_id= max_part_id;
if (part_func_value >= range_array[loc_part_id])
if (loc_part_id != max_partition)
loc_part_id++;
*part_id= (uint32)loc_part_id; *part_id= (uint32)loc_part_id;
if (loc_part_id == max_partition && if (loc_part_id == max_partition &&
part_func_value >= range_array[loc_part_id] && part_func_value >= range_array[loc_part_id] &&
...@@ -2961,6 +2958,7 @@ uint32 get_partition_id_range_for_endpoint(partition_info *part_info, ...@@ -2961,6 +2958,7 @@ uint32 get_partition_id_range_for_endpoint(partition_info *part_info,
bool include_endpoint) bool include_endpoint)
{ {
longlong *range_array= part_info->range_int_array; longlong *range_array= part_info->range_int_array;
longlong part_end_val;
uint max_partition= part_info->no_parts - 1; uint max_partition= part_info->no_parts - 1;
uint min_part_id= 0, max_part_id= max_partition, loc_part_id; uint min_part_id= 0, max_part_id= max_partition, loc_part_id;
/* Get the partitioning function value for the endpoint */ /* Get the partitioning function value for the endpoint */
...@@ -2994,46 +2992,45 @@ uint32 get_partition_id_range_for_endpoint(partition_info *part_info, ...@@ -2994,46 +2992,45 @@ uint32 get_partition_id_range_for_endpoint(partition_info *part_info,
} }
} }
if (unsigned_flag) if (unsigned_flag)
part_func_value-= 0x8000000000000000ULL; part_func_value-= 0x8000000000000000ULL;
if (left_endpoint && !include_endpoint) if (left_endpoint && !include_endpoint)
part_func_value++; part_func_value++;
/*
Search for the partition containing part_func_value
(including the right endpoint).
*/
while (max_part_id > min_part_id) while (max_part_id > min_part_id)
{ {
loc_part_id= (max_part_id + min_part_id + 1) >> 1; loc_part_id= (max_part_id + min_part_id) / 2;
if (range_array[loc_part_id] <= part_func_value) if (range_array[loc_part_id] < part_func_value)
min_part_id= loc_part_id + 1; min_part_id= loc_part_id + 1;
else else
max_part_id= loc_part_id - 1; max_part_id= loc_part_id;
} }
loc_part_id= max_part_id; loc_part_id= max_part_id;
if (loc_part_id < max_partition &&
part_func_value >= range_array[loc_part_id+1]) /* Adjust for endpoints */
{ part_end_val= range_array[loc_part_id];
loc_part_id++;
}
if (left_endpoint) if (left_endpoint)
{ {
longlong bound= range_array[loc_part_id];
/* /*
In case of PARTITION p VALUES LESS THAN MAXVALUE In case of PARTITION p VALUES LESS THAN MAXVALUE
the maximum value is in the current partition. the maximum value is in the current partition.
*/ */
if (part_func_value > bound || if (part_func_value == part_end_val &&
(part_func_value == bound && (loc_part_id < max_partition || !part_info->defined_max_value))
(!part_info->defined_max_value || loc_part_id < max_partition)))
loc_part_id++; loc_part_id++;
} }
else else
{ {
if (loc_part_id < max_partition) /* if 'WHERE <= X' and partition is LESS THAN (X) include next partition */
{ if (include_endpoint && loc_part_id < max_partition &&
if (part_func_value == range_array[loc_part_id]) part_func_value == part_end_val)
loc_part_id += test(include_endpoint); loc_part_id++;
else if (part_func_value > range_array[loc_part_id])
loc_part_id++; /* Right endpoint, set end after correct partition */
}
loc_part_id++; loc_part_id++;
} }
DBUG_RETURN(loc_part_id); DBUG_RETURN(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