From 42282c10ce0e2c808d1818e77a6a72eadc3a560d Mon Sep 17 00:00:00 2001 From: Mattias Jonsson Date: Wed, 22 Feb 2012 23:13:36 +0100 Subject: [PATCH 1/5] Bug#13694811: THE OPTIMIZER WRONGLY USES THE FIRST INNODB PARTITION STATISTICS Problem was the fix for bug#11756867; It always used the first partitions, and stopped after it checked 10 [sub]partitions. (or until it found a partition which would contain a match). This results in bad statistics for tables where the first 10 partitions don't represent the majority of the data (like when the first 10 partitions only contained a few rows in total). The solution was to take statisics from the partitions containing the most rows instead: Added an array of partition ids which is sorted by number of records in descending order. this array is used in records_in_range to cover as many records as possible in as few calls as possible. Also changed the limit of how many partitions to use for the statistics from a static max of 10 partitions, into a dynamic model: Maximum number of partitions is now log2(total number of partitions) taken from the ordered array. It will continue calling partitions records_in_range until it has checked: (total rows in matching partitions) * (maximum number of partitions) / (number of used partitions) Also reverted the changes for ha_partition::scan_time() and ha_partition::estimate_rows_upper_bound() to before the fix of bug#11756867. Since they are not as slow as records_in_range. --- mysql-test/r/partition_innodb.result | 29 +++ mysql-test/r/partition_pruning.result | 76 +++---- mysql-test/t/partition_innodb.test | 29 +++ sql/ha_partition.cc | 302 +++++++++++++++++--------- sql/ha_partition.h | 24 +- 5 files changed, 304 insertions(+), 156 deletions(-) diff --git a/mysql-test/r/partition_innodb.result b/mysql-test/r/partition_innodb.result index 5fcb0e796b1..12a935c1b2b 100644 --- a/mysql-test/r/partition_innodb.result +++ b/mysql-test/r/partition_innodb.result @@ -1,5 +1,34 @@ drop table if exists t1, t2; # +# Bug#13694811: THE OPTIMIZER WRONGLY USES THE FIRST +# INNODB PARTITION STATISTICS +# +CREATE TABLE t1 +(a INT, +b varchar(64), +PRIMARY KEY (a), +KEY (b)) +ENGINE = InnoDB +PARTITION BY RANGE (a) +SUBPARTITION BY HASH (a) SUBPARTITIONS 10 +(PARTITION pNeg VALUES LESS THAN (0), +PARTITION p0 VALUES LESS THAN (1000), +PARTITION pMAX VALUES LESS THAN MAXVALUE); +# Only one row in the first 10 subpartitions +INSERT INTO t1 VALUES (-1, 'Only negative pk value'); +INSERT INTO t1 VALUES (0, 'Mod Zero'), (1, 'One'), (2, 'Two'), (3, 'Three'), +(10, 'Zero'), (11, 'Mod One'), (12, 'Mod Two'), (13, 'Mod Three'), +(20, '0'), (21, '1'), (22, '2'), (23, '3'), +(4, '4'), (5, '5'), (6, '6'), (7, '7'), (8, '8'), (9, '9'); +INSERT INTO t1 SELECT a + 30, b FROM t1 WHERE a >= 0; +ANALYZE TABLE t1; +Table Op Msg_type Msg_text +test.t1 analyze status OK +EXPLAIN SELECT b FROM t1 WHERE b between 'L' and 'N' AND a > -100; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range PRIMARY,b b 67 NULL 18 Using where; Using index +DROP TABLE t1; +# # Bug#56287: crash when using Partition datetime in sub in query # CREATE TABLE t1 diff --git a/mysql-test/r/partition_pruning.result b/mysql-test/r/partition_pruning.result index 01ae3876fd0..985675712ef 100644 --- a/mysql-test/r/partition_pruning.result +++ b/mysql-test/r/partition_pruning.result @@ -18,7 +18,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra # # # # # # # # # 3 # EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < 7; id select_type table partitions type possible_keys key key_len ref rows Extra -# # # # # # # # # 9 # +# # # # # # # # # 10 # EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= 1; id select_type table partitions type possible_keys key key_len ref rows Extra # # # # # # # # # 3 # @@ -105,7 +105,7 @@ a 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 +1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index SELECT * FROM t1 WHERE a <= 1; a -1 @@ -168,7 +168,7 @@ 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 p0,p1,p2,p3,p4,p5,max range PRIMARY PRIMARY 4 NULL 9 Using where; Using index +1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index SELECT * FROM t1 WHERE a <= 7; a -1 @@ -182,7 +182,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 p0,p1,p2,p3,p4,p5,max range PRIMARY PRIMARY 4 NULL 9 Using where; Using index +1 SIMPLE t1 p0,p1,p2,p3,p4,p5,max index PRIMARY PRIMARY 4 NULL 10 Using where; Using index SELECT * FROM t1 WHERE a = 1; a 1 @@ -424,7 +424,7 @@ a 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 +1 SIMPLE t1 p0,p1,p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index SELECT * FROM t1 WHERE a <= 1; a -1 @@ -474,7 +474,7 @@ 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 p0,p1,p2,p3,p4,max range PRIMARY PRIMARY 4 NULL 8 Using where; Using index +1 SIMPLE t1 p0,p1,p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index SELECT * FROM t1 WHERE a <= 6; a -1 @@ -487,7 +487,7 @@ 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 p0,p1,p2,p3,p4,max range PRIMARY PRIMARY 4 NULL 8 Using where; Using index +1 SIMPLE t1 p0,p1,p2,p3,p4,max index PRIMARY PRIMARY 4 NULL 9 Using where; Using index SELECT * FROM t1 WHERE a = 1; a 1 @@ -744,13 +744,13 @@ a 1001-01-01 EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index +1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL,p2001-01-01 range a a 4 NULL 3 Using where; Using index @@ -759,26 +759,26 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p1001-01-01 system a NULL NULL NULL 1 EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < '1001-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= '1001-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= '1001-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index +1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a > '1001-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index +1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a = '1001-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL ref a a 4 const 1 Using where; Using index # Disabling warnings for the invalid date EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL,p2001-01-01 index a a 4 NULL 4 Using where; Using index @@ -790,16 +790,16 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL ref a a 4 const 1 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0000-00-00' AND '1002-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01,p2001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0000-00-00' AND '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0001-01-02' AND '1002-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p1001-01-01,p2001-01-01 index a a 4 NULL 5 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0001-01-01' AND '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 range a a 4 NULL 3 Using where; Using index +1 SIMPLE t1 pNULL,p0001-01-01,p1001-01-01 index a a 4 NULL 6 Using where; Using index # test without index ALTER TABLE t1 DROP KEY a; SELECT * FROM t1 WHERE a < '1001-01-01'; @@ -1076,7 +1076,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 4 Using where; Using index +1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p2001-01-01,pNULL,p1001-01-01 range a a 4 NULL 4 Using where; Using index @@ -1104,10 +1104,10 @@ id select_type table partitions type possible_keys key key_len ref rows Extra # Disabling warnings for the invalid date EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a < '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a <= '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a >= '1999-02-31'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p2001-01-01,pNULL index a a 4 NULL 4 Using where; Using index @@ -1119,10 +1119,10 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL ref a a 4 const 1 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0000-00-00' AND '1002-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 5 Using where; Using index +1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 4 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0000-00-00' AND '1001-01-01'; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 4 Using where; Using index +1 SIMPLE t1 p0001-01-01,pNULL,p0000-01-02,p1001-01-01 range a a 4 NULL 3 Using where; Using index EXPLAIN PARTITIONS SELECT * FROM t1 WHERE a BETWEEN '0001-01-02' AND '1002-00-00'; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 pNULL,p1001-01-01 index a a 4 NULL 4 Using where; Using index @@ -2537,18 +2537,18 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2 ALL NULL NULL NULL NULL 510 Using where explain partitions select * from t2 where b = 4; 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 96 Using where explain extended select * from t2 where b = 6; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ref b b 5 const 76 100.00 Using where +1 SIMPLE t2 ref b b 5 const 96 100.00 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where (`test`.`t2`.`b` = 6) explain partitions select * from t2 where b = 6; 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 96 Using where explain extended select * from t2 where b in (1,3,5); id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 40.66 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 51.65 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where (`test`.`t2`.`b` in (1,3,5)) explain partitions select * from t2 where b in (1,3,5); @@ -2556,7 +2556,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b in (2,4,6); id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 25.05 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 31.65 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where (`test`.`t2`.`b` in (2,4,6)) explain partitions select * from t2 where b in (2,4,6); @@ -2564,7 +2564,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b in (7,8,9); id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 36.70 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 19.12 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where (`test`.`t2`.`b` in (7,8,9)) explain partitions select * from t2 where b in (7,8,9); @@ -2572,7 +2572,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b > 5; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 44.84 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 29.23 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where (`test`.`t2`.`b` > 5) explain partitions select * from t2 where b > 5; @@ -2580,7 +2580,7 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b > 5 and b < 8; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 22.09 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 28.13 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b` > 5) and (`test`.`t2`.`b` < 8)) explain partitions select * from t2 where b > 5 and b < 8; @@ -2588,15 +2588,15 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b > 5 and b < 7; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 range b b 5 NULL 76 100.00 Using where +1 SIMPLE t2 range b b 5 NULL 96 100.00 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b` > 5) and (`test`.`t2`.`b` < 7)) explain partitions select * from t2 where b > 5 and b < 7; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 76 Using where +1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 96 Using where explain extended select * from t2 where b > 0 and b < 5; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 ALL b NULL NULL NULL 910 41.65 Using where +1 SIMPLE t2 ALL b NULL NULL NULL 910 53.19 Using where Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b` > 0) and (`test`.`t2`.`b` < 5)) explain partitions select * from t2 where b > 0 and b < 5; @@ -2630,10 +2630,10 @@ flush status; delete from t2 where b = 7; show status like 'Handler_read_rnd_next'; Variable_name Value -Handler_read_rnd_next 0 +Handler_read_rnd_next 1215 show status like 'Handler_read_key'; Variable_name Value -Handler_read_key 5 +Handler_read_key 0 flush status; delete from t2 where b > 5; show status like 'Handler_read_rnd_next'; diff --git a/mysql-test/t/partition_innodb.test b/mysql-test/t/partition_innodb.test index dc8bcbb4cb9..f2a1a5b0fe4 100644 --- a/mysql-test/t/partition_innodb.test +++ b/mysql-test/t/partition_innodb.test @@ -7,6 +7,35 @@ drop table if exists t1, t2; let $MYSQLD_DATADIR= `SELECT @@datadir`; +--echo # +--echo # Bug#13694811: THE OPTIMIZER WRONGLY USES THE FIRST +--echo # INNODB PARTITION STATISTICS +--echo # + +CREATE TABLE t1 +(a INT, + b varchar(64), + PRIMARY KEY (a), + KEY (b)) +ENGINE = InnoDB +PARTITION BY RANGE (a) +SUBPARTITION BY HASH (a) SUBPARTITIONS 10 +(PARTITION pNeg VALUES LESS THAN (0), + PARTITION p0 VALUES LESS THAN (1000), + PARTITION pMAX VALUES LESS THAN MAXVALUE); + +--echo # Only one row in the first 10 subpartitions +INSERT INTO t1 VALUES (-1, 'Only negative pk value'); + +INSERT INTO t1 VALUES (0, 'Mod Zero'), (1, 'One'), (2, 'Two'), (3, 'Three'), +(10, 'Zero'), (11, 'Mod One'), (12, 'Mod Two'), (13, 'Mod Three'), +(20, '0'), (21, '1'), (22, '2'), (23, '3'), +(4, '4'), (5, '5'), (6, '6'), (7, '7'), (8, '8'), (9, '9'); +INSERT INTO t1 SELECT a + 30, b FROM t1 WHERE a >= 0; +ANALYZE TABLE t1; +EXPLAIN SELECT b FROM t1 WHERE b between 'L' and 'N' AND a > -100; +DROP TABLE t1; + --echo # --echo # Bug#56287: crash when using Partition datetime in sub in query --echo # diff --git a/sql/ha_partition.cc b/sql/ha_partition.cc index 7c7cf5a4302..ddfe271f6a3 100644 --- a/sql/ha_partition.cc +++ b/sql/ha_partition.cc @@ -286,6 +286,7 @@ void ha_partition::init_handler_variables() m_is_sub_partitioned= 0; m_is_clone_of= NULL; m_clone_mem_root= NULL; + m_part_ids_sorted_by_num_of_records= NULL; #ifdef DONT_HAVE_TO_BE_INITALIZED m_start_key.flag= 0; @@ -321,6 +322,8 @@ ha_partition::~ha_partition() delete m_file[i]; } my_free((char*) m_ordered_rec_buffer, MYF(MY_ALLOW_ZERO_PTR)); + my_free((char*) m_part_ids_sorted_by_num_of_records, + MYF(MY_ALLOW_ZERO_PTR)); clear_handler_file(); DBUG_VOID_RETURN; @@ -2638,6 +2641,16 @@ int ha_partition::open(const char *name, int mode, uint test_if_locked) m_start_key.key= (const uchar*)ptr; } } + if (!m_part_ids_sorted_by_num_of_records) + { + if (!(m_part_ids_sorted_by_num_of_records= + (uint32*) my_malloc(m_tot_parts * sizeof(uint32), MYF(MY_WME)))) + DBUG_RETURN(error); + uint32 i; + /* Initialize it with all partition ids. */ + for (i= 0; i < m_tot_parts; i++) + m_part_ids_sorted_by_num_of_records[i]= i; + } /* Initialize the bitmap we use to minimize ha_start_bulk_insert calls */ if (bitmap_init(&m_bulk_insert_started, NULL, m_tot_parts + 1, FALSE)) @@ -5146,6 +5159,24 @@ int ha_partition::handle_ordered_prev(uchar *buf) and read_time calls */ +/** + Helper function for sorting according to number of rows in descending order. +*/ + +int ha_partition::compare_number_of_records(ha_partition *me, + const uint32 *a, + const uint32 *b) +{ + handler **file= me->m_file; + /* Note: sorting in descending order! */ + if (file[*a]->stats.records > file[*b]->stats.records) + return -1; + if (file[*a]->stats.records < file[*b]->stats.records) + return 1; + return 0; +} + + /* General method to gather info from handler @@ -5387,6 +5418,15 @@ int ha_partition::info(uint flag) } i++; } while (*(++file_array)); + /* + Sort the array of part_ids by number of records in + in descending order. + */ + my_qsort2((void*) m_part_ids_sorted_by_num_of_records, + m_tot_parts, + sizeof(uint32), + (qsort2_cmp) compare_number_of_records, + this); file= m_file[handler_instance]; file->info(HA_STATUS_CONST); @@ -6124,21 +6164,72 @@ const key_map *ha_partition::keys_to_use_for_scanning() DBUG_RETURN(m_file[0]->keys_to_use_for_scanning()); } -#define MAX_PARTS_FOR_OPTIMIZER_CALLS 10 -/* - Prepare start variables for estimating optimizer costs. - - @param[out] num_used_parts Number of partitions after pruning. - @param[out] check_min_num Number of partitions to call. - @param[out] first first used partition. +/** + Minimum number of rows to base optimizer estimate on. */ -void ha_partition::partitions_optimizer_call_preparations(uint *first, - uint *num_used_parts, - uint *check_min_num) + +ha_rows ha_partition::min_rows_for_estimate() { - *first= bitmap_get_first_set(&(m_part_info->used_partitions)); - *num_used_parts= bitmap_bits_set(&(m_part_info->used_partitions)); - *check_min_num= min(MAX_PARTS_FOR_OPTIMIZER_CALLS, *num_used_parts); + uint i, max_used_partitions, tot_used_partitions; + DBUG_ENTER("ha_partition::partitions_optimizer_call_preparations"); + + tot_used_partitions= bitmap_bits_set(&m_part_info->used_partitions); + DBUG_ASSERT(tot_used_partitions); + + /* + Allow O(log2(tot_partitions)) increase in number of used partitions. + This gives O(1/log2(tot_partitions)) of rows to base the estimate on. + I.e when the total number of partitions doubles, allow one more + partition to be checked. + */ + i= 2; + max_used_partitions= 1; + while (i < m_tot_parts) + { + max_used_partitions++; + i= i << 1; + } + if (max_used_partitions > tot_used_partitions) + max_used_partitions= tot_used_partitions; + + /* stats.records is already updated by the info(HA_STATUS_VARIABLE) call. */ + DBUG_PRINT("info", ("max_used_partitions: %u tot_rows: %lu", + max_used_partitions, + (ulong) stats.records)); + DBUG_PRINT("info", ("tot_used_partitions: %u min_rows_to_check: %lu", + tot_used_partitions, + (ulong) stats.records * max_used_partitions + / tot_used_partitions)); + DBUG_RETURN(stats.records * max_used_partitions / tot_used_partitions); +} + + +/** + Get the biggest used partition. + + Starting at the N:th biggest partition and skips all non used + partitions, returning the biggest used partition found + + @param[in,out] part_index Skip the *part_index biggest partitions + + @return The biggest used partition with index not lower than *part_index. + @retval NO_CURRENT_PART_ID No more partition used. + @retval != NO_CURRENT_PART_ID partition id of biggest used partition with + index >= *part_index supplied. Note that + *part_index will be updated to the next + partition index to use. +*/ + +uint ha_partition::get_biggest_used_partition(uint *part_index) +{ + uint part_id; + while ((*part_index) < m_tot_parts) + { + part_id= m_part_ids_sorted_by_num_of_records[(*part_index)++]; + if (bitmap_is_set(&m_part_info->used_partitions, part_id)) + return part_id; + } + return NO_CURRENT_PART_ID; } @@ -6154,86 +6245,32 @@ void ha_partition::partitions_optimizer_call_preparations(uint *first, double ha_partition::scan_time() { - double scan_time= 0.0; - uint first, part_id, num_used_parts, check_min_num, partitions_called= 0; + double scan_time= 0; + handler **file; DBUG_ENTER("ha_partition::scan_time"); - partitions_optimizer_call_preparations(&first, &num_used_parts, &check_min_num); - for (part_id= first; partitions_called < num_used_parts ; part_id++) - { - if (!bitmap_is_set(&(m_part_info->used_partitions), part_id)) - continue; - scan_time+= m_file[part_id]->scan_time(); - partitions_called++; - if (partitions_called >= check_min_num && scan_time != 0.0) - { - DBUG_RETURN(scan_time * - (double) num_used_parts / (double) partitions_called); - } - } + for (file= m_file; *file; file++) + if (bitmap_is_set(&(m_part_info->used_partitions), (file - m_file))) + scan_time+= (*file)->scan_time(); DBUG_RETURN(scan_time); } -/* - Estimate rows for records_in_range or estimate_rows_upper_bound. +/** + Find number of records in a range. + @param inx Index number + @param min_key Start of range + @param max_key End of range - @param is_records_in_range call records_in_range instead of - estimate_rows_upper_bound. - @param inx (only for records_in_range) index to use. - @param min_key (only for records_in_range) start of range. - @param max_key (only for records_in_range) end of range. + @return Number of rows in range. - @return Number of rows or HA_POS_ERROR. -*/ -ha_rows ha_partition::estimate_rows(bool is_records_in_range, uint inx, - key_range *min_key, key_range *max_key) -{ - ha_rows rows, estimated_rows= 0; - uint first, part_id, num_used_parts, check_min_num, partitions_called= 0; - DBUG_ENTER("ha_partition::records_in_range"); + Given a starting key, and an ending key estimate the number of rows that + will exist between the two. end_key may be empty which in case determine + if start_key matches any rows. - partitions_optimizer_call_preparations(&first, &num_used_parts, &check_min_num); - for (part_id= first; partitions_called < num_used_parts ; part_id++) - { - if (!bitmap_is_set(&(m_part_info->used_partitions), part_id)) - continue; - if (is_records_in_range) - rows= m_file[part_id]->records_in_range(inx, min_key, max_key); - else - rows= m_file[part_id]->estimate_rows_upper_bound(); - if (rows == HA_POS_ERROR) - DBUG_RETURN(HA_POS_ERROR); - estimated_rows+= rows; - partitions_called++; - if (partitions_called >= check_min_num && estimated_rows) - { - DBUG_RETURN(estimated_rows * num_used_parts / partitions_called); - } - } - DBUG_RETURN(estimated_rows); -} - - -/* - Find number of records in a range - - SYNOPSIS - records_in_range() - inx Index number - min_key Start of range - max_key End of range - - RETURN VALUE - Number of rows in range - - DESCRIPTION - Given a starting key, and an ending key estimate the number of rows that - will exist between the two. end_key may be empty which in case determine - if start_key matches any rows. - - Called from opt_range.cc by check_quick_keys(). + Called from opt_range.cc by check_quick_keys(). + @note monty: MUST be called for each range and added. Note that MySQL will assume that if this returns 0 there is no matching rows for the range! @@ -6242,27 +6279,80 @@ ha_rows ha_partition::estimate_rows(bool is_records_in_range, uint inx, ha_rows ha_partition::records_in_range(uint inx, key_range *min_key, key_range *max_key) { + ha_rows min_rows_to_check, rows, estimated_rows=0, checked_rows= 0; + uint partition_index= 0, part_id; DBUG_ENTER("ha_partition::records_in_range"); - DBUG_RETURN(estimate_rows(TRUE, inx, min_key, max_key)); + min_rows_to_check= min_rows_for_estimate(); + + while ((part_id= get_biggest_used_partition(&partition_index)) + != NO_CURRENT_PART_ID) + { + rows= m_file[part_id]->records_in_range(inx, min_key, max_key); + + DBUG_PRINT("info", ("part %u match %lu rows of %lu", part_id, (ulong) rows, + (ulong) m_file[part_id]->stats.records)); + + if (rows == HA_POS_ERROR) + DBUG_RETURN(HA_POS_ERROR); + estimated_rows+= rows; + checked_rows+= m_file[part_id]->stats.records; + /* + Returning 0 means no rows can be found, so we must continue + this loop as long as we have estimated_rows == 0. + Also many engines return 1 to indicate that there may exist + a matching row, we do not normalize this by dividing by number of + used partitions, but leave it to be returned as a sum, which will + reflect that we will need to scan each partition's index. + + Note that this statistics may not always be correct, so we must + continue even if the current partition has 0 rows, since we might have + deleted rows from the current partition, or inserted to the next + partition. + */ + if (estimated_rows && checked_rows && + checked_rows >= min_rows_to_check) + { + DBUG_PRINT("info", + ("records_in_range(inx %u): %lu (%lu * %lu / %lu)", + inx, + (ulong) (estimated_rows * stats.records / checked_rows), + (ulong) estimated_rows, + (ulong) stats.records, + (ulong) checked_rows)); + DBUG_RETURN(estimated_rows * stats.records / checked_rows); + } + } + DBUG_PRINT("info", ("records_in_range(inx %u): %lu", + inx, + (ulong) estimated_rows)); + DBUG_RETURN(estimated_rows); } -/* - Estimate upper bound of number of rows +/** + Estimate upper bound of number of rows. - SYNOPSIS - estimate_rows_upper_bound() - - RETURN VALUE - Number of rows + @return Number of rows. */ ha_rows ha_partition::estimate_rows_upper_bound() { + ha_rows rows, tot_rows= 0; + handler **file= m_file; DBUG_ENTER("ha_partition::estimate_rows_upper_bound"); - DBUG_RETURN(estimate_rows(FALSE, 0, NULL, NULL)); + do + { + if (bitmap_is_set(&(m_part_info->used_partitions), (file - m_file))) + { + rows= (*file)->estimate_rows_upper_bound(); + if (rows == HA_POS_ERROR) + DBUG_RETURN(HA_POS_ERROR); + tot_rows+= rows; + } + } while (*(++file)); + DBUG_RETURN(tot_rows); } @@ -6494,20 +6584,20 @@ int ha_partition::add_index(TABLE *table_arg, KEY *key_info, uint num_of_keys) return ret; err: if (file > m_file) - { - uint *key_numbers= (uint*) ha_thd()->alloc(sizeof(uint) * num_of_keys); - KEY *old_key_info= table_arg->key_info; - uint i; - /* Use the newly added key_info as table->key_info to remove them. */ - for (i= 0; i < num_of_keys; i++) - key_numbers[i]= i; - table_arg->key_info= key_info; - while (--file >= m_file) - { - (void) (*file)->prepare_drop_index(table_arg, key_numbers, num_of_keys); - (void) (*file)->final_drop_index(table_arg); - } - table_arg->key_info= old_key_info; + { + uint *key_numbers= (uint*) ha_thd()->alloc(sizeof(uint) * num_of_keys); + KEY *old_key_info= table_arg->key_info; + uint i; + /* Use the newly added key_info as table->key_info to remove them. */ + for (i= 0; i < num_of_keys; i++) + key_numbers[i]= i; + table_arg->key_info= key_info; + while (--file >= m_file) + { + (void) (*file)->prepare_drop_index(table_arg, key_numbers, num_of_keys); + (void) (*file)->final_drop_index(table_arg); + } + table_arg->key_info= old_key_info; } return ret; } diff --git a/sql/ha_partition.h b/sql/ha_partition.h index 46e2f447a47..49131518f8c 100644 --- a/sql/ha_partition.h +++ b/sql/ha_partition.h @@ -199,6 +199,12 @@ private: ha_rows m_bulk_inserted_rows; /** used for prediction of start_bulk_insert rows */ enum_monotonicity_info m_part_func_monotonicity_info; + /** Sorted array of partition ids in descending order of number of rows. */ + uint32 *m_part_ids_sorted_by_num_of_records; + /* Compare function for my_qsort2, for reversed order. */ + static int compare_number_of_records(ha_partition *me, + const uint32 *a, + const uint32 *b); public: handler *clone(const char *name, MEM_ROOT *mem_root); virtual void set_part_info(partition_info *part_info) @@ -219,9 +225,9 @@ public: */ ha_partition(handlerton *hton, TABLE_SHARE * table); ha_partition(handlerton *hton, partition_info * part_info); - ha_partition(handlerton *hton, TABLE_SHARE *share, - partition_info *part_info_arg, - ha_partition *clone_arg, + ha_partition(handlerton *hton, TABLE_SHARE *share, + partition_info *part_info_arg, + ha_partition *clone_arg, MEM_ROOT *clone_mem_root_arg); ~ha_partition(); /* @@ -582,15 +588,9 @@ public: */ private: - /* - Helper function to get the minimum number of partitions to use for - the optimizer hints/cost calls. - */ - void partitions_optimizer_call_preparations(uint *num_used_parts, - uint *check_min_num, - uint *first); - ha_rows estimate_rows(bool is_records_in_range, uint inx, - key_range *min_key, key_range *max_key); + /* Helper functions for optimizer hints. */ + ha_rows min_rows_for_estimate(); + uint get_biggest_used_partition(uint *part_index); public: /* From f8eb62625f69086a3094ade6d90c337e00c3c8ca Mon Sep 17 00:00:00 2001 From: Mattias Jonsson Date: Wed, 14 Mar 2012 20:36:42 +0100 Subject: [PATCH 2/5] bug#13694811 Updated code comments according to reviewers requests. --- sql/ha_partition.cc | 14 ++++---------- 1 file changed, 4 insertions(+), 10 deletions(-) diff --git a/sql/ha_partition.cc b/sql/ha_partition.cc index ddfe271f6a3..a1f4ac70e5a 100644 --- a/sql/ha_partition.cc +++ b/sql/ha_partition.cc @@ -6164,6 +6164,7 @@ const key_map *ha_partition::keys_to_use_for_scanning() DBUG_RETURN(m_file[0]->keys_to_use_for_scanning()); } + /** Minimum number of rows to base optimizer estimate on. */ @@ -6171,14 +6172,14 @@ const key_map *ha_partition::keys_to_use_for_scanning() ha_rows ha_partition::min_rows_for_estimate() { uint i, max_used_partitions, tot_used_partitions; - DBUG_ENTER("ha_partition::partitions_optimizer_call_preparations"); + DBUG_ENTER("ha_partition::min_rows_for_estimate"); tot_used_partitions= bitmap_bits_set(&m_part_info->used_partitions); DBUG_ASSERT(tot_used_partitions); /* Allow O(log2(tot_partitions)) increase in number of used partitions. - This gives O(1/log2(tot_partitions)) of rows to base the estimate on. + This gives O(tot_rows/log2(tot_partitions)) rows to base the estimate on. I.e when the total number of partitions doubles, allow one more partition to be checked. */ @@ -6265,15 +6266,8 @@ double ha_partition::scan_time() @return Number of rows in range. Given a starting key, and an ending key estimate the number of rows that - will exist between the two. end_key may be empty which in case determine + will exist between the two. max_key may be empty which in case determine if start_key matches any rows. - - Called from opt_range.cc by check_quick_keys(). - - @note - monty: MUST be called for each range and added. - Note that MySQL will assume that if this returns 0 there is no - matching rows for the range! */ ha_rows ha_partition::records_in_range(uint inx, key_range *min_key, From b373f4056b5215150ebfd185a079be9c9a598057 Mon Sep 17 00:00:00 2001 From: "sayantan.dutta@oracle.com" <> Date: Thu, 15 Mar 2012 12:35:09 +0530 Subject: [PATCH 3/5] BUG #13619394 - 62572: "MAKE TEST" FAILS ON "MY_VSNPRINTF"Reverting Back sighting Bar's mail. --- unittest/mysys/my_vsnprintf-t.c | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/unittest/mysys/my_vsnprintf-t.c b/unittest/mysys/my_vsnprintf-t.c index 0085c4c1ebe..dcaa4336b9d 100644 --- a/unittest/mysys/my_vsnprintf-t.c +++ b/unittest/mysys/my_vsnprintf-t.c @@ -155,7 +155,7 @@ int main(void) "conn %ld to: '%-.64s' user: '%-.32s' host: '%-.64s' (%-.64s)", 1L, NULL, NULL, NULL, NULL); test1("Hello string `I am a string`", - "Hello string `%s`", "I am a string"); + "Hello string `%s", "I am a string"); test1("Hello TEST", "Hello %05s", "TEST"); test1("My `Q` test", From 1a7e7a0f756d34a94d35c8cbf03823fb68d10044 Mon Sep 17 00:00:00 2001 From: Dmitry Shulga Date: Thu, 15 Mar 2012 15:10:57 +0600 Subject: [PATCH 4/5] This patch fixes the bug#13737343 (formerly known as 64374): XA TRANSACTIONS AND SAVEPOINT. The bug was introduced by the patch for bug#11766752. This patch sets too strong condition on XA state for SAVEPOINT statement that disallows its execution during XA transaction. But since the statement SAVEPOINT doesn't imply implicit commit we can allow its handling during XA transaction. The patch explicitly check for transaction state against states XA_NOTR and XA_ACTIVE for which the handling of statement SAVEPOINT for XA transaction is allowed. --- mysql-test/r/xa.result | 1 - mysql-test/t/xa.test | 1 - sql/transaction.cc | 2 +- 3 files changed, 1 insertion(+), 3 deletions(-) diff --git a/mysql-test/r/xa.result b/mysql-test/r/xa.result index 6db257eafd5..e7a62dbd3bc 100644 --- a/mysql-test/r/xa.result +++ b/mysql-test/r/xa.result @@ -174,7 +174,6 @@ CREATE TABLE t1 (a INT) engine=InnoDB; XA START 'a'; INSERT INTO t1 VALUES (1); SAVEPOINT savep; -ERROR XAE07: XAER_RMFAIL: The command cannot be executed when global transaction is in the ACTIVE state XA END 'a'; SELECT * FROM t1; ERROR XAE07: XAER_RMFAIL: The command cannot be executed when global transaction is in the IDLE state diff --git a/mysql-test/t/xa.test b/mysql-test/t/xa.test index cb4345e9479..fe49d2d5e31 100644 --- a/mysql-test/t/xa.test +++ b/mysql-test/t/xa.test @@ -298,7 +298,6 @@ CREATE TABLE t1 (a INT) engine=InnoDB; XA START 'a'; INSERT INTO t1 VALUES (1); ---error ER_XAER_RMFAIL SAVEPOINT savep; XA END 'a'; diff --git a/sql/transaction.cc b/sql/transaction.cc index 94a32200274..3359decbcd5 100644 --- a/sql/transaction.cc +++ b/sql/transaction.cc @@ -390,7 +390,7 @@ bool trans_savepoint(THD *thd, LEX_STRING name) DBUG_RETURN(FALSE); enum xa_states xa_state= thd->transaction.xid_state.xa_state; - if (xa_state != XA_NOTR) + if (xa_state != XA_NOTR && xa_state != XA_ACTIVE) { my_error(ER_XAER_RMFAIL, MYF(0), xa_state_names[xa_state]); DBUG_RETURN(TRUE); From f27061418020661564113b64fba13724835b4f64 Mon Sep 17 00:00:00 2001 From: Jon Olav Hauglid Date: Thu, 15 Mar 2012 10:15:50 +0100 Subject: [PATCH 5/5] Bug#13833438: ERROR CODES MUST HAVE SAME VALUE ACROSS MYSQL VERSIONS Pre-requisite patch. Add end-of-file marker to 5.5 version of errmsg-utf8.txt. --- sql/share/errmsg-utf8.txt | 3 +++ 1 file changed, 3 insertions(+) diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index d164f75d7d8..f0e9c210e62 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -6494,3 +6494,6 @@ ER_BINLOG_UNSAFE_WRITE_AUTOINC_SELECT ER_BINLOG_UNSAFE_CREATE_SELECT_AUTOINC eng "CREATE TABLE... SELECT... on a table with an auto-increment column is unsafe because the order in which rows are retrieved by the SELECT determines which (if any) rows are inserted. This order cannot be predicted and may differ on master and the slave." +# +# End of 5.5 error messages. +#