Skip to content

Commit

Permalink
MDEV-13863 sql_mode=ORACLE: DECODE does not treat two NULLs as equiva…
Browse files Browse the repository at this point in the history
…lent
  • Loading branch information
Alexander Barkov committed Sep 22, 2017
1 parent c39a744 commit 884bd1d
Show file tree
Hide file tree
Showing 7 changed files with 406 additions and 12 deletions.
146 changes: 145 additions & 1 deletion mysql-test/suite/compat/oracle/r/func_decode.result
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,150 @@ EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11','def');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 select case 12 when 10 then 'x10' when 11 then 'x11' else 'def' end AS "DECODE(12,10,'x10',11,'x11','def')"
Note 1003 select decode_oracle(12,10,'x10',11,'x11','def') AS "DECODE(12,10,'x10',11,'x11','def')"
CREATE TABLE decode (decode int);
DROP TABLE decode;
#
# MDEV-13863 sql_mode=ORACLE: DECODE does not treat two NULLs as equivalent
#
SELECT DECODE(10);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ')' at line 1
SELECT DECODE(10,10);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near ')' at line 1
SELECT DECODE_ORACLE(10);
ERROR 42000: Incorrect parameter count in the call to native function 'DECODE_ORACLE'
SELECT DECODE_ORACLE(10,10);
ERROR 42000: Incorrect parameter count in the call to native function 'DECODE_ORACLE'
EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 select decode_oracle(12,10,'x10',11,'x11') AS "DECODE(12,10,'x10',11,'x11')"
EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11','def');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 select decode_oracle(12,10,'x10',11,'x11','def') AS "DECODE(12,10,'x10',11,'x11','def')"
EXPLAIN EXTENDED SELECT DECODE_ORACLE(12,10,'x10',11,'x11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 select decode_oracle(12,10,'x10',11,'x11') AS "DECODE_ORACLE(12,10,'x10',11,'x11')"
EXPLAIN EXTENDED SELECT DECODE_ORACLE(12,10,'x10',11,'x11','def');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 select decode_oracle(12,10,'x10',11,'x11','def') AS "DECODE_ORACLE(12,10,'x10',11,'x11','def')"
CREATE TABLE t1 (a INT);
CREATE VIEW v1 AS
SELECT
DECODE(a,1,'x1',NULL,'xNULL') AS d1,
DECODE(a,1,'x1',NULL,'xNULL','xELSE') AS d2,
DECODE_ORACLE(a,1,'x1',NULL,'xNULL') AS d3,
DECODE_ORACLE(a,1,'x1',NULL,'xNULL','xELSE') AS d4
FROM t1;
SHOW CREATE VIEW v1;
View Create View character_set_client collation_connection
v1 CREATE VIEW "v1" AS select decode_oracle("t1"."a",1,'x1',NULL,'xNULL') AS "d1",decode_oracle("t1"."a",1,'x1',NULL,'xNULL','xELSE') AS "d2",decode_oracle("t1"."a",1,'x1',NULL,'xNULL') AS "d3",decode_oracle("t1"."a",1,'x1',NULL,'xNULL','xELSE') AS "d4" from "t1" latin1 latin1_swedish_ci
DROP VIEW v1;
DROP TABLE t1;
SELECT DECODE(TIME'10:20:31','10:20:31','then1','10:20:32','then2','def');
DECODE(TIME'10:20:31','10:20:31','then1','10:20:32','then2','def')
then1
SELECT DECODE(TIME'10:20:32','10:20:31','then1','10:20:32','then2','def');
DECODE(TIME'10:20:32','10:20:31','then1','10:20:32','then2','def')
then2
SELECT DECODE(TIME'10:20:33','10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def');
DECODE(TIME'10:20:33','10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def')
then3
SELECT DECODE(NULL,TIME'10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def');
DECODE(NULL,TIME'10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def')
then2NULL
SELECT DECODE(TIMESTAMP'2001-01-01 10:20:31','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def');
DECODE(TIMESTAMP'2001-01-01 10:20:31','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def')
then1
SELECT DECODE(TIMESTAMP'2001-01-01 10:20:32','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def');
DECODE(TIMESTAMP'2001-01-01 10:20:32','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def')
then2
SELECT DECODE(TIMESTAMP'2001-01-01 10:20:33','2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def');
DECODE(TIMESTAMP'2001-01-01 10:20:33','2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def')
then3
SELECT DECODE(NULL,TIMESTAMP'2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def');
DECODE(NULL,TIMESTAMP'2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def')
then2NULL
SELECT DECODE('w1','w1','then1','w2','then2','def');
DECODE('w1','w1','then1','w2','then2','def')
then1
SELECT DECODE('w2','w1','then1','w2','then2','def');
DECODE('w2','w1','then1','w2','then2','def')
then2
SELECT DECODE('w3','w1','then1',NULL,'then2NULL','w3','then3','def');
DECODE('w3','w1','then1',NULL,'then2NULL','w3','then3','def')
then3
SELECT DECODE(NULL,'w1','then1',NULL,'then2NULL','w3','then3','def');
DECODE(NULL,'w1','then1',NULL,'then2NULL','w3','then3','def')
then2NULL
SELECT DECODE(1,1,'then1',2,'then2','def');
DECODE(1,1,'then1',2,'then2','def')
then1
SELECT DECODE(2,1,'then1',2,'then2','def');
DECODE(2,1,'then1',2,'then2','def')
then2
SELECT DECODE(3,1,'then1',NULL,'then2NULL',3,'then3','def');
DECODE(3,1,'then1',NULL,'then2NULL',3,'then3','def')
then3
SELECT DECODE(NULL,1,'then1',NULL,'then2NULL',3,'then3','def');
DECODE(NULL,1,'then1',NULL,'then2NULL',3,'then3','def')
then2NULL
SELECT DECODE(CAST(NULL AS SIGNED),1,'then1',NULL,'then2NULL',3,'then3','def');
DECODE(CAST(NULL AS SIGNED),1,'then1',NULL,'then2NULL',3,'then3','def')
then2NULL
SELECT DECODE(1.0,1.0,'then1',2.0,'then2','def');
DECODE(1.0,1.0,'then1',2.0,'then2','def')
then1
SELECT DECODE(2.0,1.0,'then1',2.0,'then2','def');
DECODE(2.0,1.0,'then1',2.0,'then2','def')
then2
SELECT DECODE(3.0,1.0,'then1',NULL,'then2NULL',3.0,'then3','def');
DECODE(3.0,1.0,'then1',NULL,'then2NULL',3.0,'then3','def')
then3
SELECT DECODE(NULL,1.0,'then1',NULL,'then2NULL',3.0,'then3','def');
DECODE(NULL,1.0,'then1',NULL,'then2NULL',3.0,'then3','def')
then2NULL
SELECT DECODE(CAST(NULL AS DECIMAL),1.0,'then1',NULL,'then2NULL',3.0,'then3','def');
DECODE(CAST(NULL AS DECIMAL),1.0,'then1',NULL,'then2NULL',3.0,'then3','def')
then2NULL
SELECT DECODE(1e0,1e0,'then1',2e0,'then2','def');
DECODE(1e0,1e0,'then1',2e0,'then2','def')
then1
SELECT DECODE(2e0,1e0,'then1',2e0,'then2','def');
DECODE(2e0,1e0,'then1',2e0,'then2','def')
then2
SELECT DECODE(3e0,1e0,'then1',NULL,'then2NULL',3e0,'then3','def');
DECODE(3e0,1e0,'then1',NULL,'then2NULL',3e0,'then3','def')
then3
SELECT DECODE(NULL,1e0,'then1',NULL,'then2NULL',3e0,'then3','def');
DECODE(NULL,1e0,'then1',NULL,'then2NULL',3e0,'then3','def')
then2NULL
SELECT DECODE(CAST(NULL AS DOUBLE),1e0,'then1',NULL,'then2NULL',3e0,'then3','def');
DECODE(CAST(NULL AS DOUBLE),1e0,'then1',NULL,'then2NULL',3e0,'then3','def')
then2NULL
SELECT DECODE(NULL,NULL,1,2) FROM DUAL;
DECODE(NULL,NULL,1,2)
1
SELECT DECODE(NULL,10,10,NULL,1,2) FROM DUAL;
DECODE(NULL,10,10,NULL,1,2)
1
SELECT DECODE_ORACLE(NULL,NULL,1,2) FROM DUAL;
DECODE_ORACLE(NULL,NULL,1,2)
1
SELECT DECODE_ORACLE(NULL,10,10,NULL,1,2) FROM DUAL;
DECODE_ORACLE(NULL,10,10,NULL,1,2)
1
CREATE OR REPLACE TABLE t1 (a VARCHAR(10) DEFAULT NULL);
INSERT INTO t1 VALUES (NULL),(1);
SELECT a, DECODE(a,NULL,1,2) FROM t1;
a DECODE(a,NULL,1,2)
NULL 1
1 2
DROP TABLE t1;
77 changes: 77 additions & 0 deletions mysql-test/suite/compat/oracle/t/func_decode.test
Original file line number Diff line number Diff line change
Expand Up @@ -19,3 +19,80 @@ EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11','def');

CREATE TABLE decode (decode int);
DROP TABLE decode;


--echo #
--echo # MDEV-13863 sql_mode=ORACLE: DECODE does not treat two NULLs as equivalent
--echo #

--error ER_PARSE_ERROR
SELECT DECODE(10);
--error ER_PARSE_ERROR
SELECT DECODE(10,10);

--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
SELECT DECODE_ORACLE(10);
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
SELECT DECODE_ORACLE(10,10);


EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11');
EXPLAIN EXTENDED SELECT DECODE(12,10,'x10',11,'x11','def');
EXPLAIN EXTENDED SELECT DECODE_ORACLE(12,10,'x10',11,'x11');
EXPLAIN EXTENDED SELECT DECODE_ORACLE(12,10,'x10',11,'x11','def');

CREATE TABLE t1 (a INT);
CREATE VIEW v1 AS
SELECT
DECODE(a,1,'x1',NULL,'xNULL') AS d1,
DECODE(a,1,'x1',NULL,'xNULL','xELSE') AS d2,
DECODE_ORACLE(a,1,'x1',NULL,'xNULL') AS d3,
DECODE_ORACLE(a,1,'x1',NULL,'xNULL','xELSE') AS d4
FROM t1;
SHOW CREATE VIEW v1;
DROP VIEW v1;
DROP TABLE t1;

SELECT DECODE(TIME'10:20:31','10:20:31','then1','10:20:32','then2','def');
SELECT DECODE(TIME'10:20:32','10:20:31','then1','10:20:32','then2','def');
SELECT DECODE(TIME'10:20:33','10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def');
SELECT DECODE(NULL,TIME'10:20:31','then1',NULL,'then2NULL','10:20:33','then3','def');

SELECT DECODE(TIMESTAMP'2001-01-01 10:20:31','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def');
SELECT DECODE(TIMESTAMP'2001-01-01 10:20:32','2001-01-01 10:20:31','then1','2001-01-01 10:20:32','then2','def');
SELECT DECODE(TIMESTAMP'2001-01-01 10:20:33','2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def');
SELECT DECODE(NULL,TIMESTAMP'2001-01-01 10:20:31','then1',NULL,'then2NULL','2001-01-01 10:20:33','then3','def');

SELECT DECODE('w1','w1','then1','w2','then2','def');
SELECT DECODE('w2','w1','then1','w2','then2','def');
SELECT DECODE('w3','w1','then1',NULL,'then2NULL','w3','then3','def');
SELECT DECODE(NULL,'w1','then1',NULL,'then2NULL','w3','then3','def');

SELECT DECODE(1,1,'then1',2,'then2','def');
SELECT DECODE(2,1,'then1',2,'then2','def');
SELECT DECODE(3,1,'then1',NULL,'then2NULL',3,'then3','def');
SELECT DECODE(NULL,1,'then1',NULL,'then2NULL',3,'then3','def');
SELECT DECODE(CAST(NULL AS SIGNED),1,'then1',NULL,'then2NULL',3,'then3','def');

SELECT DECODE(1.0,1.0,'then1',2.0,'then2','def');
SELECT DECODE(2.0,1.0,'then1',2.0,'then2','def');
SELECT DECODE(3.0,1.0,'then1',NULL,'then2NULL',3.0,'then3','def');
SELECT DECODE(NULL,1.0,'then1',NULL,'then2NULL',3.0,'then3','def');
SELECT DECODE(CAST(NULL AS DECIMAL),1.0,'then1',NULL,'then2NULL',3.0,'then3','def');

SELECT DECODE(1e0,1e0,'then1',2e0,'then2','def');
SELECT DECODE(2e0,1e0,'then1',2e0,'then2','def');
SELECT DECODE(3e0,1e0,'then1',NULL,'then2NULL',3e0,'then3','def');
SELECT DECODE(NULL,1e0,'then1',NULL,'then2NULL',3e0,'then3','def');
SELECT DECODE(CAST(NULL AS DOUBLE),1e0,'then1',NULL,'then2NULL',3e0,'then3','def');

SELECT DECODE(NULL,NULL,1,2) FROM DUAL;
SELECT DECODE(NULL,10,10,NULL,1,2) FROM DUAL;

SELECT DECODE_ORACLE(NULL,NULL,1,2) FROM DUAL;
SELECT DECODE_ORACLE(NULL,10,10,NULL,1,2) FROM DUAL;

CREATE OR REPLACE TABLE t1 (a VARCHAR(10) DEFAULT NULL);
INSERT INTO t1 VALUES (NULL),(1);
SELECT a, DECODE(a,NULL,1,2) FROM t1;
DROP TABLE t1;
17 changes: 16 additions & 1 deletion sql/item.h
Original file line number Diff line number Diff line change
Expand Up @@ -56,8 +56,23 @@ struct st_value
C_MODE_END


class Value: public st_value
{
public:
bool is_null() const { return m_type == DYN_COL_NULL; }
bool is_longlong() const
{
return m_type == DYN_COL_UINT || m_type == DYN_COL_INT;
}
bool is_double() const { return m_type == DYN_COL_DOUBLE; }
bool is_temporal() const { return m_type == DYN_COL_DATETIME; }
bool is_string() const { return m_type == DYN_COL_STRING; }
bool is_decimal() const { return m_type == DYN_COL_DECIMAL; }
};


template<size_t buffer_size>
class ValueBuffer: public st_value
class ValueBuffer: public Value
{
char buffer[buffer_size];
void reset_buffer()
Expand Down
57 changes: 52 additions & 5 deletions sql/item_cmpfunc.cc
Original file line number Diff line number Diff line change
Expand Up @@ -2859,6 +2859,16 @@ Item *Item_func_case_simple::find_item()
}


Item *Item_func_decode_oracle::find_item()
{
uint idx;
if (!Predicant_to_list_comparator::cmp_nulls_equal(this, &idx))
return args[idx + 1];
Item **pos= Item_func_decode_oracle::else_expr_addr();
return pos ? pos[0] : 0;
}


String *Item_func_case::str_op(String *str)
{
DBUG_ASSERT(fixed == 1);
Expand Down Expand Up @@ -2988,7 +2998,8 @@ static void change_item_tree_if_needed(THD *thd,


bool Item_func_case_simple::prepare_predicant_and_values(THD *thd,
uint *found_types)
uint *found_types,
bool nulls_equal)
{
bool have_null= false;
uint type_cnt;
Expand All @@ -2997,7 +3008,9 @@ bool Item_func_case_simple::prepare_predicant_and_values(THD *thd,
add_predicant(this, 0);
for (uint i= 0 ; i < ncases; i++)
{
if (add_value_skip_null("case..when", this, i * 2 + 1, &have_null))
if (nulls_equal ?
add_value("case..when", this, i * 2 + 1) :
add_value_skip_null("case..when", this, i * 2 + 1, &have_null))
return true;
}
all_values_added(&tmp, &type_cnt, &m_found_types);
Expand All @@ -3021,7 +3034,16 @@ void Item_func_case_simple::fix_length_and_dec()
THD *thd= current_thd;
Item **else_ptr= Item_func_case_simple::else_expr_addr();
if (!aggregate_then_and_else_arguments(thd, &args[2], when_count(), else_ptr))
aggregate_switch_and_when_arguments(thd);
aggregate_switch_and_when_arguments(thd, false);
}


void Item_func_decode_oracle::fix_length_and_dec()
{
THD *thd= current_thd;
Item **else_ptr= Item_func_decode_oracle::else_expr_addr();
if (!aggregate_then_and_else_arguments(thd, &args[2], when_count(), else_ptr))
aggregate_switch_and_when_arguments(thd, true);
}


Expand Down Expand Up @@ -3072,13 +3094,14 @@ bool Item_func_case::aggregate_then_and_else_arguments(THD *thd,
Aggregate the predicant expression and all WHEN expression types
and collations when string comparison
*/
bool Item_func_case_simple::aggregate_switch_and_when_arguments(THD *thd)
bool Item_func_case_simple::aggregate_switch_and_when_arguments(THD *thd,
bool nulls_eq)
{
Item **agg= arg_buffer;
uint nagg;
uint ncases= when_count();
m_found_types= 0;
if (prepare_predicant_and_values(thd, &m_found_types))
if (prepare_predicant_and_values(thd, &m_found_types, nulls_eq))
{
/*
If Predicant_to_list_comparator() fails to prepare components,
Expand Down Expand Up @@ -3962,6 +3985,14 @@ void cmp_item_decimal::store_value(Item *item)
}


int cmp_item_decimal::cmp_not_null(const Value *val)
{
DBUG_ASSERT(!val->is_null());
DBUG_ASSERT(val->is_decimal());
return my_decimal_cmp(&value, &val->m_decimal);
}


int cmp_item_decimal::cmp(Item *arg)
{
my_decimal tmp_buf, *tmp= arg->val_decimal(&tmp_buf);
Expand Down Expand Up @@ -3993,13 +4024,29 @@ void cmp_item_temporal::store_value_internal(Item *item,
}


int cmp_item_datetime::cmp_not_null(const Value *val)
{
DBUG_ASSERT(!val->is_null());
DBUG_ASSERT(val->is_temporal());
return value != pack_time(&val->value.m_time);
}


int cmp_item_datetime::cmp(Item *arg)
{
const bool rc= value != arg->val_datetime_packed();
return (m_null_value || arg->null_value) ? UNKNOWN : rc;
}


int cmp_item_time::cmp_not_null(const Value *val)
{
DBUG_ASSERT(!val->is_null());
DBUG_ASSERT(val->is_temporal());
return value != pack_time(&val->value.m_time);
}


int cmp_item_time::cmp(Item *arg)
{
const bool rc= value != arg->val_time_packed();
Expand Down
Loading

0 comments on commit 884bd1d

Please sign in to comment.