Skip to content

Commit

Permalink
MDEV-11880 sql_mode=ORACLE: Make the concatenation operator ignore NU…
Browse files Browse the repository at this point in the history
…LL arguments

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

Based on the contributed patch from Jérôme Brauge.
  • Loading branch information
Alexander Barkov committed Apr 5, 2017
1 parent 46255b0 commit 0879983
Show file tree
Hide file tree
Showing 6 changed files with 483 additions and 98 deletions.
172 changes: 172 additions & 0 deletions mysql-test/suite/compat/oracle/r/func_concat.result
@@ -0,0 +1,172 @@
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;
4 changes: 2 additions & 2 deletions mysql-test/suite/compat/oracle/r/ps.result
Expand Up @@ -178,9 +178,9 @@ EXECUTE IMMEDIATE 'SELECT :1 FROM DUAL' USING 10;
# Testing erroneous and diallowed prepare source
#
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';
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');
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');
Expand Down
83 changes: 83 additions & 0 deletions mysql-test/suite/compat/oracle/t/func_concat.test
@@ -0,0 +1,83 @@
#
# 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;

0 comments on commit 0879983

Please sign in to comment.