Commit 239f727b authored by evgen@moonbone.local's avatar evgen@moonbone.local

Bug#27759: Wrong DATE/DATETIME comparison in LEAST()/GREATEST() functions.

The LEAST/GREATEST functions compared DATE/DATETIME values as
strings which in some cases could lead to a wrong result.

A new member function called cmp_datetimes() is added to the
Item_func_min_max class. It compares arguments in DATETIME context
and returns index of the least/greatest argument.
The Item_func_min_max::fix_length_and_dec() function now detects when
arguments should be compared in DATETIME context and sets the newly
added flag compare_as_dates. It indicates that the cmp_datetimes() function
should be called to get a correct result.
Item_func_min_max::val_xxx() methods are corrected to call the
cmp_datetimes() function when needed.
Objects of the Item_splocal class now stores and reports correct original
field type.
parent 1a0cf6db
...@@ -690,12 +690,12 @@ END| ...@@ -690,12 +690,12 @@ END|
CALL p1(NOW()); CALL p1(NOW());
Table Create Table Table Create Table
t1 CREATE TABLE "t1" ( t1 CREATE TABLE "t1" (
"x" varbinary(19) default NULL "x" datetime default NULL
) )
CALL p1('test'); CALL p1('test');
Table Create Table Table Create Table
t1 CREATE TABLE "t1" ( t1 CREATE TABLE "t1" (
"x" varbinary(19) default NULL "x" datetime default NULL
) )
Warnings: Warnings:
Warning 1264 Out of range value adjusted for column 'x' at row 1 Warning 1264 Out of range value adjusted for column 'x' at row 1
......
...@@ -264,3 +264,33 @@ f2 ...@@ -264,3 +264,33 @@ f2
SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE(); SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE();
1 1
drop table t1; drop table t1;
select least(cast('01-01-01' as date), '01-01-02');
least(cast('01-01-01' as date), '01-01-02')
2001-01-01
select greatest(cast('01-01-01' as date), '01-01-02');
greatest(cast('01-01-01' as date), '01-01-02')
01-01-02
select least(cast('01-01-01' as date), '01-01-02') + 0;
least(cast('01-01-01' as date), '01-01-02') + 0
20010101
select greatest(cast('01-01-01' as date), '01-01-02') + 0;
greatest(cast('01-01-01' as date), '01-01-02') + 0
20010102
select least(cast('01-01-01' as datetime), '01-01-02') + 0;
least(cast('01-01-01' as datetime), '01-01-02') + 0
20010101000000
DROP PROCEDURE IF EXISTS test27759 ;
CREATE PROCEDURE test27759()
BEGIN
declare v_a date default '2007-4-10';
declare v_b date default '2007-4-11';
declare v_c datetime default '2004-4-9 0:0:0';
select v_a as a,v_b as b,
least( v_a, v_b ) as a_then_b,
least( v_b, v_a ) as b_then_a,
least( v_c, v_a ) as c_then_a;
END;|
call test27759();
a b a_then_b b_then_a c_then_a
2007-04-10 2007-04-11 2007-04-10 2007-04-10 2004-04-09 00:00:00
drop procedure test27759;
...@@ -178,3 +178,29 @@ select f2, f3 from t1 where '01-03-10' between f2 and f3; ...@@ -178,3 +178,29 @@ select f2, f3 from t1 where '01-03-10' between f2 and f3;
select f2 from t1 where DATE(f2) between "2001-4-15" AND "01-4-15"; select f2 from t1 where DATE(f2) between "2001-4-15" AND "01-4-15";
SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE(); SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE();
drop table t1; drop table t1;
#
# Bug#27759: Wrong DATE/DATETIME comparison in LEAST()/GREATEST() functions.
#
select least(cast('01-01-01' as date), '01-01-02');
select greatest(cast('01-01-01' as date), '01-01-02');
select least(cast('01-01-01' as date), '01-01-02') + 0;
select greatest(cast('01-01-01' as date), '01-01-02') + 0;
select least(cast('01-01-01' as datetime), '01-01-02') + 0;
--disable_warnings
DROP PROCEDURE IF EXISTS test27759 ;
--enable_warnings
DELIMITER |;
CREATE PROCEDURE test27759()
BEGIN
declare v_a date default '2007-4-10';
declare v_b date default '2007-4-11';
declare v_c datetime default '2004-4-9 0:0:0';
select v_a as a,v_b as b,
least( v_a, v_b ) as a_then_b,
least( v_b, v_a ) as b_then_a,
least( v_c, v_a ) as c_then_a;
END;|
DELIMITER ;|
call test27759();
drop procedure test27759;
...@@ -1011,6 +1011,7 @@ Item_splocal::Item_splocal(const LEX_STRING &sp_var_name, ...@@ -1011,6 +1011,7 @@ Item_splocal::Item_splocal(const LEX_STRING &sp_var_name,
maybe_null= TRUE; maybe_null= TRUE;
m_type= sp_map_item_type(sp_var_type); m_type= sp_map_item_type(sp_var_type);
m_field_type= sp_var_type;
m_result_type= sp_map_result_type(sp_var_type); m_result_type= sp_map_result_type(sp_var_type);
} }
......
...@@ -946,7 +946,7 @@ class Item_splocal :public Item_sp_variable, ...@@ -946,7 +946,7 @@ class Item_splocal :public Item_sp_variable,
Type m_type; Type m_type;
Item_result m_result_type; Item_result m_result_type;
enum_field_types m_field_type;
public: public:
/* /*
Position of this reference to SP variable in the statement (the Position of this reference to SP variable in the statement (the
...@@ -978,6 +978,7 @@ public: ...@@ -978,6 +978,7 @@ public:
inline enum Type type() const; inline enum Type type() const;
inline Item_result result_type() const; inline Item_result result_type() const;
inline enum_field_types field_type() const { return m_field_type; }
private: private:
bool set_value(THD *thd, sp_rcontext *ctx, Item **it); bool set_value(THD *thd, sp_rcontext *ctx, Item **it);
......
...@@ -745,7 +745,7 @@ void Arg_comparator::set_datetime_cmp_func(Item **a1, Item **b1) ...@@ -745,7 +745,7 @@ void Arg_comparator::set_datetime_cmp_func(Item **a1, Item **b1)
obtained value obtained value
*/ */
static ulonglong ulonglong
get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg, get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg,
Item *warn_item, bool *is_null) Item *warn_item, bool *is_null)
{ {
...@@ -781,7 +781,7 @@ get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg, ...@@ -781,7 +781,7 @@ get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg,
MYSQL_TYPE_DATE ? MYSQL_TIMESTAMP_DATE : MYSQL_TIMESTAMP_DATETIME; MYSQL_TYPE_DATE ? MYSQL_TIMESTAMP_DATE : MYSQL_TIMESTAMP_DATETIME;
value= get_date_from_str(thd, str, t_type, warn_item->name, &error); value= get_date_from_str(thd, str, t_type, warn_item->name, &error);
} }
if (item->const_item()) if (item->const_item() && cache_arg)
{ {
Item_cache_int *cache= new Item_cache_int(); Item_cache_int *cache= new Item_cache_int();
/* Mark the cache as non-const to prevent re-caching. */ /* Mark the cache as non-const to prevent re-caching. */
......
...@@ -2120,6 +2120,7 @@ double Item_func_units::val_real() ...@@ -2120,6 +2120,7 @@ double Item_func_units::val_real()
void Item_func_min_max::fix_length_and_dec() void Item_func_min_max::fix_length_and_dec()
{ {
int max_int_part=0; int max_int_part=0;
bool datetime_found= FALSE;
decimals=0; decimals=0;
max_length=0; max_length=0;
maybe_null=0; maybe_null=0;
...@@ -2133,18 +2134,88 @@ void Item_func_min_max::fix_length_and_dec() ...@@ -2133,18 +2134,88 @@ void Item_func_min_max::fix_length_and_dec()
if (args[i]->maybe_null) if (args[i]->maybe_null)
maybe_null=1; maybe_null=1;
cmp_type=item_cmp_type(cmp_type,args[i]->result_type()); cmp_type=item_cmp_type(cmp_type,args[i]->result_type());
if (args[i]->result_type() != ROW_RESULT && args[i]->is_datetime())
{
datetime_found= TRUE;
if (!datetime_item || args[i]->field_type() == MYSQL_TYPE_DATETIME)
datetime_item= args[i];
}
} }
if (cmp_type == STRING_RESULT) if (cmp_type == STRING_RESULT)
{
agg_arg_charsets(collation, args, arg_count, MY_COLL_CMP_CONV, 1); agg_arg_charsets(collation, args, arg_count, MY_COLL_CMP_CONV, 1);
if (datetime_found)
{
thd= current_thd;
compare_as_dates= TRUE;
}
}
else if ((cmp_type == DECIMAL_RESULT) || (cmp_type == INT_RESULT)) else if ((cmp_type == DECIMAL_RESULT) || (cmp_type == INT_RESULT))
max_length= my_decimal_precision_to_length(max_int_part+decimals, decimals, max_length= my_decimal_precision_to_length(max_int_part+decimals, decimals,
unsigned_flag); unsigned_flag);
} }
/*
Compare item arguments in the DATETIME context.
SYNOPSIS
cmp_datetimes()
value [out] found least/greatest DATE/DATETIME value
DESCRIPTION
Compare item arguments as DATETIME values and return the index of the
least/greatest argument in the arguments array.
The correct integer DATE/DATETIME value of the found argument is
stored to the value pointer, if latter is provided.
RETURN
0 If one of arguments is NULL
# index of the least/greatest argument
*/
uint Item_func_min_max::cmp_datetimes(ulonglong *value)
{
ulonglong min_max;
uint min_max_idx= 0;
LINT_INIT(min_max);
for (uint i=0; i < arg_count ; i++)
{
Item **arg= args + i;
bool is_null;
ulonglong res= get_datetime_value(thd, &arg, 0, datetime_item, &is_null);
if ((null_value= args[i]->null_value))
return 0;
if (i == 0 || (res < min_max ? cmp_sign : -cmp_sign) > 0)
{
min_max= res;
min_max_idx= i;
}
}
if (value)
{
*value= min_max;
if (datetime_item->field_type() == MYSQL_TYPE_DATE)
*value/= 1000000L;
}
return min_max_idx;
}
String *Item_func_min_max::val_str(String *str) String *Item_func_min_max::val_str(String *str)
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
if (compare_as_dates)
{
String *str_res;
uint min_max_idx= cmp_datetimes(NULL);
if (null_value)
return 0;
str_res= args[min_max_idx]->val_str(str);
str_res->set_charset(collation.collation);
return str_res;
}
switch (cmp_type) { switch (cmp_type) {
case INT_RESULT: case INT_RESULT:
{ {
...@@ -2212,6 +2283,12 @@ double Item_func_min_max::val_real() ...@@ -2212,6 +2283,12 @@ double Item_func_min_max::val_real()
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
double value=0.0; double value=0.0;
if (compare_as_dates)
{
ulonglong result;
(void)cmp_datetimes(&result);
return (double)result;
}
for (uint i=0; i < arg_count ; i++) for (uint i=0; i < arg_count ; i++)
{ {
if (i == 0) if (i == 0)
...@@ -2233,6 +2310,12 @@ longlong Item_func_min_max::val_int() ...@@ -2233,6 +2310,12 @@ longlong Item_func_min_max::val_int()
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
longlong value=0; longlong value=0;
if (compare_as_dates)
{
ulonglong result;
(void)cmp_datetimes(&result);
return (longlong)result;
}
for (uint i=0; i < arg_count ; i++) for (uint i=0; i < arg_count ; i++)
{ {
if (i == 0) if (i == 0)
...@@ -2256,6 +2339,13 @@ my_decimal *Item_func_min_max::val_decimal(my_decimal *dec) ...@@ -2256,6 +2339,13 @@ my_decimal *Item_func_min_max::val_decimal(my_decimal *dec)
my_decimal tmp_buf, *tmp, *res; my_decimal tmp_buf, *tmp, *res;
LINT_INIT(res); LINT_INIT(res);
if (compare_as_dates)
{
ulonglong value;
(void)cmp_datetimes(&value);
ulonglong2decimal(value, dec);
return dec;
}
for (uint i=0; i < arg_count ; i++) for (uint i=0; i < arg_count ; i++)
{ {
if (i == 0) if (i == 0)
......
...@@ -693,15 +693,23 @@ class Item_func_min_max :public Item_func ...@@ -693,15 +693,23 @@ class Item_func_min_max :public Item_func
Item_result cmp_type; Item_result cmp_type;
String tmp_value; String tmp_value;
int cmp_sign; int cmp_sign;
/* TRUE <=> arguments should be compared in the DATETIME context. */
bool compare_as_dates;
/* An item used for issuing warnings while string to DATETIME conversion. */
Item *datetime_item;
THD *thd;
public: public:
Item_func_min_max(List<Item> &list,int cmp_sign_arg) :Item_func(list), Item_func_min_max(List<Item> &list,int cmp_sign_arg) :Item_func(list),
cmp_type(INT_RESULT), cmp_sign(cmp_sign_arg) {} cmp_type(INT_RESULT), cmp_sign(cmp_sign_arg), compare_as_dates(FALSE),
datetime_item(0) {}
double val_real(); double val_real();
longlong val_int(); longlong val_int();
String *val_str(String *); String *val_str(String *);
my_decimal *val_decimal(my_decimal *); my_decimal *val_decimal(my_decimal *);
void fix_length_and_dec(); void fix_length_and_dec();
enum Item_result result_type () const { return cmp_type; } enum Item_result result_type () const { return cmp_type; }
uint cmp_datetimes(ulonglong *value);
}; };
class Item_func_min :public Item_func_min_max class Item_func_min :public Item_func_min_max
......
...@@ -1525,6 +1525,8 @@ void make_date(const DATE_TIME_FORMAT *format, const TIME *l_time, ...@@ -1525,6 +1525,8 @@ void make_date(const DATE_TIME_FORMAT *format, const TIME *l_time,
String *str); String *str);
void make_time(const DATE_TIME_FORMAT *format, const TIME *l_time, void make_time(const DATE_TIME_FORMAT *format, const TIME *l_time,
String *str); String *str);
ulonglong get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg,
Item *warn_item, bool *is_null);
int test_if_number(char *str,int *res,bool allow_wildcards); int test_if_number(char *str,int *res,bool allow_wildcards);
void change_byte(byte *,uint,char,char); void change_byte(byte *,uint,char,char);
......
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