List:Commits« Previous MessageNext Message »
From:mhansson Date:August 28 2007 4:01pm
Subject:bk commit into 5.1 tree (mhansson:1.2571) BUG#30596
View as plain text  
Below is the list of changes that have just been committed into a local
5.1 repository of martin. When martin does a push these changes will
be propagated to the main repository and, within 24 hours after the
push, to the public repository.
For information on how to access the public repository
see http://dev.mysql.com/doc/mysql/en/installing-source-tree.html

ChangeSet@stripped, 2007-08-28 18:01:29+02:00, mhansson@stripped +6 -0
  Bug #30596  	GROUP BY optimization gives wrong result order
    
  The optimization that uses a unique index to remove GROUP BY did not 
  ensure that the index was actually used, thus violating the ORDER BY
  that is implied by GROUP BY.
  Fixed by replacing GROUP BY with ORDER BY if the GROUP BY clause contains
  a unique index over non-nullable field(s). In case GROUP BY ... ORDER BY 
  null is used, GROUP BY is simply removed.

  mysql-test/include/mix1.inc@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +27 -0
    Bug#30596: Test case for InnoDB
    Here, as opposed to for MyISAM, row lookup is done using index 
    whenever the index covers the group list.

  mysql-test/r/distinct.result@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +3 -3
    Bug#30596: Changed test case. 
    Prior to Bug#16458, These queries use temp table and filesort. The
    bug was that they used a temp table. However, that patch removed
    filesort also, in which case we can no longer gurantee correct ordering.

  mysql-test/r/group_by.result@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +92 -1
    Bug#30596: Correct result
    The test case for IGNORE INDEX FOR GROUP BY gets degraded performance 
    (unneccesary filesort). This is due to Bug#30665, which will be fixed separately.

  mysql-test/r/innodb_mysql.result@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +49 -0
    Bug#30596: Test result

  mysql-test/t/group_by.test@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +44 -0
    Bug#30596: Test case

  sql/sql_select.cc@stripped, 2007-08-28 18:01:26+02:00, mhansson@stripped +14 -0
    Bug#30596: The fix: 
    - replace GROUP BY with ORDER BY unless ORDER BY [NULL|<constant>]
    - make sure to use the keys for GROUP BY in this ORDER BY.

diff -Nrup a/mysql-test/include/mix1.inc b/mysql-test/include/mix1.inc
--- a/mysql-test/include/mix1.inc	2007-08-21 11:27:03 +02:00
+++ b/mysql-test/include/mix1.inc	2007-08-28 18:01:26 +02:00
@@ -969,6 +969,33 @@ ROLLBACK;
 ROLLBACK;
 DROP TABLE t1;
 
+#
+# Bug#30596: GROUP BY optimization gives wrong result order
+#  
+CREATE TABLE t1(
+  a INT, 
+  b INT NOT NULL, 
+  c INT NOT NULL, 
+  d INT, 
+  UNIQUE KEY (c,b)
+) engine=innodb;
+
+INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
+
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
+SELECT c,b,d FROM t1 GROUP BY c,b,d;
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
+SELECT c,b,d FROM t1 ORDER BY c,b,d;
+
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
+SELECT c,b,d FROM t1 GROUP BY c,b;
+EXPLAIN SELECT c,b   FROM t1 GROUP BY c,b;
+SELECT c,b   FROM t1 GROUP BY c,b;
+
+DROP TABLE t1;
+
 --echo End of 5.0 tests
 
 # Fix for BUG#19243 "wrong LAST_INSERT_ID() after ON DUPLICATE KEY
diff -Nrup a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result
--- a/mysql-test/r/distinct.result	2007-08-02 21:45:48 +02:00
+++ b/mysql-test/r/distinct.result	2007-08-28 18:01:26 +02:00
@@ -526,10 +526,10 @@ id	select_type	table	type	possible_keys	
 1	SIMPLE	t1	index	NULL	PRIMARY	4	NULL	3	Using index
 EXPLAIN SELECT a,b FROM t1 GROUP BY a,b;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
 EXPLAIN SELECT DISTINCT a,b FROM t1 GROUP BY a,b;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
 CREATE TABLE t2(a INT, b INT NOT NULL, c INT NOT NULL, d INT, 
 PRIMARY KEY (a,b));
 INSERT INTO t2 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
@@ -554,7 +554,7 @@ id	select_type	table	type	possible_keys	
 CREATE UNIQUE INDEX c_b_unq ON t2 (c,b);
 EXPLAIN SELECT DISTINCT a,b,d FROM t2 GROUP BY c,b,d;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	3	
+1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	3	Using filesort
 DROP TABLE t1,t2;
 create table t1 (id int, dsc varchar(50));
 insert into t1 values (1, "line number one"), (2, "line number two"), (3, "line number three");
diff -Nrup a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result
--- a/mysql-test/r/group_by.result	2007-08-03 17:45:44 +02:00
+++ b/mysql-test/r/group_by.result	2007-08-28 18:01:26 +02:00
@@ -1093,7 +1093,7 @@ id	select_type	table	type	possible_keys	
 1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	144	
 EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR GROUP BY (PRIMARY,i2) GROUP BY a;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	index	NULL	PRIMARY	4	NULL	144	Using index
+1	SIMPLE	t1	index	NULL	PRIMARY	4	NULL	144	Using index; Using filesort
 EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY,i2) ORDER BY a;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	index	NULL	PRIMARY	4	NULL	144	Using index; Using filesort
@@ -1176,3 +1176,94 @@ old	OFF
 SET @@old = off;
 ERROR HY000: Variable 'old' is a read only variable
 DROP TABLE t1, t2;
+CREATE TABLE t1(
+a INT, 
+b INT NOT NULL, 
+c INT NOT NULL, 
+d INT, 
+UNIQUE KEY (c,b)
+);
+INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
+CREATE TABLE t2(
+a INT,
+b INT,
+UNIQUE KEY(a,b)
+);
+INSERT INTO t2 VALUES (NULL, NULL), (NULL, NULL), (NULL, 1), (1, NULL), (1, 1), (1,2);
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
+SELECT c,b,d FROM t1 GROUP BY c,b,d;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	
+SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+c	b	d
+1	1	50
+3	2	40
+3	1	4
+EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
+SELECT c,b,d FROM t1 ORDER BY c,b,d;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
+SELECT c,b,d FROM t1 GROUP BY c,b;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b   FROM t1 GROUP BY c,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	index	NULL	c	8	NULL	3	Using index
+SELECT c,b   FROM t1 GROUP BY c,b;
+c	b
+1	1
+3	1
+3	2
+EXPLAIN SELECT a,b from t2 ORDER BY a,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	index	NULL	a	10	NULL	6	Using index
+SELECT a,b from t2 ORDER BY a,b;
+a	b
+NULL	NULL
+NULL	NULL
+NULL	1
+1	NULL
+1	1
+1	2
+EXPLAIN SELECT a,b from t2 GROUP BY a,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	index	NULL	a	10	NULL	6	Using index
+SELECT a,b from t2 GROUP BY a,b;
+a	b
+NULL	NULL
+NULL	1
+1	NULL
+1	1
+1	2
+EXPLAIN SELECT a from t2 GROUP BY a;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	index	NULL	a	10	NULL	6	Using index
+SELECT a from t2 GROUP BY a;
+a
+NULL
+1
+EXPLAIN SELECT b from t2 GROUP BY b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	index	NULL	a	10	NULL	6	Using index; Using temporary; Using filesort
+SELECT b from t2 GROUP BY b;
+b
+NULL
+1
+2
+DROP TABLE t1;
diff -Nrup a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result
--- a/mysql-test/r/innodb_mysql.result	2007-08-21 11:27:03 +02:00
+++ b/mysql-test/r/innodb_mysql.result	2007-08-28 18:01:26 +02:00
@@ -1141,6 +1141,55 @@ a	b
 ROLLBACK;
 ROLLBACK;
 DROP TABLE t1;
+CREATE TABLE t1(
+a INT, 
+b INT NOT NULL, 
+c INT NOT NULL, 
+d INT, 
+UNIQUE KEY (c,b)
+) engine=innodb;
+INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
+SELECT c,b,d FROM t1 GROUP BY c,b,d;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	
+SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using filesort
+SELECT c,b,d FROM t1 ORDER BY c,b,d;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	index	NULL	c	8	NULL	3	
+SELECT c,b,d FROM t1 GROUP BY c,b;
+c	b	d
+1	1	50
+3	1	4
+3	2	40
+EXPLAIN SELECT c,b   FROM t1 GROUP BY c,b;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	index	NULL	c	8	NULL	3	Using index
+SELECT c,b   FROM t1 GROUP BY c,b;
+c	b
+1	1
+3	1
+3	2
+DROP TABLE t1;
 End of 5.0 tests
 CREATE TABLE `t2` (
 `k` int(11) NOT NULL auto_increment,
diff -Nrup a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test
--- a/mysql-test/t/group_by.test	2007-07-31 08:12:19 +02:00
+++ b/mysql-test/t/group_by.test	2007-08-28 18:01:26 +02:00
@@ -861,3 +861,47 @@ SHOW VARIABLES LIKE 'old';  
 SET @@old = off;  
 
 DROP TABLE t1, t2;
+
+#
+# Bug#30596: GROUP BY optimization gives wrong result order
+#
+CREATE TABLE t1(
+  a INT, 
+  b INT NOT NULL, 
+  c INT NOT NULL, 
+  d INT, 
+  UNIQUE KEY (c,b)
+);
+
+INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
+
+CREATE TABLE t2(
+  a INT,
+  b INT,
+  UNIQUE KEY(a,b)
+);
+
+INSERT INTO t2 VALUES (NULL, NULL), (NULL, NULL), (NULL, 1), (1, NULL), (1, 1), (1,2);
+
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
+SELECT c,b,d FROM t1 GROUP BY c,b,d;
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
+EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
+SELECT c,b,d FROM t1 ORDER BY c,b,d;
+
+EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
+SELECT c,b,d FROM t1 GROUP BY c,b;
+EXPLAIN SELECT c,b   FROM t1 GROUP BY c,b;
+SELECT c,b   FROM t1 GROUP BY c,b;
+
+EXPLAIN SELECT a,b from t2 ORDER BY a,b;
+SELECT a,b from t2 ORDER BY a,b;
+EXPLAIN SELECT a,b from t2 GROUP BY a,b;
+SELECT a,b from t2 GROUP BY a,b;
+EXPLAIN SELECT a from t2 GROUP BY a;
+SELECT a from t2 GROUP BY a;
+EXPLAIN SELECT b from t2 GROUP BY b;
+SELECT b from t2 GROUP BY b;
+
+DROP TABLE t1;
diff -Nrup a/sql/sql_select.cc b/sql/sql_select.cc
--- a/sql/sql_select.cc	2007-08-21 16:46:26 +02:00
+++ b/sql/sql_select.cc	2007-08-28 18:01:26 +02:00
@@ -1042,6 +1042,20 @@ JOIN::optimize()
                                  find_field_in_order_list,
                                  (void *) group_list))
     {
+      /*
+        We have found that grouping can be removed since groups correspond to
+        only one row anyway, but we still have to guarantee correct result
+        order. The line below effectively rewrites the query from GROUP BY
+        <fields> to ORDER BY <fields>. One exception is if skip_sort_order is
+        set (see above), then we can simply skip GROUP BY.
+      */
+      order= skip_sort_order ? 0 : group_list;
+      /*
+        If we have an IGNORE INDEX FOR GROUP BY(fields) clause, this must be 
+        rewritten to IGNORE INDEX FOR ORDER BY(fields).
+      */
+      join_tab->table->keys_in_use_for_order_by=
+        join_tab->table->keys_in_use_for_group_by;
       group_list= 0;
       group= 0;
     }
Thread
bk commit into 5.1 tree (mhansson:1.2571) BUG#30596mhansson28 Aug