From 3e6893e29a4298e9bb11bd91c6f8f88c7c1191d0 Mon Sep 17 00:00:00 2001 From: halfspawn Date: Tue, 13 Mar 2018 10:34:28 +0100 Subject: [PATCH] MDEV-10574 / SUBSTR - sql_mode=Oracle: return null instead of empty string --- .../suite/compat/oracle/r/func_substr.result | 47 +++++++++++++++++-- .../suite/compat/oracle/t/func_substr.test | 31 +++++++++--- sql/item_strfunc.h | 9 +++- 3 files changed, 75 insertions(+), 12 deletions(-) diff --git a/mysql-test/suite/compat/oracle/r/func_substr.result b/mysql-test/suite/compat/oracle/r/func_substr.result index eca5f480191..5d9fdd5f2b9 100644 --- a/mysql-test/suite/compat/oracle/r/func_substr.result +++ b/mysql-test/suite/compat/oracle/r/func_substr.result @@ -1,3 +1,7 @@ +# +# MDEV-14012 - sql_mode=Oracle: substr(): treat position 0 as position 1 +# MDEV-10574 - sql_mode=Oracle: return null instead of empty string +# SET sql_mode=ORACLE; SELECT SUBSTR('abc',2,1),SUBSTR('abc',1,1), SUBSTR('abc',0,1) FROM dual; SUBSTR('abc',2,1) SUBSTR('abc',1,1) SUBSTR('abc',0,1) @@ -22,19 +26,52 @@ SUBSTR('abc',2,null) SUBSTR('abc',1,null) SUBSTR('abc',0,null) NULL NULL NULL SELECT SUBSTR('abc',2,0),SUBSTR('abc',1,0), SUBSTR('abc',0,0) FROM dual; SUBSTR('abc',2,0) SUBSTR('abc',1,0) SUBSTR('abc',0,0) - -create table t1 (c1 varchar(10),start integer, length integer); +NULL NULL NULL +SELECT SUBSTR('abc',2,-1),SUBSTR('abc',1,-1), SUBSTR('abc',0,-1) FROM dual; +SUBSTR('abc',2,-1) SUBSTR('abc',1,-1) SUBSTR('abc',0,-1) +NULL NULL NULL +SELECT SUBSTR(SPACE(0),1) FROM DUAL; +SUBSTR(SPACE(0),1) +NULL +CREATE TABLE t1 (c1 VARCHAR(10),start INTEGER, length INTEGER); INSERT INTO t1 VALUES ('abc', 1, 1); INSERT INTO t1 VALUES ('abc', 0, 1); INSERT INTO t1 VALUES (null, 1, 1); INSERT INTO t1 VALUES (null, 0, 1); -select substr(c1,start,length) from t1; -substr(c1,start,length) +INSERT INTO t1 VALUES ('abc', 1, 0); +INSERT INTO t1 VALUES ('abc', 0, 0); +INSERT INTO t1 VALUES (null, 1, 0); +INSERT INTO t1 VALUES (null, 0, 0); +INSERT INTO t1 VALUES ('abc', 1, -1); +INSERT INTO t1 VALUES ('abc', 0, -1); +INSERT INTO t1 VALUES (null, 1, -1); +INSERT INTO t1 VALUES (null, 0, -1); +INSERT INTO t1 VALUES (SPACE(0), 0, 1); +SELECT SUBSTR(c1,start,length) FROM t1; +SUBSTR(c1,start,length) a a NULL NULL -drop table t1; +NULL +NULL +NULL +NULL +NULL +NULL +NULL +NULL +NULL +DROP TABLE t1; +CREATE TABLE t1 (c1 VARCHAR(10) NOT NULL); +CREATE TABLE t2 AS SELECT SUBSTR(C1,1,1) AS C1 from t1; +SHOW CREATE TABLE t2; +Table Create Table +t2 CREATE TABLE "t2" ( + "C1" varchar(1) DEFAULT NULL +) +DROP TABLE t2; +DROP TABLE t1; EXPLAIN EXTENDED SELECT SUBSTR('abc',2,1) ; 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 diff --git a/mysql-test/suite/compat/oracle/t/func_substr.test b/mysql-test/suite/compat/oracle/t/func_substr.test index 5d5ec78abdd..b661dfd3779 100644 --- a/mysql-test/suite/compat/oracle/t/func_substr.test +++ b/mysql-test/suite/compat/oracle/t/func_substr.test @@ -1,6 +1,7 @@ -# -# MDEV-14012 - sql_mode=Oracle: substr(): treat position 0 as position 1 -# +--echo # +--echo # MDEV-14012 - sql_mode=Oracle: substr(): treat position 0 as position 1 +--echo # MDEV-10574 - sql_mode=Oracle: return null instead of empty string +--echo # SET sql_mode=ORACLE; SELECT SUBSTR('abc',2,1),SUBSTR('abc',1,1), SUBSTR('abc',0,1) FROM dual; @@ -11,14 +12,32 @@ SELECT SUBSTR('abc',-2,1),SUBSTR('abc',-1,1), SUBSTR('abc',-0,1) FROM dual; SELECT SUBSTR('abc',null) FROM dual; SELECT SUBSTR('abc',2,null),SUBSTR('abc',1,null), SUBSTR('abc',0,null) FROM dual; SELECT SUBSTR('abc',2,0),SUBSTR('abc',1,0), SUBSTR('abc',0,0) FROM dual; +SELECT SUBSTR('abc',2,-1),SUBSTR('abc',1,-1), SUBSTR('abc',0,-1) FROM dual; +SELECT SUBSTR(SPACE(0),1) FROM DUAL; -create table t1 (c1 varchar(10),start integer, length integer); +CREATE TABLE t1 (c1 VARCHAR(10),start INTEGER, length INTEGER); INSERT INTO t1 VALUES ('abc', 1, 1); INSERT INTO t1 VALUES ('abc', 0, 1); INSERT INTO t1 VALUES (null, 1, 1); INSERT INTO t1 VALUES (null, 0, 1); -select substr(c1,start,length) from t1; -drop table t1; +INSERT INTO t1 VALUES ('abc', 1, 0); +INSERT INTO t1 VALUES ('abc', 0, 0); +INSERT INTO t1 VALUES (null, 1, 0); +INSERT INTO t1 VALUES (null, 0, 0); +INSERT INTO t1 VALUES ('abc', 1, -1); +INSERT INTO t1 VALUES ('abc', 0, -1); +INSERT INTO t1 VALUES (null, 1, -1); +INSERT INTO t1 VALUES (null, 0, -1); +INSERT INTO t1 VALUES (SPACE(0), 0, 1); + +SELECT SUBSTR(c1,start,length) FROM t1; +DROP TABLE t1; + +CREATE TABLE t1 (c1 VARCHAR(10) NOT NULL); +CREATE TABLE t2 AS SELECT SUBSTR(C1,1,1) AS C1 from t1; +SHOW CREATE TABLE t2; +DROP TABLE t2; +DROP TABLE t1; EXPLAIN EXTENDED SELECT SUBSTR('abc',2,1) ; diff --git a/sql/item_strfunc.h b/sql/item_strfunc.h index a357c03bda5..3c8a699fffe 100644 --- a/sql/item_strfunc.h +++ b/sql/item_strfunc.h @@ -35,7 +35,7 @@ protected: character set. No memory is allocated. @retval A pointer to the str_value member. */ - String *make_empty_result() + virtual String *make_empty_result() { /* Reset string length to an empty string. We don't use str_value.set() as @@ -500,11 +500,18 @@ class Item_func_substr_oracle :public Item_func_substr protected: longlong get_position() { longlong pos= args[1]->val_int(); return pos == 0 ? 1 : pos; } + String *make_empty_result() + { null_value= 1; return NULL; } public: Item_func_substr_oracle(THD *thd, Item *a, Item *b): Item_func_substr(thd, a, b) {} Item_func_substr_oracle(THD *thd, Item *a, Item *b, Item *c): Item_func_substr(thd, a, b, c) {} + void fix_length_and_dec() + { + Item_func_substr::fix_length_and_dec(); + maybe_null= true; + } const char *func_name() const { return "substr_oracle"; } Item *get_copy(THD *thd, MEM_ROOT *mem_root) { return get_item_copy(thd, mem_root, this); }