From 6ae94723ca07c0938d25105d6180c96bc6abeaae Mon Sep 17 00:00:00 2001
From: unknown <igor@olga.mysql.com>
Date: Wed, 14 Feb 2007 22:06:41 -0800
Subject: [PATCH] Fixed bug #25971: indexes on text columns were ignored when
 ref accesses were evaluated. According to the new rules for string comparison
 partial indexes on text columns can be used in the same cases when partial
 indexes on varchar columns can be used.

mysql-test/r/endspace.result:
  Adjusted results after the fix for bug #25971.
mysql-test/r/innodb.result:
  Adjusted results after the fix for bug #25971.
mysql-test/r/myisam.result:
  Adjusted results after the fix for bug #25971.
mysql-test/r/select.result:
  Added a test case for bug #25971.
mysql-test/r/type_blob.result:
  Adjusted results after the fix for bug #25971.
mysql-test/t/select.test:
  Added a test case for bug #25971.
---
 mysql-test/r/endspace.result  |   2 +-
 mysql-test/r/innodb.result    |   2 +-
 mysql-test/r/myisam.result    |   2 +-
 mysql-test/r/select.result    | 148 ++++++++++++++++++++++++++++++++++
 mysql-test/r/type_blob.result |   4 +-
 mysql-test/t/select.test      |  46 +++++++++++
 sql/sql_select.cc             |   8 +-
 7 files changed, 200 insertions(+), 12 deletions(-)

diff --git a/mysql-test/r/endspace.result b/mysql-test/r/endspace.result
index 0e68418a80..003ee7ffd5 100644
--- a/mysql-test/r/endspace.result
+++ b/mysql-test/r/endspace.result
@@ -98,7 +98,7 @@ concat('|', text1, '|')
 |teststring |
 explain select concat('|', text1, '|') from t1 where text1='teststring ';
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	range	key1	key1	22	NULL	2	Using where
+1	SIMPLE	t1	ref	key1	key1	22	const	2	Using where
 select concat('|', text1, '|') from t1 where text1 like 'teststring_%';
 concat('|', text1, '|')
 |teststring	|
diff --git a/mysql-test/r/innodb.result b/mysql-test/r/innodb.result
index 38d71ac7a4..496c8aa90d 100644
--- a/mysql-test/r/innodb.result
+++ b/mysql-test/r/innodb.result
@@ -1991,7 +1991,7 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	ref	c	c	11	const	#	Using where; Using index
 explain select count(*) from t1 where t='a  ';
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	range	t	t	13	NULL	#	Using where
+1	SIMPLE	t1	ref	t	t	13	const	#	Using where
 explain select count(*) from t1 where v like 'a%';
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	range	v	v	13	NULL	#	Using where; Using index
diff --git a/mysql-test/r/myisam.result b/mysql-test/r/myisam.result
index 0f6e0ad537..83359048a8 100644
--- a/mysql-test/r/myisam.result
+++ b/mysql-test/r/myisam.result
@@ -1071,7 +1071,7 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	ref	c	c	11	const	#	Using where; Using index
 explain select count(*) from t1 where t='a  ';
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	range	t	t	13	NULL	#	Using where
+1	SIMPLE	t1	ref	t	t	13	const	#	Using where
 explain select count(*) from t1 where v like 'a%';
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	range	v	v	13	NULL	#	Using where; Using index
diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result
index f50f4859d4..c3132a1b5f 100644
--- a/mysql-test/r/select.result
+++ b/mysql-test/r/select.result
@@ -3785,4 +3785,152 @@ case when 1 then cast(1111111111111111111 as unsigned) else 1 end c,
 coalesce(cast(1111111111111111111 as unsigned), 1) co;
 i	c	co
 1111111111111111111	1111111111111111111	1111111111111111111
+CREATE TABLE t1 (name varchar(255));
+CREATE TABLE t2 (name varchar(255), n int, KEY (name(3)));
+INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa  '), ('aa');
+INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc   ',3);
+INSERT INTO t2 VALUES (concat('cc ', 0x06), 4);
+INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7);
+SELECT * FROM t2;
+name	n
+bb	1
+aa	2
+cc   	3
+cc 	4
+cc	5
+bb 	6
+cc 	7
+SELECT * FROM t2 ORDER BY name;
+name	n
+aa	2
+bb	1
+bb 	6
+cc 	4
+cc   	3
+cc	5
+cc 	7
+SELECT name, LENGTH(name), n FROM t2 ORDER BY name;
+name	LENGTH(name)	n
+aa	2	2
+bb	2	1
+bb 	3	6
+cc 	4	4
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc ';
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	ref	name	name	6	const	3	Using where
+SELECT name, LENGTH(name), n FROM t2 WHERE name='cc ';
+name	LENGTH(name)	n
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	range	name	name	6	NULL	3	Using where
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+name	LENGTH(name)	n
+cc   	5	3
+cc 	4	4
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	range	name	name	6	NULL	3	Using where; Using filesort
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+name	LENGTH(name)	n
+cc 	4	4
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	5	
+1	SIMPLE	t2	ref	name	name	6	test.t1.name	2	
+SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+name	name	n
+ccc	NULL	NULL
+bb	bb	1
+bb	bb 	6
+cc 	cc   	3
+cc 	cc	5
+cc 	cc 	7
+aa  	aa	2
+aa	aa	2
+DROP TABLE t1,t2;
+CREATE TABLE t1 (name text);
+CREATE TABLE t2 (name text, n int, KEY (name(3)));
+INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa  '), ('aa');
+INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc   ',3);
+INSERT INTO t2 VALUES (concat('cc ', 0x06), 4);
+INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7);
+SELECT * FROM t2;
+name	n
+bb	1
+aa	2
+cc   	3
+cc 	4
+cc	5
+bb 	6
+cc 	7
+SELECT * FROM t2 ORDER BY name;
+name	n
+aa	2
+bb	1
+bb 	6
+cc 	4
+cc   	3
+cc	5
+cc 	7
+SELECT name, LENGTH(name), n FROM t2 ORDER BY name;
+name	LENGTH(name)	n
+aa	2	2
+bb	2	1
+bb 	3	6
+cc 	4	4
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc ';
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	ref	name	name	6	const	3	Using where
+SELECT name, LENGTH(name), n FROM t2 WHERE name='cc ';
+name	LENGTH(name)	n
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	range	name	name	6	NULL	3	Using where
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+name	LENGTH(name)	n
+cc   	5	3
+cc 	4	4
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t2	range	name	name	6	NULL	3	Using where; Using filesort
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+name	LENGTH(name)	n
+cc 	4	4
+cc   	5	3
+cc	2	5
+cc 	3	7
+EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	5	
+1	SIMPLE	t2	ref	name	name	6	test.t1.name	2	
+SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+name	name	n
+ccc	NULL	NULL
+bb	bb	1
+bb	bb 	6
+cc 	cc   	3
+cc 	cc	5
+cc 	cc 	7
+aa  	aa	2
+aa	aa	2
+DROP TABLE t1,t2;
 End of 5.0 tests
diff --git a/mysql-test/r/type_blob.result b/mysql-test/r/type_blob.result
index 73b67a2241..b28f404c64 100644
--- a/mysql-test/r/type_blob.result
+++ b/mysql-test/r/type_blob.result
@@ -610,12 +610,12 @@ create table t1 (id integer primary key auto_increment, txt text, index txt_inde
 insert into t1 (txt) values ('Chevy'), ('Chevy '), (NULL);
 select * from t1 where txt='Chevy' or txt is NULL;
 id	txt
-3	NULL
 1	Chevy
 2	Chevy 
+3	NULL
 explain select * from t1 where txt='Chevy' or txt is NULL;
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
-1	SIMPLE	t1	range	txt_index	txt_index	23	NULL	2	Using where
+1	SIMPLE	t1	ref_or_null	txt_index	txt_index	23	const	2	Using where
 select * from t1 where txt='Chevy ';
 id	txt
 1	Chevy
diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test
index c473781413..ea5fadb2e1 100644
--- a/mysql-test/t/select.test
+++ b/mysql-test/t/select.test
@@ -3253,4 +3253,50 @@ select
   case when 1 then cast(1111111111111111111 as unsigned) else 1 end c,
   coalesce(cast(1111111111111111111 as unsigned), 1) co;
 
+#
+# Bug #22971: indexes on text columns are ignored for ref accesses 
+#
+
+CREATE TABLE t1 (name varchar(255));
+CREATE TABLE t2 (name varchar(255), n int, KEY (name(3)));
+INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa  '), ('aa');
+INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc   ',3);
+INSERT INTO t2 VALUES (concat('cc ', 0x06), 4);
+INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7);
+SELECT * FROM t2;
+SELECT * FROM t2 ORDER BY name;
+SELECT name, LENGTH(name), n FROM t2 ORDER BY name;
+
+EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; 
+SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; 
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+
+DROP TABLE t1,t2;
+
+CREATE TABLE t1 (name text);
+CREATE TABLE t2 (name text, n int, KEY (name(3)));
+INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa  '), ('aa');
+INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc   ',3);
+INSERT INTO t2 VALUES (concat('cc ', 0x06), 4);
+INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7);
+SELECT * FROM t2;
+SELECT * FROM t2 ORDER BY name;
+SELECT name, LENGTH(name), n FROM t2 ORDER BY name;
+
+EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; 
+SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; 
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%';
+EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name;
+EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name;
+
+DROP TABLE t1,t2;
+
 --echo End of 5.0 tests
diff --git a/sql/sql_select.cc b/sql/sql_select.cc
index ed10882890..93f5092fd6 100644
--- a/sql/sql_select.cc
+++ b/sql/sql_select.cc
@@ -2854,15 +2854,9 @@ add_key_field(KEY_FIELD **key_fields,uint and_level, Item_func *cond,
           /*
             We can't use indexes if the effective collation
             of the operation differ from the field collation.
-
-            We also cannot use index on a text column, as the column may
-            contain 'x' 'x\t' 'x ' and 'read_next_same' will stop after
-            'x' when searching for WHERE col='x '
           */
           if (field->cmp_type() == STRING_RESULT &&
-              (((Field_str*)field)->charset() != cond->compare_collation() ||
-               ((*value)->type() != Item::NULL_ITEM &&
-                (field->flags & BLOB_FLAG) && !field->binary())))
+              ((Field_str*)field)->charset() != cond->compare_collation())
             return;
         }
       }
-- 
2.30.9