From 7bae0de39879cba51aa5bbd73c26bb8b8b467a89 Mon Sep 17 00:00:00 2001
From: "gkodinov@mysql.com" <>
Date: Tue, 9 May 2006 18:13:01 +0300
Subject: [PATCH 1/2] BUG#18068: SELECT DISTINCT (with duplicates and covering
 index)

When converting DISTINCT to GROUP BY where the columns are from the covering
index and they are quoted twice in the SELECT list the optimizer is creating
improper processing sequence. This is because of the fact that the columns
of the covering index are not recognized as such and treated as non-index
columns.

Generally speaking duplicate columns can safely be removed from the GROUP
BY/DISTINCT list because this will not add or remove new rows in the
resulting set. Duplicates can be removed even if they are not consecutive
(as is the case for ORDER BY, where the duplicate columns can be removed
only if they are consecutive).

So we can safely transform "SELECT DISTINCT a,a FROM ... ORDER BY a" to
"SELECT a,a FROM ... GROUP BY a ORDER BY a" instead of
"SELECT a,a FROM .. GROUP BY a,a ORDER BY a". We can even transform
"SELECT DISTINCT a,b,a FROM ... ORDER BY a,b" to
"SELECT a,b,a FROM ... GROUP BY a,b ORDER BY a,b".

The fix to this bug consists of checking for duplicate columns in the SELECT
list when constructing the GROUP BY list in transforming DISTINCT to GROUP
BY and skipping the ones that are already in.
---
 mysql-test/r/distinct.result      | 12 ++++++++++++
 mysql-test/r/group_min_max.result | 22 ++++++++++++++++++++++
 mysql-test/t/distinct.test        | 16 ++++++++++++++++
 mysql-test/t/group_min_max.test   | 16 ++++++++++++++++
 sql/sql_select.cc                 | 11 +++++++++++
 5 files changed, 77 insertions(+)

diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result
index a6ad95570f8..89b17d69f40 100644
--- a/mysql-test/r/distinct.result
+++ b/mysql-test/r/distinct.result
@@ -533,3 +533,15 @@ select count(distinct concat(x,y)) from t1;
 count(distinct concat(x,y))
 2
 drop table t1;
+CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a,b));
+INSERT INTO t1 VALUES (1, 101);
+INSERT INTO t1 SELECT a + 1, a + 101 FROM t1;
+INSERT INTO t1 SELECT a + 2, a + 102 FROM t1;
+INSERT INTO t1 SELECT a + 4, a + 104 FROM t1;
+INSERT INTO t1 SELECT a + 8, a + 108 FROM t1;
+EXPLAIN SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	index	NULL	PRIMARY	8	NULL	16	Using where; Using index
+SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a;
+a	a
+DROP TABLE t1;
diff --git a/mysql-test/r/group_min_max.result b/mysql-test/r/group_min_max.result
index 6370f7699b3..f9b55cc6a7b 100644
--- a/mysql-test/r/group_min_max.result
+++ b/mysql-test/r/group_min_max.result
@@ -2116,3 +2116,25 @@ COUNT(DISTINCT a)
 1
 DROP TABLE t1;
 DROP PROCEDURE a;
+CREATE TABLE t1 (a varchar(64) NOT NULL default '', PRIMARY KEY(a));
+INSERT INTO t1 (a) VALUES 
+(''), ('CENTRAL'), ('EASTERN'), ('GREATER LONDON'),
+('NORTH CENTRAL'), ('NORTH EAST'), ('NORTH WEST'), ('SCOTLAND'),
+('SOUTH EAST'), ('SOUTH WEST'), ('WESTERN');
+EXPLAIN SELECT DISTINCT a,a FROM t1 ORDER BY a;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	range	NULL	PRIMARY	66	NULL	12	Using index for group-by
+SELECT DISTINCT a,a FROM t1 ORDER BY a;
+a	a
+	
+CENTRAL	CENTRAL
+EASTERN	EASTERN
+GREATER LONDON	GREATER LONDON
+NORTH CENTRAL	NORTH CENTRAL
+NORTH EAST	NORTH EAST
+NORTH WEST	NORTH WEST
+SCOTLAND	SCOTLAND
+SOUTH EAST	SOUTH EAST
+SOUTH WEST	SOUTH WEST
+WESTERN	WESTERN
+DROP TABLE t1;
diff --git a/mysql-test/t/distinct.test b/mysql-test/t/distinct.test
index 45bd0c7a51c..09f07c2852f 100644
--- a/mysql-test/t/distinct.test
+++ b/mysql-test/t/distinct.test
@@ -382,3 +382,19 @@ INSERT INTO t1 VALUES
 select count(distinct x,y) from t1;
 select count(distinct concat(x,y)) from t1;
 drop table t1;
+
+#
+# Bug #18068: SELECT DISTINCT
+#
+CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a,b));
+
+INSERT INTO t1 VALUES (1, 101);
+INSERT INTO t1 SELECT a + 1, a + 101 FROM t1;
+INSERT INTO t1 SELECT a + 2, a + 102 FROM t1;
+INSERT INTO t1 SELECT a + 4, a + 104 FROM t1;
+INSERT INTO t1 SELECT a + 8, a + 108 FROM t1;
+
+EXPLAIN SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a;
+SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a;
+
+DROP TABLE t1;
diff --git a/mysql-test/t/group_min_max.test b/mysql-test/t/group_min_max.test
index bff07366ec2..d9836ccc8df 100644
--- a/mysql-test/t/group_min_max.test
+++ b/mysql-test/t/group_min_max.test
@@ -782,3 +782,19 @@ SELECT COUNT(DISTINCT a) FROM t1 WHERE a=0;
 
 DROP TABLE t1;
 DROP PROCEDURE a;
+
+#
+# Bug #18068: SELECT DISTINCT
+#
+
+CREATE TABLE t1 (a varchar(64) NOT NULL default '', PRIMARY KEY(a));
+
+INSERT INTO t1 (a) VALUES 
+  (''), ('CENTRAL'), ('EASTERN'), ('GREATER LONDON'),
+  ('NORTH CENTRAL'), ('NORTH EAST'), ('NORTH WEST'), ('SCOTLAND'),
+  ('SOUTH EAST'), ('SOUTH WEST'), ('WESTERN');
+
+EXPLAIN SELECT DISTINCT a,a FROM t1 ORDER BY a;  
+SELECT DISTINCT a,a FROM t1 ORDER BY a;  
+
+DROP TABLE t1;
diff --git a/sql/sql_select.cc b/sql/sql_select.cc
index 3a616c28755..9a896fa55d2 100644
--- a/sql/sql_select.cc
+++ b/sql/sql_select.cc
@@ -12698,6 +12698,17 @@ create_distinct_group(THD *thd, Item **ref_pointer_array,
   {
     if (!item->const_item() && !item->with_sum_func && !item->marker)
     {
+      /* 
+        Don't put duplicate columns from the SELECT list into the 
+        GROUP BY list.
+      */
+      ORDER *ord_iter;
+      for (ord_iter= group; ord_iter; ord_iter= ord_iter->next)
+        if ((*ord_iter->item)->eq(item, 1))
+          break;
+      if (ord_iter)
+        continue;
+      
       ORDER *ord=(ORDER*) thd->calloc(sizeof(ORDER));
       if (!ord)
 	return 0;

From c4f3410449a3220134dbf9694e0997e7158bf037 Mon Sep 17 00:00:00 2001
From: "serg@sergbook.mysql.com" <>
Date: Tue, 9 May 2006 11:14:31 -0400
Subject: [PATCH 2/2] results fixed

---
 mysql-test/r/ctype_utf8.result |  8 ++++----
 mysql-test/r/heap.result       |  6 +++---
 mysql-test/r/show_check.result | 14 +++++++-------
 mysql-test/r/sql_mode.result   |  6 +++---
 4 files changed, 17 insertions(+), 17 deletions(-)

diff --git a/mysql-test/r/ctype_utf8.result b/mysql-test/r/ctype_utf8.result
index 44f6945238c..1246c6f3d5d 100644
--- a/mysql-test/r/ctype_utf8.result
+++ b/mysql-test/r/ctype_utf8.result
@@ -412,7 +412,7 @@ show create table t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `c` char(10) CHARACTER SET utf8 DEFAULT NULL,
-  UNIQUE KEY `a` USING HASH (`c`(1))
+  UNIQUE KEY `a` (`c`(1)) USING HASH
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 insert into t1 values ('a'),('b'),('c'),('d'),('e'),('f');
 insert into t1 values ('aa');
@@ -448,7 +448,7 @@ show create table t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `c` char(10) CHARACTER SET utf8 DEFAULT NULL,
-  UNIQUE KEY `a` USING BTREE (`c`(1))
+  UNIQUE KEY `a` (`c`(1)) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 insert into t1 values ('a'),('b'),('c'),('d'),('e'),('f');
 insert into t1 values ('aa');
@@ -570,7 +570,7 @@ show create table t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `c` char(10) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
-  UNIQUE KEY `a` USING HASH (`c`(1))
+  UNIQUE KEY `a` (`c`(1)) USING HASH
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 insert into t1 values ('a'),('b'),('c'),('d'),('e'),('f');
 insert into t1 values ('aa');
@@ -606,7 +606,7 @@ show create table t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `c` char(10) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL,
-  UNIQUE KEY `a` USING BTREE (`c`(1))
+  UNIQUE KEY `a` (`c`(1)) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 insert into t1 values ('a'),('b'),('c'),('d'),('e'),('f');
 insert into t1 values ('aa');
diff --git a/mysql-test/r/heap.result b/mysql-test/r/heap.result
index 5a2d07db5e6..2c0e8123667 100644
--- a/mysql-test/r/heap.result
+++ b/mysql-test/r/heap.result
@@ -556,9 +556,9 @@ t1	CREATE TABLE `t1` (
   `v` varchar(10) DEFAULT NULL,
   `c` char(10) DEFAULT NULL,
   `t` varchar(50) DEFAULT NULL,
-  KEY `v` USING BTREE (`v`),
-  KEY `c` USING BTREE (`c`),
-  KEY `t` USING BTREE (`t`(10))
+  KEY `v` (`v`) USING BTREE,
+  KEY `c` (`c`) USING BTREE,
+  KEY `t` (`t`(10)) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 select count(*) from t1;
 count(*)
diff --git a/mysql-test/r/show_check.result b/mysql-test/r/show_check.result
index a8af5c59b81..5dcb8b2afd6 100644
--- a/mysql-test/r/show_check.result
+++ b/mysql-test/r/show_check.result
@@ -460,7 +460,7 @@ SHOW CREATE TABLE t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `i` int(11) DEFAULT NULL,
-  KEY `i` USING HASH (`i`)
+  KEY `i` (`i`) USING HASH
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 DROP TABLE t1;
 CREATE TABLE t1 (i int, KEY USING BTREE (i)) ENGINE=MEMORY;
@@ -468,7 +468,7 @@ SHOW CREATE TABLE t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `i` int(11) DEFAULT NULL,
-  KEY `i` USING BTREE (`i`)
+  KEY `i` (`i`) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 DROP TABLE t1;
 CREATE TABLE t1 (i int, KEY (i)) ENGINE=MyISAM;
@@ -484,7 +484,7 @@ SHOW CREATE TABLE t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `i` int(11) DEFAULT NULL,
-  KEY `i` USING BTREE (`i`)
+  KEY `i` (`i`) USING BTREE
 ) ENGINE=MyISAM DEFAULT CHARSET=latin1
 DROP TABLE t1;
 CREATE TABLE t1 (i int, KEY (i)) ENGINE=MyISAM;
@@ -507,14 +507,14 @@ SHOW CREATE TABLE t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `i` int(11) DEFAULT NULL,
-  KEY `i` USING BTREE (`i`)
+  KEY `i` (`i`) USING BTREE
 ) ENGINE=MyISAM DEFAULT CHARSET=latin1
 ALTER TABLE t1 ENGINE=MEMORY;
 SHOW CREATE TABLE t1;
 Table	Create Table
 t1	CREATE TABLE `t1` (
   `i` int(11) DEFAULT NULL,
-  KEY `i` USING BTREE (`i`)
+  KEY `i` (`i`) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1
 DROP TABLE t1;
 CREATE TABLE t1(
@@ -549,8 +549,8 @@ Table	Create Table
 t1	CREATE TABLE `t1` (
   `c1` int(11) NOT NULL,
   `c2` int(11) NOT NULL,
-  PRIMARY KEY USING HASH (`c1`),
-  KEY `c2` USING BTREE (`c2`)
+  PRIMARY KEY (`c1`) USING HASH,
+  KEY `c2` (`c2`) USING BTREE
 ) ENGINE=MyISAM DEFAULT CHARSET=latin1
 DROP TABLE t1;
 flush tables;
diff --git a/mysql-test/r/sql_mode.result b/mysql-test/r/sql_mode.result
index 31b67529f8d..3466282a4b1 100644
--- a/mysql-test/r/sql_mode.result
+++ b/mysql-test/r/sql_mode.result
@@ -18,7 +18,7 @@ t1	CREATE TABLE `t1` (
   `pseudo` varchar(35) CHARACTER SET latin2 NOT NULL DEFAULT '',
   `email` varchar(60) CHARACTER SET latin2 NOT NULL DEFAULT '',
   PRIMARY KEY (`a`),
-  UNIQUE KEY `email` USING BTREE (`email`)
+  UNIQUE KEY `email` (`email`) USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1 ROW_FORMAT=DYNAMIC
 set @@sql_mode="ansi_quotes";
 show variables like 'sql_mode';
@@ -31,7 +31,7 @@ t1	CREATE TABLE "t1" (
   "pseudo" varchar(35) CHARACTER SET latin2 NOT NULL DEFAULT '',
   "email" varchar(60) CHARACTER SET latin2 NOT NULL DEFAULT '',
   PRIMARY KEY ("a"),
-  UNIQUE KEY "email" USING BTREE ("email")
+  UNIQUE KEY "email" ("email") USING BTREE
 ) ENGINE=MEMORY DEFAULT CHARSET=latin1 ROW_FORMAT=DYNAMIC
 set @@sql_mode="no_table_options";
 show variables like 'sql_mode';
@@ -44,7 +44,7 @@ t1	CREATE TABLE `t1` (
   `pseudo` varchar(35) CHARACTER SET latin2 NOT NULL DEFAULT '',
   `email` varchar(60) CHARACTER SET latin2 NOT NULL DEFAULT '',
   PRIMARY KEY (`a`),
-  UNIQUE KEY `email` USING BTREE (`email`)
+  UNIQUE KEY `email` (`email`) USING BTREE
 )
 set @@sql_mode="no_key_options";
 show variables like 'sql_mode';