List:Commits« Previous MessageNext Message »
From:Georgi Kodinov Date:July 3 2009 10:29am
Subject:bzr commit into mysql-5.1-bugteam branch (joro:2990) Bug#36259 Bug#45828
View as plain text  
#At file:///home/kgeorge/mysql/work/B45828-5.1-bugteam/ based on revid:satya.bn@stripped

 2990 Georgi Kodinov	2009-07-03
      Bug #36259 (Optimizing with ORDER BY) and bug#45828 (Optimizer won't 
      use partial primary key if another index can prevent filesort
      
      The fix for bug #28404 causes the covering indexes to be preferred 
      over non-covering in the following two cases : 
       - when comparing the ordering indexes among themselves
       - when comparing the ref key to ordering indexes.
      
      Fixed by not considering the ordering indexes supperior to the 
      ref key. They're only supperior to non-covering ordering indexes. 
     @ mysql-test/include/mix1.inc
        Bug #36259: fixed a non-stable test case
     @ mysql-test/r/innodb_mysql.result
        Bug #36259 and #45828 : test case
     @ mysql-test/t/innodb_mysql.test
        Bug #36259 and #45828 : test case
     @ sql/sql_select.cc
        Bug #36259 and #45828 : don't consider covering indexes supperior to
        ref keys.

    modified:
      mysql-test/include/mix1.inc
      mysql-test/r/innodb_mysql.result
      mysql-test/t/innodb_mysql.test
      sql/sql_select.cc
=== modified file 'mysql-test/include/mix1.inc'
--- a/mysql-test/include/mix1.inc	2009-06-15 15:57:06 +0000
+++ b/mysql-test/include/mix1.inc	2009-07-03 10:29:30 +0000
@@ -1498,9 +1498,9 @@ INSERT INTO t1 VALUES
   (4,1,3,'pk',NULL),(5,1,3,'c2',NULL),
   (2,1,4,'c_extra',NULL),(3,1,4,'c_extra',NULL);
 
-EXPLAIN SELECT * FROM t1 WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
+EXPLAIN SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
 
-SELECT * FROM t1 WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
+SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
 
 DROP TABLE t1;
 

=== modified file 'mysql-test/r/innodb_mysql.result'
--- a/mysql-test/r/innodb_mysql.result	2009-06-15 15:57:06 +0000
+++ b/mysql-test/r/innodb_mysql.result	2009-07-03 10:29:30 +0000
@@ -1701,10 +1701,10 @@ INSERT INTO t1 VALUES
 (4,1,2,'c2',NULL),(5,1,2,'c1',NULL),(2,1,3,'c2',NULL),(3,1,3,'c2',NULL),
 (4,1,3,'pk',NULL),(5,1,3,'c2',NULL),
 (2,1,4,'c_extra',NULL),(3,1,4,'c_extra',NULL);
-EXPLAIN SELECT * FROM t1 WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
+EXPLAIN SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	index	vid	PRIMARY	12	NULL	16	Using where
-SELECT * FROM t1 WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
+1	SIMPLE	t1	index	NULL	PRIMARY	12	NULL	16	Using where
+SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE tid = 1 AND vid = 3 ORDER BY idx DESC;
 vid	tid	idx	name	type
 3	1	4	c_extra	NULL
 3	1	3	c2	NULL
@@ -2137,4 +2137,85 @@ GROUP BY t1.b;
 a	b	c	d	a	b	e	a	b
 1	1	1	0	1	1	2	1	1
 DROP TABLE t1, t2, t3;
+#
+# Bug #45828: Optimizer won't use partial primary key if another 
+# index can prevent filesort
+#
+CREATE TABLE `t1` (
+c1 int NOT NULL,
+c2 int NOT NULL,
+c3 int NOT NULL,
+PRIMARY KEY (c1,c2),
+KEY  (c3)
+) ENGINE=InnoDB;
+INSERT INTO t1 VALUES (5,2,1246276747);
+INSERT INTO t1 VALUES (2,1,1246281721);
+INSERT INTO t1 VALUES (7,3,1246281756);
+INSERT INTO t1 VALUES (4,2,1246282139);
+INSERT INTO t1 VALUES (3,1,1246282230);
+INSERT INTO t1 VALUES (1,0,1246282712);
+INSERT INTO t1 VALUES (8,3,1246282765);
+INSERT INTO t1 SELECT c1+10,c2+10,c3+10 FROM t1;
+INSERT INTO t1 SELECT c1+100,c2+100,c3+100 from t1;
+INSERT INTO t1 SELECT c1+1000,c2+1000,c3+1000 from t1;
+INSERT INTO t1 SELECT c1+10000,c2+10000,c3+10000 from t1;
+INSERT INTO t1 SELECT c1+100000,c2+100000,c3+100000 from t1;
+INSERT INTO t1 SELECT c1+1000000,c2+1000000,c3+1000000 from t1;
+SELECT * FROM t1 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+c1	c2	c3
+EXPLAIN SELECT * FROM t1 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ref	PRIMARY,c3	PRIMARY	4	const	1	Using where; Using filesort
+EXPLAIN SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ref	PRIMARY	PRIMARY	4	const	1	Using where; Using filesort
+CREATE TABLE t2 (
+c1 int NOT NULL,
+c2 int NOT NULL,
+c3 int NOT NULL,
+KEY (c1,c2),
+KEY (c3)
+) ENGINE=InnoDB;
+explain SELECT * FROM t2 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	ref	c1,c3	c1	4	const	1	Using where; Using filesort
+DROP TABLE t1,t2;
+#
+# 36259: Optimizing with ORDER BY
+#
+CREATE TABLE `testable2` (
+`col1` int(10) NOT NULL AUTO_INCREMENT,
+`col2` int(10) unsigned NOT NULL DEFAULT '0',
+`col3` int(10) unsigned NOT NULL DEFAULT '0',
+`col4` varchar(5) DEFAULT NULL,
+`col5` int(10) unsigned NOT NULL,
+PRIMARY KEY (`col1`) USING BTREE,
+KEY `I2` (`col2`,`col3`,`col4`) USING BTREE
+) ENGINE=InnoDB DEFAULT CHARSET=latin1
+;
+insert into testable2 (col2, col3, col4, col5) values (1,1,'a', 1), (2,2,'b', 2);
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+EXPLAIN SELECT * FROM testable2 where col2=1 and col3=1 order by col1;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	testable2	ref	I2	I2	8	const,const	1	Using where; Using filesort
+EXPLAIN SELECT * FROM testable2 force index(i2) where col2=1 and col3=1 order by
+col1;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	testable2	ref	I2	I2	8	const,const	1	Using where; Using filesort
+EXPLAIN SELECT * FROM testable2 force index(PRIMARY) where col2=1 and col3=1 order by
+col1;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	testable2	index	NULL	PRIMARY	4	NULL	128	Using where
+DROP TABLE testable2;
 End of 5.1 tests

=== modified file 'mysql-test/t/innodb_mysql.test'
--- a/mysql-test/t/innodb_mysql.test	2009-06-07 20:40:53 +0000
+++ b/mysql-test/t/innodb_mysql.test	2009-07-03 10:29:30 +0000
@@ -380,4 +380,94 @@ SELECT * FROM t1, t2, t3
 
 DROP TABLE t1, t2, t3;
 
+--echo #
+--echo # Bug #45828: Optimizer won't use partial primary key if another 
+--echo # index can prevent filesort
+--echo #
+
+# Create the table
+CREATE TABLE `t1` (
+  c1 int NOT NULL,
+  c2 int NOT NULL,
+  c3 int NOT NULL,
+  PRIMARY KEY (c1,c2),
+  KEY  (c3)
+) ENGINE=InnoDB;
+
+# populate with data
+INSERT INTO t1 VALUES (5,2,1246276747);
+INSERT INTO t1 VALUES (2,1,1246281721);
+INSERT INTO t1 VALUES (7,3,1246281756);
+INSERT INTO t1 VALUES (4,2,1246282139);
+INSERT INTO t1 VALUES (3,1,1246282230);
+INSERT INTO t1 VALUES (1,0,1246282712);
+INSERT INTO t1 VALUES (8,3,1246282765);
+INSERT INTO t1 SELECT c1+10,c2+10,c3+10 FROM t1;
+INSERT INTO t1 SELECT c1+100,c2+100,c3+100 from t1;
+INSERT INTO t1 SELECT c1+1000,c2+1000,c3+1000 from t1;
+INSERT INTO t1 SELECT c1+10000,c2+10000,c3+10000 from t1;
+INSERT INTO t1 SELECT c1+100000,c2+100000,c3+100000 from t1;
+INSERT INTO t1 SELECT c1+1000000,c2+1000000,c3+1000000 from t1;
+
+# query and no rows will match the c1 condition, whereas all will match c3
+SELECT * FROM t1 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+
+# SHOULD use the pk.
+# index on c3 will be used instead of primary key
+EXPLAIN SELECT * FROM t1 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+
+# if we force the primary key, we can see the estimate is 1 
+EXPLAIN SELECT * FROM t1 FORCE INDEX (PRIMARY) WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+
+
+CREATE TABLE t2 (
+  c1 int NOT NULL,
+  c2 int NOT NULL,
+  c3 int NOT NULL,
+  KEY (c1,c2),
+  KEY (c3)
+) ENGINE=InnoDB;
+
+# SHOULD use the pk.
+# if we switch it from a primary key to a regular index, it works correctly as well
+explain SELECT * FROM t2 WHERE c1 = 99999999 AND c3 > 1 ORDER BY c3;
+
+DROP TABLE t1,t2;
+
+
+--echo #
+--echo # 36259: Optimizing with ORDER BY
+--echo #
+
+CREATE TABLE `testable2` (
+  `col1` int(10) NOT NULL AUTO_INCREMENT,
+  `col2` int(10) unsigned NOT NULL DEFAULT '0',
+  `col3` int(10) unsigned NOT NULL DEFAULT '0',
+  `col4` varchar(5) DEFAULT NULL,
+  `col5` int(10) unsigned NOT NULL,
+  PRIMARY KEY (`col1`) USING BTREE,
+  KEY `I2` (`col2`,`col3`,`col4`) USING BTREE
+) ENGINE=InnoDB DEFAULT CHARSET=latin1
+;
+insert into testable2 (col2, col3, col4, col5) values (1,1,'a', 1), (2,2,'b', 2);
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+insert into testable2 (col2, col3, col4, col5) select rand()*10000, rand(
+)*10000, col4, col5 from testable2;
+EXPLAIN SELECT * FROM testable2 where col2=1 and col3=1 order by col1;
+EXPLAIN SELECT * FROM testable2 force index(i2) where col2=1 and col3=1 order by
+col1;
+EXPLAIN SELECT * FROM testable2 force index(PRIMARY) where col2=1 and col3=1 order by
+col1;
+
+DROP TABLE testable2;
+
 --echo End of 5.1 tests

=== modified file 'sql/sql_select.cc'
--- a/sql/sql_select.cc	2009-06-26 19:57:42 +0000
+++ b/sql/sql_select.cc	2009-07-03 10:29:30 +0000
@@ -13144,7 +13144,7 @@ test_if_skip_sort_order(JOIN_TAB *tab,OR
           temporary table + filesort could be cheaper for grouping
           queries too.
 	*/ 
-        if (is_covering ||
+        if ((ref_key < 0 && is_covering) ||
             select_limit != HA_POS_ERROR || 
             (ref_key < 0 && (group || table->force_index)))
         { 


Attachment: [text/bzr-bundle] bzr/joro@sun.com-20090703102930-mf8wrm7v2ya2irbt.bundle
Thread
bzr commit into mysql-5.1-bugteam branch (joro:2990) Bug#36259 Bug#45828Georgi Kodinov3 Jul