Details
-
Bug
-
Status: Closed (View Workflow)
-
Major
-
Resolution: Fixed
-
10.0(EOL), 10.1(EOL)
Description
This script:
DROP TABLE IF EXISTS t1;
|
CREATE TABLE t1 (a VARCHAR(10)) ENGINE=MyISAM;
|
INSERT INTO t1 VALUES ('a'),('A');
|
SELECT * FROM t1 WHERE a='a' AND a <> _latin1'A' COLLATE latin1_bin;
|
correctly returns one row:
+------+
|
| a |
|
+------+
|
| a |
|
+------+
|
If I rewrite the query to use a derived table:
DROP TABLE IF EXISTS t1;
|
CREATE TABLE t1 (a VARCHAR(10)) ENGINE=MyISAM;
|
INSERT INTO t1 VALUES ('a'),('A');
|
SELECT * FROM (SELECT * FROM t1) AS table1 WHERE a='a' AND a <> _latin1'A' COLLATE latin1_bin;
|
it erroneously returns two rows:
+------+
|
| a |
|
+------+
|
| a |
|
| A |
|
+------+
|
The problems happens because Item_direct_view_ref has cmp_context correctly set to STRING_RESULT, while its referenced field has cmp_context set to IMPOSSIBLE_RESULT. This makes equal field propagation replace the field to constant in <>.
The same bug causes ENUM column to return bad results:
DROP TABLE IF EXISTS t1;
|
CREATE TABLE t1 (a ENUM('5','6')) ENGINE=MyISAM;
|
INSERT INTO t1 VALUES ('5'),('6');
|
SELECT * FROM (SELECT * FROM t1) AS table1 WHERE a='5';
|
SELECT * FROM (SELECT * FROM t1) AS table1 WHERE a=1;
|
SELECT * FROM (SELECT * FROM t1) AS table1 WHERE a='5' AND a=1;
|
The first and the second query correctly return one row, equal to '5'. The third query erroneously returns empty set.
The same problem is also demonstrated in this script:
DROP TABLE IF EXISTS t1;
|
DROP VIEW IF EXISTS v1;
|
CREATE TABLE t1 (a varchar(10) character set cp1251 collate cp1251_ukrainian_ci, KEY (a)) ;
|
INSERT INTO t1 VALUES ('DD'), ('ZZ'), ('ZZ'), ('KK'), ('FF'), ('HH'),('MM'),('`1');
|
CREATE VIEW v1 AS SELECT * FROM t1;
|
SELECT * FROM t1 WHERE a <> 0 AND a = ' 1';
|
SELECT * FROM v1 WHERE a <> 0 AND a = ' 1';
|
The first SELECT returns empty set, the second SELECT returns one row.
The same problem is repeatable in this script:
DROP TABLE IF EXISTS t1;
|
CREATE TABLE t1 (a ENUM('5','6'));
|
INSERT INTO t1 VALUES ('5'),('6');
|
DROP VIEW IF EXISTS v1;
|
CREATE VIEW v1 AS SELECT * FROM t1;
|
SELECT * FROM t1 WHERE a='5' AND a<2;
|
SELECT * FROM v1 WHERE a='5' AND a<2;
|
The first SELECT correctly return one row, the second SELECT erroneously returns no rows.