Commit c1bbfb2b authored by unknown's avatar unknown

Fixed bug #18360: Type aggregation for IN and CASE may lead to a wrong

result

The IN function aggregates result types of all expressions. It uses that 
type in comparison of left expression and expressions in right part. 
This approach works in most cases. But let's consider the case when the
right part contains both strings and integers. In that case this approach may
cause wrong results because all strings which do not start with a digit are
evaluated as 0.
CASE uses the same approach when a CASE expression is given thus it's also
affected.

The idea behind this fix is to make IN function to compare expressions with
different result types differently. For example a string in the left
part will be compared as string with strings specified in right part and
will be converted to real for comparison to int or real items in the right
part.

A new function called collect_cmp_types() is added. It collects different
result types for comparison of first item in the provided list with each 
other item in the list. 

The Item_func_in class now can refer up to 5 cmp_item objects: 1 for each
result type for comparison purposes. cmp_item objects are allocated according
to found result types. The comparison of the left expression with any
right part expression is now based only on result types of these expressions.

The Item_func_case class is modified in the similar way when a CASE
expression is specified. Now it can allocate up to 5 cmp_item objects
to compare CASE expression with WHEN expressions of different types.
The comparison of the CASE expression with any WHEN expression now based only 
on result types of these expressions.



sql/item.cc:
  Cleaned up an outdated comment.
sql/item_cmpfunc.cc:
      Fixed bug #18360: Type aggregation for IN and CASE may lead to a wrong result
      A new function called collect_cmp_types() is added. It collects different
      result types for comparison of first item in the provided list with each 
      other item in the list. 
      The Item_func_in class now can refer up to 5 cmp_item objects: 1 for each
      result type for comparison purposes. cmp_item objects are allocated according
      to found result types. The comparison of the left expression with any
      right part expression is now based only on result types of these expressions.
      The Item_func_case class is modified in the similar way when a CASE
      expression is specified. Now it can allocate up to 5 cmp_item objects
      to compare CASE expression with WHEN expressions of different types.
      The comparison of the CASE expression with any WHEN expression now based only 
      on result types of these expressions.
sql/item_cmpfunc.h:
      Fixed bug#18360: Type aggregation for IN and CASE may lead to a wrong result
      The Item_func_in class now can refer up to 5 cmp_item objects.
      The Item_func_case class is modified in the similar way.
sql/opt_range.cc:
      Fixed bug #18360: Type aggregation for IN and CASE may lead to a wrong
      resultSmall code changes due to changes in Item_func_in class.
mysql-test/t/view.test:
  Added a test comment
mysql-test/t/func_in.test:
  Added a test case for bug#18360: Type aggregation for IN and CASE may lead to a wrong
  result
mysql-test/r/func_in.result:
  Added a test case for bug#18360: Type aggregation for IN and CASE may lead to a wrong
  result
parent d752b1a8
......@@ -343,3 +343,71 @@ some_id
1
2
drop table t1;
create table t1(f1 char(1));
insert into t1 values ('a'),('b'),('1');
select f1 from t1 where f1 in ('a',1);
f1
a
1
select f1, case f1 when 'a' then '+' when 1 then '-' end from t1;
f1 case f1 when 'a' then '+' when 1 then '-' end
a +
b NULL
1 -
create index t1f1_idx on t1(f1);
select f1 from t1 where f1 in ('a',1);
f1
1
a
explain select f1 from t1 where f1 in ('a',1);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL t1f1_idx 2 NULL 3 Using where; Using index
select f1 from t1 where f1 in ('a','b');
f1
a
b
explain select f1 from t1 where f1 in ('a','b');
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index t1f1_idx t1f1_idx 2 NULL 3 Using where; Using index
select f1 from t1 where f1 in (2,1);
f1
1
explain select f1 from t1 where f1 in (2,1);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index t1f1_idx t1f1_idx 2 NULL 3 Using where; Using index
create table t2(f2 int, index t2f2(f2));
insert into t2 values(0),(1),(2);
select f2 from t2 where f2 in ('a',2);
f2
0
2
Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'a'
Warning 1292 Truncated incorrect DOUBLE value: 'a'
Warning 1292 Truncated incorrect DOUBLE value: 'a'
explain select f2 from t2 where f2 in ('a',2);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index NULL t2f2 5 NULL 3 Using where; Using index
select f2 from t2 where f2 in ('a','b');
f2
0
Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'a'
Warning 1292 Truncated incorrect DOUBLE value: 'b'
explain select f2 from t2 where f2 in ('a','b');
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index t2f2 t2f2 5 NULL 3 Using where; Using index
Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'a'
Warning 1292 Truncated incorrect DOUBLE value: 'b'
select f2 from t2 where f2 in (1,'b');
f2
0
1
Warnings:
Warning 1292 Truncated incorrect DOUBLE value: 'b'
Warning 1292 Truncated incorrect DOUBLE value: 'b'
explain select f2 from t2 where f2 in (1,'b');
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index NULL t2f2 5 NULL 3 Using where; Using index
drop table t1, t2;
......@@ -232,3 +232,27 @@ select some_id from t1 where some_id not in(2,-1);
select some_id from t1 where some_id not in(-4,-1,-4);
select some_id from t1 where some_id not in(-4,-1,3423534,2342342);
drop table t1;
#
# Bug#18360: Type aggregation for IN and CASE may lead to a wrong result
#
create table t1(f1 char(1));
insert into t1 values ('a'),('b'),('1');
select f1 from t1 where f1 in ('a',1);
select f1, case f1 when 'a' then '+' when 1 then '-' end from t1;
create index t1f1_idx on t1(f1);
select f1 from t1 where f1 in ('a',1);
explain select f1 from t1 where f1 in ('a',1);
select f1 from t1 where f1 in ('a','b');
explain select f1 from t1 where f1 in ('a','b');
select f1 from t1 where f1 in (2,1);
explain select f1 from t1 where f1 in (2,1);
create table t2(f2 int, index t2f2(f2));
insert into t2 values(0),(1),(2);
select f2 from t2 where f2 in ('a',2);
explain select f2 from t2 where f2 in ('a',2);
select f2 from t2 where f2 in ('a','b');
explain select f2 from t2 where f2 in ('a','b');
select f2 from t2 where f2 in (1,'b');
explain select f2 from t2 where f2 in (1,'b');
drop table t1, t2;
......@@ -2443,7 +2443,7 @@ DROP TABLE t1, t2;
#
# Bug #16069: VIEW does return the same results as underlying SELECT
# with WHERE condition containing BETWEEN over dates
# Dates as strings should be casted to date type
CREATE TABLE t1 (id int NOT NULL PRIMARY KEY,
td date DEFAULT NULL, KEY idx(td));
......
......@@ -5704,11 +5704,6 @@ void Item_trigger_field::cleanup()
}
/*
If item is a const function, calculate it and return a const item
The original item is freed if not returned
*/
Item_result item_cmp_type(Item_result a,Item_result b)
{
if (a == STRING_RESULT && b == STRING_RESULT)
......
This diff is collapsed.
......@@ -589,49 +589,6 @@ class Item_func_nullif :public Item_bool_func2
};
class Item_func_case :public Item_func
{
int first_expr_num, else_expr_num;
enum Item_result cached_result_type;
String tmp_value;
uint ncases;
Item_result cmp_type;
DTCollation cmp_collation;
public:
Item_func_case(List<Item> &list, Item *first_expr_arg, Item *else_expr_arg)
:Item_func(), first_expr_num(-1), else_expr_num(-1),
cached_result_type(INT_RESULT)
{
ncases= list.elements;
if (first_expr_arg)
{
first_expr_num= list.elements;
list.push_back(first_expr_arg);
}
if (else_expr_arg)
{
else_expr_num= list.elements;
list.push_back(else_expr_arg);
}
set_arguments(list);
}
double val_real();
longlong val_int();
String *val_str(String *);
my_decimal *val_decimal(my_decimal *);
bool fix_fields(THD *thd, Item **ref);
void fix_length_and_dec();
uint decimal_precision() const;
table_map not_null_tables() const { return 0; }
enum Item_result result_type () const { return cached_result_type; }
const char *func_name() const { return "case"; }
void print(String *str);
Item *find_item(String *str);
CHARSET_INFO *compare_collation() { return cmp_collation.collation; }
bool check_partition_func_processor(byte *bool_arg) { return 0;}
};
/* Functions to handle the optimized IN */
......@@ -686,6 +643,7 @@ class in_vector :public Sql_alloc
{
return test(compare(collation, base + pos1*size, base + pos2*size));
}
virtual Item_result result_type()= 0;
};
class in_string :public in_vector
......@@ -707,6 +665,7 @@ class in_string :public in_vector
Item_string *to= (Item_string*)item;
to->str_value= *str;
}
Item_result result_type() { return STRING_RESULT; }
};
class in_longlong :public in_vector
......@@ -729,6 +688,7 @@ class in_longlong :public in_vector
{
((Item_int*)item)->value= ((longlong*)base)[pos];
}
Item_result result_type() { return INT_RESULT; }
};
class in_double :public in_vector
......@@ -746,6 +706,7 @@ class in_double :public in_vector
{
((Item_float*)item)->value= ((double*) base)[pos];
}
Item_result result_type() { return REAL_RESULT; }
};
......@@ -766,6 +727,8 @@ class in_decimal :public in_vector
Item_decimal *item_dec= (Item_decimal*)item;
item_dec->set_decimal_value(dec);
}
Item_result result_type() { return DECIMAL_RESULT; }
};
......@@ -796,7 +759,9 @@ class cmp_item_string :public cmp_item
protected:
String *value_res;
public:
cmp_item_string () {}
cmp_item_string (CHARSET_INFO *cs) { cmp_charset= cs; }
void set_charset(CHARSET_INFO *cs) { cmp_charset= cs; }
friend class cmp_item_sort_string;
friend class cmp_item_sort_string_in_static;
};
......@@ -807,6 +772,8 @@ class cmp_item_sort_string :public cmp_item_string
char value_buff[STRING_BUFFER_USUAL_SIZE];
String value;
public:
cmp_item_sort_string():
cmp_item_string() {}
cmp_item_sort_string(CHARSET_INFO *cs):
cmp_item_string(cs),
value(value_buff, sizeof(value_buff), cs) {}
......@@ -828,6 +795,11 @@ class cmp_item_sort_string :public cmp_item_string
return sortcmp(value_res, cmp->value_res, cmp_charset);
}
cmp_item *make_same();
void set_charset(CHARSET_INFO *cs)
{
cmp_charset= cs;
value.set_quick(value_buff, sizeof(value_buff), cs);
}
};
class cmp_item_int :public cmp_item
......@@ -908,6 +880,7 @@ class in_row :public in_vector
~in_row();
void set(uint pos,Item *item);
byte *get_value(Item *item);
Item_result result_type() { return ROW_RESULT; }
};
/*
......@@ -943,18 +916,109 @@ class cmp_item_sort_string_in_static :public cmp_item_string
}
};
/*
The class Item_func_case is the CASE ... WHEN ... THEN ... END function
implementation.
When there is no expression between CASE and the first WHEN
(the CASE expression) then this function simple checks all WHEN expressions
one after another. When some WHEN expression evaluated to TRUE then the
value of the corresponding THEN expression is returned.
When the CASE expression is specified then it is compared to each WHEN
expression individually. When an equal WHEN expression is found
corresponding THEN expression is returned.
In order to do correct comparisons several comparators are used. One for
each result type. Different result types that are used in particular
CASE ... END expression are collected in the fix_length_and_dec() member
function and only comparators for there result types are used.
*/
class Item_func_case :public Item_func
{
int first_expr_num, else_expr_num;
enum Item_result cached_result_type, left_result_type;
String tmp_value;
uint ncases;
Item_result cmp_type;
DTCollation cmp_collation;
cmp_item *cmp_items[5]; /* For all result types */
cmp_item *case_item;
public:
Item_func_case(List<Item> &list, Item *first_expr_arg, Item *else_expr_arg)
:Item_func(), first_expr_num(-1), else_expr_num(-1),
cached_result_type(INT_RESULT), left_result_type(INT_RESULT), case_item(0)
{
ncases= list.elements;
if (first_expr_arg)
{
first_expr_num= list.elements;
list.push_back(first_expr_arg);
}
if (else_expr_arg)
{
else_expr_num= list.elements;
list.push_back(else_expr_arg);
}
set_arguments(list);
bzero(&cmp_items, sizeof(cmp_items));
}
double val_real();
longlong val_int();
String *val_str(String *);
my_decimal *val_decimal(my_decimal *);
bool fix_fields(THD *thd, Item **ref);
void fix_length_and_dec();
uint decimal_precision() const;
table_map not_null_tables() const { return 0; }
enum Item_result result_type () const { return cached_result_type; }
const char *func_name() const { return "case"; }
void print(String *str);
Item *find_item(String *str);
CHARSET_INFO *compare_collation() { return cmp_collation.collation; }
bool check_partition_func_processor(byte *bool_arg) { return 0;}
void cleanup()
{
uint i;
DBUG_ENTER("Item_func_case::cleanup");
Item_func::cleanup();
for (i= 0; i <= (uint)DECIMAL_RESULT; i++)
{
delete cmp_items[i];
cmp_items[i]= 0;
}
DBUG_VOID_RETURN;
}
};
/*
The Item_func_in class implements the in_expr IN(values_list) function.
The current implementation distinguishes 2 cases:
1) all items in the value_list are constants and have the same
result type. This case is handled by in_vector class.
2) items in the value_list have different result types or there is some
non-constant items.
In this case Item_func_in employs several cmp_item objects to performs
comparisons of in_expr and an item from the values_list. One cmp_item
object for each result type. Different result types are collected in the
fix_length_and_dec() member function by means of collect_cmp_types()
function.
*/
class Item_func_in :public Item_func_opt_neg
{
public:
Item_result cmp_type;
in_vector *array;
cmp_item *in_item;
bool have_null;
Item_result left_result_type;
cmp_item *cmp_items[5]; /* One cmp_item for each result type */
DTCollation cmp_collation;
Item_func_in(List<Item> &list)
:Item_func_opt_neg(list), array(0), in_item(0), have_null(0)
:Item_func_opt_neg(list), array(0), have_null(0)
{
bzero(&cmp_items, sizeof(cmp_items));
allowed_arg_cols= 0; // Fetch this value from first argument
}
longlong val_int();
......@@ -963,12 +1027,16 @@ class Item_func_in :public Item_func_opt_neg
uint decimal_precision() const { return 1; }
void cleanup()
{
uint i;
DBUG_ENTER("Item_func_in::cleanup");
Item_int_func::cleanup();
delete array;
delete in_item;
array= 0;
in_item= 0;
for (i= 0; i <= (uint)DECIMAL_RESULT; i++)
{
delete cmp_items[i];
cmp_items[i]= 0;
}
DBUG_VOID_RETURN;
}
optimize_type select_optimize() const
......
......@@ -4917,9 +4917,17 @@ static SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Item_func *cond_func,
{
Item_func_in *func=(Item_func_in*) cond_func;
/*
Array for IN() is constructed when all values have the same result
type. Tree won't be built for values with different result types,
so we check it here to avoid unnecessary work.
*/
if (!func->array)
break;
if (inv)
{
if (func->array && func->cmp_type != ROW_RESULT)
if (func->array->result_type() != ROW_RESULT)
{
/*
We get here for conditions in form "t.key NOT IN (c1, c2, ...)",
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment