Commit 08799831 authored by Alexander Barkov's avatar Alexander Barkov

MDEV-11880 sql_mode=ORACLE: Make the concatenation operator ignore NULL arguments

Now when sql_mode=ORACLE, the concatenation operator || treats
NULLs as empty strings.

Based on the contributed patch from Jérôme Brauge.
parent 46255b0c
SET sql_mode=ORACLE;
EXPLAIN EXTENDED SELECT 'a'||'b'||'c';
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 'a' || 'b' || 'c' AS "'a'||'b'||'c'"
SELECT '' || '';
'' || ''
SELECT '' || 'b';
'' || 'b'
b
SELECT '' || NULL;
'' || NULL
SELECT 'a' || '';
'a' || ''
a
SELECT 'a' || 'b';
'a' || 'b'
ab
SELECT 'a' || NULL;
'a' || NULL
a
SELECT NULL || '';
NULL || ''
SELECT NULL || 'b';
NULL || 'b'
b
SELECT NULL || NULL;
NULL || NULL
NULL
SELECT '' || '' || '';
'' || '' || ''
SELECT '' || '' || 'c';
'' || '' || 'c'
c
SELECT '' || '' || NULL;
'' || '' || NULL
SELECT '' || 'b' || '';
'' || 'b' || ''
b
SELECT '' || 'b' || 'c';
'' || 'b' || 'c'
bc
SELECT '' || 'b' || NULL;
'' || 'b' || NULL
b
SELECT '' || NULL || '';
'' || NULL || ''
SELECT '' || NULL || 'c';
'' || NULL || 'c'
c
SELECT '' || NULL || NULL;
'' || NULL || NULL
SELECT 'a' || '' || '';
'a' || '' || ''
a
SELECT 'a' || '' || 'c';
'a' || '' || 'c'
ac
SELECT 'a' || '' || NULL;
'a' || '' || NULL
a
SELECT 'a' || 'b' || '';
'a' || 'b' || ''
ab
SELECT 'a' || 'b' || 'c';
'a' || 'b' || 'c'
abc
SELECT 'a' || 'b' || NULL;
'a' || 'b' || NULL
ab
SELECT 'a' || NULL || '';
'a' || NULL || ''
a
SELECT 'a' || NULL || 'c';
'a' || NULL || 'c'
ac
SELECT 'a' || NULL || NULL;
'a' || NULL || NULL
a
SELECT NULL || '' || '';
NULL || '' || ''
SELECT NULL || '' || 'c';
NULL || '' || 'c'
c
SELECT NULL || '' || NULL;
NULL || '' || NULL
SELECT NULL || 'b' || '';
NULL || 'b' || ''
b
SELECT NULL || 'b' || 'c';
NULL || 'b' || 'c'
bc
SELECT NULL || 'b' || NULL;
NULL || 'b' || NULL
b
SELECT NULL || NULL || '';
NULL || NULL || ''
SELECT NULL || NULL || 'c';
NULL || NULL || 'c'
c
SELECT NULL || NULL || NULL;
NULL || NULL || NULL
NULL
CREATE TABLE t1 (a VARCHAR(10), b VARCHAR(10), c VARCHAR(10));
INSERT INTO t1 VALUES ('', '', '');
INSERT INTO t1 VALUES ('', '', 'c');
INSERT INTO t1 VALUES ('', '', NULL);
INSERT INTO t1 VALUES ('', 'b', '');
INSERT INTO t1 VALUES ('', 'b', 'c');
INSERT INTO t1 VALUES ('', 'b', NULL);
INSERT INTO t1 VALUES ('', NULL, '');
INSERT INTO t1 VALUES ('', NULL, 'c');
INSERT INTO t1 VALUES ('', NULL, NULL);
INSERT INTO t1 VALUES ('a', '', '');
INSERT INTO t1 VALUES ('a', '', 'c');
INSERT INTO t1 VALUES ('a', '', NULL);
INSERT INTO t1 VALUES ('a', 'b', '');
INSERT INTO t1 VALUES ('a', 'b', 'c');
INSERT INTO t1 VALUES ('a', 'b', NULL);
INSERT INTO t1 VALUES ('a', NULL, '');
INSERT INTO t1 VALUES ('a', NULL, 'c');
INSERT INTO t1 VALUES ('a', NULL, NULL);
INSERT INTO t1 VALUES (NULL, '', '');
INSERT INTO t1 VALUES (NULL, '', 'c');
INSERT INTO t1 VALUES (NULL, '', NULL);
INSERT INTO t1 VALUES (NULL, 'b', '');
INSERT INTO t1 VALUES (NULL, 'b', 'c');
INSERT INTO t1 VALUES (NULL, 'b', NULL);
INSERT INTO t1 VALUES (NULL, NULL, '');
INSERT INTO t1 VALUES (NULL, NULL, 'c');
INSERT INTO t1 VALUES (NULL, NULL, NULL);
SELECT LENGTH(a||b||c), a||b||c FROM t1 ORDER BY a,b,c;
LENGTH(a||b||c) a||b||c
NULL NULL
0
1 c
0
0
1 c
1 b
1 b
2 bc
0
0
1 c
0
0
1 c
1 b
1 b
2 bc
1 a
1 a
2 ac
1 a
1 a
2 ac
2 ab
2 ab
3 abc
DROP TABLE t1;
...@@ -178,9 +178,9 @@ EXECUTE IMMEDIATE 'SELECT :1 FROM DUAL' USING 10; ...@@ -178,9 +178,9 @@ EXECUTE IMMEDIATE 'SELECT :1 FROM DUAL' USING 10;
# Testing erroneous and diallowed prepare source # Testing erroneous and diallowed prepare source
# #
EXECUTE IMMEDIATE _latin1'SELECT 1 AS c FROM ' || _latin2 'DUAL'; EXECUTE IMMEDIATE _latin1'SELECT 1 AS c FROM ' || _latin2 'DUAL';
ERROR HY000: Illegal mix of collations (latin1_swedish_ci,COERCIBLE) and (latin2_general_ci,COERCIBLE) for operation 'concat' ERROR HY000: Illegal mix of collations (latin1_swedish_ci,COERCIBLE) and (latin2_general_ci,COERCIBLE) for operation '||'
PREPARE stmt FROM _latin1'SELECT 1 AS c FROM ' || _latin2 'DUAL'; PREPARE stmt FROM _latin1'SELECT 1 AS c FROM ' || _latin2 'DUAL';
ERROR HY000: Illegal mix of collations (latin1_swedish_ci,COERCIBLE) and (latin2_general_ci,COERCIBLE) for operation 'concat' ERROR HY000: Illegal mix of collations (latin1_swedish_ci,COERCIBLE) and (latin2_general_ci,COERCIBLE) for operation '||'
EXECUTE IMMEDIATE (SELECT 'SELECT 1'); EXECUTE IMMEDIATE (SELECT 'SELECT 1');
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 'SELECT 'SELECT 1')' at line 1 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 'SELECT 'SELECT 1')' at line 1
PREPARE stmt FROM (SELECT 'SELECT 1'); PREPARE stmt FROM (SELECT 'SELECT 1');
......
#
# Testing CONCAT with null values
#
SET sql_mode=ORACLE;
EXPLAIN EXTENDED SELECT 'a'||'b'||'c';
SELECT '' || '';
SELECT '' || 'b';
SELECT '' || NULL;
SELECT 'a' || '';
SELECT 'a' || 'b';
SELECT 'a' || NULL;
SELECT NULL || '';
SELECT NULL || 'b';
SELECT NULL || NULL;
SELECT '' || '' || '';
SELECT '' || '' || 'c';
SELECT '' || '' || NULL;
SELECT '' || 'b' || '';
SELECT '' || 'b' || 'c';
SELECT '' || 'b' || NULL;
SELECT '' || NULL || '';
SELECT '' || NULL || 'c';
SELECT '' || NULL || NULL;
SELECT 'a' || '' || '';
SELECT 'a' || '' || 'c';
SELECT 'a' || '' || NULL;
SELECT 'a' || 'b' || '';
SELECT 'a' || 'b' || 'c';
SELECT 'a' || 'b' || NULL;
SELECT 'a' || NULL || '';
SELECT 'a' || NULL || 'c';
SELECT 'a' || NULL || NULL;
SELECT NULL || '' || '';
SELECT NULL || '' || 'c';
SELECT NULL || '' || NULL;
SELECT NULL || 'b' || '';
SELECT NULL || 'b' || 'c';
SELECT NULL || 'b' || NULL;
SELECT NULL || NULL || '';
SELECT NULL || NULL || 'c';
SELECT NULL || NULL || NULL;
CREATE TABLE t1 (a VARCHAR(10), b VARCHAR(10), c VARCHAR(10));
INSERT INTO t1 VALUES ('', '', '');
INSERT INTO t1 VALUES ('', '', 'c');
INSERT INTO t1 VALUES ('', '', NULL);
INSERT INTO t1 VALUES ('', 'b', '');
INSERT INTO t1 VALUES ('', 'b', 'c');
INSERT INTO t1 VALUES ('', 'b', NULL);
INSERT INTO t1 VALUES ('', NULL, '');
INSERT INTO t1 VALUES ('', NULL, 'c');
INSERT INTO t1 VALUES ('', NULL, NULL);
INSERT INTO t1 VALUES ('a', '', '');
INSERT INTO t1 VALUES ('a', '', 'c');
INSERT INTO t1 VALUES ('a', '', NULL);
INSERT INTO t1 VALUES ('a', 'b', '');
INSERT INTO t1 VALUES ('a', 'b', 'c');
INSERT INTO t1 VALUES ('a', 'b', NULL);
INSERT INTO t1 VALUES ('a', NULL, '');
INSERT INTO t1 VALUES ('a', NULL, 'c');
INSERT INTO t1 VALUES ('a', NULL, NULL);
INSERT INTO t1 VALUES (NULL, '', '');
INSERT INTO t1 VALUES (NULL, '', 'c');
INSERT INTO t1 VALUES (NULL, '', NULL);
INSERT INTO t1 VALUES (NULL, 'b', '');
INSERT INTO t1 VALUES (NULL, 'b', 'c');
INSERT INTO t1 VALUES (NULL, 'b', NULL);
INSERT INTO t1 VALUES (NULL, NULL, '');
INSERT INTO t1 VALUES (NULL, NULL, 'c');
INSERT INTO t1 VALUES (NULL, NULL, NULL);
SELECT LENGTH(a||b||c), a||b||c FROM t1 ORDER BY a,b,c;
DROP TABLE t1;
...@@ -547,125 +547,85 @@ String *Item_func_decode_histogram::val_str(String *str) ...@@ -547,125 +547,85 @@ String *Item_func_decode_histogram::val_str(String *str)
String *Item_func_concat::val_str(String *str) String *Item_func_concat::val_str(String *str)
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
String *res,*res2,*use_as_buff; THD *thd= current_thd;
String *res,*use_as_buff;
uint i; uint i;
bool is_const= 0; bool is_const= 0;
null_value=0; null_value=0;
if (!(res=args[0]->val_str(str))) if (!(res= arg_val_str(0, str, &is_const)))
goto null; goto null;
use_as_buff= &tmp_value; use_as_buff= &tmp_value;
is_const= args[0]->const_item();
for (i=1 ; i < arg_count ; i++) for (i=1 ; i < arg_count ; i++)
{ {
if (res->length() == 0) if (res->length() == 0)
{ {
if (!(res=args[i]->val_str(str)))
goto null;
/* /*
CONCAT accumulates its result in the result of its the first CONCAT accumulates its result in the result of its the first
non-empty argument. Because of this we need is_const to be non-empty argument. Because of this we need is_const to be
evaluated only for it. evaluated only for it.
*/ */
is_const= args[i]->const_item(); if (!(res= arg_val_str(i, str, &is_const)))
goto null;
} }
else else
{ {
const String *res2;
if (!(res2=args[i]->val_str(use_as_buff))) if (!(res2=args[i]->val_str(use_as_buff)))
goto null; goto null;
if (res2->length() == 0) if (res2->length() == 0)
continue; continue;
if (res->length()+res2->length() > if (!(res= append_value(thd, res, is_const, str, &use_as_buff, res2)))
current_thd->variables.max_allowed_packet) goto null;
{ is_const= 0;
THD *thd= current_thd; }
push_warning_printf(thd, Sql_condition::WARN_LEVEL_WARN, }
ER_WARN_ALLOWED_PACKET_OVERFLOWED, res->set_charset(collation.collation);
ER_THD(thd, ER_WARN_ALLOWED_PACKET_OVERFLOWED), return res;
func_name(),
thd->variables.max_allowed_packet);
goto null;
}
if (!is_const && res->alloced_length() >= res->length()+res2->length())
{ // Use old buffer
res->append(*res2);
}
else if (str->alloced_length() >= res->length()+res2->length())
{
if (str->ptr() == res2->ptr())
str->replace(0,0,*res);
else
{
str->copy(*res);
str->append(*res2);
}
res= str;
use_as_buff= &tmp_value;
}
else if (res == &tmp_value)
{
if (res->append(*res2)) // Must be a blob
goto null;
}
else if (res2 == &tmp_value)
{ // This can happend only 1 time
if (tmp_value.replace(0,0,*res))
goto null;
res= &tmp_value;
use_as_buff=str; // Put next arg here
}
else if (tmp_value.is_alloced() && res2->ptr() >= tmp_value.ptr() &&
res2->ptr() <= tmp_value.ptr() + tmp_value.alloced_length())
{
/*
This happens really seldom:
In this case res2 is sub string of tmp_value. We will
now work in place in tmp_value to set it to res | res2
*/
/* Chop the last characters in tmp_value that isn't in res2 */
tmp_value.length((uint32) (res2->ptr() - tmp_value.ptr()) +
res2->length());
/* Place res2 at start of tmp_value, remove chars before res2 */
if (tmp_value.replace(0,(uint32) (res2->ptr() - tmp_value.ptr()),
*res))
goto null;
res= &tmp_value;
use_as_buff=str; // Put next arg here
}
else
{ // Two big const strings
/*
NOTE: We should be prudent in the initial allocation unit -- the
size of the arguments is a function of data distribution, which
can be any. Instead of overcommitting at the first row, we grow
the allocated amount by the factor of 2. This ensures that no
more than 25% of memory will be overcommitted on average.
*/
uint concat_len= res->length() + res2->length(); null:
null_value=1;
return 0;
}
if (tmp_value.alloced_length() < concat_len)
{
if (tmp_value.alloced_length() == 0)
{
if (tmp_value.alloc(concat_len))
goto null;
}
else
{
uint new_len = MY_MAX(tmp_value.alloced_length() * 2, concat_len);
if (tmp_value.realloc(new_len)) String *Item_func_concat_operator_oracle::val_str(String *str)
goto null; {
} THD *thd= current_thd;
} DBUG_ASSERT(fixed == 1);
String *res, *use_as_buff;
uint i;
bool is_const= false;
if (tmp_value.copy(*res) || tmp_value.append(*res2)) null_value= 0;
goto null; // Search first non null argument
for (i= 0; i < arg_count; i++)
{
if ((res= arg_val_str(i, str, &is_const)))
break;
}
if (i == arg_count)
goto null;
res= &tmp_value; use_as_buff= &tmp_value;
use_as_buff=str;
} for (i++ ; i < arg_count ; i++)
{
if (res->length() == 0)
{
// See comments in Item_func_concat::val_str()
String *tmp;
if (!(tmp= arg_val_str(i, str, &is_const)))
continue;
res= tmp;
}
else
{
const String *res2;
if (!(res2= args[i]->val_str(use_as_buff)) || res2->length() == 0)
continue;
if (!(res= append_value(thd, res, is_const, str, &use_as_buff, res2)))
goto null;
is_const= 0; is_const= 0;
} }
} }
...@@ -673,11 +633,123 @@ String *Item_func_concat::val_str(String *str) ...@@ -673,11 +633,123 @@ String *Item_func_concat::val_str(String *str)
return res; return res;
null: null:
null_value=1; null_value= true;
return 0; return 0;
} }
String *Item_func_concat::append_value(THD *thd,
String *res,
bool res_is_const,
String *str,
String **use_as_buff,
const String *res2)
{
DBUG_ASSERT(res2->length() > 0);
if ((ulong) res->length() + (ulong) res2->length() >
thd->variables.max_allowed_packet)
{
push_warning_printf(thd, Sql_condition::WARN_LEVEL_WARN,
ER_WARN_ALLOWED_PACKET_OVERFLOWED,
ER_THD(thd, ER_WARN_ALLOWED_PACKET_OVERFLOWED),
func_name(),
thd->variables.max_allowed_packet);
return NULL;
}
uint32 concat_len= res->length() + res2->length();
if (!res_is_const && res->alloced_length() >= concat_len)
{ // Use old buffer
return res->append(*res2) ? NULL : res;
}
if (str->alloced_length() >= concat_len)
{
if (str->ptr() == res2->ptr())
{
if (str->replace(0, 0, *res))
return NULL;
}
else
{
if (str->copy(*res) || str->append(*res2))
return NULL;
}
*use_as_buff= &tmp_value;
return str;
}
if (res == &tmp_value)
{
if (res->append(*res2)) // Must be a blob
return NULL;
return res;
}
if (res2 == &tmp_value)
{ // This can happend only 1 time
if (tmp_value.replace(0, 0, *res))
return NULL;
*use_as_buff= str; // Put next arg here
return &tmp_value;
}
if (tmp_value.is_alloced() && res2->ptr() >= tmp_value.ptr() &&
res2->ptr() <= tmp_value.ptr() + tmp_value.alloced_length())
{
/*
This happens really seldom:
In this case res2 is sub string of tmp_value. We will
now work in place in tmp_value to set it to res | res2
*/
/* Chop the last characters in tmp_value that isn't in res2 */
tmp_value.length((uint32) (res2->ptr() - tmp_value.ptr()) +
res2->length());
/* Place res2 at start of tmp_value, remove chars before res2 */
if (tmp_value.replace(0,(uint32) (res2->ptr() - tmp_value.ptr()),
*res))
return NULL;
*use_as_buff= str; // Put next arg here
return &tmp_value;
}
/*
Two big const strings
NOTE: We should be prudent in the initial allocation unit -- the
size of the arguments is a function of data distribution, which
can be any. Instead of overcommitting at the first row, we grow
the allocated amount by the factor of 2. This ensures that no
more than 25% of memory will be overcommitted on average.
*/
if (tmp_value.alloced_length() < concat_len)
{
if (tmp_value.alloced_length() == 0)
{
if (tmp_value.alloc(concat_len))
return NULL;
}
else
{
uint32 new_len= tmp_value.alloced_length() > INT_MAX32 ?
UINT_MAX32 - 1 :
tmp_value.alloced_length() * 2;
set_if_bigger(new_len, concat_len);
if (tmp_value.realloc(new_len))
return NULL;
}
}
if (tmp_value.copy(*res) || tmp_value.append(*res2))
return NULL;
*use_as_buff= str;
return &tmp_value;
}
void Item_func_concat::fix_length_and_dec() void Item_func_concat::fix_length_and_dec()
{ {
ulonglong char_length= 0; ulonglong char_length= 0;
......
...@@ -245,7 +245,40 @@ class Item_func_aes_decrypt :public Item_aes_crypt ...@@ -245,7 +245,40 @@ class Item_func_aes_decrypt :public Item_aes_crypt
class Item_func_concat :public Item_str_func class Item_func_concat :public Item_str_func
{ {
protected:
String tmp_value; String tmp_value;
/*
Get the i-th argument val_str() and its const_item()
@param i[IN] - The argument number
@param str[IN] - The buffer for val_str()
@param is_const[IN/OUT] - If args[i]->val_str() returned a non-null value,
then args[i]->const_item() is returned here.
Otherwise, the value of is_const is not touched.
@retval - the result of val_str().
*/
String *arg_val_str(uint i, String *str, bool *is_const)
{
String *res= args[i]->val_str(str);
if (res)
*is_const= args[i]->const_item();
return res;
}
/*
Append a non-NULL value to the result.
@param [IN] thd - The current thread.
@param [IN/OUT] res - The current val_str() return value.
@param [IN] res_is_const - If "false", then OK to append to "res"
@param [IN/OUT] str - The val_str() argument.
@param [IN] res2 - The value to be appended.
@param [IN/OUT] use_as_buff - Which buffer to use for the next argument:
args[next_arg]->val_str(use_as_buff)
*/
String *append_value(THD *thd,
String *res,
bool res_is_const,
String *str,
String **use_as_buff,
const String *res2);
public: public:
Item_func_concat(THD *thd, List<Item> &list): Item_str_func(thd, list) {} Item_func_concat(THD *thd, List<Item> &list): Item_str_func(thd, list) {}
Item_func_concat(THD *thd, Item *a, Item *b): Item_str_func(thd, a, b) {} Item_func_concat(THD *thd, Item *a, Item *b): Item_str_func(thd, a, b) {}
...@@ -256,6 +289,30 @@ class Item_func_concat :public Item_str_func ...@@ -256,6 +289,30 @@ class Item_func_concat :public Item_str_func
{ return get_item_copy<Item_func_concat>(thd, mem_root, this); } { return get_item_copy<Item_func_concat>(thd, mem_root, this); }
}; };
/*
This class handles the || operator in sql_mode=ORACLE.
Unlike the traditional MariaDB concat(), it treats NULL arguments as ''.
*/
class Item_func_concat_operator_oracle :public Item_func_concat
{
public:
Item_func_concat_operator_oracle(THD *thd, Item *a, Item *b)
:Item_func_concat(thd, a, b)
{ }
void print(String *str, enum_query_type query_type)
{
print_op(str, query_type);
}
String *val_str(String *);
const char *func_name() const { return "||"; }
Item *get_copy(THD *thd, MEM_ROOT *mem_root)
{
return get_item_copy<Item_func_concat_operator_oracle>(thd, mem_root, this);
}
};
class Item_func_decode_histogram :public Item_str_func class Item_func_decode_histogram :public Item_str_func
{ {
String tmp_value; String tmp_value;
......
...@@ -9102,7 +9102,8 @@ simple_expr: ...@@ -9102,7 +9102,8 @@ simple_expr:
} }
| simple_expr OR_OR_SYM simple_expr | simple_expr OR_OR_SYM simple_expr
{ {
$$= new (thd->mem_root) Item_func_concat(thd, $1, $3); $$= new (thd->mem_root) Item_func_concat_operator_oracle(thd,
$1, $3);
if ($$ == NULL) if ($$ == NULL)
MYSQL_YYABORT; MYSQL_YYABORT;
} }
......
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