MDEV-6978 Bad results with join comparing case insensitive VARCHAR/ENUM/SET
expression to a _bin ENUM column
This commit is contained in:
parent
b52d4d0076
commit
55dd89e919
@ -1908,6 +1908,90 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE t1, t2;
|
||||
#
|
||||
# MDEV-6978 Bad results with join comparing case insensitive VARCHAR/ENUM/SET expression to a _bin ENUM column
|
||||
#
|
||||
CREATE TABLE t1 (c1 ENUM('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
CREATE TABLE t1 (c1 SET('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
CREATE TABLE t1 (c1 VARCHAR(10) CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
#
|
||||
# MDEV-6991 GROUP_MIN_MAX optimization is erroneously applied in some cases
|
||||
#
|
||||
CREATE TABLE t1 (id INT NOT NULL, a ENUM('04','03','02','01')) ENGINE=MyISAM;
|
||||
|
@ -143,5 +143,89 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE t1, t2;
|
||||
#
|
||||
# MDEV-6978 Bad results with join comparing case insensitive VARCHAR/ENUM/SET expression to a _bin ENUM column
|
||||
#
|
||||
CREATE TABLE t1 (c1 ENUM('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
CREATE TABLE t1 (c1 SET('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
CREATE TABLE t1 (c1 VARCHAR(10) CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
c1
|
||||
a
|
||||
a
|
||||
# t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t2 index PRIMARY PRIMARY 1 NULL 2 Using where; Using index
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
#
|
||||
# End of 10.0 tests
|
||||
#
|
||||
|
@ -260,6 +260,48 @@ SELECT t1.* FROM t1 LEFT JOIN t2 USING (c1);
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 USING (c1);
|
||||
DROP TABLE t1, t2;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-6978 Bad results with join comparing case insensitive VARCHAR/ENUM/SET expression to a _bin ENUM column
|
||||
--echo #
|
||||
CREATE TABLE t1 (c1 ENUM('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
CREATE TABLE t1 (c1 SET('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
CREATE TABLE t1 (c1 VARCHAR(10) CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 ENUM('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-6991 GROUP_MIN_MAX optimization is erroneously applied in some cases
|
||||
--echo #
|
||||
|
@ -119,6 +119,48 @@ SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1=t2.c1;
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1=t2.c1;
|
||||
DROP TABLE t1, t2;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-6978 Bad results with join comparing case insensitive VARCHAR/ENUM/SET expression to a _bin ENUM column
|
||||
--echo #
|
||||
CREATE TABLE t1 (c1 ENUM('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
CREATE TABLE t1 (c1 SET('a') CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
CREATE TABLE t1 (c1 VARCHAR(10) CHARACTER SET latin1 PRIMARY KEY);
|
||||
INSERT INTO t1 VALUES ('a');
|
||||
CREATE TABLE t2 (c1 SET('a','A') CHARACTER SET latin1 COLLATE latin1_bin);
|
||||
INSERT INTO t2 VALUES ('a'),('A');
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
ALTER TABLE t2 ADD PRIMARY KEY(c1);
|
||||
SELECT t1.* FROM t1 JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
--echo # t2 should NOT be eliminated
|
||||
EXPLAIN SELECT t1.* FROM t1 LEFT JOIN t2 ON t1.c1 COLLATE latin1_swedish_ci=t2.c1;
|
||||
DROP TABLE IF EXISTS t1,t2;
|
||||
|
||||
--echo #
|
||||
--echo # End of 10.0 tests
|
||||
--echo #
|
||||
|
@ -1501,7 +1501,9 @@ void check_equality(Dep_analysis_context *ctx, Dep_module_expr **eq_mod,
|
||||
We can't assume there's a functional dependency if the effective
|
||||
collation of the operation differ from the field collation.
|
||||
*/
|
||||
if (field->cmp_type() == STRING_RESULT &&
|
||||
if ((field->cmp_type() == STRING_RESULT ||
|
||||
field->real_type() == MYSQL_TYPE_ENUM ||
|
||||
field->real_type() == MYSQL_TYPE_SET) &&
|
||||
field->charset() != cond->compare_collation())
|
||||
return;
|
||||
}
|
||||
|
@ -4444,6 +4444,28 @@ add_key_field(JOIN *join,
|
||||
field->cmp_type() != TIME_RESULT)
|
||||
return;
|
||||
|
||||
/*
|
||||
Note, for ITEM/ENUM columns:
|
||||
- field->cmp_type() returns INT_RESULT
|
||||
- field->result_type() returns STRING_RESULT
|
||||
- field->type() returns MYSQL_TYPE_STRING
|
||||
|
||||
Using field->real_type() to detect ENUM/SET,
|
||||
as they need a special handling:
|
||||
- Conditions between a ENUM/SET filter and a TIME expression
|
||||
cannot be optimized. They were filtered out in the previous if block.
|
||||
- It's Ok to use ref access for an ENUM/SET field compared to an
|
||||
INT/REAL/DECIMAL expression.
|
||||
- It's Ok to use ref for an ENUM/SET field compared to a STRING
|
||||
expression if the collation of the field and the collation of
|
||||
the condition match.
|
||||
*/
|
||||
if ((field->real_type() == MYSQL_TYPE_ENUM ||
|
||||
field->real_type() == MYSQL_TYPE_SET) &&
|
||||
(*value)->cmp_type () == STRING_RESULT &&
|
||||
field->charset() != cond->compare_collation())
|
||||
return;
|
||||
|
||||
/*
|
||||
We can't use indexes when comparing a string index to a
|
||||
number or two strings if the effective collation
|
||||
|
Loading…
x
Reference in New Issue
Block a user