Commit ea751857 authored by Alexander Barkov's avatar Alexander Barkov

Merge bb-10.2-compatibility into 10.3

parents 9764efe5 e1cff0ac
......@@ -161,6 +161,8 @@ sql/mysqld
sql/sql_builtin.cc
sql/sql_yacc.cc
sql/sql_yacc.h
sql/sql_yacc_ora.cc
sql/sql_yacc_ora.h
storage/heap/hp_test1
storage/heap/hp_test2
storage/maria/aria_chk
......
......@@ -50,7 +50,7 @@ MACRO (RUN_BISON input_yy output_cc output_h)
ADD_CUSTOM_COMMAND(
OUTPUT ${output_cc}
${output_h}
COMMAND ${BISON_EXECUTABLE} -y -p MYSQL
COMMAND ${BISON_EXECUTABLE} -y
--output=${output_cc}
--defines=${output_h}
${input_yy}
......
......@@ -30,6 +30,8 @@ ${SSL_INTERNAL_INCLUDE_DIRS}
SET(GEN_SOURCES
${CMAKE_BINARY_DIR}/sql/sql_yacc.h
${CMAKE_BINARY_DIR}/sql/sql_yacc.cc
${CMAKE_BINARY_DIR}/sql/sql_yacc_ora.h
${CMAKE_BINARY_DIR}/sql/sql_yacc_ora.cc
${CMAKE_BINARY_DIR}/sql/lex_hash.h
)
......
......@@ -171,6 +171,7 @@ my @DEFAULT_SUITES= qw(
binlog-
binlog_encryption-
csv-
compat/oracle-
encryption-
federated-
funcs_1-
......
......@@ -274,7 +274,7 @@ drop table option;
set option=1;
ERROR HY000: Unknown system variable 'option'
set option option=1;
ERROR HY000: Unknown system variable 'option'
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 'option=1' at line 1
#
# MDEV-9979 Keywords UNBOUNDED, PRECEDING, FOLLOWING, TIES, OTHERS should be non-reserved
#
......@@ -331,3 +331,30 @@ DROP TABLE OTHERS;
#
CREATE TABLE immediate (immediate int);
DROP TABLE immediate;
#
# MDEV-10142 Pluggable parser
# Testing keywords that were added into lex.h for Oracle compatibility
# that are not reserved keywords in MariaDB
#
CREATE TABLE clob (clob int);
DROP TABLE clob;
CREATE TABLE elsif (elsif INT);
DROP TABLE elsif;
CREATE TABLE exception (exception INT);
DROP TABLE exception;
CREATE TABLE raw (raw int);
DROP TABLE raw;
CREATE TABLE varchar2 (varchar2 int);
DROP TABLE varchar2;
CREATE TABLE decode (decode int);
DROP TABLE decode;
CREATE TABLE rowcount (rowcount int);
DROP TABLE rowcount;
CREATE TABLE isopen (isopen int);
DROP TABLE isopen;
CREATE TABLE notfound (notfound int);
DROP TABLE notfound;
CREATE TABLE raise (raise int);
DROP TABLE raise;
CREATE TABLE reuse (reuse int);
DROP TABLE reuse;
......@@ -1319,3 +1319,12 @@ t1 CREATE TABLE `t1` (
UNIQUE KEY `id` (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=latin1
drop table t1;
#
# MDEV-10343 Providing compatibility for basic SQL data types
#
CREATE TABLE clob (clob int);
DROP TABLE clob;
CREATE TABLE raw (raw int);
DROP TABLE raw;
CREATE TABLE varchar2 (varchar2 int);
DROP TABLE varchar2;
......@@ -1504,7 +1504,7 @@ ERROR 42000: FUNCTION inexistent does not exist
SELECT .inexistent();
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 ..inexistent();
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 '.inexistent()' 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 '..inexistent()' at line 1
USE test;
create function f1() returns int
begin
......
This diff is collapsed.
......@@ -673,7 +673,6 @@ vb IS TRUE;
END|
call p1();
HEX(b) b = 0 b = FALSE b IS FALSE b = 1 b = TRUE b IS TRUE
0 1 1 1 0 0 0
1 0 0 0 1 1 1
call p2();
......
......@@ -6908,7 +6908,7 @@ drop procedure if exists p;
set @old_mode= @@sql_mode;
set @@sql_mode= cast(pow(2,32)-1 as unsigned integer);
select @@sql_mode into @full_mode;
create procedure p() begin end;
create procedure p() as begin end;
call p();
set @@sql_mode= @old_mode;
select replace(@full_mode, 'ALLOW_INVALID_DATES', 'INVALID_DATES') into @full_mode;
......@@ -8127,3 +8127,109 @@ v_name v_total
c 1
DROP PROCEDURE p1;
DROP TABLE t1;
#
# Start of 10.3 tests
#
#
# MDEV-12007 Allow ROW variables as a cursor FETCH target
#
# The cursor and the ROW variable in FETCH must have the same number of fields
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32), cc INT);
DECLARE cur CURSOR FOR SELECT 10 AS a,'b10' AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
ERROR HY000: Incorrect number of FETCH variables
DROP PROCEDURE p1;
# Multiple ROW variables in FETCH
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec1 ROW(aa INT);
DECLARE rec2 ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a, 20 AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec1, rec2;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
ERROR 21000: Operand should contain 1 column(s)
DROP PROCEDURE p1;
# A complete working example
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10,'b10');
INSERT INTO t1 VALUES (20,'b20');
INSERT INTO t1 VALUES (30,'b30');
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32));
DECLARE cur CURSOR FOR SELECT a,b FROM t1;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,',',rec.bb,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
c
rec=(10,b10)
c
rec=(20,b20)
c
rec=(30,b30)
DROP PROCEDURE p1;
DROP TABLE t1;
# A ROW variable with a single field
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a UNION SELECT 20;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
c
rec=(10)
c
rec=(20)
DROP PROCEDURE p1;
......@@ -672,9 +672,9 @@ select @a, @b;
@a @b
2 1
set @@global.global.key_buffer_size= 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 'key_buffer_size= 1' at line 1
ERROR HY000: Unknown structured system variable or ROW routine variable 'global'
set GLOBAL global.key_buffer_size= 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 'key_buffer_size= 1' at line 1
ERROR HY000: Unknown structured system variable or ROW routine variable 'global'
SELECT @@global.global.key_buffer_size;
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 'key_buffer_size' at line 1
SELECT @@global.session.key_buffer_size;
......
SET sql_mode=ORACLE;
#
# MDEV-10914 ROW data type for stored routine variables
#
CREATE TABLE t1 (a INT, b INT);
CREATE PROCEDURE p1
AS
rec ROW(a INT,b INT);
BEGIN
rec.a:=100;
rec.b:=200;
INSERT INTO t1 VALUES (rec.a,rec.b);
INSERT INTO t1 VALUES (10, rec=ROW(100,200));
INSERT INTO t1 VALUES (10, ROW(100,200)=rec);
INSERT INTO t1 SELECT 10, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 10, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.a:=NULL;
INSERT INTO t1 VALUES (11, rec=ROW(100,200));
INSERT INTO t1 VALUES (11, rec=ROW(100,201));
INSERT INTO t1 VALUES (11, ROW(100,200)=rec);
INSERT INTO t1 VALUES (11, ROW(100,201)=rec);
INSERT INTO t1 SELECT 11, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 11, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.b:=NULL;
INSERT INTO t1 VALUES (12, rec=ROW(100,200));
INSERT INTO t1 VALUES (12, ROW(100,200)=rec);
INSERT INTO t1 SELECT 12, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 12, 21 FROM DUAL WHERE ROW(100,200)=rec;
END;
$$
CALL p1();
SELECT * FROM t1;
a b
100 200
10 1
10 1
10 20
10 21
11 NULL
11 0
11 NULL
11 0
12 NULL
12 NULL
DROP TABLE t1;
DROP PROCEDURE p1;
include/show_binlog_events.inc
Log_name Pos Event_type Server_id End_log_pos Info
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE TABLE t1 (a INT, b INT)
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
AS
rec ROW(a INT,b INT);
BEGIN
rec.a:=100;
rec.b:=200;
INSERT INTO t1 VALUES (rec.a,rec.b);
INSERT INTO t1 VALUES (10, rec=ROW(100,200));
INSERT INTO t1 VALUES (10, ROW(100,200)=rec);
INSERT INTO t1 SELECT 10, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 10, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.a:=NULL;
INSERT INTO t1 VALUES (11, rec=ROW(100,200));
INSERT INTO t1 VALUES (11, rec=ROW(100,201));
INSERT INTO t1 VALUES (11, ROW(100,200)=rec);
INSERT INTO t1 VALUES (11, ROW(100,201)=rec);
INSERT INTO t1 SELECT 11, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 11, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.b:=NULL;
INSERT INTO t1 VALUES (12, rec=ROW(100,200));
INSERT INTO t1 VALUES (12, ROW(100,200)=rec);
INSERT INTO t1 SELECT 12, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 12, 21 FROM DUAL WHERE ROW(100,200)=rec;
END
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES ( NAME_CONST('rec.a',100), NAME_CONST('rec.b',200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10, ROW(100,200)=ROW(100,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10, ROW(100,200)=ROW(100,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 10, 20 FROM DUAL WHERE ROW(100,200)=ROW(100,200)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 10, 21 FROM DUAL WHERE ROW(100,200)=ROW(100,200)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (11, ROW(NULL,200)=ROW(100,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (11, ROW(NULL,200)=ROW(100,201))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (11, ROW(100,200)=ROW(NULL,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (11, ROW(100,201)=ROW(NULL,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 11, 20 FROM DUAL WHERE ROW(NULL,200)=ROW(100,200)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 11, 21 FROM DUAL WHERE ROW(100,200)=ROW(NULL,200)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (12, ROW(NULL,NULL)=ROW(100,200))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (12, ROW(100,200)=ROW(NULL,NULL))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 12, 20 FROM DUAL WHERE ROW(NULL,NULL)=ROW(100,200)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 SELECT 12, 21 FROM DUAL WHERE ROW(100,200)=ROW(NULL,NULL)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP TABLE "t1" /* generated by server */
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PROCEDURE p1
#
# Testing ROW fields in LIMIT
#
FLUSH LOGS;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(10);
CREATE TABLE t2 (a INT);
CREATE PROCEDURE p1()
AS
a INT:= 1;
rec ROW(a INT);
BEGIN
rec.a:= 1;
INSERT INTO t2 SELECT 1 FROM t1 LIMIT a;
INSERT INTO t2 SELECT 2 FROM t1 LIMIT rec.a;
END;
$$
CALL p1();
Warnings:
Note 1592 Unsafe statement written to the binary log using statement format since BINLOG_FORMAT = STATEMENT. The statement is unsafe because it uses a LIMIT clause. This is unsafe because the set of rows included cannot be predicted
DROP TABLE t1,t2;
DROP PROCEDURE p1;
include/show_binlog_events.inc
Log_name Pos Event_type Server_id End_log_pos Info
master-bin.000002 # Binlog_checkpoint # # master-bin.000002
master-bin.000002 # Gtid # # GTID #-#-#
master-bin.000002 # Query # # use `test`; CREATE TABLE t1 (a INT)
master-bin.000002 # Gtid # # BEGIN GTID #-#-#
master-bin.000002 # Query # # use `test`; INSERT INTO t1 VALUES (10),(10)
master-bin.000002 # Query # # COMMIT
master-bin.000002 # Gtid # # GTID #-#-#
master-bin.000002 # Query # # use `test`; CREATE TABLE t2 (a INT)
master-bin.000002 # Gtid # # GTID #-#-#
master-bin.000002 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
AS
a INT:= 1;
rec ROW(a INT);
BEGIN
rec.a:= 1;
INSERT INTO t2 SELECT 1 FROM t1 LIMIT a;
INSERT INTO t2 SELECT 2 FROM t1 LIMIT rec.a;
END
master-bin.000002 # Gtid # # BEGIN GTID #-#-#
master-bin.000002 # Query # # use `test`; INSERT INTO t2 SELECT 1 FROM t1 LIMIT 1
master-bin.000002 # Query # # COMMIT
master-bin.000002 # Gtid # # BEGIN GTID #-#-#
master-bin.000002 # Query # # use `test`; INSERT INTO t2 SELECT 2 FROM t1 LIMIT 1
master-bin.000002 # Query # # COMMIT
master-bin.000002 # Gtid # # GTID #-#-#
master-bin.000002 # Query # # use `test`; DROP TABLE "t1","t2" /* generated by server */
master-bin.000002 # Gtid # # GTID #-#-#
master-bin.000002 # Query # # use `test`; DROP PROCEDURE p1
#
# End of MDEV-10914 ROW data type for stored routine variables
#
#
# MDEV-12291 Allow ROW variables as SELECT INTO targets
#
FLUSH LOGS;
SET sql_mode=DEFAULT;
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10, 'b10');
CREATE TABLE t2 LIKE t1;
CREATE PROCEDURE p1()
BEGIN
DECLARE rec1 ROW(a INT, b VARCHAR(32));
SELECT * INTO rec1 FROM t1;
INSERT INTO t2 VALUES (rec1.a, rec1.b);
END;
$$
CALL p1();
SELECT * FROM t1;
a b
10 b10
DROP TABLE t1;
DROP TABLE t2;
DROP PROCEDURE p1;
include/show_binlog_events.inc
Log_name Pos Event_type Server_id End_log_pos Info
master-bin.000003 # Binlog_checkpoint # # master-bin.000003
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; CREATE TABLE t1 (a INT, b VARCHAR(32))
master-bin.000003 # Gtid # # BEGIN GTID #-#-#
master-bin.000003 # Query # # use `test`; INSERT INTO t1 VALUES (10, 'b10')
master-bin.000003 # Query # # COMMIT
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; CREATE TABLE t2 LIKE t1
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; CREATE DEFINER=`root`@`localhost` PROCEDURE `p1`()
BEGIN
DECLARE rec1 ROW(a INT, b VARCHAR(32));
SELECT * INTO rec1 FROM t1;
INSERT INTO t2 VALUES (rec1.a, rec1.b);
END
master-bin.000003 # Gtid # # BEGIN GTID #-#-#
master-bin.000003 # Query # # use `test`; INSERT INTO t2 VALUES ( NAME_CONST('rec1.a',10), NAME_CONST('rec1.b',_latin1'b10' COLLATE 'latin1_swedish_ci'))
master-bin.000003 # Query # # COMMIT
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; DROP TABLE `t1` /* generated by server */
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; DROP TABLE `t2` /* generated by server */
master-bin.000003 # Gtid # # GTID #-#-#
master-bin.000003 # Query # # use `test`; DROP PROCEDURE p1
--source include/not_embedded.inc
--source include/have_binlog_format_statement.inc
--disable_query_log
call mtr.add_suppression("Unsafe statement written to the binary log using statement format since BINLOG_FORMAT = STATEMENT");
reset master; # get rid of previous tests binlog
--enable_query_log
SET sql_mode=ORACLE;
--echo #
--echo # MDEV-10914 ROW data type for stored routine variables
--echo #
CREATE TABLE t1 (a INT, b INT);
DELIMITER $$;
CREATE PROCEDURE p1
AS
rec ROW(a INT,b INT);
BEGIN
rec.a:=100;
rec.b:=200;
INSERT INTO t1 VALUES (rec.a,rec.b);
INSERT INTO t1 VALUES (10, rec=ROW(100,200));
INSERT INTO t1 VALUES (10, ROW(100,200)=rec);
INSERT INTO t1 SELECT 10, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 10, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.a:=NULL;
INSERT INTO t1 VALUES (11, rec=ROW(100,200));
INSERT INTO t1 VALUES (11, rec=ROW(100,201));
INSERT INTO t1 VALUES (11, ROW(100,200)=rec);
INSERT INTO t1 VALUES (11, ROW(100,201)=rec);
INSERT INTO t1 SELECT 11, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 11, 21 FROM DUAL WHERE ROW(100,200)=rec;
rec.b:=NULL;
INSERT INTO t1 VALUES (12, rec=ROW(100,200));
INSERT INTO t1 VALUES (12, ROW(100,200)=rec);
INSERT INTO t1 SELECT 12, 20 FROM DUAL WHERE rec=ROW(100,200);
INSERT INTO t1 SELECT 12, 21 FROM DUAL WHERE ROW(100,200)=rec;
END;
$$
DELIMITER ;$$
CALL p1();
SELECT * FROM t1;
DROP TABLE t1;
DROP PROCEDURE p1;
--let $binlog_file = LAST
source include/show_binlog_events.inc;
--echo #
--echo # Testing ROW fields in LIMIT
--echo #
FLUSH LOGS;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(10);
CREATE TABLE t2 (a INT);
DELIMITER $$;
CREATE PROCEDURE p1()
AS
a INT:= 1;
rec ROW(a INT);
BEGIN
rec.a:= 1;
INSERT INTO t2 SELECT 1 FROM t1 LIMIT a;
INSERT INTO t2 SELECT 2 FROM t1 LIMIT rec.a;
END;
$$
DELIMITER ;$$
CALL p1();
DROP TABLE t1,t2;
DROP PROCEDURE p1;
--let $binlog_file = LAST
source include/show_binlog_events.inc;
--echo #
--echo # End of MDEV-10914 ROW data type for stored routine variables
--echo #
--echo #
--echo # MDEV-12291 Allow ROW variables as SELECT INTO targets
--echo #
FLUSH LOGS;
SET sql_mode=DEFAULT;
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10, 'b10');
CREATE TABLE t2 LIKE t1;
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE rec1 ROW(a INT, b VARCHAR(32));
SELECT * INTO rec1 FROM t1;
INSERT INTO t2 VALUES (rec1.a, rec1.b);
END;
$$
DELIMITER ;$$
CALL p1();
SELECT * FROM t1;
DROP TABLE t1;
DROP TABLE t2;
DROP PROCEDURE p1;
--let $binlog_file = LAST
source include/show_binlog_events.inc;
SET sql_mode=ORACLE;
#
# MDEV-10801 sql_mode: dynamic SQL placeholders
#
CREATE TABLE t1 (a INT, b INT);
SET @a=10, @b=20;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (?,?)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:a,:b)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:aaa,:bbb)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:"a",:"b")';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:"aaa",:"bbb")';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:1,:2)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:222,:111)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:0,:65535)';
EXECUTE stmt USING @a, @b;
PREPARE stmt FROM 'INSERT INTO t1 VALUES (:65535,:0)';
EXECUTE stmt USING @a, @b;
SELECT * FROM t1;
a b
10 20
10 20
10 20
10 20
10 20
10 20
10 20
10 20
10 20
include/show_binlog_events.inc
Log_name Pos Event_type Server_id End_log_pos Info
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE TABLE t1 (a INT, b INT)
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES (10,20)
master-bin.000001 # Query # # COMMIT
DROP TABLE t1;
This diff is collapsed.
SET sql_mode=ORACLE;
#
# sql_mode=ORACLE: Predefined exceptions: TOO_MANY_ROWS, NO_DATA_FOUND, DUP_VAL_ON_INDEX
#
#
# Testing NO_DATA_FOUND and TOO_MANY_ROWS
#
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20);
CREATE PROCEDURE p1(lim INT, res OUT VARCHAR)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1 LIMIT lim;
EXCEPTION
WHEN TOO_MANY_ROWS THEN res:='--- too_many_rows cought ---';
WHEN NO_DATA_FOUND THEN res:='--- no_data_found cought ---';
END;
$$
SET @res='';
CALL p1(0, @res);
SELECT @res;
@res
--- no_data_found cought ---
CALL p1(2, @res);
SELECT @res;
@res
--- too_many_rows cought ---
DROP PROCEDURE p1;
DROP TABLE t1;
#
# Testing DUP_VAL_ON_INDEX
#
CREATE TABLE t1 (a INT PRIMARY KEY);
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
BEGIN
INSERT INTO t1 VALUES (10);
INSERT INTO t1 VALUES (10);
EXCEPTION
WHEN DUP_VAL_ON_INDEX THEN res:='--- dup_val_on_index cought ---';
END;
$$
SET @res='';
CALL p1(@res);
SELECT @res;
@res
--- dup_val_on_index cought ---
SELECT * FROM t1;
a
10
DROP PROCEDURE p1;
DROP TABLE t1;
#
# MDEV-10840 sql_mode=ORACLE: RAISE statement for predefined exceptions
#
#
# RAISE outside of an SP context
#
RAISE NO_DATA_FOUND;
ERROR 42000: Undefined CONDITION: NO_DATA_FOUND
RAISE INVALID_CURSOR;
ERROR 42000: Undefined CONDITION: INVALID_CURSOR
RAISE DUP_VAL_ON_INDEX;
ERROR 42000: Undefined CONDITION: DUP_VAL_ON_INDEX
RAISE TOO_MANY_ROWS;
ERROR 42000: Undefined CONDITION: TOO_MANY_ROWS
RAISE;
ERROR 0K000: RESIGNAL when handler not active
#
# RAISE for an undefinite exception
#
CREATE PROCEDURE p1
AS
BEGIN
RAISE xxx;
END;
$$
ERROR 42000: Undefined CONDITION: xxx
#
# RAISE for predefined exceptions
#
CREATE PROCEDURE p1
AS
BEGIN
RAISE no_data_found;
END;
$$
CALL p1();
Warnings:
Warning 1329 No data - zero rows fetched, selected, or processed
DROP PROCEDURE p1;
CREATE PROCEDURE p1
AS
BEGIN
RAISE invalid_cursor;
END;
$$
CALL p1();
ERROR 24000: Cursor is not open
DROP PROCEDURE p1;
CREATE PROCEDURE p1
AS
BEGIN
RAISE dup_val_on_index;
END;
$$
CALL p1();
ERROR 23000: Duplicate entry '%-.192s' for key %d
DROP PROCEDURE p1;
CREATE PROCEDURE p1
AS
BEGIN
raise too_many_rows;
END;
$$
CALL p1();
ERROR 42000: Result consisted of more than one row
DROP PROCEDURE p1;
#
# RAISE with no exception name (resignal)
#
CREATE PROCEDURE p1()
AS
BEGIN
RAISE;
END;
$$
CALL p1();
ERROR 0K000: RESIGNAL when handler not active
DROP PROCEDURE p1;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20);
CREATE PROCEDURE p1(lim INT)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1 LIMIT lim;
EXCEPTION
WHEN TOO_MANY_ROWS THEN RAISE;
WHEN NO_DATA_FOUND THEN RAISE;
END;
$$
CALL p1(0);
Warnings:
Warning 1329 No data - zero rows fetched, selected, or processed
CALL p1(2);
ERROR 42000: Result consisted of more than one row
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20);
CREATE PROCEDURE p1(lim INT)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1 LIMIT lim;
EXCEPTION
WHEN OTHERS THEN RAISE;
END;
$$
CALL p1(0);
Warnings:
Warning 1329 No data - zero rows fetched, selected, or processed
CALL p1(2);
ERROR 42000: Result consisted of more than one row
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20);
CREATE PROCEDURE p1()
AS
a INT;
CURSOR c IS SELECT a FROM t1;
BEGIN
FETCH c INTO a;
EXCEPTION
WHEN INVALID_CURSOR THEN RAISE;
END;
$$
CALL p1();
ERROR 24000: Cursor is not open
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20);
CREATE PROCEDURE p1()
AS
a INT;
CURSOR c IS SELECT a FROM t1;
BEGIN
FETCH c INTO a;
EXCEPTION
WHEN OTHERS THEN RAISE;
END;
$$
CALL p1();
ERROR 24000: Cursor is not open
DROP PROCEDURE p1;
DROP TABLE t1;
#
# Testing that warning-alike errors are caught by OTHERS
#
CREATE TABLE t1 (a INT);
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'OK';
EXCEPTION
WHEN OTHERS THEN RETURN 'Exception';
END;
$$
SELECT f1() FROM DUAL;
f1()
Exception
DROP FUNCTION f1;
DROP TABLE t1;
#
# End of MDEV-10840 sql_mode=ORACLE: RAISE statement for predefined exceptions
#
#
# MDEV-10587 sql_mode=ORACLE: User defined exceptions
#
#
# Checking that duplicate WHEN clause is not allowed
#
CREATE FUNCTION f1() RETURN VARCHAR
AS
e EXCEPTION;
BEGIN
RETURN 'Got no exceptions';
EXCEPTION
WHEN e THEN RETURN 'Got exception e';
WHEN e THEN RETURN 'Got exception e';
END;
$$
ERROR 42000: Duplicate handler declared in the same block
#
# Checking that raised user exceptions are further caught by name
#
CREATE FUNCTION f1(c VARCHAR) RETURN VARCHAR
AS
e EXCEPTION;
f EXCEPTION;
BEGIN
IF c = 'e' THEN RAISE e; END IF;
IF c = 'f' THEN RAISE f; END IF;
RETURN 'Got no exceptions';
EXCEPTION
WHEN e THEN RETURN 'Got exception e';
END;
$$
SELECT f1('');
f1('')
Got no exceptions
SELECT f1('e');
f1('e')
Got exception e
SELECT f1('f');
ERROR 45000: Unhandled user-defined exception condition
DROP FUNCTION f1;
#
# Checking that raised user exceptions are further caught by OTHERS
#
CREATE FUNCTION f1(c VARCHAR) RETURN VARCHAR
AS
e EXCEPTION;
f EXCEPTION;
BEGIN
IF c = 'e' THEN RAISE e; END IF;
IF c = 'f' THEN RAISE f; END IF;
RETURN 'Got no exceptions';
EXCEPTION
WHEN OTHERS THEN RETURN 'Got some exception';
END;
$$
SELECT f1('');
f1('')
Got no exceptions
SELECT f1('e');
f1('e')
Got some exception
SELECT f1('f');
f1('f')
Got some exception
DROP FUNCTION f1;
#
# Checking that 'WHEN e .. WHEN f' does not produce ER_SP_DUP_HANDLER
#
CREATE FUNCTION f1(c VARCHAR) RETURN VARCHAR
AS
e EXCEPTION;
f EXCEPTION;
a VARCHAR(64):='';
BEGIN
BEGIN
IF c = 'e' THEN RAISE e; END IF;
IF c = 'f' THEN RAISE f; END IF;
EXCEPTION
WHEN e THEN BEGIN a:='Got EXCEPTION1/e; '; RAISE e; END;
WHEN f THEN BEGIN a:='Got EXCEPTION1/f; '; RAISE f; END;
END;
RETURN 'Got no exceptions';
EXCEPTION
WHEN OTHERS THEN RETURN a || 'Got EXCEPTION2/OTHERS;';
END;
$$
SELECT f1('');
f1('')
Got no exceptions
SELECT f1('e');
f1('e')
Got EXCEPTION1/e; Got EXCEPTION2/OTHERS;
SELECT f1('f');
f1('f')
Got EXCEPTION1/f; Got EXCEPTION2/OTHERS;
DROP FUNCTION f1;
#
# Checking that resignaled user exceptions are further caught by name
#
CREATE FUNCTION f1(c VARCHAR) RETURN VARCHAR
AS
e EXCEPTION;
f EXCEPTION;
a VARCHAR(64):='';
BEGIN
BEGIN
IF c = 'e' THEN RAISE e; END IF;
IF c = 'f' THEN RAISE f; END IF;
EXCEPTION
WHEN e THEN BEGIN a:='Got EXCEPTION1/e; '; RAISE; END;
WHEN f THEN BEGIN a:='Got EXCEPTION1/f; '; RAISE; END;
END;
RETURN 'Got no exceptions';
EXCEPTION
WHEN e THEN RETURN a || 'Got EXCEPTION2/e;';
END;
$$
SELECT f1('');
f1('')
Got no exceptions
SELECT f1('e');
f1('e')
Got EXCEPTION1/e; Got EXCEPTION2/e;
SELECT f1('f');
ERROR 45000: Unhandled user-defined exception condition
DROP FUNCTION f1;
#
# Checking that resignaled user exceptions are further caught by OTHERS
#
CREATE FUNCTION f1(c VARCHAR) RETURN VARCHAR
AS
e EXCEPTION;
f EXCEPTION;
a VARCHAR(64):='';
BEGIN
BEGIN
IF c = 'e' THEN RAISE e; END IF;
IF c = 'f' THEN RAISE f; END IF;
EXCEPTION
WHEN e THEN BEGIN a:='Got EXCEPTION1/e; '; RAISE; END;
WHEN f THEN BEGIN a:='Got EXCEPTION1/f; '; RAISE; END;
END;
RETURN 'Got no exceptions';
EXCEPTION
WHEN OTHERS THEN RETURN a || 'Got EXCEPTION2/OTHERS;';
END;
$$
SELECT f1('');
f1('')
Got no exceptions
SELECT f1('e');
f1('e')
Got EXCEPTION1/e; Got EXCEPTION2/OTHERS;
SELECT f1('f');
f1('f')
Got EXCEPTION1/f; Got EXCEPTION2/OTHERS;
DROP FUNCTION f1;
#
# End of MDEV-10587 sql_mode=ORACLE: User defined exceptions
#
#
# MDEV-12088 sql_mode=ORACLE: Do not require BEGIN..END in multi-statement exception handlers in THEN clause
#
CREATE TABLE t1 (a INT PRIMARY KEY);
INSERT INTO t1 VALUES (10),(20),(30);
CREATE PROCEDURE p1(a INT) AS
BEGIN
INSERT INTO t1 (a) VALUES (a);
EXCEPTION
WHEN DUP_VAL_ON_INDEX THEN
a:= a+1;
INSERT INTO t1 VALUES (a);
WHEN OTHERS THEN
NULL;
NULL;
END;
$$
CALL p1(30);
SELECT * FROM t1;
a
10
20
30
31
DROP PROCEDURE p1;
DROP TABLE t1;
SET sql_mode=ORACLE;
SELECT NVL(NULL, 'a'), NVL('a', 'b');
NVL(NULL, 'a') NVL('a', 'b')
a a
SELECT NVL2(NULL, 'a', 'b'), NVL2('a', 'b', 'c');
NVL2(NULL, 'a', 'b') NVL2('a', 'b', 'c')
b b
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'"
EXPLAIN EXTENDED SELECT CONCAT('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 "CONCAT('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
SELECT LENGTH(CONCAT(a||b||c)), CONCAT(a||b||c) FROM t1 ORDER BY a,b,c;
LENGTH(CONCAT(a||b||c)) CONCAT(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;
SET sql_mode=ORACLE;
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(10,10,'x10');
DECODE(10,10,'x10')
x10
SELECT DECODE(11,10,'x10');
DECODE(11,10,'x10')
NULL
SELECT DECODE(10,10,'x10','def');
DECODE(10,10,'x10','def')
x10
SELECT DECODE(11,10,'x10','def');
DECODE(11,10,'x10','def')
def
SELECT DECODE(10,10,'x10',11,'x11','def');
DECODE(10,10,'x10',11,'x11','def')
x10
SELECT DECODE(11,10,'x10',11,'x11','def');
DECODE(11,10,'x10',11,'x11','def')
x11
SELECT DECODE(12,10,'x10',11,'x11','def');
DECODE(12,10,'x10',11,'x11','def')
def
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')"
CREATE TABLE decode (decode int);
DROP TABLE decode;
SET sql_mode=ORACLE;
#
# MDEV-10578 sql_mode=ORACLE: SP control functions SQLCODE, SQLERRM
#
#
# Using SQLCODE and SQLERRM outside of an SP
#
SELECT SQLCODE;
ERROR 42S22: Unknown column 'SQLCODE' in 'field list'
SELECT SQLERRM;
ERROR 42S22: Unknown column 'SQLERRM' in 'field list'
CREATE TABLE t1 (SQLCODE INT, SQLERRM VARCHAR(10));
INSERT INTO t1 VALUES (10, 'test');
SELECT SQLCODE, SQLERRM FROM t1;
SQLCODE SQLERRM
10 test
DROP TABLE t1;
#
# Normal SQLCODE and SQLERRM usage
#
CREATE PROCEDURE p1(stmt VARCHAR)
AS
BEGIN
EXECUTE IMMEDIATE stmt;
SELECT 'Error1: ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
SELECT 'Error2: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1('SELECT 1');
1
1
'Error1: ' || SQLCODE || ' ' || SQLERRM
Error1: 0 normal, successful completition
CALL p1('xxx');
'Error2: ' || SQLCODE || ' ' || SQLERRM
Error2: 1193 Unknown system variable 'xxx'
CALL p1('SELECT 1');
1
1
'Error1: ' || SQLCODE || ' ' || SQLERRM
Error1: 0 normal, successful completition
DROP PROCEDURE p1;
#
# SQLCODE and SQLERRM hidden by local variables
#
CREATE PROCEDURE p1()
AS
sqlcode INT:= 10;
sqlerrm VARCHAR(64) := 'test';
BEGIN
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1;
'Error: ' || SQLCODE || ' ' || SQLERRM
Error: 10 test
DROP PROCEDURE p1;
CREATE PROCEDURE p1()
AS
sqlcode INT;
sqlerrm VARCHAR(64);
BEGIN
SQLCODE:= 10;
sqlerrm:= 'test';
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1;
'Error: ' || SQLCODE || ' ' || SQLERRM
Error: 10 test
DROP PROCEDURE p1;
#
# SQLCODE and SQLERRM hidden by parameters
#
CREATE PROCEDURE p1(sqlcode INT, sqlerrm VARCHAR)
AS
BEGIN
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1(10, 'test');
'Error: ' || SQLCODE || ' ' || SQLERRM
Error: 10 test
DROP PROCEDURE p1;
#
# SQLCODE and SQLERRM in CREATE..SELECT
#
CREATE PROCEDURE p1
AS
BEGIN
CREATE TABLE t1 AS SELECT SQLCODE, SQLERRM;
END;
$$
CALL p1;
SHOW CREATE TABLE t1;
Table Create Table
t1 CREATE TABLE "t1" (
"SQLCODE" int(11) NOT NULL,
"SQLERRM" varchar(512) CHARACTER SET utf8 NOT NULL
)
DROP TABLE t1;
DROP PROCEDURE p1;
#
# SQLCODE and SQLERRM in EXPLAIN EXTENDED SELECT
#
CREATE PROCEDURE p1
AS
BEGIN
EXPLAIN EXTENDED SELECT SQLCode, SQLErrm;
END;
$$
CALL p1;
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 SQLCODE AS "SQLCode",SQLERRM AS "SQLErrm"
DROP PROCEDURE p1;
#
# Warning-alike errors in stored functions
#
CREATE TABLE t1 (a INT);
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RETURN 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f1() FROM DUAL;
f1()
Exception 1329 No data - zero rows fetched, selected, or processed
DROP FUNCTION f1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
RETURN 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f1() FROM DUAL;
f1()
Exception 1329 No data - zero rows fetched, selected, or processed
DROP FUNCTION f1;
DROP TABLE t1;
#
# Warning-alike errors in stored procedures
#
CREATE TABLE t1 (a INT);
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
res:= 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN NO_DATA_FOUND THEN
res:= 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1(@a);
SELECT @a;
@a
Exception 1329 No data - zero rows fetched, selected, or processed
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
res:= 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
res:= 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
CALL p1(@a);
SELECT @a;
@a
Exception 1329 No data - zero rows fetched, selected, or processed
DROP PROCEDURE p1;
DROP TABLE t1;
#
# SQLCODE and SQLERRM are cleared on RETURN
#
CREATE TABLE t1 (a INT);
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'Value=' || a;
EXCEPTION
WHEN NO_DATA_FOUND THEN RETURN 'Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
a VARCHAR(128);
BEGIN
RETURN f1() || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f1() FROM DUAL;
f1()
Exception|1329 No data - zero rows fetched, selected, or processed
SELECT f2() FROM DUAL;
f2()
Exception|1329 No data - zero rows fetched, selected, or processed|0 normal, successful completition
DROP TABLE t1;
DROP FUNCTION f2;
DROP FUNCTION f1;
CREATE TABLE t1 (a INT);
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'Value=' || a;
EXCEPTION
WHEN OTHERS THEN RETURN 'Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
a VARCHAR(128);
BEGIN
RETURN f1() || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f1() FROM DUAL;
f1()
Exception|1329 No data - zero rows fetched, selected, or processed
SELECT f2() FROM DUAL;
f2()
Exception|1329 No data - zero rows fetched, selected, or processed|0 normal, successful completition
DROP TABLE t1;
DROP FUNCTION f2;
DROP FUNCTION f1;
#
# SQLCODE and SQLERRM are cleared on a return from a PROCEDURE
#
CREATE TABLE t1 (a INT);
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
res:='Value=' || a;
EXCEPTION
WHEN NO_DATA_FOUND THEN res:='Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
res VARCHAR(128);
BEGIN
CALL p1(res);
RETURN res || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f2() FROM DUAL;
f2()
Exception|1329 No data - zero rows fetched, selected, or processed|0 normal, successful completition
DROP FUNCTION f2;
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
res:='Value=' || a;
EXCEPTION
WHEN OTHERS THEN res:='Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
res VARCHAR(128);
BEGIN
CALL p1(res);
RETURN res || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
SELECT f2() FROM DUAL;
f2()
Exception|1329 No data - zero rows fetched, selected, or processed|0 normal, successful completition
DROP FUNCTION f2;
DROP PROCEDURE p1;
DROP TABLE t1;
#
# End of MDEV-10578 sql_mode=ORACLE: SP control functions SQLCODE, SQLERRM
#
SET sql_mode=ORACLE;
#
# MDEV-12086 sql_mode=ORACLE: allow SELECT UNIQUE as a synonym for SELECT DISTINCT
#
CREATE TABLE t1 (a INT);
INSERT INTO t1 VALUES (10),(20),(20),(30),(30),(30);
SELECT UNIQUE a FROM t1;
a
10
20
30
DROP TABLE t1;
SET sql_mode=ORACLE;
#
# MDEV-10801 sql_mode: dynamic SQL placeholders
#
SET @a=10, @b=20;
PREPARE stmt FROM 'SELECT ?,?';
EXECUTE stmt USING @a, @b;
? ?
10 20
PREPARE stmt FROM 'SELECT :a,:b';
EXECUTE stmt USING @a, @b;
:a :b
10 20
PREPARE stmt FROM 'SELECT :aaa,:bbb';
EXECUTE stmt USING @a, @b;
:aaa :bbb
10 20
PREPARE stmt FROM 'SELECT :"a",:"b"';
EXECUTE stmt USING @a, @b;
:"a" :"b"
10 20
PREPARE stmt FROM 'SELECT :"aaa",:"bbb"';
EXECUTE stmt USING @a, @b;
:"aaa" :"bbb"
10 20
PREPARE stmt FROM 'SELECT :1,:2';
EXECUTE stmt USING @a, @b;
:1 :2
10 20
PREPARE stmt FROM 'SELECT :222,:111';
EXECUTE stmt USING @a, @b;
:222 :111
10 20
PREPARE stmt FROM 'SELECT :0,:65535';
EXECUTE stmt USING @a, @b;
:0 :65535
10 20
PREPARE stmt FROM 'SELECT :65535,:0';
EXECUTE stmt USING @a, @b;
:65535 :0
10 20
#
# MDEV-10709 Expressions as parameters to Dynamic SQL
#
#
# Testing disallowed expressions in USING
#
PREPARE stmt FROM 'SELECT :1 FROM DUAL';
EXECUTE stmt USING (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 1)' at line 1
DEALLOCATE PREPARE stmt;
CREATE FUNCTION f1() RETURN VARCHAR
AS
BEGIN
RETURN 'test';
END;
$$
PREPARE stmt FROM 'SELECT ? FROM DUAL';
EXECUTE stmt USING f1();
ERROR 42000: EXECUTE..USING does not support subqueries or stored functions
DEALLOCATE PREPARE stmt;
DROP FUNCTION f1;
#
# Using a user variable as a EXECUTE..USING out parameter
#
CREATE PROCEDURE p1(a OUT INT)
AS
BEGIN
a:= 10;
END;
/
SET @a=1;
CALL p1(@a);
SELECT @a;
@a
10
SET @a=2;
PREPARE stmt FROM 'CALL p1(?)';
EXECUTE stmt USING @a;
SELECT @a;
@a
10
DROP PROCEDURE p1;
#
# Using an SP variable as a EXECUTE..USING out parameter
#
CREATE PROCEDURE p1 (a OUT INT)
AS
BEGIN
a:=10;
END;
/
CREATE PROCEDURE p2 (a OUT INT)
AS
BEGIN
PREPARE stmt FROM 'CALL p1(?)';
EXECUTE stmt USING a;
END;
/
SET @a= 1;
CALL p2(@a);
SELECT @a;
@a
10
DROP PROCEDURE p2;
DROP PROCEDURE p1;
#
# Using a trigger field as a EXECUTE..USING out parameter
#
CREATE PROCEDURE p1 (a OUT INT)
AS
BEGIN
a:= 10;
END;
/
CREATE TABLE t1 (a INT);
CREATE TRIGGER tr1 BEFORE INSERT ON t1 FOR EACH ROW CALL p1(:NEW.a);
INSERT INTO t1 VALUES (1);
SELECT * FROM t1;
a
10
DROP TABLE t1;
DROP PROCEDURE p1;
#
# Testing re-prepare on a table metadata update between PREPARE and EXECUTE
#
CREATE TABLE t1 (a INT);
CREATE PROCEDURE p1(a IN INT)
AS
BEGIN
INSERT INTO t1 VALUES (a);
END;
/
PREPARE stmt FROM 'CALL p1(?)';
EXECUTE stmt USING 10;
SELECT * FROM t1;
a
10
CREATE TRIGGER tr1 BEFORE INSERT ON t1 FOR EACH ROW NEW.a:=NEW.a+1;
EXECUTE stmt USING 20;
SELECT * FROM t1;
a
10
21
DEALLOCATE PREPARE stmt;
DROP PROCEDURE p1;
DROP TABLE t1;
#
# End of MDEV-10709 Expressions as parameters to Dynamic SQL
#
#
# MDEV-10585 EXECUTE IMMEDIATE statement
#
#
# Testing disallowed expressions in USING
#
EXECUTE IMMEDIATE 'SELECT :1 FROM DUAL' USING (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 1)' at line 1
CREATE FUNCTION f1() RETURN VARCHAR
AS
BEGIN
RETURN 'test';
END;
$$
EXECUTE IMMEDIATE 'SELECT ? FROM DUAL' USING f1();
ERROR 42000: EXECUTE..USING does not support subqueries or stored functions
DROP FUNCTION f1;
#
# Testing simple expressions
#
EXECUTE IMMEDIATE 'SELECT :1 FROM DUAL' USING 10;
:1
10
#
# MDEV-10866 Extend PREPARE and EXECUTE IMMEDIATE to understand expressions
#
#
# 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 '||'
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 '||'
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');
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
EXECUTE IMMEDIATE a;
ERROR 42S22: Unknown column 'a' in 'field list'
PREPARE stmt FROM a;
ERROR 42S22: Unknown column 'a' in 'field list'
EXECUTE IMMEDIATE NULL;
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 'NULL' at line 1
PREPARE stmt FROM NULL;
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 'NULL' at line 1
EXECUTE IMMEDIATE COALESCE(NULL);
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 'NULL' at line 1
PREPARE stmt FROM COALESCE(NULL);
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 'NULL' at line 1
CREATE FUNCTION f1() RETURN VARCHAR
AS
BEGIN
RETURN 't1';
END;
$$
EXECUTE IMMEDIATE f1();
ERROR 42000: EXECUTE IMMEDIATE does not support subqueries or stored functions
PREPARE stmt FROM f1();
ERROR 42000: PREPARE..FROM does not support subqueries or stored functions
DROP FUNCTION f1;
#
# Testing user variables in prepare source
#
SET @table_name='DUAL';
EXECUTE IMMEDIATE 'SELECT 1 AS a FROM ' || @table_name;
a
1
PREPARE stmt FROM 'SELECT 1 AS a FROM ' || @table_name;
EXECUTE stmt;
a
1
DEALLOCATE PREPARE stmt;
#
# Testing SP parameters and variables in prepare source
#
CREATE PROCEDURE p1(table_name VARCHAR)
AS
BEGIN
EXECUTE IMMEDIATE 'SELECT 1 AS c FROM '|| table_name;
END;
$$
CALL p1('DUAL');
c
1
DROP PROCEDURE p1;
CREATE PROCEDURE p1()
AS
table_name VARCHAR(64):='DUAL';
BEGIN
EXECUTE IMMEDIATE 'SELECT 1 AS c FROM ' || table_name;
END;
$$
CALL p1();
c
1
DROP PROCEDURE p1;
#
# End of MDEV-10866 Extend PREPARE and EXECUTE IMMEDIATE to understand expressions
#
SET sql_mode=ORACLE;
#
# MDEV-10655 Anonymous blocks
#
# Testing BEGIN NOT ATOMIC with no declarations
BEGIN NOT ATOMIC
SELECT 1 AS a;
END
/
a
1
# Testing BEGIN NOT ATOMIC with declarations
# DECLARE starts a new block and thus must be followed by BEGIN .. END
BEGIN NOT ATOMIC
DECLARE
i INT DEFAULT 5;
x INT DEFAULT 10;
BEGIN
<<label>>
WHILE i > 3 LOOP
i:= i - 1;
SELECT i;
END LOOP label;
END;
END
/
i
4
i
3
# Anonymous blocks with no declarations and no exceptions
BEGIN
SELECT 1 AS a;
END
$$
a
1
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(30);
ROLLBACK;
END;
$$
SELECT * FROM t1;
a
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(30);
END;
$$
ROLLBACK;
SELECT * FROM t1;
a
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(30);
COMMIT;
END;
$$
SELECT * FROM t1;
a
10
20
30
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(30);
END;
$$
COMMIT;
SELECT * FROM t1;
a
10
20
30
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(20);
END;
$$
ERROR 23000: Duplicate entry '20' for key 'PRIMARY'
COMMIT;
SELECT * FROM t1;
a
10
20
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
# Anonymous blocks with no declarations, with exceptions
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
BEGIN
INSERT INTO t1 VALUES(20);
INSERT INTO t1 VALUES(20);
EXCEPTION
WHEN DUP_VAL_ON_INDEX THEN NULL;
END;
$$
COMMIT;
SELECT * FROM t1;
a
10
20
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
# Anonymous blocks with declarations, with no exceptions
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
DECLARE
a20 INT:=20;
a30 INT:=30;
BEGIN
INSERT INTO t1 VALUES(a20);
INSERT INTO t1 VALUES(a30);
ROLLBACK;
END;
$$
SELECT * FROM t1;
a
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
DECLARE
a20 INT:=20;
a30 INT:=30;
BEGIN
INSERT INTO t1 VALUES(a20);
INSERT INTO t1 VALUES(a30);
END;
$$
ROLLBACK;
SELECT * FROM t1;
a
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
DECLARE
a20 INT:=20;
a30 INT:=30;
BEGIN
INSERT INTO t1 VALUES(a20);
INSERT INTO t1 VALUES(a30);
COMMIT;
END;
$$
SELECT * FROM t1;
a
10
20
30
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
DECLARE
a20 INT:=20;
a30 INT:=30;
BEGIN
INSERT INTO t1 VALUES(a20);
INSERT INTO t1 VALUES(a30);
END;
$$
COMMIT;
SELECT * FROM t1;
a
10
20
30
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
# Anonymous blocks with declarations, with exceptions
SET AUTOCOMMIT=OFF;
CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY) ENGINE=InnoDB;
INSERT INTO t1 VALUES (10);
DECLARE
a20 INT:=20;
BEGIN
INSERT INTO t1 VALUES(a20);
INSERT INTO t1 VALUES(a20);
EXCEPTION
WHEN DUP_VAL_ON_INDEX THEN NULL;
END;
$$
COMMIT;
SELECT * FROM t1;
a
10
20
DROP TABLE t1;
SET AUTOCOMMIT=DEFAULT;
This diff is collapsed.
SET sql_mode=ORACLE;
#
# MDEV-10598 sql_mode=ORACLE: Variable declarations can go after cursor declarations
#
#
# Variable after cursor declaration
#
CREATE TABLE t1 (a INT);
insert into t1 values (1);
insert into t1 values (2);
CREATE PROCEDURE p1
AS
CURSOR c IS SELECT a FROM t1;
var1 varchar(10);
BEGIN
OPEN c;
fetch c into var1;
SELECT c%ROWCOUNT,var1;
close c;
END;
$$
CALL p1;
c%ROWCOUNT var1
1 1
DROP PROCEDURE p1;
drop table t1;
#
# Variable after condition declaration
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
dup_key CONDITION FOR SQLSTATE '23000';
var1 varchar(40);
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
BEGIN
var1:='';
insert into t1 values (1);
select var1;
END;
$$
CALL p1;
var1
duplicate key in index
DROP PROCEDURE p1;
drop table t1;
#
# Condition after cursor declaration
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
var1 varchar(40);
var2 integer;
CURSOR c IS SELECT col1 FROM t1;
dup_key CONDITION FOR SQLSTATE '23000';
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
BEGIN
var1:='';
insert into t1 values (1);
SELECT var1;
END;
$$
CALL p1;
var1
duplicate key in index
DROP PROCEDURE p1;
drop table t1;
#
# Cursor after handler declaration
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
var1 varchar(40);
var2 integer;
dup_key CONDITION FOR SQLSTATE '23000';
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
CURSOR c IS SELECT col1 FROM t1;
BEGIN
var1:='';
insert into t1 values (1);
SELECT var1;
END;
$$
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 'CURSOR c IS SELECT col1 FROM t1;
BEGIN
var1:='';
insert into t1 values (1);
SELE' at line 10
drop table t1;
#
# Condition after handler declaration
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
var1 varchar(40);
var2 integer;
dup_key CONDITION FOR SQLSTATE '23000';
CURSOR c IS SELECT col1 FROM t1;
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
var1:='';
insert into t1 values (1);
SELECT var1;
END;
$$
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 'divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
var1:='';
insert into t1 va' at line 11
drop table t1;
#
# Variable after handler declaration
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
var1 varchar(40);
var2 integer;
dup_key CONDITION FOR SQLSTATE '23000';
CURSOR c IS SELECT col1 FROM t1;
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
var1:='';
insert into t1 values (1);
SELECT var1;
END;
$$
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 'divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
var1:='';
insert into t1 va' at line 11
drop table t1;
#
# Variable after cursor (inner block)
#
CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
insert into t1 values (2);
create unique index t1_col1 on t1 (col1);
CREATE PROCEDURE p1
AS
CURSOR c IS SELECT col1 FROM t1;
var1 varchar(40);
BEGIN
OPEN c;
begin
declare
CURSOR c IS SELECT col1 FROM t1 where col1=2;
var2 integer;
dup_key CONDITION FOR SQLSTATE '23000';
CONTINUE HANDLER FOR dup_key
BEGIN
var1:='duplicate key in index';
END;
begin
OPEN c;
fetch c into var1;
SELECT 'inner cursor',var1;
insert into t1 values (2);
close c;
end;
end;
SELECT var1;
fetch c into var1;
SELECT c%ROWCOUNT,var1;
begin
insert into t1 values (2);
exception when 1062 then
begin
SELECT 'dup key caugth';
end;
end;
close c;
END;
$$
CALL p1;
inner cursor var1
inner cursor 2
var1
duplicate key in index
c%ROWCOUNT var1
1 1
dup key caugth
dup key caugth
DROP PROCEDURE p1;
drop table t1;
#
# Cursor declaration and row type declaration in same block
#
CREATE TABLE t1 (a INT, b VARCHAR(10));
insert into t1 values(1,'a');
CREATE PROCEDURE p1()
AS
CURSOR cur1 IS SELECT a FROM t1;
rec1 cur1%ROWTYPE;
BEGIN
rec1.a:= 10;
END;
$$
call p1;
DROP PROCEDURE p1;
drop table t1;
#
# Recursive cursor and cursor%ROWTYPE declarations in the same block
#
CREATE PROCEDURE p1
AS
a INT:=10;
b VARCHAR(10):='b0';
c DOUBLE:=0.1;
CURSOR cur1 IS SELECT a, b, c;
rec1 cur1%ROWTYPE;
CURSOR cur2 IS SELECT rec1.a + 1 "a", rec1.b||'0' AS b, rec1.c AS c;
rec2 cur2%ROWTYPE;
BEGIN
OPEN cur1;
FETCH cur1 INTO rec1;
CLOSE cur1;
SELECT rec1.a;
OPEN cur2;
FETCH cur2 INTO rec2;
CLOSE cur2;
SELECT rec2.a;
CREATE TABLE t2 AS SELECT rec2.a AS a, rec2.b AS b, rec2.c AS c;
SHOW CREATE TABLE t2;
DROP TABLE t2;
END;
$$
CALL p1();
rec1.a
10
rec2.a
11
Table Create Table
t2 CREATE TABLE "t2" (
"a" bigint(21) DEFAULT NULL,
"b" varchar(11) DEFAULT NULL,
"c" double DEFAULT NULL
)
DROP PROCEDURE p1;
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
SET sql_mode=ORACLE;
#
# MDEV-10588 sql_mode=ORACLE: TRUNCATE TABLE t1 [ {DROP|REUSE} STORAGE ]
#
CREATE TABLE t1 (a INT);
TRUNCATE TABLE t1 REUSE STORAGE;
TRUNCATE TABLE t1 DROP STORAGE;
DROP TABLE t1;
CREATE TABLE reuse (reuse INT);
DROP TABLE reuse;
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
SET sql_mode=ORACLE;
CREATE TABLE t1 (a BLOB);
SHOW CREATE TABLE t1;
DROP TABLE t1;
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
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