Bug #15881: cast problems
The optimizer removes expressions from GROUP BY/DISTINCT if they happen to participate in a <expression> = <const> predicates of the WHERE clause (the idea being that if it's always equal to a constant it can't have multiple values). However for predicates where the expression and the constant item are of different result type this is not valid (e.g. a string column compared to 0). Fixed by additional check of the result types of the expression and the constant and if they differ the expression don't get removed from the group by list.
This commit is contained in:
parent
47c044e418
commit
a63df24a68
@ -607,3 +607,40 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
SELECT DISTINCT a,a FROM t1 WHERE b < 12 ORDER BY a;
|
||||
a a
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a CHAR(1));
|
||||
INSERT INTO t1 VALUES('A'), (0);
|
||||
SELECT a FROM t1 WHERE a=0;
|
||||
a
|
||||
A
|
||||
0
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DOUBLE value: 'A'
|
||||
SELECT DISTINCT a FROM t1 WHERE a=0;
|
||||
a
|
||||
A
|
||||
0
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect DOUBLE value: 'A'
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a DATE);
|
||||
INSERT INTO t1 VALUES ('1972-07-29'), ('1972-02-06');
|
||||
EXPLAIN SELECT (SELECT DISTINCT a FROM t1 WHERE a = '2002-08-03');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
2 SUBQUERY t1 ALL NULL NULL NULL NULL 2 Using where
|
||||
EXPLAIN SELECT (SELECT DISTINCT ADDDATE(a,1) FROM t1
|
||||
WHERE ADDDATE(a,1) = '2002-08-03');
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used
|
||||
2 SUBQUERY t1 ALL NULL NULL NULL NULL 2 Using where; Using temporary
|
||||
CREATE TABLE t2 (a CHAR(5) CHARACTER SET latin1 COLLATE latin1_general_ci);
|
||||
INSERT INTO t2 VALUES (0xf6);
|
||||
INSERT INTO t2 VALUES ('oe');
|
||||
SELECT COUNT(*) FROM (SELECT DISTINCT a FROM t2) dt;
|
||||
COUNT(*)
|
||||
2
|
||||
SELECT COUNT(*) FROM
|
||||
(SELECT DISTINCT a FROM t2 WHERE a='oe' COLLATE latin1_german2_ci) dt;
|
||||
COUNT(*)
|
||||
2
|
||||
DROP TABLE t1, t2;
|
||||
|
@ -504,3 +504,24 @@ DROP TABLE t1;
|
||||
#DROP TABLE t1;
|
||||
#DROP TABLE t2;
|
||||
|
||||
#
|
||||
# Bug #15881: cast problems
|
||||
#
|
||||
CREATE TABLE t1 (a CHAR(1)); INSERT INTO t1 VALUES('A'), (0);
|
||||
SELECT a FROM t1 WHERE a=0;
|
||||
SELECT DISTINCT a FROM t1 WHERE a=0;
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (a DATE);
|
||||
INSERT INTO t1 VALUES ('1972-07-29'), ('1972-02-06');
|
||||
EXPLAIN SELECT (SELECT DISTINCT a FROM t1 WHERE a = '2002-08-03');
|
||||
EXPLAIN SELECT (SELECT DISTINCT ADDDATE(a,1) FROM t1
|
||||
WHERE ADDDATE(a,1) = '2002-08-03');
|
||||
CREATE TABLE t2 (a CHAR(5) CHARACTER SET latin1 COLLATE latin1_general_ci);
|
||||
INSERT INTO t2 VALUES (0xf6);
|
||||
INSERT INTO t2 VALUES ('oe');
|
||||
|
||||
SELECT COUNT(*) FROM (SELECT DISTINCT a FROM t2) dt;
|
||||
SELECT COUNT(*) FROM
|
||||
(SELECT DISTINCT a FROM t2 WHERE a='oe' COLLATE latin1_german2_ci) dt;
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
|
@ -8432,6 +8432,46 @@ remove_eq_conds(THD *thd, COND *cond, Item::cond_result *cond_value)
|
||||
return cond; // Point at next and level
|
||||
}
|
||||
|
||||
/*
|
||||
Check if equality can be used in removing components of GROUP BY/DISTINCT
|
||||
|
||||
SYNOPSIS
|
||||
test_if_equality_guarantees_uniqueness()
|
||||
l the left comparison argument (a field if any)
|
||||
r the right comparison argument (a const of any)
|
||||
|
||||
DESCRIPTION
|
||||
Checks if an equality predicate can be used to take away
|
||||
DISTINCT/GROUP BY because it is known to be true for exactly one
|
||||
distinct value (e.g. <expr> == <const>).
|
||||
Arguments must be of the same type because e.g.
|
||||
<string_field> = <int_const> may match more than 1 distinct value from
|
||||
the column.
|
||||
We must take into consideration and the optimization done for various
|
||||
string constants when compared to dates etc (see Item_int_with_ref) as
|
||||
well as the collation of the arguments.
|
||||
|
||||
RETURN VALUE
|
||||
TRUE can be used
|
||||
FALSE cannot be used
|
||||
*/
|
||||
static bool
|
||||
test_if_equality_guarantees_uniqueness(Item *l, Item *r)
|
||||
{
|
||||
return r->const_item() &&
|
||||
/* elements must be of the same result type */
|
||||
(r->result_type() == l->result_type() ||
|
||||
/* or dates compared to longs */
|
||||
(((l->type() == Item::FIELD_ITEM &&
|
||||
((Item_field *)l)->field->can_be_compared_as_longlong()) ||
|
||||
(l->type() == Item::FUNC_ITEM &&
|
||||
((Item_func *)l)->result_as_longlong())) &&
|
||||
r->result_type() == INT_RESULT))
|
||||
/* and must have the same collation if compared as strings */
|
||||
&& (l->result_type() != STRING_RESULT ||
|
||||
l->collation.collation == r->collation.collation);
|
||||
}
|
||||
|
||||
/*
|
||||
Return 1 if the item is a const value in all the WHERE clause
|
||||
*/
|
||||
@ -8468,7 +8508,7 @@ const_expression_in_where(COND *cond, Item *comp_item, Item **const_item)
|
||||
Item *right_item= ((Item_func*) cond)->arguments()[1];
|
||||
if (left_item->eq(comp_item,1))
|
||||
{
|
||||
if (right_item->const_item())
|
||||
if (test_if_equality_guarantees_uniqueness (left_item, right_item))
|
||||
{
|
||||
if (*const_item)
|
||||
return right_item->eq(*const_item, 1);
|
||||
@ -8478,7 +8518,7 @@ const_expression_in_where(COND *cond, Item *comp_item, Item **const_item)
|
||||
}
|
||||
else if (right_item->eq(comp_item,1))
|
||||
{
|
||||
if (left_item->const_item())
|
||||
if (test_if_equality_guarantees_uniqueness (right_item, left_item))
|
||||
{
|
||||
if (*const_item)
|
||||
return left_item->eq(*const_item, 1);
|
||||
|
Loading…
x
Reference in New Issue
Block a user