mirror of
https://github.com/MariaDB/server.git
synced 2025-07-29 05:21:33 +03:00
MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
This patch adds support for SYS_REFCURSOR (a weakly typed cursor) for both sql_mode=ORACLE and sql_mode=DEFAULT. Works as a regular stored routine variable, parameter and return value: - can be passed as an IN parameter to stored functions and procedures - can be passed as an INOUT and OUT parameter to stored procedures - can be returned from a stored function Note, strongly typed REF CURSOR will be added separately. Note, to maintain dependencies easier, some parts of sql_class.h and item.h were moved to new header files: - select_results.h: class select_result_sink class select_result class select_result_interceptor - sp_cursor.h: class sp_cursor_statistics class sp_cursor - sp_rcontext_handler.h class Sp_rcontext_handler and its descendants The implementation consists of the following parts: - A new class sp_cursor_array deriving from Dynamic_array - A new class Statement_rcontext which contains data shared between sub-statements of a compound statement. It has a member m_statement_cursors of the sp_cursor_array data type, as well as open cursor counter. THD inherits from Statement_rcontext. - A new data type handler Type_handler_sys_refcursor in plugins/type_cursor/ It is designed to store uint16 references - positions of the cursor in THD::m_statement_cursors. - Type_handler_sys_refcursor suppresses some derived numeric features. When a SYS_REFCURSOR variable is used as an integer an error is raised. - A new abstract class sp_instr_fetch_cursor. It's needed to share the common code between "OPEN cur" (for static cursors) and "OPER cur FOR stmt" (for SYS_REFCURSORs). - New sp_instr classes: * sp_instr_copen_by_ref - OPEN sys_ref_curor FOR stmt; * sp_instr_cfetch_by_ref - FETCH sys_ref_cursor INTO targets; * sp_instr_cclose_by_ref - CLOSE sys_ref_cursor; * sp_instr_destruct_variable - to destruct SYS_REFCURSOR variables when the execution goes out of the BEGIN..END block where SYS_REFCURSOR variables are declared. - New methods in LEX: * sp_open_cursor_for_stmt - handles "OPEN sys_ref_cursor FOR stmt". * sp_add_instr_fetch_cursor - "FETCH cur INTO targets" for both static cursors and SYS_REFCURSORs. * sp_close - handles "CLOSE cur" both for static cursors and SYS_REFCURSORs. - Changes in cursor functions to handle both static cursors and SYS_REFCURSORs: * Item_func_cursor_isopen * Item_func_cursor_found * Item_func_cursor_notfound * Item_func_cursor_rowcount - A new system variable @@max_open_cursors - to limit the number of cursors (static and SYS_REFCURSORs) opened at the same time. Its allowed range is [0-65536], with 50 by default. - A new virtual method Type_handler::can_return_bool() telling if calling item->val_bool() is allowed for Items of this data type, or if otherwise the "Illegal parameter for operation" error should be raised at fix_fields() time. - New methods in Sp_rcontext_handler: * get_cursor() * get_cursor_by_ref() - A new class Sp_rcontext_handler_statement to handle top level statement wide cursors which are shared by all substatements. - A new virtual method expr_event_handler() in classes Item and Field. It's needed to close (and make available for a new OPEN) unused THD::m_statement_cursors elements which do not have any references any more. It can happen in various moments in time, e.g. * after evaluation parameters of an SQL routine * after assigning a cursor expression into a SYS_REFCURSOR variable * when leaving a BEGIN..END block with SYS_REFCURSOR variables * after setting OUT/INOUT routine actual parameters from formal parameters.
This commit is contained in:
@ -157,6 +157,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc
|
||||
../sql/json_table.cc
|
||||
../sql/opt_histogram_json.cc
|
||||
../sql/sp_instr.cc
|
||||
../sql/sp_cursor.cc
|
||||
${GEN_SOURCES}
|
||||
${MYSYS_LIBWRAP_SOURCE}
|
||||
)
|
||||
|
18
mysql-test/include/bool_to_char.inc
Normal file
18
mysql-test/include/bool_to_char.inc
Normal file
@ -0,0 +1,18 @@
|
||||
SET @sql_mode=@@sql_mode;
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION bool_to_char(b BOOLEAN) RETURN VARCHAR AS
|
||||
BEGIN
|
||||
RETURN
|
||||
CASE
|
||||
WHEN b IS NULL THEN 'NULL'
|
||||
WHEN b THEN 'true'
|
||||
WHEN NOT b THEN 'false'
|
||||
END;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
SET sql_mode=@sql_mode;
|
22
mysql-test/include/dbms_output.inc
Normal file
22
mysql-test/include/dbms_output.inc
Normal file
@ -0,0 +1,22 @@
|
||||
SET @sql_mode=@@sql_mode;
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
DELIMITER /;
|
||||
|
||||
CREATE PACKAGE DBMS_OUTPUT AS
|
||||
PROCEDURE PUT_LINE(s VARCHAR);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE PACKAGE BODY DBMS_OUTPUT AS
|
||||
PROCEDURE PUT_LINE(s VARCHAR) AS
|
||||
BEGIN
|
||||
SELECT s AS `` FROM DUAL;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
|
||||
DELIMITER ;/
|
||||
|
||||
SET sql_mode=@sql_mode;
|
17
mysql-test/include/fetch_one_value.inc
Normal file
17
mysql-test/include/fetch_one_value.inc
Normal file
@ -0,0 +1,17 @@
|
||||
# Fetch one value from an open SYS_REFCURSOR
|
||||
|
||||
SET @sql_mode=@@sql_mode;
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION fetch_one_value(c SYS_REFCURSOR) RETURN VARCHAR AS
|
||||
v VARCHAR(128) :='none';
|
||||
BEGIN
|
||||
IF c%ISOPEN THEN
|
||||
FETCH c INTO v;
|
||||
END IF;
|
||||
RETURN v;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SET sql_mode=@sql_mode;
|
@ -658,6 +658,8 @@ The following specify which files/extra groups are read (specified before remain
|
||||
max_join_size records return an error
|
||||
--max-length-for-sort-data=#
|
||||
Max number of bytes in sorted records
|
||||
--max-open-cursors=#
|
||||
The maximum number of open cursors allowed per session
|
||||
--max-password-errors=#
|
||||
If there is more than this number of failed connect
|
||||
attempts due to invalid password, user will be blocked
|
||||
@ -1817,6 +1819,7 @@ max-error-count 64
|
||||
max-heap-table-size 16777216
|
||||
max-join-size 18446744073709551615
|
||||
max-length-for-sort-data 1024
|
||||
max-open-cursors 50
|
||||
max-password-errors 18446744073709551615
|
||||
max-prepared-stmt-count 16382
|
||||
max-recursive-iterations 1000
|
||||
@ -1932,7 +1935,7 @@ performance-schema-max-socket-classes 10
|
||||
performance-schema-max-socket-instances -1
|
||||
performance-schema-max-sql-text-length 1024
|
||||
performance-schema-max-stage-classes 160
|
||||
performance-schema-max-statement-classes 223
|
||||
performance-schema-max-statement-classes 227
|
||||
performance-schema-max-statement-stack 10
|
||||
performance-schema-max-table-handles -1
|
||||
performance-schema-max-table-instances -1
|
||||
|
366
mysql-test/main/sp-sys_refcursor.result
Normal file
366
mysql-test/main/sp-sys_refcursor.result
Normal file
@ -0,0 +1,366 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# p1() does not cause "Too many open cursors"
|
||||
# as on every iteration it closes an existng cursor and reopens it.
|
||||
#
|
||||
SET @@max_open_cursors=3;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
CREATE PROCEDURE p1(count INT)
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE va INT;
|
||||
FOR i IN 1..count
|
||||
DO
|
||||
SET c=f1();
|
||||
FETCH c INTO va;
|
||||
END FOR;
|
||||
END;
|
||||
$$
|
||||
CALL p1(30);
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Error: too many open cursors
|
||||
#
|
||||
SET @@max_open_cursors=3;
|
||||
SET @@max_sp_recursion_depth=50;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
CREATE PROCEDURE p1(count INT)
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE va INT;
|
||||
IF count > 0 THEN
|
||||
SET c=f1();
|
||||
CALL p1(count-1);
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
CALL p1(3);
|
||||
CALL p1(4);
|
||||
ERROR HY000: Too many open cursors; max 3 cursors allowed
|
||||
CALL p1(3);
|
||||
CALL p1(4);
|
||||
ERROR HY000: Too many open cursors; max 3 cursors allowed
|
||||
DROP FUNCTION f1;
|
||||
DROP PROCEDURE p1;
|
||||
SET max_open_cursors=DEFAULT;
|
||||
SET @@max_sp_recursion_depth=DEFAULT;
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1),(2),(3),(4);
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE va INT;
|
||||
DECLARE stage TEXT DEFAULT '';
|
||||
DECLARE c1, c2, c3, c4 SYS_REFCURSOR;
|
||||
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION, SQLWARNING
|
||||
BEGIN
|
||||
GET DIAGNOSTICS CONDITION 1 @msg= MESSAGE_TEXT;
|
||||
SELECT @@max_open_cursors, stage, @msg;
|
||||
END;
|
||||
SET max_open_cursors=3;
|
||||
SET stage='OPEN1 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c2'; OPEN c2 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: too many open cursors
|
||||
SET max_open_cursors= 1;
|
||||
-- Cursors beyond the limit are still available for FETCH
|
||||
SET stage='FETCH1 c1'; FETCH c1 INTO va; SELECT 'c1', va; -- Ok
|
||||
SET stage='FETCH1 c2'; FETCH c2 INTO va; SELECT 'c2', va; -- Ok
|
||||
SET stage='FETCH1 c3'; FETCH c3 INTO va; SELECT 'c3', va; -- Ok
|
||||
SET stage='FETCH1 c4'; FETCH c4 INTO va; -- Error: not open
|
||||
-- Open cursors beyond the limit are still available for reopen
|
||||
-- Reasoning: CLOSE+OPEN do not increase the total amount of open cursors
|
||||
SET stage='REOPEN1 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c2'; OPEN c2 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: too many open cursors
|
||||
-- Cursors beyond the limit are still available for FETCH after reopen
|
||||
SET stage='FETCH2 c1'; FETCH c1 INTO va; SELECT 'c1', va; -- Ok
|
||||
SET stage='FETCH2 c2'; FETCH c2 INTO va; SELECT 'c2', va; -- Ok
|
||||
SET stage='FETCH2 c3'; FETCH c3 INTO va; SELECT 'c3', va; -- Ok
|
||||
SET stage='FETCH2 c4'; FETCH c4 INTO va; -- Error: not open
|
||||
-- Open cursors beyond the limit are available for CLOSE
|
||||
SET stage='CLOSE1 c1'; CLOSE c1; -- Ok
|
||||
SET stage='CLOSE1 c2'; CLOSE c2; -- Ok
|
||||
SET stage='CLOSE1 c3'; CLOSE c3; -- Ok
|
||||
SET stage='CLOSE1 c4'; CLOSE c4; -- Error: not open
|
||||
-- Closed cursors beyond the limit are not available for a new OPEN
|
||||
SET stage='OPEN2 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok: fits the limit
|
||||
SET stage='OPEN2 c2'; OPEN c2 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
SET stage='OPEN2 c3'; OPEN c3 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
SET stage='OPEN2 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
-- c1 is open. Close it, so we get all cursors c1..c4 closed.
|
||||
SET stage= 'CLOSE2 c1'; CLOSE c1; -- Ok
|
||||
-- All cursors are closed. Now open c3.
|
||||
SET stage= 'OPEN3 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage= 'FETCH3 c3'; FETCH c3 INTO va; -- Ok
|
||||
SET stage= 'CLOSE3 c3'; CLOSE c3; -- Ok
|
||||
END;
|
||||
$$
|
||||
CALL p1;
|
||||
@@max_open_cursors stage @msg
|
||||
3 OPEN1 c4 Too many open cursors; max 3 cursors allowed
|
||||
c1 va
|
||||
c1 1
|
||||
c2 va
|
||||
c2 1
|
||||
c3 va
|
||||
c3 1
|
||||
@@max_open_cursors stage @msg
|
||||
1 FETCH1 c4 Cursor is not open
|
||||
@@max_open_cursors stage @msg
|
||||
1 REOPEN1 c4 Too many open cursors; max 1 cursors allowed
|
||||
c1 va
|
||||
c1 1
|
||||
c2 va
|
||||
c2 1
|
||||
c3 va
|
||||
c3 1
|
||||
@@max_open_cursors stage @msg
|
||||
1 FETCH2 c4 Cursor is not open
|
||||
@@max_open_cursors stage @msg
|
||||
1 CLOSE1 c4 Cursor is not open
|
||||
@@max_open_cursors stage @msg
|
||||
1 OPEN2 c2 Too many open cursors; max 1 cursors allowed
|
||||
@@max_open_cursors stage @msg
|
||||
1 OPEN2 c3 Too many open cursors; max 1 cursors allowed
|
||||
@@max_open_cursors stage @msg
|
||||
1 OPEN2 c4 Too many open cursors; max 1 cursors allowed
|
||||
SET max_open_cursors=DEFAULT;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Two consequent OPEN (without a CLOSE in beetween) are allowed
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1;
|
||||
OPEN c FOR SELECT 2;
|
||||
FETCH c INTO a;
|
||||
SELECT a;
|
||||
END;
|
||||
$$
|
||||
a
|
||||
2
|
||||
#
|
||||
# Many consequent OPEN (without a CLOSE in between) are allowed
|
||||
# and do not cause ER_TOO_MANY_OPEN_CURSORS.
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
FOR i IN 0..300
|
||||
DO
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END FOR;
|
||||
END;
|
||||
$$
|
||||
#
|
||||
# Simple use example (OPEN, FETCH, CLOSE)
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE a INT;
|
||||
OPEN c FOR SELECT 1;
|
||||
FETCH c INTO a;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
#
|
||||
# Fetching from two parallel cursors
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1);
|
||||
CREATE OR REPLACE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE a0 INT;
|
||||
DECLARE a1 INT;
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT a*10 FROM t1;
|
||||
OPEN c1 FOR SELECT a*20 FROM t1;
|
||||
FETCH c0 INTO a0;
|
||||
FETCH c1 INTO a1;
|
||||
SELECT a0, a1;
|
||||
CLOSE c0;
|
||||
CLOSE c1;
|
||||
END;
|
||||
$$
|
||||
CALL p1;
|
||||
a0 a1
|
||||
10 20
|
||||
DROP PROCEDURE p1;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# SYS_REFCURSOR alasing
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE a INT;
|
||||
OPEN c0 FOR SELECT 11 FROM DUAL UNION SELECT 12 FROM DUAL;
|
||||
SET c1= c0;
|
||||
FETCH c0 INTO a;
|
||||
SELECT a;
|
||||
OPEN c0 FOR SELECT 21 FROM DUAL UNION SELECT 22 FROM DUAL;
|
||||
FETCH c1 INTO a; /* c1 now points to the new "OPEN c0" */
|
||||
SELECT a;
|
||||
END;
|
||||
$$
|
||||
a
|
||||
11
|
||||
a
|
||||
21
|
||||
#
|
||||
# Function returning SYS_REFCURSOR and mysql.proc
|
||||
#
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
RETURN c0;
|
||||
END;
|
||||
$$
|
||||
SELECT returns FROM mysql.proc WHERE name='f1';
|
||||
returns
|
||||
sys_refcursor
|
||||
SHOW CREATE FUNCTION f1;
|
||||
Function sql_mode Create Function character_set_client collation_connection Database Collation
|
||||
f1 STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION CREATE DEFINER=`root`@`localhost` FUNCTION `f1`() RETURNS sys_refcursor
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
RETURN c0;
|
||||
END latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
|
||||
DROP FUNCTION f1;
|
||||
#
|
||||
# Procedure with a SYS_REFCURSOR parameter and mysql.proc
|
||||
#
|
||||
CREATE PROCEDURE p1(OUT a0 SYS_REFCURSOR)
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SET a0= c0;
|
||||
END;
|
||||
$$
|
||||
SELECT param_list FROM mysql.proc WHERE name='p1';
|
||||
param_list
|
||||
OUT a0 SYS_REFCURSOR
|
||||
SHOW CREATE PROCEDURE p1;
|
||||
Procedure sql_mode Create Procedure character_set_client collation_connection Database Collation
|
||||
p1 STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION CREATE DEFINER=`root`@`localhost` PROCEDURE `p1`(OUT a0 SYS_REFCURSOR)
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SET a0= c0;
|
||||
END latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Returning a open cursor from a function
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE done INT DEFAULT FALSE;
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR DEFAULT f1();
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
||||
fetch_loop:
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
IF done THEN
|
||||
LEAVE fetch_loop;
|
||||
END IF;
|
||||
SELECT a;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
CALL p1;
|
||||
a
|
||||
10
|
||||
a
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Returning an open cursor as an OUT param
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
CREATE PROCEDURE p1(OUT c SYS_REFCURSOR)
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
$$
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE done INT DEFAULT FALSE;
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
||||
CALL p1(c);
|
||||
fetch_loop:
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
IF done THEN
|
||||
LEAVE fetch_loop;
|
||||
END IF;
|
||||
SELECT a;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
CALL p2;
|
||||
a
|
||||
10
|
||||
a
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# A prepared statement calls its own thd->cleanup_after_query()
|
||||
# Make sure it does not close SYS_REFCURSORs,
|
||||
# and does not assert that all static cursors are closed.
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v0, v1 VARCHAR(64);
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val';
|
||||
OPEN c0 FOR SELECT 'c0val';
|
||||
OPEN c1;
|
||||
EXECUTE IMMEDIATE 'SELECT "ps1val"'; -- PS calls thd->cleanup_after_query()
|
||||
FETCH c1 INTO v1; -- this still works, no asserts happened.
|
||||
FETCH c0 INTO v0; -- this still works, c0 is still open.
|
||||
SELECT v0, v1;
|
||||
CLOSE c1;
|
||||
CLOSE c0;
|
||||
END
|
||||
$$
|
||||
CALL p1;
|
||||
ps1val
|
||||
ps1val
|
||||
v0 v1
|
||||
c0val c1val
|
||||
DROP PROCEDURE p1;
|
387
mysql-test/main/sp-sys_refcursor.test
Normal file
387
mysql-test/main/sp-sys_refcursor.test
Normal file
@ -0,0 +1,387 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # p1() does not cause "Too many open cursors"
|
||||
--echo # as on every iteration it closes an existng cursor and reopens it.
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=3;
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
|
||||
CREATE PROCEDURE p1(count INT)
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE va INT;
|
||||
FOR i IN 1..count
|
||||
DO
|
||||
SET c=f1();
|
||||
FETCH c INTO va;
|
||||
END FOR;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
CALL p1(30);
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Error: too many open cursors
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=3;
|
||||
SET @@max_sp_recursion_depth=50;
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
|
||||
CREATE PROCEDURE p1(count INT)
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE va INT;
|
||||
IF count > 0 THEN
|
||||
SET c=f1();
|
||||
CALL p1(count-1);
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
CALL p1(3);
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
CALL p1(4);
|
||||
CALL p1(3);
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
CALL p1(4);
|
||||
|
||||
DROP FUNCTION f1;
|
||||
DROP PROCEDURE p1;
|
||||
SET max_open_cursors=DEFAULT;
|
||||
SET @@max_sp_recursion_depth=DEFAULT;
|
||||
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1),(2),(3),(4);
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE va INT;
|
||||
DECLARE stage TEXT DEFAULT '';
|
||||
DECLARE c1, c2, c3, c4 SYS_REFCURSOR;
|
||||
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION, SQLWARNING
|
||||
BEGIN
|
||||
GET DIAGNOSTICS CONDITION 1 @msg= MESSAGE_TEXT;
|
||||
SELECT @@max_open_cursors, stage, @msg;
|
||||
END;
|
||||
|
||||
SET max_open_cursors=3;
|
||||
SET stage='OPEN1 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c2'; OPEN c2 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='OPEN1 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: too many open cursors
|
||||
|
||||
SET max_open_cursors= 1;
|
||||
-- Cursors beyond the limit are still available for FETCH
|
||||
SET stage='FETCH1 c1'; FETCH c1 INTO va; SELECT 'c1', va; -- Ok
|
||||
SET stage='FETCH1 c2'; FETCH c2 INTO va; SELECT 'c2', va; -- Ok
|
||||
SET stage='FETCH1 c3'; FETCH c3 INTO va; SELECT 'c3', va; -- Ok
|
||||
SET stage='FETCH1 c4'; FETCH c4 INTO va; -- Error: not open
|
||||
|
||||
-- Open cursors beyond the limit are still available for reopen
|
||||
-- Reasoning: CLOSE+OPEN do not increase the total amount of open cursors
|
||||
SET stage='REOPEN1 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c2'; OPEN c2 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage='REOPEN1 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: too many open cursors
|
||||
|
||||
-- Cursors beyond the limit are still available for FETCH after reopen
|
||||
SET stage='FETCH2 c1'; FETCH c1 INTO va; SELECT 'c1', va; -- Ok
|
||||
SET stage='FETCH2 c2'; FETCH c2 INTO va; SELECT 'c2', va; -- Ok
|
||||
SET stage='FETCH2 c3'; FETCH c3 INTO va; SELECT 'c3', va; -- Ok
|
||||
SET stage='FETCH2 c4'; FETCH c4 INTO va; -- Error: not open
|
||||
|
||||
-- Open cursors beyond the limit are available for CLOSE
|
||||
SET stage='CLOSE1 c1'; CLOSE c1; -- Ok
|
||||
SET stage='CLOSE1 c2'; CLOSE c2; -- Ok
|
||||
SET stage='CLOSE1 c3'; CLOSE c3; -- Ok
|
||||
SET stage='CLOSE1 c4'; CLOSE c4; -- Error: not open
|
||||
|
||||
-- Closed cursors beyond the limit are not available for a new OPEN
|
||||
SET stage='OPEN2 c1'; OPEN c1 FOR SELECT a FROM t1; -- Ok: fits the limit
|
||||
SET stage='OPEN2 c2'; OPEN c2 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
SET stage='OPEN2 c3'; OPEN c3 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
SET stage='OPEN2 c4'; OPEN c4 FOR SELECT a FROM t1; -- Error: beyond the limit
|
||||
|
||||
-- c1 is open. Close it, so we get all cursors c1..c4 closed.
|
||||
SET stage= 'CLOSE2 c1'; CLOSE c1; -- Ok
|
||||
|
||||
-- All cursors are closed. Now open c3.
|
||||
SET stage= 'OPEN3 c3'; OPEN c3 FOR SELECT a FROM t1; -- Ok
|
||||
SET stage= 'FETCH3 c3'; FETCH c3 INTO va; -- Ok
|
||||
SET stage= 'CLOSE3 c3'; CLOSE c3; -- Ok
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
CALL p1;
|
||||
SET max_open_cursors=DEFAULT;
|
||||
DROP TABLE t1;
|
||||
|
||||
--echo #
|
||||
--echo # Two consequent OPEN (without a CLOSE in beetween) are allowed
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT 1;
|
||||
OPEN c FOR SELECT 2;
|
||||
FETCH c INTO a;
|
||||
SELECT a;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Many consequent OPEN (without a CLOSE in between) are allowed
|
||||
--echo # and do not cause ER_TOO_MANY_OPEN_CURSORS.
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
FOR i IN 0..300
|
||||
DO
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END FOR;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Simple use example (OPEN, FETCH, CLOSE)
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE a INT;
|
||||
OPEN c FOR SELECT 1;
|
||||
FETCH c INTO a;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Fetching from two parallel cursors
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1);
|
||||
DELIMITER $$;
|
||||
CREATE OR REPLACE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE a0 INT;
|
||||
DECLARE a1 INT;
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT a*10 FROM t1;
|
||||
OPEN c1 FOR SELECT a*20 FROM t1;
|
||||
FETCH c0 INTO a0;
|
||||
FETCH c1 INTO a1;
|
||||
SELECT a0, a1;
|
||||
CLOSE c0;
|
||||
CLOSE c1;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
DROP TABLE t1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # SYS_REFCURSOR alasing
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE a INT;
|
||||
OPEN c0 FOR SELECT 11 FROM DUAL UNION SELECT 12 FROM DUAL;
|
||||
SET c1= c0;
|
||||
FETCH c0 INTO a;
|
||||
SELECT a;
|
||||
OPEN c0 FOR SELECT 21 FROM DUAL UNION SELECT 22 FROM DUAL;
|
||||
FETCH c1 INTO a; /* c1 now points to the new "OPEN c0" */
|
||||
SELECT a;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Function returning SYS_REFCURSOR and mysql.proc
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
RETURN c0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
SELECT returns FROM mysql.proc WHERE name='f1';
|
||||
SHOW CREATE FUNCTION f1;
|
||||
DROP FUNCTION f1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Procedure with a SYS_REFCURSOR parameter and mysql.proc
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1(OUT a0 SYS_REFCURSOR)
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SET a0= c0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
SELECT param_list FROM mysql.proc WHERE name='p1';
|
||||
SHOW CREATE PROCEDURE p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning a open cursor from a function
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
DELIMITER $$;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
RETURN c;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE done INT DEFAULT FALSE;
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR DEFAULT f1();
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
||||
fetch_loop:
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
IF done THEN
|
||||
LEAVE fetch_loop;
|
||||
END IF;
|
||||
SELECT a;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
DROP TABLE t1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor as an OUT param
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1(OUT c SYS_REFCURSOR)
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE done INT DEFAULT FALSE;
|
||||
DECLARE a INT;
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
||||
CALL p1(c);
|
||||
fetch_loop:
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
IF done THEN
|
||||
LEAVE fetch_loop;
|
||||
END IF;
|
||||
SELECT a;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
CALL p2;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
|
||||
--echo #
|
||||
--echo # A prepared statement calls its own thd->cleanup_after_query()
|
||||
--echo # Make sure it does not close SYS_REFCURSORs,
|
||||
--echo # and does not assert that all static cursors are closed.
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v0, v1 VARCHAR(64);
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val';
|
||||
OPEN c0 FOR SELECT 'c0val';
|
||||
OPEN c1;
|
||||
EXECUTE IMMEDIATE 'SELECT "ps1val"'; -- PS calls thd->cleanup_after_query()
|
||||
FETCH c1 INTO v1; -- this still works, no asserts happened.
|
||||
FETCH c0 INTO v0; -- this still works, c0 is still open.
|
||||
SELECT v0, v1;
|
||||
CLOSE c1;
|
||||
CLOSE c0;
|
||||
END
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
@ -1234,7 +1234,7 @@ ALTER TABLE t1 ADD COLUMN b INT DEFAULT 1;
|
||||
CALL p1(3);
|
||||
x
|
||||
3
|
||||
ERROR 21000: Operand should contain 1 column(s)
|
||||
ERROR HY000: Illegal parameter data type row for operation 'not'
|
||||
ALTER TABLE t1 DROP COLUMN a;
|
||||
CALL p1(3);
|
||||
x
|
||||
|
@ -1768,7 +1768,7 @@ UPDATE t1 SET a = 1;
|
||||
|
||||
ALTER TABLE t1 ADD COLUMN b INT DEFAULT 1;
|
||||
|
||||
--error ER_OPERAND_COLUMNS
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
CALL p1(3);
|
||||
|
||||
ALTER TABLE t1 DROP COLUMN a;
|
||||
|
225
mysql-test/suite/compat/oracle/r/sp-sys_refcursor-alias.result
Normal file
225
mysql-test/suite/compat/oracle/r/sp-sys_refcursor-alias.result
Normal file
@ -0,0 +1,225 @@
|
||||
SET sql_mode=ORACLE;
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Aliasing
|
||||
#
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v0 INT;
|
||||
v1 INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 100 FROM DUAL UNION SELECT 101 FROM DUAL;
|
||||
c1:= c0;
|
||||
FETCH c0 INTO v0; -- fetch 100
|
||||
FETCH c1 INTO v1; -- fetch 101
|
||||
DBMS_OUTPUT.PUT_LINE('actual=' || v0 || ' ' || v1 || ' ' || 'expected=100 101');
|
||||
IF task LIKE '%close_c0%' THEN
|
||||
CLOSE c0;
|
||||
END IF;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' ||
|
||||
'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
OPEN c1 FOR SELECT 200 FROM DUAL UNION SELECT 201 FROM DUAL;
|
||||
FETCH c0 INTO v0; -- fetch 200 from the new OPEN c1
|
||||
FETCH c1 INTO v1; -- fetch 201 from the new OPEN c1
|
||||
DBMS_OUTPUT.PUT_LINE('actual=' || v0 || ' ' || v1 || ' ' || 'expected=200 201');
|
||||
IF task LIKE '%close_c1%' THEN
|
||||
CLOSE c1;
|
||||
END IF;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' ||
|
||||
'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
END;
|
||||
/
|
||||
CALL p1('');
|
||||
|
||||
actual=100 101 expected=100 101
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
|
||||
actual=200 201 expected=200 201
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
CALL p1('close_c0');
|
||||
|
||||
actual=100 101 expected=100 101
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
|
||||
actual=200 201 expected=200 201
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
CALL p1('close_c1');
|
||||
|
||||
actual=100 101 expected=100 101
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
|
||||
actual=200 201 expected=200 201
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
CALL p1('close_c0 close_c1');
|
||||
|
||||
actual=100 101 expected=100 101
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
|
||||
actual=200 201 expected=200 201
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
DROP PROCEDURE p1;
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 FROM DUAL;
|
||||
CLOSE c0;
|
||||
CASE task
|
||||
WHEN 'c0:=c1' THEN c0:=c1; -- Expect: Cursor is not open
|
||||
WHEN 'c1:=c0' THEN c1:=c0; -- Expect: v is set to 2
|
||||
ELSE NULL; -- Expect: Cursor is not open
|
||||
END CASE;
|
||||
OPEN c1 FOR SELECT 2 FROM DUAL;
|
||||
FETCH c0 INTO v;
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1('');
|
||||
ERROR 24000: Cursor is not open
|
||||
CALL p1('c0:=c1');
|
||||
ERROR 24000: Cursor is not open
|
||||
CALL p1('c1:=c0');
|
||||
|
||||
v=2
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Aliasing: different variable scope
|
||||
#
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
DECLARE
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 1 AS c FROM DUAL;
|
||||
c0:= c1;
|
||||
END;
|
||||
-- Although c1 who opened the cursor goes out of the scope here,
|
||||
-- the alias still works:
|
||||
FETCH c0 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v='||v);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
v=1
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# A comprex script with many OPEN, FETCH, CLOSE statements
|
||||
#
|
||||
CREATE OR REPLACE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v0 VARCHAR(32);
|
||||
v1 VARCHAR(32);
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('test1');
|
||||
OPEN c0 FOR SELECT '10' FROM DUAL UNION SELECT '11' FROM DUAL;
|
||||
c1:= c0;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
DBMS_OUTPUT.PUT_LINE('test1a');
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
DBMS_OUTPUT.PUT_LINE('test2:');
|
||||
OPEN c1 FOR SELECT '20' FROM DUAL UNION SELECT '21' FROM DUAL UNION SELECT '22' FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
DBMS_OUTPUT.PUT_LINE('test2a');
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' ||bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
DBMS_OUTPUT.PUT_LINE('test3');
|
||||
OPEN c0 FOR SELECT '30' FROM DUAL UNION SELECT '31' FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' ||bool_to_char(c1%ISOPEN));
|
||||
FETCH c0 INTO v0;
|
||||
FETCH c1 INTO v1;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
DBMS_OUTPUT.PUT_LINE('test4');
|
||||
OPEN c0 FOR SELECT 'c0-40' FROM DUAL UNION SELECT 'c0-41' FROM DUAL;
|
||||
OPEN c1 FOR SELECT 'c1-40' FROM DUAL UNION SELECT 'c1-41' FROM DUAL;
|
||||
FETCH c0 INTO v0;
|
||||
FETCH c1 INTO v1;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
test1
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
|
||||
test1a
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
|
||||
v0=<FETCH c0 FAILED> v1=<FETCH c1 FAILED>
|
||||
|
||||
test2:
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
|
||||
v0=20 v1=21
|
||||
|
||||
test2a
|
||||
|
||||
c0%ISOPEN=false c1%ISOPEN=false
|
||||
|
||||
v0=<FETCH c0 FAILED> v1=<FETCH c1 FAILED>
|
||||
|
||||
test3
|
||||
|
||||
c0%ISOPEN=true c1%ISOPEN=true
|
||||
|
||||
v0=30 v1=31
|
||||
|
||||
test4
|
||||
|
||||
v0=c1-40 v1=c1-41
|
||||
DROP PROCEDURE p1;
|
||||
DROP PACKAGE DBMS_OUTPUT;
|
||||
DROP FUNCTION bool_to_char;
|
@ -0,0 +1,111 @@
|
||||
SET sql_mode=ORACLE;
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Hybrid functions
|
||||
#
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= CASE WHEN c0 IS NULL THEN c1 ELSE c0 END;
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
v=10
|
||||
DROP PROCEDURE p1;
|
||||
CREATE PROCEDURE p1(switch INT) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
c3 SYS_REFCURSOR;
|
||||
c4 SYS_REFCURSOR;
|
||||
cx SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 10 FROM DUAL;
|
||||
OPEN c1 FOR SELECT 11 FROM DUAL;
|
||||
OPEN c2 FOR SELECT 12 FROM DUAL;
|
||||
OPEN c3 FOR SELECT 13 FROM DUAL;
|
||||
OPEN c4 FOR SELECT 14 FROM DUAL;
|
||||
cx:= DECODE(switch, 0, c0, 1, c1, 2, c2, 3, c3, c4);
|
||||
FETCH cx INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1(0);
|
||||
|
||||
v=10
|
||||
CALL p1(1);
|
||||
|
||||
v=11
|
||||
CALL p1(2);
|
||||
|
||||
v=12
|
||||
CALL p1(3);
|
||||
|
||||
v=13
|
||||
CALL p1(4);
|
||||
|
||||
v=14
|
||||
CALL p1(5);
|
||||
|
||||
v=14
|
||||
DROP PROCEDURE p1;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= COALESCE(c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
v=10
|
||||
DROP PROCEDURE p1;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= IF(false, c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
v=10
|
||||
DROP PROCEDURE p1;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= GREATEST(c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and sys_refcursor for operation 'greatest'
|
||||
DROP PROCEDURE p1;
|
||||
DROP PACKAGE dbms_output;
|
||||
DROP FUNCTION bool_to_char;
|
||||
SET sql_mode=DEFAULT;
|
643
mysql-test/suite/compat/oracle/r/sp-sys_refcursor.result
Normal file
643
mysql-test/suite/compat/oracle/r/sp-sys_refcursor.result
Normal file
@ -0,0 +1,643 @@
|
||||
SET sql_mode=ORACLE;
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Error: Unknown cursor and wrong variable data type in OPEN, FETCH, CLOSE
|
||||
#
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
/
|
||||
ERROR 42000: Undeclared variable: c
|
||||
DECLARE
|
||||
c INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type int for operation 'OPEN'
|
||||
DECLARE
|
||||
c INT;
|
||||
BEGIN
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type int for operation 'CLOSE'
|
||||
DECLARE
|
||||
a INT;
|
||||
c INT;
|
||||
BEGIN
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type int for operation 'FETCH'
|
||||
#
|
||||
# Error: Closing a not open cursor
|
||||
#
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR 24000: Cursor is not open
|
||||
#
|
||||
# Error: Fetching from a not open cursor
|
||||
#
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
/
|
||||
ERROR 24000: Cursor is not open
|
||||
#
|
||||
# Error: fetching beyond the available number of records
|
||||
# sql_mode=ORACLE preserves the variable value
|
||||
#
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
|
||||
1
|
||||
|
||||
1
|
||||
#
|
||||
# Two consequent OPEN (without a CLOSE in beetween) are allowed
|
||||
#
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
OPEN c FOR SELECT 2 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
|
||||
2
|
||||
#
|
||||
# Many consequent OPEN (without a CLOSE in between) are allowed
|
||||
# and do not cause ER_TOO_MANY_OPEN_CURSORS.
|
||||
#
|
||||
SET max_open_cursors=2;
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..3
|
||||
LOOP
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
SET max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Simple use example (OPEN, FETCH, CLOSE)
|
||||
#
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
CLOSE c;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
|
||||
1
|
||||
#
|
||||
# Fetching from two parallel cursors
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1);
|
||||
CREATE PROCEDURE p1() AS
|
||||
a0 INT;
|
||||
a1 INT;
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT a*10 FROM t1;
|
||||
OPEN c1 FOR SELECT a*20 FROM t1;
|
||||
FETCH c0 INTO a0;
|
||||
FETCH c1 INTO a1;
|
||||
DBMS_OUTPUT.PUT_LINE(a0 || ' ' || a1);
|
||||
CLOSE c0;
|
||||
CLOSE c1;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
10 20
|
||||
DROP PROCEDURE p1;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Returning an open cursor from a function
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
CREATE FUNCTION f1 RETURN SYS_REFCURSOR AS
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR DEFAULT f1();
|
||||
BEGIN
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Returning SYS_REFCURSOR from a function: too many open cursors
|
||||
#
|
||||
SET max_open_cursors=2;
|
||||
CREATE OR REPLACE FUNCTION f1 RETURN SYS_REFCURSOR IS
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
c0:= f1();
|
||||
FETCH c0 INTO a;
|
||||
c1:= f1();
|
||||
FETCH c1 INTO a;
|
||||
c2:= f1();
|
||||
FETCH c2 INTO a;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Too many open cursors; max 2 cursors allowed
|
||||
DROP FUNCTION f1;
|
||||
SET max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Returning an open cursor as an OUT param
|
||||
#
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10);
|
||||
INSERT INTO t1 VALUES (20);
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
p1(c);
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
#
|
||||
# Returning an open cursor as an OUT param: Too many open cursors
|
||||
#
|
||||
SET @@max_open_cursors=2;
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR VALUES (10),(20);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
p1(c0);
|
||||
LOOP
|
||||
FETCH c0 INTO a;
|
||||
EXIT WHEN c0%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
p1(c1);
|
||||
LOOP
|
||||
FETCH c1 INTO a;
|
||||
EXIT WHEN c1%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
p1(c2);
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
ERROR HY000: Too many open cursors; max 2 cursors allowed
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Returning an open cursor as an OUT param: no "Too many open cursors"
|
||||
#
|
||||
SET @@max_open_cursors=2;
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10);
|
||||
INSERT INTO t1 VALUES (20);
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..5
|
||||
LOOP
|
||||
p1(c); -- This closes the cursor and reopens it in p1
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Returning an open cursor as an INOUT param: no "Too many open cursors"
|
||||
#
|
||||
SET @@max_open_cursors=2;
|
||||
CREATE PROCEDURE p1(c INOUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR VALUES (10), (20);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..5
|
||||
LOOP
|
||||
p1(c); -- This closes the cursor and reopens it in p1
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
|
||||
10
|
||||
|
||||
20
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Function returning SYS_REFCURSOR and mysql.proc
|
||||
#
|
||||
CREATE FUNCTION f1() RETURN SYS_REFCURSOR AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
SELECT returns FROM mysql.proc WHERE name='f1';
|
||||
returns
|
||||
sys_refcursor
|
||||
SHOW CREATE FUNCTION f1;
|
||||
Function sql_mode Create Function character_set_client collation_connection Database Collation
|
||||
f1 PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER,SIMULTANEOUS_ASSIGNMENT CREATE DEFINER="root"@"localhost" FUNCTION "f1"() RETURN sys_refcursor
|
||||
AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RETURN c0;
|
||||
END latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
|
||||
DROP FUNCTION f1;
|
||||
#
|
||||
# Procedure with a SYS_REFCURSOR parameter and mysql.proc
|
||||
#
|
||||
CREATE PROCEDURE p1(a0 OUT SYS_REFCURSOR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
a0:= c0;
|
||||
END;
|
||||
/
|
||||
SELECT param_list FROM mysql.proc WHERE name='p1';
|
||||
param_list
|
||||
a0 OUT SYS_REFCURSOR
|
||||
SHOW CREATE PROCEDURE p1;
|
||||
Procedure sql_mode Create Procedure character_set_client collation_connection Database Collation
|
||||
p1 PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER,SIMULTANEOUS_ASSIGNMENT CREATE DEFINER="root"@"localhost" PROCEDURE "p1"(a0 OUT SYS_REFCURSOR)
|
||||
AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
a0:= c0;
|
||||
END latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# NULL predicate
|
||||
#
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
OPEN c0 FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
FETCH c0 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
CLOSE c0;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
true
|
||||
|
||||
false
|
||||
|
||||
false
|
||||
|
||||
false
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Cursor attributes on a not open SYS_REFCURSOR
|
||||
#
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%ISOPEN=' || bool_to_char(c%ISOPEN));
|
||||
END;
|
||||
/
|
||||
|
||||
c%ISOPEN=false
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
END;
|
||||
/
|
||||
ERROR 24000: Cursor is not open
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
END;
|
||||
/
|
||||
ERROR 24000: Cursor is not open
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
END;
|
||||
/
|
||||
ERROR 24000: Cursor is not open
|
||||
#
|
||||
# Cursor attributes on an open SYS_REFCURSOR
|
||||
#
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ISOPEN=' || bool_to_char(c%ISOPEN));
|
||||
END;
|
||||
/
|
||||
|
||||
c%ISOPEN=true
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
c%FOUND=NULL
|
||||
|
||||
c%FOUND=true
|
||||
|
||||
c%FOUND=false
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
c%NOTFOUND=NULL
|
||||
|
||||
c%NOTFOUND=false
|
||||
|
||||
c%NOTFOUND=true
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
END;
|
||||
/
|
||||
|
||||
c%ROWCOUNT=0
|
||||
|
||||
c%ROWCOUNT=1
|
||||
|
||||
c%ROWCOUNT=1
|
||||
#
|
||||
# - Returning a never opened cursor does not cause ER_TOO_MANY_OPEN_CURSORS
|
||||
# - Returning an opened+closed cursor does not cause ER_TOO_MANY_OPEN_CURSORS
|
||||
# - Only returning an opened cursor causes ER_TOO_MANY_OPEN_CURSORS
|
||||
#
|
||||
SET @@max_open_cursors=2;
|
||||
CREATE FUNCTION f1(task VARCHAR) RETURN SYS_REFCURSOR AS
|
||||
c SYS_REFCURSOR := NULL;
|
||||
BEGIN
|
||||
IF task LIKE '%open%' THEN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
END IF;
|
||||
IF task LIKE '%close%' THEN
|
||||
CLOSE c;
|
||||
END IF;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
c0:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('0' || ' ' || CASE WHEN c0 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c0%ISOPEN));
|
||||
c1:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('1' || ' ' || CASE WHEN c1 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c1%ISOPEN));
|
||||
c2:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('2' || ' ' || CASE WHEN c2 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c2%ISOPEN));
|
||||
END;
|
||||
/
|
||||
CALL p1('none');
|
||||
|
||||
0 <NULL> false
|
||||
|
||||
1 <NULL> false
|
||||
|
||||
2 <NULL> false
|
||||
CALL p1('open_close');
|
||||
|
||||
0 <NOTNULL> false
|
||||
|
||||
1 <NOTNULL> false
|
||||
|
||||
2 <NOTNULL> false
|
||||
CALL p1('open');
|
||||
|
||||
0 <NOTNULL> true
|
||||
|
||||
1 <NOTNULL> true
|
||||
ERROR HY000: Too many open cursors; max 2 cursors allowed
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
#
|
||||
# Cursor variables cannot be declared as part of a package
|
||||
#
|
||||
CREATE PACKAGE pkg AS
|
||||
FUNCTION f1 RETURN INT;
|
||||
END;
|
||||
/
|
||||
CREATE PACKAGE BODY pkg AS
|
||||
cur SYS_REFCURSOR; -- This is wrong (the top PACKAGE BODY frame)
|
||||
FUNCTION f1 RETURN INT AS
|
||||
BEGIN
|
||||
RETURN 1;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: 'sys_refcursor' is not allowed in this context
|
||||
CREATE PACKAGE BODY pkg AS
|
||||
vc INT := 0;
|
||||
FUNCTION f1 RETURN INT AS
|
||||
cur SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RETURN vc;
|
||||
END;
|
||||
BEGIN
|
||||
DECLARE
|
||||
cur SYS_REFCURSOR; -- This is OK (executable section)
|
||||
BEGIN
|
||||
OPEN cur FOR SELECT 1 AS c FROM DUAL;
|
||||
FETCH cur INTO vc;
|
||||
CLOSE cur;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
SELECT pkg.f1() FROM DUAL;
|
||||
pkg.f1()
|
||||
1
|
||||
DROP PACKAGE pkg;
|
||||
DROP FUNCTION bool_to_char;
|
||||
DROP PACKAGE DBMS_OUTPUT;
|
192
mysql-test/suite/compat/oracle/t/sp-sys_refcursor-alias.test
Normal file
192
mysql-test/suite/compat/oracle/t/sp-sys_refcursor-alias.test
Normal file
@ -0,0 +1,192 @@
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
# Helper functions and packages
|
||||
--disable_query_log
|
||||
--source include/dbms_output.inc
|
||||
--source include/bool_to_char.inc
|
||||
--enable_query_log
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Aliasing
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v0 INT;
|
||||
v1 INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 100 FROM DUAL UNION SELECT 101 FROM DUAL;
|
||||
c1:= c0;
|
||||
FETCH c0 INTO v0; -- fetch 100
|
||||
FETCH c1 INTO v1; -- fetch 101
|
||||
DBMS_OUTPUT.PUT_LINE('actual=' || v0 || ' ' || v1 || ' ' || 'expected=100 101');
|
||||
IF task LIKE '%close_c0%' THEN
|
||||
CLOSE c0;
|
||||
END IF;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' ||
|
||||
'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
OPEN c1 FOR SELECT 200 FROM DUAL UNION SELECT 201 FROM DUAL;
|
||||
FETCH c0 INTO v0; -- fetch 200 from the new OPEN c1
|
||||
FETCH c1 INTO v1; -- fetch 201 from the new OPEN c1
|
||||
DBMS_OUTPUT.PUT_LINE('actual=' || v0 || ' ' || v1 || ' ' || 'expected=200 201');
|
||||
IF task LIKE '%close_c1%' THEN
|
||||
CLOSE c1;
|
||||
END IF;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' ||
|
||||
'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1('');
|
||||
CALL p1('close_c0');
|
||||
CALL p1('close_c1');
|
||||
CALL p1('close_c0 close_c1');
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 FROM DUAL;
|
||||
CLOSE c0;
|
||||
CASE task
|
||||
WHEN 'c0:=c1' THEN c0:=c1; -- Expect: Cursor is not open
|
||||
WHEN 'c1:=c0' THEN c1:=c0; -- Expect: v is set to 2
|
||||
ELSE NULL; -- Expect: Cursor is not open
|
||||
END CASE;
|
||||
OPEN c1 FOR SELECT 2 FROM DUAL;
|
||||
FETCH c0 INTO v;
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
CALL p1('');
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
CALL p1('c0:=c1');
|
||||
CALL p1('c1:=c0');
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Aliasing: different variable scope
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
DECLARE
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 1 AS c FROM DUAL;
|
||||
c0:= c1;
|
||||
END;
|
||||
-- Although c1 who opened the cursor goes out of the scope here,
|
||||
-- the alias still works:
|
||||
FETCH c0 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v='||v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # A comprex script with many OPEN, FETCH, CLOSE statements
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
v0 VARCHAR(32);
|
||||
v1 VARCHAR(32);
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('test1');
|
||||
OPEN c0 FOR SELECT '10' FROM DUAL UNION SELECT '11' FROM DUAL;
|
||||
c1:= c0;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
|
||||
DBMS_OUTPUT.PUT_LINE('test1a');
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
|
||||
DBMS_OUTPUT.PUT_LINE('test2:');
|
||||
OPEN c1 FOR SELECT '20' FROM DUAL UNION SELECT '21' FROM DUAL UNION SELECT '22' FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' || bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
|
||||
DBMS_OUTPUT.PUT_LINE('test2a');
|
||||
CLOSE c1;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' ||bool_to_char(c1%ISOPEN));
|
||||
BEGIN
|
||||
FETCH c0 INTO v0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v0:='<FETCH c0 FAILED>';
|
||||
END;
|
||||
BEGIN
|
||||
FETCH c1 INTO v1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN v1:='<FETCH c1 FAILED>';
|
||||
END;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
|
||||
DBMS_OUTPUT.PUT_LINE('test3');
|
||||
OPEN c0 FOR SELECT '30' FROM DUAL UNION SELECT '31' FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c0%ISOPEN=' || bool_to_char(c0%ISOPEN) || ' ' || 'c1%ISOPEN=' ||bool_to_char(c1%ISOPEN));
|
||||
FETCH c0 INTO v0;
|
||||
FETCH c1 INTO v1;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
|
||||
DBMS_OUTPUT.PUT_LINE('test4');
|
||||
OPEN c0 FOR SELECT 'c0-40' FROM DUAL UNION SELECT 'c0-41' FROM DUAL;
|
||||
OPEN c1 FOR SELECT 'c1-40' FROM DUAL UNION SELECT 'c1-41' FROM DUAL;
|
||||
FETCH c0 INTO v0;
|
||||
FETCH c1 INTO v1;
|
||||
DBMS_OUTPUT.PUT_LINE('v0=' || v0 || ' v1=' || v1);
|
||||
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
DROP PACKAGE DBMS_OUTPUT;
|
||||
DROP FUNCTION bool_to_char;
|
@ -0,0 +1,143 @@
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
# Helper functions and packages
|
||||
--disable_query_log
|
||||
--source include/dbms_output.inc
|
||||
--source include/bool_to_char.inc
|
||||
--enable_query_log
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # Hybrid functions
|
||||
--echo #
|
||||
|
||||
#
|
||||
# CASE
|
||||
#
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= CASE WHEN c0 IS NULL THEN c1 ELSE c0 END;
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
#
|
||||
# Oracle style DECODE(switch , when1 , then1 [, when2 , then2]... [, default] )
|
||||
#
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(switch INT) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
c3 SYS_REFCURSOR;
|
||||
c4 SYS_REFCURSOR;
|
||||
cx SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 10 FROM DUAL;
|
||||
OPEN c1 FOR SELECT 11 FROM DUAL;
|
||||
OPEN c2 FOR SELECT 12 FROM DUAL;
|
||||
OPEN c3 FOR SELECT 13 FROM DUAL;
|
||||
OPEN c4 FOR SELECT 14 FROM DUAL;
|
||||
|
||||
cx:= DECODE(switch, 0, c0, 1, c1, 2, c2, 3, c3, c4);
|
||||
FETCH cx INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1(0);
|
||||
CALL p1(1);
|
||||
CALL p1(2);
|
||||
CALL p1(3);
|
||||
CALL p1(4);
|
||||
CALL p1(5);
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
#
|
||||
# COALESCE
|
||||
#
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= COALESCE(c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
#
|
||||
# IF
|
||||
#
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= IF(false, c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
#
|
||||
# GREATEST
|
||||
#
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 10 FROM DUAL;
|
||||
c2:= GREATEST(c0,c1);
|
||||
FETCH c2 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE('v=' || v);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
DROP PACKAGE dbms_output;
|
||||
DROP FUNCTION bool_to_char;
|
||||
|
||||
SET sql_mode=DEFAULT;
|
646
mysql-test/suite/compat/oracle/t/sp-sys_refcursor.test
Normal file
646
mysql-test/suite/compat/oracle/t/sp-sys_refcursor.test
Normal file
@ -0,0 +1,646 @@
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
# Helper functions and packages
|
||||
--disable_query_log
|
||||
--source include/dbms_output.inc
|
||||
--source include/bool_to_char.inc
|
||||
--enable_query_log
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Error: Unknown cursor and wrong variable data type in OPEN, FETCH, CLOSE
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
|
||||
--error ER_SP_UNDECLARED_VAR
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
c INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
c INT;
|
||||
BEGIN
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
a INT;
|
||||
c INT;
|
||||
BEGIN
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
/
|
||||
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Error: Closing a not open cursor
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Error: Fetching from a not open cursor
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
--echo #
|
||||
--echo # Error: fetching beyond the available number of records
|
||||
--echo # sql_mode=ORACLE preserves the variable value
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Two consequent OPEN (without a CLOSE in beetween) are allowed
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
DECLARE
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
OPEN c FOR SELECT 2 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Many consequent OPEN (without a CLOSE in between) are allowed
|
||||
--echo # and do not cause ER_TOO_MANY_OPEN_CURSORS.
|
||||
--echo #
|
||||
|
||||
SET max_open_cursors=2;
|
||||
DELIMITER /;
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..3
|
||||
LOOP
|
||||
OPEN c FOR SELECT 1 AS c FROM DUAL;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SET max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Simple use example (OPEN, FETCH, CLOSE)
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
FETCH c INTO a;
|
||||
CLOSE c;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Fetching from two parallel cursors
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (1);
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1() AS
|
||||
a0 INT;
|
||||
a1 INT;
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT a*10 FROM t1;
|
||||
OPEN c1 FOR SELECT a*20 FROM t1;
|
||||
FETCH c0 INTO a0;
|
||||
FETCH c1 INTO a1;
|
||||
DBMS_OUTPUT.PUT_LINE(a0 || ' ' || a1);
|
||||
CLOSE c0;
|
||||
CLOSE c1;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
DROP TABLE t1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor from a function
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10),(20);
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION f1 RETURN SYS_REFCURSOR AS
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR DEFAULT f1();
|
||||
BEGIN
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
DROP TABLE t1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning SYS_REFCURSOR from a function: too many open cursors
|
||||
--echo #
|
||||
|
||||
SET max_open_cursors=2;
|
||||
DELIMITER /;
|
||||
CREATE OR REPLACE FUNCTION f1 RETURN SYS_REFCURSOR IS
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 AS a FROM DUAL;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
c0:= f1();
|
||||
FETCH c0 INTO a;
|
||||
c1:= f1();
|
||||
FETCH c1 INTO a;
|
||||
c2:= f1();
|
||||
FETCH c2 INTO a;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
DROP FUNCTION f1;
|
||||
SET max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor as an OUT param
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10);
|
||||
INSERT INTO t1 VALUES (20);
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
p1(c);
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor as an OUT param: Too many open cursors
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=2;
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR VALUES (10),(20);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
p1(c0);
|
||||
|
||||
LOOP
|
||||
FETCH c0 INTO a;
|
||||
EXIT WHEN c0%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
|
||||
p1(c1);
|
||||
|
||||
LOOP
|
||||
FETCH c1 INTO a;
|
||||
EXIT WHEN c1%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
|
||||
p1(c2);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
CALL p2;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor as an OUT param: no "Too many open cursors"
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=2;
|
||||
CREATE TABLE t1 (a INT);
|
||||
INSERT INTO t1 VALUES (10);
|
||||
INSERT INTO t1 VALUES (20);
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(c OUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t1 ORDER BY a;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..5
|
||||
LOOP
|
||||
p1(c); -- This closes the cursor and reopens it in p1
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Returning an open cursor as an INOUT param: no "Too many open cursors"
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=2;
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(c INOUT SYS_REFCURSOR) AS
|
||||
BEGIN
|
||||
OPEN c FOR VALUES (10), (20);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
a INT;
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
FOR i IN 1..5
|
||||
LOOP
|
||||
p1(c); -- This closes the cursor and reopens it in p1
|
||||
LOOP
|
||||
FETCH c INTO a;
|
||||
EXIT WHEN c%NOTFOUND;
|
||||
DBMS_OUTPUT.PUT_LINE(a);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Function returning SYS_REFCURSOR and mysql.proc
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION f1() RETURN SYS_REFCURSOR AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SELECT returns FROM mysql.proc WHERE name='f1';
|
||||
SHOW CREATE FUNCTION f1;
|
||||
DROP FUNCTION f1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Procedure with a SYS_REFCURSOR parameter and mysql.proc
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(a0 OUT SYS_REFCURSOR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
a0:= c0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SELECT param_list FROM mysql.proc WHERE name='p1';
|
||||
SHOW CREATE PROCEDURE p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # NULL predicate
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
OPEN c0 FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
FETCH c0 INTO v;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
CLOSE c0;
|
||||
DBMS_OUTPUT.PUT_LINE(bool_to_char(c0 IS NULL));
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Cursor attributes on a not open SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%ISOPEN=' || bool_to_char(c%ISOPEN));
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_SP_CURSOR_NOT_OPEN
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
END;
|
||||
/
|
||||
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Cursor attributes on an open SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ISOPEN=' || bool_to_char(c%ISOPEN));
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%FOUND=' || bool_to_char(c%FOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%NOTFOUND=' || bool_to_char(c%NOTFOUND));
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
c SYS_REFCURSOR;
|
||||
a INT;
|
||||
BEGIN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
FETCH c INTO a;
|
||||
DBMS_OUTPUT.PUT_LINE('c%ROWCOUNT=' || c%ROWCOUNT);
|
||||
END;
|
||||
/
|
||||
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # - Returning a never opened cursor does not cause ER_TOO_MANY_OPEN_CURSORS
|
||||
--echo # - Returning an opened+closed cursor does not cause ER_TOO_MANY_OPEN_CURSORS
|
||||
--echo # - Only returning an opened cursor causes ER_TOO_MANY_OPEN_CURSORS
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=2;
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION f1(task VARCHAR) RETURN SYS_REFCURSOR AS
|
||||
c SYS_REFCURSOR := NULL;
|
||||
BEGIN
|
||||
IF task LIKE '%open%' THEN
|
||||
OPEN c FOR SELECT 1 FROM DUAL;
|
||||
END IF;
|
||||
IF task LIKE '%close%' THEN
|
||||
CLOSE c;
|
||||
END IF;
|
||||
RETURN c;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1(task VARCHAR) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
c0:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('0' || ' ' || CASE WHEN c0 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c0%ISOPEN));
|
||||
c1:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('1' || ' ' || CASE WHEN c1 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c1%ISOPEN));
|
||||
c2:= f1(task);
|
||||
DBMS_OUTPUT.PUT_LINE('2' || ' ' || CASE WHEN c2 IS NULL THEN '<NULL>' ELSE '<NOTNULL>' END ||
|
||||
' ' || bool_to_char(c2%ISOPEN));
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1('none');
|
||||
CALL p1('open_close');
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
CALL p1('open');
|
||||
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION f1;
|
||||
SET @@max_open_cursors=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Cursor variables cannot be declared as part of a package
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PACKAGE pkg AS
|
||||
FUNCTION f1 RETURN INT;
|
||||
END;
|
||||
/
|
||||
|
||||
--error ER_NOT_ALLOWED_IN_THIS_CONTEXT
|
||||
CREATE PACKAGE BODY pkg AS
|
||||
cur SYS_REFCURSOR; -- This is wrong (the top PACKAGE BODY frame)
|
||||
FUNCTION f1 RETURN INT AS
|
||||
BEGIN
|
||||
RETURN 1;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE PACKAGE BODY pkg AS
|
||||
vc INT := 0;
|
||||
FUNCTION f1 RETURN INT AS
|
||||
cur SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RETURN vc;
|
||||
END;
|
||||
BEGIN
|
||||
DECLARE
|
||||
cur SYS_REFCURSOR; -- This is OK (executable section)
|
||||
BEGIN
|
||||
OPEN cur FOR SELECT 1 AS c FROM DUAL;
|
||||
FETCH cur INTO vc;
|
||||
CLOSE cur;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SELECT pkg.f1() FROM DUAL;
|
||||
DROP PACKAGE pkg;
|
||||
|
||||
|
||||
DROP FUNCTION bool_to_char;
|
||||
DROP PACKAGE DBMS_OUTPUT;
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 1
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -251,7 +251,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -57,7 +57,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 0
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 0
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 0
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 0
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 0
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 10
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
@ -135,7 +135,7 @@ performance_schema_max_socket_classes 10
|
||||
performance_schema_max_socket_instances 1000
|
||||
performance_schema_max_sql_text_length 1024
|
||||
performance_schema_max_stage_classes 160
|
||||
performance_schema_max_statement_classes 223
|
||||
performance_schema_max_statement_classes 227
|
||||
performance_schema_max_statement_stack 2
|
||||
performance_schema_max_table_handles 1000
|
||||
performance_schema_max_table_instances 500
|
||||
|
184
mysql-test/suite/sys_vars/r/max_open_cursors_basic.result
Normal file
184
mysql-test/suite/sys_vars/r/max_open_cursors_basic.result
Normal file
@ -0,0 +1,184 @@
|
||||
SET @start_global_value = @@global.max_open_cursors;
|
||||
SET @start_session_value = @@session.max_open_cursors;
|
||||
SELECT @start_session_value = @start_global_value;
|
||||
@start_session_value = @start_global_value
|
||||
1
|
||||
'#--------------------FN_DYNVARS_077_01-------------------------#'
|
||||
SET @@global.max_open_cursors = 1677721610;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '1677721610'
|
||||
SET @@global.max_open_cursors = DEFAULT;
|
||||
SELECT @@global.max_open_cursors > 0;
|
||||
@@global.max_open_cursors > 0
|
||||
1
|
||||
SET @@session.max_open_cursors = 1677721610;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '1677721610'
|
||||
SET @@session.max_open_cursors = DEFAULT;
|
||||
SELECT @@session.max_open_cursors > 0;
|
||||
@@session.max_open_cursors > 0
|
||||
1
|
||||
'#--------------------FN_DYNVARS_077_03-------------------------#'
|
||||
SET @@global.max_open_cursors = 16384;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
16384
|
||||
SET @@global.max_open_cursors = 16385;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
16385
|
||||
SET @@global.max_open_cursors = 65535;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65535
|
||||
SET @@global.max_open_cursors = 4294967294;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '4294967294'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65536
|
||||
SET @@global.max_open_cursors = 4294967295;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '4294967295'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65536
|
||||
'#--------------------FN_DYNVARS_077_04-------------------------#'
|
||||
SET @@session.max_open_cursors = 16384;
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
16384
|
||||
SET @@session.max_open_cursors = 16385;
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
16385
|
||||
SET @@session.max_open_cursors = 65535;
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65535
|
||||
SET @@session.max_open_cursors = 4294967294;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '4294967294'
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65536
|
||||
SET @@session.max_open_cursors = 4294967295;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '4294967295'
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65536
|
||||
'#------------------FN_DYNVARS_077_05-----------------------#'
|
||||
SET @@global.max_open_cursors = -1;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '-1'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
0
|
||||
SET @@global.max_open_cursors = -1024;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '-1024'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
0
|
||||
SET @@global.max_open_cursors = 1024;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
1024
|
||||
SET @@global.max_open_cursors = 16383;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
16383
|
||||
SET @@global.max_open_cursors = 4294967296;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65536
|
||||
SET @@global.max_open_cursors = 65530.34;
|
||||
ERROR 42000: Incorrect argument type to variable 'max_open_cursors'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65536
|
||||
SET @@global.max_open_cursors = test;
|
||||
ERROR 42000: Incorrect argument type to variable 'max_open_cursors'
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
65536
|
||||
SET @@session.max_open_cursors = -1;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '-1'
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
0
|
||||
SET @@session.max_open_cursors = 16383;
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
16383
|
||||
SET @@session.max_open_cursors = 4294967296;
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65536
|
||||
SET @@session.max_open_cursors = 65530.34;
|
||||
ERROR 42000: Incorrect argument type to variable 'max_open_cursors'
|
||||
SET @@session.max_open_cursors = 10737418241;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '10737418241'
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65536
|
||||
SET @@session.max_open_cursors = test;
|
||||
ERROR 42000: Incorrect argument type to variable 'max_open_cursors'
|
||||
SELECT @@session.max_open_cursors;
|
||||
@@session.max_open_cursors
|
||||
65536
|
||||
'#------------------FN_DYNVARS_077_06-----------------------#'
|
||||
SELECT @@global.max_open_cursors = VARIABLE_VALUE
|
||||
FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES
|
||||
WHERE VARIABLE_NAME='max_open_cursors';
|
||||
@@global.max_open_cursors = VARIABLE_VALUE
|
||||
1
|
||||
'#------------------FN_DYNVARS_077_07-----------------------#'
|
||||
SELECT @@session.max_open_cursors = VARIABLE_VALUE
|
||||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
|
||||
WHERE VARIABLE_NAME='max_open_cursors';
|
||||
@@session.max_open_cursors = VARIABLE_VALUE
|
||||
1
|
||||
'#------------------FN_DYNVARS_077_08-----------------------#'
|
||||
SET @@global.max_open_cursors = TRUE;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
1
|
||||
SET @@global.max_open_cursors = FALSE;
|
||||
SELECT @@global.max_open_cursors;
|
||||
@@global.max_open_cursors
|
||||
0
|
||||
'#---------------------FN_DYNVARS_077_09----------------------#'
|
||||
SET @@global.max_open_cursors = 163845;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '163845'
|
||||
SELECT @@max_open_cursors = @@global.max_open_cursors;
|
||||
@@max_open_cursors = @@global.max_open_cursors
|
||||
1
|
||||
'#---------------------FN_DYNVARS_077_10----------------------#'
|
||||
SET @@max_open_cursors = 16777216;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '16777216'
|
||||
SELECT @@max_open_cursors = @@local.max_open_cursors;
|
||||
@@max_open_cursors = @@local.max_open_cursors
|
||||
1
|
||||
SELECT @@local.max_open_cursors = @@session.max_open_cursors;
|
||||
@@local.max_open_cursors = @@session.max_open_cursors
|
||||
1
|
||||
'#---------------------FN_DYNVARS_077_11----------------------#'
|
||||
SET max_open_cursors = 316777216;
|
||||
Warnings:
|
||||
Warning 1292 Truncated incorrect max_open_cursors value: '316777216'
|
||||
SELECT @@max_open_cursors;
|
||||
@@max_open_cursors
|
||||
65536
|
||||
SELECT local.max_open_cursors;
|
||||
ERROR 42S02: Unknown table 'local' in SELECT
|
||||
SELECT session.max_open_cursors;
|
||||
ERROR 42S02: Unknown table 'session' in SELECT
|
||||
SELECT max_open_cursors = @@session.max_open_cursors;
|
||||
ERROR 42S22: Unknown column 'max_open_cursors' in 'SELECT'
|
||||
SET @@global.max_open_cursors = @start_global_value;
|
21
mysql-test/suite/sys_vars/r/max_open_cursors_func.result
Normal file
21
mysql-test/suite/sys_vars/r/max_open_cursors_func.result
Normal file
@ -0,0 +1,21 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
SET @@max_open_cursors=1;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val' FROM DUAL;
|
||||
OPEN c0 FOR SELECT 'c0val' FROM DUAL;
|
||||
OPEN c1;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Too many open cursors; max 1 cursors allowed
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val' FROM DUAL;
|
||||
OPEN c1;
|
||||
OPEN c0 FOR SELECT 'c0val' FROM DUAL;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Too many open cursors; max 1 cursors allowed
|
||||
SET @@max_open_cursors=DEFAULT;
|
@ -2032,6 +2032,16 @@ NUMERIC_BLOCK_SIZE 1
|
||||
ENUM_VALUE_LIST NULL
|
||||
READ_ONLY NO
|
||||
COMMAND_LINE_ARGUMENT REQUIRED
|
||||
VARIABLE_NAME MAX_OPEN_CURSORS
|
||||
VARIABLE_SCOPE SESSION
|
||||
VARIABLE_TYPE INT UNSIGNED
|
||||
VARIABLE_COMMENT The maximum number of open cursors allowed per session
|
||||
NUMERIC_MIN_VALUE 0
|
||||
NUMERIC_MAX_VALUE 65536
|
||||
NUMERIC_BLOCK_SIZE 1
|
||||
ENUM_VALUE_LIST NULL
|
||||
READ_ONLY NO
|
||||
COMMAND_LINE_ARGUMENT REQUIRED
|
||||
VARIABLE_NAME MAX_PASSWORD_ERRORS
|
||||
VARIABLE_SCOPE GLOBAL
|
||||
VARIABLE_TYPE INT UNSIGNED
|
||||
|
@ -2232,6 +2232,16 @@ NUMERIC_BLOCK_SIZE 1
|
||||
ENUM_VALUE_LIST NULL
|
||||
READ_ONLY NO
|
||||
COMMAND_LINE_ARGUMENT REQUIRED
|
||||
VARIABLE_NAME MAX_OPEN_CURSORS
|
||||
VARIABLE_SCOPE SESSION
|
||||
VARIABLE_TYPE INT UNSIGNED
|
||||
VARIABLE_COMMENT The maximum number of open cursors allowed per session
|
||||
NUMERIC_MIN_VALUE 0
|
||||
NUMERIC_MAX_VALUE 65536
|
||||
NUMERIC_BLOCK_SIZE 1
|
||||
ENUM_VALUE_LIST NULL
|
||||
READ_ONLY NO
|
||||
COMMAND_LINE_ARGUMENT REQUIRED
|
||||
VARIABLE_NAME MAX_PASSWORD_ERRORS
|
||||
VARIABLE_SCOPE GLOBAL
|
||||
VARIABLE_TYPE INT UNSIGNED
|
||||
|
207
mysql-test/suite/sys_vars/t/max_open_cursors_basic.test
Normal file
207
mysql-test/suite/sys_vars/t/max_open_cursors_basic.test
Normal file
@ -0,0 +1,207 @@
|
||||
############## mysql-test\t\max_open_cursors_basic.test ###############
|
||||
# #
|
||||
# Variable Name: max_open_cursors #
|
||||
# Scope: GLOBAL | SESSION #
|
||||
# Access Type: Dynamic #
|
||||
# Data Type: numeric #
|
||||
# Default Value: 16777216 #
|
||||
# Range: 0-65535 #
|
||||
# #
|
||||
# #
|
||||
# Creation Date: 2025-02-10 #
|
||||
# Author: Salman #
|
||||
# #
|
||||
# Description: Test Cases of Dynamic System Variable max_open_cursors #
|
||||
# that checks the behavior of this variable in the following ways#
|
||||
# * Default Value #
|
||||
# * Valid & Invalid values #
|
||||
# * Scope & Access method #
|
||||
# * Data Integrity #
|
||||
# #
|
||||
###############################################################################
|
||||
|
||||
--source include/load_sysvars.inc
|
||||
|
||||
###############################################################
|
||||
# START OF max_open_cursors TESTS #
|
||||
###############################################################
|
||||
|
||||
|
||||
#############################################################
|
||||
# Save initial value #
|
||||
#############################################################
|
||||
|
||||
SET @start_global_value = @@global.max_open_cursors;
|
||||
SET @start_session_value = @@session.max_open_cursors;
|
||||
SELECT @start_session_value = @start_global_value;
|
||||
|
||||
|
||||
--echo '#--------------------FN_DYNVARS_077_01-------------------------#'
|
||||
###############################################################
|
||||
# Display the DEFAULT value of max_open_cursors #
|
||||
###############################################################
|
||||
|
||||
SET @@global.max_open_cursors = 1677721610;
|
||||
SET @@global.max_open_cursors = DEFAULT;
|
||||
SELECT @@global.max_open_cursors > 0;
|
||||
|
||||
SET @@session.max_open_cursors = 1677721610;
|
||||
SET @@session.max_open_cursors = DEFAULT;
|
||||
SELECT @@session.max_open_cursors > 0;
|
||||
|
||||
|
||||
--echo '#--------------------FN_DYNVARS_077_03-------------------------#'
|
||||
############################################################################
|
||||
# Change the value of max_open_cursors to a valid value for GLOBAL Scope #
|
||||
############################################################################
|
||||
|
||||
SET @@global.max_open_cursors = 16384;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 16385;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 65535;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 4294967294;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 4294967295;
|
||||
SELECT @@global.max_open_cursors;
|
||||
|
||||
--echo '#--------------------FN_DYNVARS_077_04-------------------------#'
|
||||
#############################################################################
|
||||
# Change the value of max_open_cursors to a valid value for SESSION Scope #
|
||||
#############################################################################
|
||||
|
||||
SET @@session.max_open_cursors = 16384;
|
||||
SELECT @@session.max_open_cursors;
|
||||
SET @@session.max_open_cursors = 16385;
|
||||
SELECT @@session.max_open_cursors;
|
||||
SET @@session.max_open_cursors = 65535;
|
||||
SELECT @@session.max_open_cursors;
|
||||
SET @@session.max_open_cursors = 4294967294;
|
||||
SELECT @@session.max_open_cursors;
|
||||
SET @@session.max_open_cursors = 4294967295;
|
||||
SELECT @@session.max_open_cursors;
|
||||
|
||||
--echo '#------------------FN_DYNVARS_077_05-----------------------#'
|
||||
##############################################################
|
||||
# Change the value of max_open_cursors to an invalid value #
|
||||
##############################################################
|
||||
|
||||
SET @@global.max_open_cursors = -1;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = -1024;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 1024;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = 16383;
|
||||
SELECT @@global.max_open_cursors;
|
||||
--disable_warnings
|
||||
SET @@global.max_open_cursors = 4294967296;
|
||||
--enable_warnings
|
||||
--replace_result 4294966272 4294967296
|
||||
SELECT @@global.max_open_cursors;
|
||||
--Error ER_WRONG_TYPE_FOR_VAR
|
||||
SET @@global.max_open_cursors = 65530.34;
|
||||
--replace_result 4294966272 4294967296
|
||||
SELECT @@global.max_open_cursors;
|
||||
--Error ER_WRONG_TYPE_FOR_VAR
|
||||
SET @@global.max_open_cursors = test;
|
||||
--replace_result 4294966272 4294967296
|
||||
SELECT @@global.max_open_cursors;
|
||||
|
||||
SET @@session.max_open_cursors = -1;
|
||||
SELECT @@session.max_open_cursors;
|
||||
SET @@session.max_open_cursors = 16383;
|
||||
SELECT @@session.max_open_cursors;
|
||||
--disable_warnings
|
||||
SET @@session.max_open_cursors = 4294967296;
|
||||
--enable_warnings
|
||||
--replace_result 4294966272 4294967296
|
||||
SELECT @@session.max_open_cursors;
|
||||
--Error ER_WRONG_TYPE_FOR_VAR
|
||||
SET @@session.max_open_cursors = 65530.34;
|
||||
SET @@session.max_open_cursors = 10737418241;
|
||||
--replace_result 4294966272 10737418240
|
||||
SELECT @@session.max_open_cursors;
|
||||
|
||||
--Error ER_WRONG_TYPE_FOR_VAR
|
||||
SET @@session.max_open_cursors = test;
|
||||
--replace_result 4294966272 10737418240
|
||||
SELECT @@session.max_open_cursors;
|
||||
|
||||
|
||||
--echo '#------------------FN_DYNVARS_077_06-----------------------#'
|
||||
####################################################################
|
||||
# Check if the value in GLOBAL Table matches value in variable #
|
||||
####################################################################
|
||||
|
||||
|
||||
SELECT @@global.max_open_cursors = VARIABLE_VALUE
|
||||
FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES
|
||||
WHERE VARIABLE_NAME='max_open_cursors';
|
||||
|
||||
--echo '#------------------FN_DYNVARS_077_07-----------------------#'
|
||||
####################################################################
|
||||
# Check if the value in SESSION Table matches value in variable #
|
||||
####################################################################
|
||||
|
||||
SELECT @@session.max_open_cursors = VARIABLE_VALUE
|
||||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
|
||||
WHERE VARIABLE_NAME='max_open_cursors';
|
||||
|
||||
|
||||
--echo '#------------------FN_DYNVARS_077_08-----------------------#'
|
||||
####################################################################
|
||||
# Check if TRUE and FALSE values can be used on variable #
|
||||
####################################################################
|
||||
|
||||
SET @@global.max_open_cursors = TRUE;
|
||||
SELECT @@global.max_open_cursors;
|
||||
SET @@global.max_open_cursors = FALSE;
|
||||
SELECT @@global.max_open_cursors;
|
||||
|
||||
|
||||
--echo '#---------------------FN_DYNVARS_077_09----------------------#'
|
||||
#################################################################################
|
||||
# Check if accessing variable with and without GLOBAL point to same variable #
|
||||
#################################################################################
|
||||
|
||||
SET @@global.max_open_cursors = 163845;
|
||||
SELECT @@max_open_cursors = @@global.max_open_cursors;
|
||||
|
||||
|
||||
--echo '#---------------------FN_DYNVARS_077_10----------------------#'
|
||||
########################################################################################################
|
||||
# Check if accessing variable with SESSION,LOCAL and without SCOPE points to same session variable #
|
||||
########################################################################################################
|
||||
|
||||
SET @@max_open_cursors = 16777216;
|
||||
SELECT @@max_open_cursors = @@local.max_open_cursors;
|
||||
SELECT @@local.max_open_cursors = @@session.max_open_cursors;
|
||||
|
||||
|
||||
--echo '#---------------------FN_DYNVARS_077_11----------------------#'
|
||||
#############################################################################
|
||||
# Check if max_open_cursors can be accessed with and without @@ sign #
|
||||
#############################################################################
|
||||
|
||||
SET max_open_cursors = 316777216;
|
||||
SELECT @@max_open_cursors;
|
||||
--Error ER_UNKNOWN_TABLE
|
||||
SELECT local.max_open_cursors;
|
||||
--Error ER_UNKNOWN_TABLE
|
||||
SELECT session.max_open_cursors;
|
||||
--Error ER_BAD_FIELD_ERROR
|
||||
SELECT max_open_cursors = @@session.max_open_cursors;
|
||||
|
||||
|
||||
####################################
|
||||
# Restore initial value #
|
||||
####################################
|
||||
|
||||
SET @@global.max_open_cursors = @start_global_value;
|
||||
|
||||
|
||||
#######################################################
|
||||
# END OF max_open_cursors TESTS #
|
||||
#######################################################
|
31
mysql-test/suite/sys_vars/t/max_open_cursors_func.test
Normal file
31
mysql-test/suite/sys_vars/t/max_open_cursors_func.test
Normal file
@ -0,0 +1,31 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
SET @@max_open_cursors=1;
|
||||
|
||||
# Make sure @@max_open_cursors counts both static cursors and SYS_REFCURSORs.
|
||||
DELIMITER $$;
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val' FROM DUAL;
|
||||
OPEN c0 FOR SELECT 'c0val' FROM DUAL;
|
||||
OPEN c1;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
# Same as above, but with the opposite OPEN order
|
||||
DELIMITER $$;
|
||||
--error ER_TOO_MANY_OPEN_CURSORS
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 CURSOR FOR SELECT 'c1val' FROM DUAL;
|
||||
OPEN c1;
|
||||
OPEN c0 FOR SELECT 'c0val' FROM DUAL;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
SET @@max_open_cursors=DEFAULT;
|
17
plugin/type_cursor/CMakeLists.txt
Normal file
17
plugin/type_cursor/CMakeLists.txt
Normal file
@ -0,0 +1,17 @@
|
||||
# Copyright (c) 2023-2025, MariaDB corporation
|
||||
#
|
||||
# This program is free software; you can redistribute it and/or modify
|
||||
# it under the terms of the GNU General Public License as published by
|
||||
# the Free Software Foundation; version 2 of the License.
|
||||
#
|
||||
# This program is distributed in the hope that it will be useful,
|
||||
# but WITHOUT ANY WARRANTY; without even the implied warranty of
|
||||
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
||||
# GNU General Public License for more details.
|
||||
#
|
||||
# You should have received a copy of the GNU General Public License
|
||||
# along with this program; if not, write to the Free Software
|
||||
# Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1335 USA
|
||||
|
||||
MYSQL_ADD_PLUGIN(type_cursor plugin.cc RECOMPILE_FOR_EMBEDDED
|
||||
MANDATORY COMPONENT Cursor)
|
7
plugin/type_cursor/mysql-test/type_cursor/suite.pm
Normal file
7
plugin/type_cursor/mysql-test/type_cursor/suite.pm
Normal file
@ -0,0 +1,7 @@
|
||||
package My::Suite::Type_cursor;
|
||||
|
||||
@ISA = qw(My::Suite);
|
||||
|
||||
sub is_default { 1 }
|
||||
|
||||
bless { };
|
@ -0,0 +1,241 @@
|
||||
#
|
||||
# Helper routines
|
||||
#
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# sql_mode=DEFAULT: TYPE OF declaration for a single SYS_REFCURSOR:
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v00 INT;
|
||||
DECLARE c10 SYS_REFCURSOR;
|
||||
DECLARE c11 TYPE OF c10;
|
||||
OPEN c11 FOR SELECT 1;
|
||||
FETCH c11 INTO v00;
|
||||
SELECT c10, c11, v00, refs(0,4) AS refs;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
Pos Instruction
|
||||
0 set v00@0 NULL
|
||||
1 set c10@1 NULL
|
||||
2 set c11@2 NULL
|
||||
3 copen STMT.cursor[c11@2]
|
||||
4 cfetch STMT.cursor[c11@2] v00@0
|
||||
5 stmt 0 "SELECT c10, c11, v00, refs(0,4) AS refs"
|
||||
6 destruct sys_refcursor c11@2
|
||||
7 destruct sys_refcursor c10@1
|
||||
CALL p1;
|
||||
c10 c11 v00 refs
|
||||
NULL 0 1 [1 NULL NULL NULL NULL]
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# sql_mode=ORACLE" %TYPE declaration for a single SYS_REFCURSOR:
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 c0%TYPE;
|
||||
v1 INT;
|
||||
v2 INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 AS c1, 2 AS c2 FROM DUAL;
|
||||
c1:= c0;
|
||||
FETCH c1 INTO v1, v2;
|
||||
DBMS_OUTPUT.PUT_LINE(v1 ||' '|| v2);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
1 2
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# Anchored TYPE OF declarations for a ROW of SYS_REFCURSORs:
|
||||
# DECLARE r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR);
|
||||
# DECLARE r11 TYPE OF r10;
|
||||
#
|
||||
CREATE PROCEDURE open1(INOUT c00 SYS_REFCURSOR, value INT)
|
||||
BEGIN
|
||||
OPEN c00 FOR SELECT value;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE open1
|
||||
/
|
||||
Pos Instruction
|
||||
0 copen STMT.cursor[c00@0]
|
||||
CREATE PROCEDURE open2(INOUT r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR))
|
||||
BEGIN
|
||||
CALL open1(r00.c00, 20);
|
||||
CALL open1(r00.c01, 21);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE open2
|
||||
/
|
||||
Pos Instruction
|
||||
0 stmt 88 "CALL open1(r00.c00, 20)"
|
||||
1 stmt 88 "CALL open1(r00.c01, 21)"
|
||||
CREATE PROCEDURE fetch1(c00 SYS_REFCURSOR, OUT v00 INT)
|
||||
BEGIN
|
||||
FETCH c00 INTO v00;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE fetch1
|
||||
/
|
||||
Pos Instruction
|
||||
0 cfetch STMT.cursor[c00@0] v00@1
|
||||
CREATE PROCEDURE fetch2(r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR),
|
||||
OUT v00 ROW(i00 INT, i01 INT))
|
||||
BEGIN
|
||||
CALL fetch1(r00.c00, v00.i00);
|
||||
CALL fetch1(r00.c01, v00.i01);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE fetch2
|
||||
/
|
||||
Pos Instruction
|
||||
0 stmt 88 "CALL fetch1(r00.c00, v00.i00)"
|
||||
1 stmt 88 "CALL fetch1(r00.c01, v00.i01)"
|
||||
CREATE PROCEDURE close1(c00 SYS_REFCURSOR)
|
||||
BEGIN
|
||||
CLOSE c00;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE close1
|
||||
/
|
||||
Pos Instruction
|
||||
0 cclose STMT.cursor[c00@0]
|
||||
CREATE PROCEDURE close2(r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR))
|
||||
BEGIN
|
||||
CALL close1(r00.c00);
|
||||
CALL close1(r00.c01);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE close2
|
||||
/
|
||||
Pos Instruction
|
||||
0 stmt 88 "CALL close1(r00.c00)"
|
||||
1 stmt 88 "CALL close1(r00.c01)"
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v00 ROW(i00 INT, i01 iNT);
|
||||
DECLARE r10 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR);
|
||||
DECLARE r11 TYPE OF r10;
|
||||
CALL open2(r11);
|
||||
CALL fetch2(r11, v00);
|
||||
CALL close2(r11);
|
||||
SELECT r11.c00, r11.c01, refs(0,3) AS refs, v00.i00, v00.i01;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
Pos Instruction
|
||||
0 set v00@0 NULL
|
||||
1 set r10@1 NULL
|
||||
2 set r11@2 NULL
|
||||
3 stmt 88 "CALL open2(r11)"
|
||||
4 stmt 88 "CALL fetch2(r11, v00)"
|
||||
5 stmt 88 "CALL close2(r11)"
|
||||
6 stmt 0 "SELECT r11.c00, r11.c01, refs(0,3) AS..."
|
||||
7 destruct row r11@2
|
||||
8 destruct row r10@1
|
||||
CALL p1;
|
||||
r11.c00 r11.c01 refs v00.i00 v00.i01
|
||||
0 1 [1 1 NULL NULL] 20 21
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE open1;
|
||||
DROP PROCEDURE open2;
|
||||
DROP PROCEDURE fetch1;
|
||||
DROP PROCEDURE fetch2;
|
||||
DROP PROCEDURE close1;
|
||||
DROP PROCEDURE close2;
|
||||
#
|
||||
# This declaration raises "Illegal parameter data type":
|
||||
# DECLARE r00 ROW TYPE OF static_cursor_with_refcursor_fields;
|
||||
# But only of the execution really comes into its block.
|
||||
#
|
||||
CREATE PROCEDURE p1(declare_row_type_of BOOLEAN)
|
||||
BEGIN
|
||||
DECLARE v00 INT;
|
||||
DECLARE v01 INT;
|
||||
DECLARE c00 SYS_REFCURSOR;
|
||||
DECLARE c01 SYS_REFCURSOR;
|
||||
DECLARE s00 CURSOR FOR SELECT c00, c01;
|
||||
OPEN c00 FOR SELECT 10;
|
||||
OPEN c01 FOR SELECT 11;
|
||||
IF declare_row_type_of THEN
|
||||
BEGIN
|
||||
DECLARE r00 ROW TYPE OF s00;
|
||||
END;
|
||||
END IF;
|
||||
FETCH c00 INTO v00;
|
||||
FETCH c01 INTO v01;
|
||||
SELECT c00, c01, refs(0,4) AS refs, v00, v01;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
Pos Instruction
|
||||
0 set v00@1 NULL
|
||||
1 set v01@2 NULL
|
||||
2 set c00@3 NULL
|
||||
3 set c01@4 NULL
|
||||
4 cpush s00@0
|
||||
5 copen STMT.cursor[c00@3]
|
||||
6 copen STMT.cursor[c01@4]
|
||||
7 jump_if_not 10(10) declare_row_type_of@0
|
||||
8 cursor_copy_struct s00 r00@5
|
||||
9 set r00@5 NULL
|
||||
10 cfetch STMT.cursor[c00@3] v00@1
|
||||
11 cfetch STMT.cursor[c01@4] v01@2
|
||||
12 stmt 0 "SELECT c00, c01, refs(0,4) AS refs, v..."
|
||||
13 cpop 1
|
||||
14 destruct sys_refcursor c01@4
|
||||
15 destruct sys_refcursor c00@3
|
||||
CALL p1(false);
|
||||
c00 c01 refs v00 v01
|
||||
0 1 [1 1 NULL NULL NULL] 10 11
|
||||
CALL p1(true);
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'CREATE TABLE'
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# sql_mode=ORACLE:
|
||||
# static_cursor_with_refcursor_field%ROWTYPE
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 AS c1, 2 AS c2 FROM DUAL;
|
||||
DECLARE
|
||||
r c0%ROWTYPE; -- This is considered as a table c0.
|
||||
BEGIN
|
||||
CREATE TABLE t1 AS SELECT r.c1 AS c1, r.c2 AS c2;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
ERROR 42S02: Table 'test.c0' doesn't exist
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# Fetching from a SYS_REFCURSOR into a %ROWTYPE variable
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE TABLE t1 (a INT, b VARCHAR(32));
|
||||
INSERT INTO t1 VALUES (1, 'b1');
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
r0 t1%ROWTYPE;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT * FROM t1;
|
||||
FETCH c0 INTO r0;
|
||||
DBMS_OUTPUT.PUT_LINE(r0.a ||' '|| r0.b);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
1 b1
|
||||
DROP TABLE t1;
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
@ -0,0 +1,223 @@
|
||||
--source include/have_debug.inc
|
||||
|
||||
--disable_query_log
|
||||
--disable_result_log
|
||||
--source type_sys_refcursor-helper_routines-debug-create.inc
|
||||
--source include/dbms_output.inc
|
||||
--enable_result_log
|
||||
--enable_query_log
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # sql_mode=DEFAULT: TYPE OF declaration for a single SYS_REFCURSOR:
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v00 INT;
|
||||
DECLARE c10 SYS_REFCURSOR;
|
||||
DECLARE c11 TYPE OF c10;
|
||||
OPEN c11 FOR SELECT 1;
|
||||
FETCH c11 INTO v00;
|
||||
SELECT c10, c11, v00, refs(0,4) AS refs;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # sql_mode=ORACLE" %TYPE declaration for a single SYS_REFCURSOR:
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 c0%TYPE;
|
||||
v1 INT;
|
||||
v2 INT;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 AS c1, 2 AS c2 FROM DUAL;
|
||||
c1:= c0;
|
||||
FETCH c1 INTO v1, v2;
|
||||
DBMS_OUTPUT.PUT_LINE(v1 ||' '|| v2);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Anchored TYPE OF declarations for a ROW of SYS_REFCURSORs:
|
||||
--echo # DECLARE r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR);
|
||||
--echo # DECLARE r11 TYPE OF r10;
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE open1(INOUT c00 SYS_REFCURSOR, value INT)
|
||||
BEGIN
|
||||
OPEN c00 FOR SELECT value;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE open1
|
||||
/
|
||||
CREATE PROCEDURE open2(INOUT r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR))
|
||||
BEGIN
|
||||
CALL open1(r00.c00, 20);
|
||||
CALL open1(r00.c01, 21);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE open2
|
||||
/
|
||||
CREATE PROCEDURE fetch1(c00 SYS_REFCURSOR, OUT v00 INT)
|
||||
BEGIN
|
||||
FETCH c00 INTO v00;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE fetch1
|
||||
/
|
||||
CREATE PROCEDURE fetch2(r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR),
|
||||
OUT v00 ROW(i00 INT, i01 INT))
|
||||
BEGIN
|
||||
CALL fetch1(r00.c00, v00.i00);
|
||||
CALL fetch1(r00.c01, v00.i01);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE fetch2
|
||||
/
|
||||
CREATE PROCEDURE close1(c00 SYS_REFCURSOR)
|
||||
BEGIN
|
||||
CLOSE c00;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE close1
|
||||
/
|
||||
CREATE PROCEDURE close2(r00 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR))
|
||||
BEGIN
|
||||
CALL close1(r00.c00);
|
||||
CALL close1(r00.c01);
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE close2
|
||||
/
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE v00 ROW(i00 INT, i01 iNT);
|
||||
DECLARE r10 ROW(c00 SYS_REFCURSOR, c01 SYS_REFCURSOR);
|
||||
DECLARE r11 TYPE OF r10;
|
||||
CALL open2(r11);
|
||||
CALL fetch2(r11, v00);
|
||||
CALL close2(r11);
|
||||
SELECT r11.c00, r11.c01, refs(0,3) AS refs, v00.i00, v00.i01;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE open1;
|
||||
DROP PROCEDURE open2;
|
||||
DROP PROCEDURE fetch1;
|
||||
DROP PROCEDURE fetch2;
|
||||
DROP PROCEDURE close1;
|
||||
DROP PROCEDURE close2;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # This declaration raises "Illegal parameter data type":
|
||||
--echo # DECLARE r00 ROW TYPE OF static_cursor_with_refcursor_fields;
|
||||
--echo # But only of the execution really comes into its block.
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(declare_row_type_of BOOLEAN)
|
||||
BEGIN
|
||||
DECLARE v00 INT;
|
||||
DECLARE v01 INT;
|
||||
DECLARE c00 SYS_REFCURSOR;
|
||||
DECLARE c01 SYS_REFCURSOR;
|
||||
DECLARE s00 CURSOR FOR SELECT c00, c01;
|
||||
OPEN c00 FOR SELECT 10;
|
||||
OPEN c01 FOR SELECT 11;
|
||||
IF declare_row_type_of THEN
|
||||
BEGIN
|
||||
DECLARE r00 ROW TYPE OF s00;
|
||||
END;
|
||||
END IF;
|
||||
FETCH c00 INTO v00;
|
||||
FETCH c01 INTO v01;
|
||||
SELECT c00, c01, refs(0,4) AS refs, v00, v01;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
CALL p1(false);
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
CALL p1(true);
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # sql_mode=ORACLE:
|
||||
--echo # static_cursor_with_refcursor_field%ROWTYPE
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1 AS c1, 2 AS c2 FROM DUAL;
|
||||
DECLARE
|
||||
r c0%ROWTYPE; -- This is considered as a table c0.
|
||||
BEGIN
|
||||
CREATE TABLE t1 AS SELECT r.c1 AS c1, r.c2 AS c2;
|
||||
END;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--error ER_NO_SUCH_TABLE
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Fetching from a SYS_REFCURSOR into a %ROWTYPE variable
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE TABLE t1 (a INT, b VARCHAR(32));
|
||||
INSERT INTO t1 VALUES (1, 'b1');
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
r0 t1%ROWTYPE;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT * FROM t1;
|
||||
FETCH c0 INTO r0;
|
||||
DBMS_OUTPUT.PUT_LINE(r0.a ||' '|| r0.b);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP TABLE t1;
|
||||
DROP PROCEDURE p1;
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--disable_query_log
|
||||
--disable_result_log
|
||||
--source type_sys_refcursor-helper_routines-debug-drop.inc
|
||||
DROP PACKAGE dbms_output;
|
||||
--enable_result_log
|
||||
--enable_query_log
|
@ -0,0 +1,131 @@
|
||||
SET NAMES utf8mb4;
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# CAST(sys_refcursor_expr AS CHAR) is allowed
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 10;
|
||||
OPEN c1 FOR SELECT 20;
|
||||
SELECT CAST(c0 AS CHAR) AS col0, CAST(c1 AS CHAR) AS col1;
|
||||
CREATE TABLE t1 AS
|
||||
SELECT CAST(c0 AS CHAR) AS col0, CAST(c1 AS CHAR) AS col1;
|
||||
SHOW CREATE TABLE t1;
|
||||
SELECT * FROM t1;
|
||||
DROP TABLE t1;
|
||||
END;
|
||||
$$
|
||||
col0 col1
|
||||
0 1
|
||||
Table Create Table
|
||||
t1 CREATE TABLE `t1` (
|
||||
`col0` varchar(6) DEFAULT NULL,
|
||||
`col1` varchar(6) DEFAULT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_uca1400_ai_ci
|
||||
col0 col1
|
||||
0 1
|
||||
#
|
||||
# Type cast to other data types
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS SIGNED);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'cast_as_signed'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS UNSIGNED);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'cast_as_unsigned'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DOUBLE);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'double_typecast'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS FLOAT);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'float_typecast'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DECIMAL(10,0));
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'decimal_typecast'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS TIME);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'cast_as_time'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DATE);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'cast_as_date'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DATETIME);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'cast_as_datetime'
|
||||
#
|
||||
# Type cast from other data types
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DOUBLE;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a FLOAT;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DECIMAL;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a CHAR(30);
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a TIME;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DATE;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DATETIME;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
@ -0,0 +1,179 @@
|
||||
SET NAMES utf8mb4;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # CAST(sys_refcursor_expr AS CHAR) is allowed
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 10;
|
||||
OPEN c1 FOR SELECT 20;
|
||||
SELECT CAST(c0 AS CHAR) AS col0, CAST(c1 AS CHAR) AS col1;
|
||||
CREATE TABLE t1 AS
|
||||
SELECT CAST(c0 AS CHAR) AS col0, CAST(c1 AS CHAR) AS col1;
|
||||
SHOW CREATE TABLE t1;
|
||||
SELECT * FROM t1;
|
||||
DROP TABLE t1;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Type cast to other data types
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS SIGNED);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS UNSIGNED);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DOUBLE);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS FLOAT);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DECIMAL(10,0));
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS TIME);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DATE);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CAST(c0 AS DATETIME);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Type cast from other data types
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DOUBLE;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a FLOAT;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DECIMAL;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a CHAR(30);
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a TIME;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DATE;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a DATETIME;
|
||||
SELECT CAST(a AS SYS_REFCURSOR);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
@ -0,0 +1,40 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Using sys_refcursor operations on non-cursor variables
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur INT;
|
||||
OPEN cur FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type int for operation 'OPEN'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur, var INT;
|
||||
FETCH cur INTO var;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type int for operation 'FETCH'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur INT;
|
||||
CLOSE cur;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type int for operation 'CLOSE'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
DECLARE c INT;
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type int for operation 'FETCH'
|
||||
SET sql_mode=ORACLE;
|
||||
DECLARE
|
||||
cur INT;
|
||||
BEGIN
|
||||
SELECT cur%isopen;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type int for operation '%cursor_attr'
|
||||
SET sql_mode=DEFAULT;
|
@ -0,0 +1,57 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # Using sys_refcursor operations on non-cursor variables
|
||||
--echo #
|
||||
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur INT;
|
||||
OPEN cur FOR SELECT 1 AS c FROM DUAL;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur, var INT;
|
||||
FETCH cur INTO var;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE cur INT;
|
||||
CLOSE cur;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE a INT;
|
||||
DECLARE c INT;
|
||||
FETCH c INTO a;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
cur INT;
|
||||
BEGIN
|
||||
SELECT cur%isopen;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
SET sql_mode=DEFAULT;
|
@ -0,0 +1,16 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
CREATE AGGREGATE FUNCTION f1(x int) RETURNS INT
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE mini INT DEFAULT 0;
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND RETURN mini;
|
||||
LOOP
|
||||
FETCH GROUP NEXT ROW;
|
||||
SET mini= mini+x;
|
||||
FETCH GROUP NEXT ROW;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: 'sys_refcursor' is not allowed in this context
|
@ -0,0 +1,19 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_NOT_ALLOWED_IN_THIS_CONTEXT
|
||||
CREATE AGGREGATE FUNCTION f1(x int) RETURNS INT
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE mini INT DEFAULT 0;
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND RETURN mini;
|
||||
LOOP
|
||||
FETCH GROUP NEXT ROW;
|
||||
SET mini= mini+x;
|
||||
FETCH GROUP NEXT ROW;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
@ -0,0 +1,317 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# A small OPEN+FETCH+CLOSE example
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE a, b INT;
|
||||
OPEN c FOR SELECT 1, 2;
|
||||
FETCH c INTO a, b;
|
||||
CLOSE c;
|
||||
SELECT c, CURSOR_REF_COUNT(c) AS cnt, a, b;
|
||||
END;
|
||||
$$
|
||||
SHOW PROCEDURE CODE p1;
|
||||
Pos Instruction
|
||||
0 set c@0 NULL
|
||||
1 set a@1 NULL
|
||||
2 set b@2 NULL
|
||||
3 copen STMT.cursor[c@0]
|
||||
4 cfetch STMT.cursor[c@0] a@1 b@2
|
||||
5 cclose STMT.cursor[c@0]
|
||||
6 stmt 0 "SELECT c, CURSOR_REF_COUNT(c) AS cnt,..."
|
||||
7 destruct sys_refcursor c@0
|
||||
CALL p1;
|
||||
c cnt a b
|
||||
0 1 1 2
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Nested blocks
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'c0';
|
||||
DECLARE
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 'c1';
|
||||
DECLARE
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c2 FOR SELECT 'c2';
|
||||
DECLARE
|
||||
c3 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c3 FOR SELECT 'c3';
|
||||
SELECT c3, c3%ISOPEN AS op, CURSOR_REF_COUNT(c3) AS cnt;
|
||||
END;
|
||||
SELECT c2, c2%ISOPEN AS op, CURSOR_REF_COUNT(c2) AS cnt;
|
||||
END;
|
||||
SELECT c1, c1%ISOPEN AS op, CURSOR_REF_COUNT(c1) AS cnt;
|
||||
END;
|
||||
SELECT c0, c0%ISOPEN AS op, CURSOR_REF_COUNT(c0) AS cnt;
|
||||
SELECT
|
||||
CURSOR_REF_COUNT(0) AS cnt0,
|
||||
CURSOR_REF_COUNT(1) AS cnt1,
|
||||
CURSOR_REF_COUNT(2) AS cnt2,
|
||||
CURSOR_REF_COUNT(3) AS cnt3;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'p2-c0';
|
||||
CALL p1;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p3 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'p3-c0';
|
||||
CALL p2;
|
||||
END;
|
||||
/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
Pos Instruction
|
||||
0 set c0@0 NULL
|
||||
1 copen STMT.cursor[c0@0]
|
||||
2 set c1@1 NULL
|
||||
3 copen STMT.cursor[c1@1]
|
||||
4 set c2@2 NULL
|
||||
5 copen STMT.cursor[c2@2]
|
||||
6 set c3@3 NULL
|
||||
7 copen STMT.cursor[c3@3]
|
||||
8 stmt 0 "SELECT c3, c3%ISOPEN AS op, CURSOR_RE..."
|
||||
9 destruct sys_refcursor c3@3
|
||||
10 stmt 0 "SELECT c2, c2%ISOPEN AS op, CURSOR_RE..."
|
||||
11 destruct sys_refcursor c2@2
|
||||
12 stmt 0 "SELECT c1, c1%ISOPEN AS op, CURSOR_RE..."
|
||||
13 destruct sys_refcursor c1@1
|
||||
14 stmt 0 "SELECT c0, c0%ISOPEN AS op, CURSOR_RE..."
|
||||
15 stmt 0 "SELECT CURSOR_REF_COUNT(0) AS cnt0, C..."
|
||||
16 destruct sys_refcursor c0@0
|
||||
SHOW PROCEDURE CODE p2;
|
||||
Pos Instruction
|
||||
0 set c0@0 NULL
|
||||
1 copen STMT.cursor[c0@0]
|
||||
2 stmt 88 "CALL p1"
|
||||
3 destruct sys_refcursor c0@0
|
||||
SHOW PROCEDURE CODE p3;
|
||||
Pos Instruction
|
||||
0 set c0@0 NULL
|
||||
1 copen STMT.cursor[c0@0]
|
||||
2 stmt 88 "CALL p2"
|
||||
3 destruct sys_refcursor c0@0
|
||||
CALL p1;
|
||||
c3 op cnt
|
||||
3 1 1
|
||||
c2 op cnt
|
||||
2 1 1
|
||||
c1 op cnt
|
||||
1 1 1
|
||||
c0 op cnt
|
||||
0 1 1
|
||||
cnt0 cnt1 cnt2 cnt3
|
||||
1 0 0 0
|
||||
CALL p2;
|
||||
c3 op cnt
|
||||
4 1 1
|
||||
c2 op cnt
|
||||
3 1 1
|
||||
c1 op cnt
|
||||
2 1 1
|
||||
c0 op cnt
|
||||
1 1 1
|
||||
cnt0 cnt1 cnt2 cnt3
|
||||
1 1 0 0
|
||||
CALL p3;
|
||||
c3 op cnt
|
||||
5 1 1
|
||||
c2 op cnt
|
||||
4 1 1
|
||||
c1 op cnt
|
||||
3 1 1
|
||||
c0 op cnt
|
||||
2 1 1
|
||||
cnt0 cnt1 cnt2 cnt3
|
||||
1 1 1 0
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP PROCEDURE p3;
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# Setting a cursor variable to itself does not change ref count
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = c0; -- neither directly
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = COALESCE(c0); -- nor through an expression
|
||||
SELECT 'p1-3' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-1 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-2 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-3 0 1 1
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Setting a cursor variable from not-NULL to NULL
|
||||
# decrements ref count at its old position
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = NULL;
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-1 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-2 NULL NULL 0
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Setting a cursor variable to a never opened cursor variable
|
||||
# decrements ref count at its old position
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = c1;
|
||||
SELECT 'p2-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-1 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p2-1 NULL NULL 0
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Multiple OPEN of the same cursor variable reuses
|
||||
# the cursor at the same offset. Ref count stays 1.
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-3' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-4' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-5' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-6' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= NULL;
|
||||
SELECT 'p1-7' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-1 NULL NULL NULL
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-2 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-3 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-4 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-5 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-6 0 1 1
|
||||
stage c0 cnt_c0 cnt_0
|
||||
p1-7 NULL NULL 0
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# Multiple assignment to the same variable does not increase ref count.
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
BEGIN
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE c2 SYS_REFCURSOR;
|
||||
SELECT 'stage 0' AS ``;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SELECT 'stage 1' AS ``;
|
||||
OPEN c1 FOR SELECT 1 AS c FROM DUAL;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SELECT 'stage 2' AS ``;
|
||||
SET c0 = c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c0= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c0= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SELECT 'stage 3' AS ``;
|
||||
SET c2= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c2= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c2= NULL;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
END;
|
||||
SELECT 'stage 4' AS ``;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt_c0;
|
||||
FETCH c0 INTO v;
|
||||
SELECT CONCAT('v=',v);
|
||||
SET c0=COALESCE(NULL); -- Reset c0 to NULL
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
|
||||
stage 0
|
||||
c0 cnt0 c1 cnt1
|
||||
NULL NULL NULL NULL
|
||||
|
||||
stage 1
|
||||
c0 cnt0 c1 cnt1
|
||||
NULL NULL 0 1
|
||||
|
||||
stage 2
|
||||
c0 cnt0 c1 cnt1
|
||||
0 2 0 2
|
||||
c0 cnt0 c1 cnt1
|
||||
0 2 0 2
|
||||
c0 cnt0 c1 cnt1
|
||||
0 2 0 2
|
||||
|
||||
stage 3
|
||||
c0 cnt0 c1 cnt1
|
||||
0 3 0 3
|
||||
c0 cnt0 c1 cnt1
|
||||
0 3 0 3
|
||||
c0 cnt0 c1 cnt1
|
||||
0 2 0 2
|
||||
|
||||
stage 4
|
||||
c0 cnt_c0
|
||||
0 1
|
||||
CONCAT('v=',v)
|
||||
v=1
|
||||
c0 cnt_c0 cnt_0
|
||||
NULL NULL 0
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,228 @@
|
||||
--source include/have_debug.inc
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # A small OPEN+FETCH+CLOSE example
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE a, b INT;
|
||||
OPEN c FOR SELECT 1, 2;
|
||||
FETCH c INTO a, b;
|
||||
CLOSE c;
|
||||
SELECT c, CURSOR_REF_COUNT(c) AS cnt, a, b;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
SHOW PROCEDURE CODE p1;
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Nested blocks
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'c0';
|
||||
DECLARE
|
||||
c1 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c1 FOR SELECT 'c1';
|
||||
DECLARE
|
||||
c2 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c2 FOR SELECT 'c2';
|
||||
DECLARE
|
||||
c3 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c3 FOR SELECT 'c3';
|
||||
SELECT c3, c3%ISOPEN AS op, CURSOR_REF_COUNT(c3) AS cnt;
|
||||
END;
|
||||
SELECT c2, c2%ISOPEN AS op, CURSOR_REF_COUNT(c2) AS cnt;
|
||||
END;
|
||||
SELECT c1, c1%ISOPEN AS op, CURSOR_REF_COUNT(c1) AS cnt;
|
||||
END;
|
||||
SELECT c0, c0%ISOPEN AS op, CURSOR_REF_COUNT(c0) AS cnt;
|
||||
SELECT
|
||||
CURSOR_REF_COUNT(0) AS cnt0,
|
||||
CURSOR_REF_COUNT(1) AS cnt1,
|
||||
CURSOR_REF_COUNT(2) AS cnt2,
|
||||
CURSOR_REF_COUNT(3) AS cnt3;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'p2-c0';
|
||||
CALL p1;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p3 AS
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 'p3-c0';
|
||||
CALL p2;
|
||||
END;
|
||||
/DELIMITER ;/
|
||||
SHOW PROCEDURE CODE p1;
|
||||
SHOW PROCEDURE CODE p2;
|
||||
SHOW PROCEDURE CODE p3;
|
||||
CALL p1;
|
||||
CALL p2;
|
||||
CALL p3;
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP PROCEDURE p3;
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Setting a cursor variable to itself does not change ref count
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = c0; -- neither directly
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = COALESCE(c0); -- nor through an expression
|
||||
SELECT 'p1-3' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Setting a cursor variable from not-NULL to NULL
|
||||
--echo # decrements ref count at its old position
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = NULL;
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Setting a cursor variable to a never opened cursor variable
|
||||
--echo # decrements ref count at its old position
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0 = c1;
|
||||
SELECT 'p2-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
--echo #
|
||||
--echo # Multiple OPEN of the same cursor variable reuses
|
||||
--echo # the cursor at the same offset. Ref count stays 1.
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT 'p1-1' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-2' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-3' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-4' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-5' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT 'p1-6' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= NULL;
|
||||
SELECT 'p1-7' AS stage, c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # Multiple assignment to the same variable does not increase ref count.
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
BEGIN
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE c2 SYS_REFCURSOR;
|
||||
|
||||
SELECT 'stage 0' AS ``;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
|
||||
SELECT 'stage 1' AS ``;
|
||||
OPEN c1 FOR SELECT 1 AS c FROM DUAL;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
|
||||
SELECT 'stage 2' AS ``;
|
||||
SET c0 = c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c0= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c0= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
|
||||
SELECT 'stage 3' AS ``;
|
||||
SET c2= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c2= c1;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
SET c2= NULL;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt0, c1, CURSOR_REF_COUNT(c1) AS cnt1;
|
||||
END;
|
||||
|
||||
SELECT 'stage 4' AS ``;
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt_c0;
|
||||
FETCH c0 INTO v;
|
||||
SELECT CONCAT('v=',v);
|
||||
SET c0=COALESCE(NULL); -- Reset c0 to NULL
|
||||
SELECT c0, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,51 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# DEFAULT clause in SYS_REFCURSOR declarations
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT NULL;
|
||||
END;
|
||||
$$
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT c0;
|
||||
END;
|
||||
$$
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
OPEN c0 FOR SELECT 'c0-value';
|
||||
BEGIN
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT c0;
|
||||
DECLARE v VARCHAR(30);
|
||||
FETCH c1 INTO v;
|
||||
SELECT v;
|
||||
END;
|
||||
END;
|
||||
$$
|
||||
v
|
||||
c0-value
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT DEFAULT(c0);
|
||||
END;
|
||||
$$
|
||||
ERROR 42000: Incorrect column name 'c0'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT 0;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Cannot cast 'int' as 'sys_refcursor' in assignment of `c`
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT IGNORE;
|
||||
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 'IGNORE;
|
||||
END' at line 2
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT DEFAULT;
|
||||
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 ';
|
||||
END' at line 2
|
@ -0,0 +1,70 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # DEFAULT clause in SYS_REFCURSOR declarations
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT NULL;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT c0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
OPEN c0 FOR SELECT 'c0-value';
|
||||
BEGIN
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT c0;
|
||||
DECLARE v VARCHAR(30);
|
||||
FETCH c1 INTO v;
|
||||
SELECT v;
|
||||
END;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_WRONG_COLUMN_NAME
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR DEFAULT NULL;
|
||||
DECLARE c1 SYS_REFCURSOR DEFAULT DEFAULT(c0);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT 0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_PARSE_ERROR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT IGNORE;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_PARSE_ERROR
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR DEFAULT DEFAULT;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
@ -0,0 +1,171 @@
|
||||
SET NAMES utf8mb4;
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Helper routines
|
||||
#
|
||||
CREATE FUNCTION refs(first INT, last INT) RETURNS TEXT
|
||||
BEGIN
|
||||
DECLARE res TEXT DEFAULT '[';
|
||||
FOR i IN first..last
|
||||
DO
|
||||
SET res= CONCAT(res, COALESCE(CURSOR_REF_COUNT(i), 'NULL'));
|
||||
IF i < last THEN
|
||||
SET res= CONCAT(res, '\t');
|
||||
END IF;
|
||||
END FOR;
|
||||
SET res= CONCAT(res, ']');
|
||||
RETURN res;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE show_cursor_and_refs(stage VARCHAR(32),
|
||||
curs VARCHAR(32),
|
||||
first INT, last INT)
|
||||
BEGIN
|
||||
SELECT stage, COALESCE(curs, 'NULL') AS curs, refs(first, last) AS refs;
|
||||
END;
|
||||
/
|
||||
CREATE FUNCTION ff0() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
IF @log <> '' THEN
|
||||
SET @log= CONCAT(@log, '\n');
|
||||
END IF;
|
||||
SET @log= CONCAT(@log, 'ff0-0','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5), '\n');
|
||||
OPEN c0 FOR SELECT 10;
|
||||
SET @log= CONCAT(@log, 'ff0-1','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5));
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
SHOW FUNCTION CODE ff0;
|
||||
Pos Instruction
|
||||
0 set c0@0 NULL
|
||||
1 jump_if_not 3(3) @`log` <> ''
|
||||
2 stmt 31 "SET @log= CONCAT(@log, '\n')"
|
||||
3 stmt 31 "SET @log= CONCAT(@log, 'ff0-0','\t', ..."
|
||||
4 copen STMT.cursor[c0@0]
|
||||
5 stmt 31 "SET @log= CONCAT(@log, 'ff0-1','\t', ..."
|
||||
6 freturn sys_refcursor c0@0
|
||||
CREATE FUNCTION ff1(c0 SYS_REFCURSOR) RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
IF @log <> '' THEN
|
||||
SET @log= CONCAT(@log, '\n');
|
||||
END IF;
|
||||
SET @log= CONCAT(@log, 'ff1-0','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5));
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
SHOW FUNCTION CODE ff1;
|
||||
Pos Instruction
|
||||
0 jump_if_not 2(2) @`log` <> ''
|
||||
1 stmt 31 "SET @log= CONCAT(@log, '\n')"
|
||||
2 stmt 31 "SET @log= CONCAT(@log, 'ff1-0','\t', ..."
|
||||
3 freturn sys_refcursor c0@0
|
||||
#
|
||||
# DO statement cleans ref counters
|
||||
#
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
CALL show_cursor_and_refs('p2-0', '-', 0, 5);
|
||||
SET @log= '';
|
||||
DO ff0(), ff0();
|
||||
SELECT @log;
|
||||
CALL show_cursor_and_refs('p2-1', '-', 0, 5);
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
stage curs refs
|
||||
p2-0 - [NULL NULL NULL NULL NULL NULL]
|
||||
@log
|
||||
ff0-0 NULL [NULL NULL NULL NULL NULL NULL]
|
||||
ff0-1 0 [1 NULL NULL NULL NULL NULL]
|
||||
ff0-0 NULL [0 NULL NULL NULL NULL NULL]
|
||||
ff0-1 0 [1 NULL NULL NULL NULL NULL]
|
||||
stage curs refs
|
||||
p2-1 - [0 NULL NULL NULL NULL NULL]
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
stage curs refs
|
||||
/p2 - [NULL NULL NULL NULL NULL NULL]
|
||||
DROP PROCEDURE p2;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE p2c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p2-0', CAST(p2c0 AS CHAR), 0, 5);
|
||||
OPEN p2c0 FOR SELECT 1;
|
||||
CALL show_cursor_and_refs('p2-1', CAST(p2c0 AS CHAR), 0, 5);
|
||||
SET @log= '';
|
||||
DO ff1(p2c0), ff1(p2c0);
|
||||
SELECT @log;
|
||||
CALL show_cursor_and_refs('p2-2', CAST(p2c0 AS CHAR), 0, 5);
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
stage curs refs
|
||||
p2-0 NULL [NULL NULL NULL NULL NULL NULL]
|
||||
stage curs refs
|
||||
p2-1 0 [1 NULL NULL NULL NULL NULL]
|
||||
@log
|
||||
ff1-0 0 [2 NULL NULL NULL NULL NULL]
|
||||
ff1-0 0 [2 NULL NULL NULL NULL NULL]
|
||||
stage curs refs
|
||||
p2-2 0 [1 NULL NULL NULL NULL NULL]
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
stage curs refs
|
||||
/p2 - [NULL NULL NULL NULL NULL NULL]
|
||||
DROP PROCEDURE p2;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE p2c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p2-0', CAST(p2c0 AS CHAR), 0, 5);
|
||||
OPEN p2c0 FOR SELECT 1;
|
||||
CALL show_cursor_and_refs('p2-1', CAST(p2c0 AS CHAR), 0, 5);
|
||||
DO COALESCE(p2c0), COALESCE(p2c0);
|
||||
CALL show_cursor_and_refs('p2-2', CAST(p2c0 AS CHAR), 0, 5);
|
||||
END;
|
||||
/
|
||||
CALL p2;
|
||||
stage curs refs
|
||||
p2-0 NULL [NULL NULL NULL NULL NULL NULL]
|
||||
stage curs refs
|
||||
p2-1 0 [1 NULL NULL NULL NULL NULL]
|
||||
stage curs refs
|
||||
p2-2 0 [1 NULL NULL NULL NULL NULL]
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
stage curs refs
|
||||
/p2 - [NULL NULL NULL NULL NULL NULL]
|
||||
DROP PROCEDURE p2;
|
||||
#
|
||||
# DO + EXECUTE IMMEDIATE
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p1-0', CAST(c0 AS CHAR), 0, 1);
|
||||
OPEN c0 FOR SELECT 10;
|
||||
CALL show_cursor_and_refs('p1-1', CAST(c0 AS CHAR), 0, 1);
|
||||
EXECUTE IMMEDIATE 'DO ?' USING c0;
|
||||
CALL show_cursor_and_refs('p1-2', CAST(c0 AS CHAR), 0, 1);
|
||||
EXECUTE IMMEDIATE 'DO ?' USING c0;
|
||||
CALL show_cursor_and_refs('p1-3', CAST(c0 AS CHAR), 0, 1);
|
||||
SET c0= NULL;
|
||||
CALL show_cursor_and_refs('p1-0', CAST(c0 AS CHAR), 0, 1);
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
p1-0 NULL [NULL NULL]
|
||||
p1-1 0 [1 NULL]
|
||||
p1-2 0 [1 NULL]
|
||||
p1-3 0 [1 NULL]
|
||||
p1-0 NULL [0 NULL]
|
||||
DROP PROCEDURE p1;
|
||||
DROP FUNCTION ff0;
|
||||
DROP FUNCTION ff1;
|
||||
DROP PROCEDURE show_cursor_and_refs;
|
||||
DROP FUNCTION refs;
|
@ -0,0 +1,96 @@
|
||||
--source include/have_debug.inc
|
||||
|
||||
SET NAMES utf8mb4;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--source type_sys_refcursor-helper_routines-debug-create.inc
|
||||
|
||||
--echo #
|
||||
--echo # DO statement cleans ref counters
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
CALL show_cursor_and_refs('p2-0', '-', 0, 5);
|
||||
SET @log= '';
|
||||
DO ff0(), ff0();
|
||||
SELECT @log;
|
||||
CALL show_cursor_and_refs('p2-1', '-', 0, 5);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
DROP PROCEDURE p2;
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE p2c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p2-0', CAST(p2c0 AS CHAR), 0, 5);
|
||||
OPEN p2c0 FOR SELECT 1;
|
||||
CALL show_cursor_and_refs('p2-1', CAST(p2c0 AS CHAR), 0, 5);
|
||||
SET @log= '';
|
||||
DO ff1(p2c0), ff1(p2c0);
|
||||
SELECT @log;
|
||||
CALL show_cursor_and_refs('p2-2', CAST(p2c0 AS CHAR), 0, 5);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
DROP PROCEDURE p2;
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p2()
|
||||
BEGIN
|
||||
DECLARE p2c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p2-0', CAST(p2c0 AS CHAR), 0, 5);
|
||||
OPEN p2c0 FOR SELECT 1;
|
||||
CALL show_cursor_and_refs('p2-1', CAST(p2c0 AS CHAR), 0, 5);
|
||||
DO COALESCE(p2c0), COALESCE(p2c0);
|
||||
CALL show_cursor_and_refs('p2-2', CAST(p2c0 AS CHAR), 0, 5);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2;
|
||||
CALL show_cursor_and_refs('/p2', '-', 0, 5);
|
||||
DROP PROCEDURE p2;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # DO + EXECUTE IMMEDIATE
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CALL show_cursor_and_refs('p1-0', CAST(c0 AS CHAR), 0, 1);
|
||||
|
||||
OPEN c0 FOR SELECT 10;
|
||||
CALL show_cursor_and_refs('p1-1', CAST(c0 AS CHAR), 0, 1);
|
||||
|
||||
EXECUTE IMMEDIATE 'DO ?' USING c0;
|
||||
CALL show_cursor_and_refs('p1-2', CAST(c0 AS CHAR), 0, 1);
|
||||
|
||||
EXECUTE IMMEDIATE 'DO ?' USING c0;
|
||||
CALL show_cursor_and_refs('p1-3', CAST(c0 AS CHAR), 0, 1);
|
||||
|
||||
SET c0= NULL;
|
||||
CALL show_cursor_and_refs('p1-0', CAST(c0 AS CHAR), 0, 1);
|
||||
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--disable_column_names
|
||||
CALL p1;
|
||||
--enable_column_names
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--source type_sys_refcursor-helper_routines-debug-drop.inc
|
@ -0,0 +1,63 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Dyadic operations
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c + i;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and int for operation '+'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c - i;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and int for operation '-'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c * i;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and int for operation '*'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c / i;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and int for operation '/'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c % i;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and int for operation 'MOD'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
IF c = TRUE THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and boolean for operation '='
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
SELECT STR_TO_DATE(c, '%W, %M %e, %Y');
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and varchar for operation 'str_to_date'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
SELECT DATE_FORMAT('2009-10-04 22:23:00', c); -- can_return_text
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'date_format'
|
@ -0,0 +1,89 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # Dyadic operations
|
||||
--echo #
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c + i;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c - i;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c * i;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c / i;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE i INT;
|
||||
SELECT c % i;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
IF c = TRUE THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
SELECT STR_TO_DATE(c, '%W, %M %e, %Y');
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
SELECT DATE_FORMAT('2009-10-04 22:23:00', c); -- can_return_text
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
@ -0,0 +1,19 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
OPEN c1 FOR SELECT 1;
|
||||
RETURN c1;
|
||||
END;
|
||||
/
|
||||
SET @a=(SELECT COLUMN_CREATE(1, f1()));
|
||||
SELECT COLUMN_GET(@a, 1 AS INT);
|
||||
COLUMN_GET(@a, 1 AS INT)
|
||||
1
|
||||
SELECT COLUMN_GET(@a, 1 AS SYS_REFCURSOR);
|
||||
ERROR HY000: Operator does not exist: 'CAST(expr AS sys_refcursor)'
|
||||
DROP FUNCTION f1;
|
@ -0,0 +1,27 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION f1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
OPEN c1 FOR SELECT 1;
|
||||
RETURN c1;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
# SYS_REFCURSOR works like an integer.
|
||||
# QQ: Perhaps SYS_REFCURSOR should be disallowed as a COLUMN_CREATE() parameter.
|
||||
|
||||
SET @a=(SELECT COLUMN_CREATE(1, f1()));
|
||||
SELECT COLUMN_GET(@a, 1 AS INT);
|
||||
|
||||
# COLUMN_GET(dyncol, 1 AS SYS_REFCURSOR) is not supported
|
||||
--error ER_UNKNOWN_OPERATOR
|
||||
SELECT COLUMN_GET(@a, 1 AS SYS_REFCURSOR);
|
||||
|
||||
DROP FUNCTION f1;
|
@ -0,0 +1,114 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# IF expr
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
IF c0 THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END IF;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'IF'
|
||||
#
|
||||
# CASE expr WHEN..THEN
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CASE c0 WHEN TRUE THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END CASE;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'EXPRESSION CACHE (e.g. SUBSELECT)'
|
||||
#
|
||||
# CASE WHEN expr THEN
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CASE
|
||||
WHEN c0 THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END CASE;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'IF'
|
||||
#
|
||||
# UNTIL expr
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
REPEAT
|
||||
FETCH c0 INTO v;
|
||||
UNTIL c0
|
||||
END REPEAT;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'IF'
|
||||
#
|
||||
# WHILE expr
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
WHILE c0 DO
|
||||
FETCH c0 INTO v;
|
||||
END WHILE;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'IF'
|
||||
#
|
||||
# EXIT WHEN expr
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1;
|
||||
FOR i IN 0..5
|
||||
LOOP
|
||||
EXIT WHEN c0;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'IF'
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# RAISE expr
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RAISE c0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN SELECT 'Got some exception';
|
||||
END;
|
||||
/
|
||||
ERROR 42000: Undefined CONDITION: c0
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# EXCEPTION WHEN expr
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
SELECT 1;
|
||||
EXCEPTION
|
||||
WHEN c0 THEN RETURN 'Got exception c0';
|
||||
END;
|
||||
/
|
||||
ERROR 42000: Undefined CONDITION: c0
|
||||
SET sql_mode=DEFAULT;
|
@ -0,0 +1,153 @@
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # IF expr
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
IF c0 THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END IF;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # CASE expr WHEN..THEN
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CASE c0 WHEN TRUE THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END CASE;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # CASE WHEN expr THEN
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
CASE
|
||||
WHEN c0 THEN
|
||||
SELECT 'TRUE';
|
||||
ELSE
|
||||
SELECT 'NOT TRUE';
|
||||
END CASE;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # UNTIL expr
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
REPEAT
|
||||
FETCH c0 INTO v;
|
||||
UNTIL c0
|
||||
END REPEAT;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # WHILE expr
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
WHILE c0 DO
|
||||
FETCH c0 INTO v;
|
||||
END WHILE;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # EXIT WHEN expr
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
OPEN c0 FOR SELECT 1;
|
||||
FOR i IN 0..5
|
||||
LOOP
|
||||
EXIT WHEN c0;
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # RAISE expr
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
--error ER_SP_COND_MISMATCH
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
RAISE c0;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN SELECT 'Got some exception';
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # EXCEPTION WHEN expr
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER /;
|
||||
--error ER_SP_COND_MISMATCH
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
SELECT 1;
|
||||
EXCEPTION
|
||||
WHEN c0 THEN RETURN 'Got exception c0';
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SET sql_mode=DEFAULT;
|
@ -0,0 +1,657 @@
|
||||
CREATE FUNCTION f1cs1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
RETURN c0;
|
||||
END;
|
||||
$$
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Hybrid functions
|
||||
#
|
||||
#
|
||||
# SET var=COALESCE()
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE c2 SYS_REFCURSOR;
|
||||
SELECT 'p1-0' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c2 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= COALESCE(c1, c2);
|
||||
SELECT 'p1-2' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c2= NULL;
|
||||
SELECT 'p1-3' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= NULL;
|
||||
SELECT 'p1-4' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
stage c0 c1 c2 cnt_c0 cnt_0
|
||||
p1-0 NULL NULL NULL NULL NULL
|
||||
stage c0 c1 c2 cnt_c0 cnt_0
|
||||
p1-1 NULL NULL 0 NULL 1
|
||||
stage c0 c1 c2 cnt_c0 cnt_0
|
||||
p1-2 0 NULL 0 2 2
|
||||
stage c0 c1 c2 cnt_c0 cnt_0
|
||||
p1-3 0 NULL NULL 1 1
|
||||
stage c0 c1 c2 cnt_c0 cnt_0
|
||||
p1-4 NULL NULL NULL NULL 0
|
||||
DROP PROCEDURE p1;
|
||||
#
|
||||
# SET var=CASE
|
||||
#
|
||||
SET sql_mode=ORACLE;
|
||||
CREATE PROCEDURE p1(task VARCHAR(32)) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
IF task LIKE '%open_c0%' THEN
|
||||
OPEN c0 FOR SELECT 1;
|
||||
END IF;
|
||||
SELECT 'p1-1' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
OPEN c1 FOR SELECT 11 FROM DUAL;
|
||||
SELECT 'p1-2' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
c2:= CASE WHEN c0 IS NULL THEN c1 ELSE c0 END;
|
||||
SELECT 'p1-3' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
FETCH c2 INTO v;
|
||||
SELECT v;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2(task VARCHAR(32)) AS
|
||||
BEGIN
|
||||
SELECT 'p2-0' AS stage, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
CALL p1(task);
|
||||
SELECT 'p2-1' AS stage, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
CALL p2('');
|
||||
stage cnt_0
|
||||
p2-0 NULL
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-1 NULL NULL NULL NULL NULL
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-2 NULL 0 NULL 1 NULL
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-3 NULL 0 0 2 NULL
|
||||
v
|
||||
11
|
||||
stage cnt_0
|
||||
p2-1 0
|
||||
CALL p2('open_c0');
|
||||
stage cnt_0
|
||||
p2-0 NULL
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-1 0 NULL NULL 1 NULL
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-2 0 1 NULL 1 1
|
||||
stage c0 c1 c2 cnt_0 cnt_1
|
||||
p1-3 0 1 0 2 1
|
||||
v
|
||||
1
|
||||
stage cnt_0
|
||||
p2-1 0
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# COALESCE in select list
|
||||
#
|
||||
SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
cl_f1 cnt_0 cnt_1
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `cl_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1` from `test`.`seq_1_to_5`
|
||||
EXECUTE IMMEDIATE 'SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5';
|
||||
cl_f1 cnt_0 cnt_1
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
EXECUTE IMMEDIATE 'EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5';
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `cl_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1` from `test`.`seq_1_to_5`
|
||||
SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5`
|
||||
EXECUTE IMMEDIATE 'SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5';
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
EXECUTE IMMEDIATE 'EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5';
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5`
|
||||
#
|
||||
# COALESCE in WHERE
|
||||
#
|
||||
SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1 cnt_0 cnt_1 cnt_2
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5` where coalesce(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3` from `test`.`seq_1_to_5` where coalesce(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,coalesce(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4` from `test`.`seq_1_to_5` where coalesce(`f1cs1`(),`f1cs1`()) is not null and coalesce(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1()) IS NOT NULL;
|
||||
cnt_0 cnt_1
|
||||
0 NULL
|
||||
0 NULL
|
||||
0 NULL
|
||||
0 NULL
|
||||
0 NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1` from `test`.`seq_1_to_5` where coalesce(`f1cs1`()) is not null
|
||||
#
|
||||
# IFNULL in select list
|
||||
#
|
||||
SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
cl_f1 cnt_0 cnt_1
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `cl_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1` from `test`.`seq_1_to_5`
|
||||
EXECUTE IMMEDIATE 'SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5';
|
||||
cl_f1 cnt_0 cnt_1
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
0 1 NULL
|
||||
EXECUTE IMMEDIATE 'EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5';
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `cl_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1` from `test`.`seq_1_to_5`
|
||||
SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5`
|
||||
EXECUTE IMMEDIATE 'SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5';
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
0 1 1 1 NULL
|
||||
EXECUTE IMMEDIATE 'EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5';
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5`
|
||||
#
|
||||
# IFNULL in WHERE
|
||||
#
|
||||
SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1 cnt_0 cnt_1 cnt_2
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5` where ifnull(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
0 1 1 1 NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3` from `test`.`seq_1_to_5` where ifnull(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,ifnull(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4` from `test`.`seq_1_to_5` where ifnull(`f1cs1`(),`f1cs1`()) is not null and ifnull(`f1cs1`(),`f1cs1`()) is not null
|
||||
#
|
||||
# LAST_VALUE in select list
|
||||
#
|
||||
SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
c_f1 cnt_0 cnt_1 cnt_2
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
0 1 NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select last_value(`f1cs1`(),`f1cs1`()) AS `c_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2` from `test`.`seq_1_to_5`
|
||||
SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
0 1 1 1 NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using index
|
||||
Warnings:
|
||||
Note 1003 select last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4` from `test`.`seq_1_to_5`
|
||||
#
|
||||
# LAST_VALUE in WHERE
|
||||
#
|
||||
SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4
|
||||
1 1 1 NULL NULL NULL
|
||||
1 1 1 NULL NULL NULL
|
||||
1 1 1 NULL NULL NULL
|
||||
1 1 1 NULL NULL NULL
|
||||
1 1 1 NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select last_value(`f1cs1`(),`f1cs1`()) AS `c_f1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4` from `test`.`seq_1_to_5` where last_value(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4 cnt_5 cnt_6
|
||||
1 2 1 1 1 NULL NULL NULL NULL
|
||||
1 2 1 1 1 NULL NULL NULL NULL
|
||||
1 2 1 1 1 NULL NULL NULL NULL
|
||||
1 2 1 1 1 NULL NULL NULL NULL
|
||||
1 2 1 1 1 NULL NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4`,cursor_ref_count(5) AS `cnt_5`,cursor_ref_count(6) AS `cnt_6` from `test`.`seq_1_to_5` where last_value(`f1cs1`(),`f1cs1`()) is not null
|
||||
SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6,
|
||||
CURSOR_REF_COUNT(7) AS cnt_7,
|
||||
CURSOR_REF_COUNT(8) AS cnt_8
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
c_f1_0 c_f1_1 cnt_0 cnt_1 cnt_2 cnt_3 cnt_4 cnt_5 cnt_6 cnt_7 cnt_8
|
||||
2 3 1 1 1 1 NULL NULL NULL NULL NULL
|
||||
2 3 1 1 1 1 NULL NULL NULL NULL NULL
|
||||
2 3 1 1 1 1 NULL NULL NULL NULL NULL
|
||||
2 3 1 1 1 1 NULL NULL NULL NULL NULL
|
||||
2 3 1 1 1 1 NULL NULL NULL NULL NULL
|
||||
EXPLAIN EXTENDED SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6,
|
||||
CURSOR_REF_COUNT(7) AS cnt_7,
|
||||
CURSOR_REF_COUNT(8) AS cnt_8
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||
1 SIMPLE seq_1_to_5 index NULL PRIMARY 8 NULL 5 100.00 Using where; Using index
|
||||
Warnings:
|
||||
Note 1003 select last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_0`,last_value(`f1cs1`(),`f1cs1`()) AS `c_f1_1`,cursor_ref_count(0) AS `cnt_0`,cursor_ref_count(1) AS `cnt_1`,cursor_ref_count(2) AS `cnt_2`,cursor_ref_count(3) AS `cnt_3`,cursor_ref_count(4) AS `cnt_4`,cursor_ref_count(5) AS `cnt_5`,cursor_ref_count(6) AS `cnt_6`,cursor_ref_count(7) AS `cnt_7`,cursor_ref_count(8) AS `cnt_8` from `test`.`seq_1_to_5` where last_value(`f1cs1`(),`f1cs1`()) is not null and last_value(`f1cs1`(),`f1cs1`()) is not null
|
||||
DROP FUNCTION f1cs1;
|
@ -0,0 +1,328 @@
|
||||
--source include/have_debug.inc
|
||||
--source include/have_sequence.inc
|
||||
|
||||
DELIMITER $$;
|
||||
CREATE FUNCTION f1cs1() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
RETURN c0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # Hybrid functions
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # SET var=COALESCE()
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
DECLARE c2 SYS_REFCURSOR;
|
||||
SELECT 'p1-0' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
OPEN c2 FOR SELECT 1;
|
||||
SELECT 'p1-1' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= COALESCE(c1, c2);
|
||||
SELECT 'p1-2' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c2= NULL;
|
||||
SELECT 'p1-3' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
SET c0= NULL;
|
||||
SELECT 'p1-4' AS stage, c0, c1, c2, CURSOR_REF_COUNT(c0) AS cnt_c0, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # SET var=CASE
|
||||
--echo #
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1(task VARCHAR(32)) AS
|
||||
c0 SYS_REFCURSOR;
|
||||
c1 SYS_REFCURSOR;
|
||||
c2 SYS_REFCURSOR;
|
||||
v INT;
|
||||
BEGIN
|
||||
IF task LIKE '%open_c0%' THEN
|
||||
OPEN c0 FOR SELECT 1;
|
||||
END IF;
|
||||
SELECT 'p1-1' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
OPEN c1 FOR SELECT 11 FROM DUAL;
|
||||
SELECT 'p1-2' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
c2:= CASE WHEN c0 IS NULL THEN c1 ELSE c0 END;
|
||||
SELECT 'p1-3' AS stage, c0, c1, c2, CURSOR_REF_COUNT(0) AS cnt_0, CURSOR_REF_COUNT(1) AS cnt_1;
|
||||
FETCH c2 INTO v;
|
||||
SELECT v;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p2(task VARCHAR(32)) AS
|
||||
BEGIN
|
||||
SELECT 'p2-0' AS stage, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
CALL p1(task);
|
||||
SELECT 'p2-1' AS stage, CURSOR_REF_COUNT(0) AS cnt_0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p2('');
|
||||
CALL p2('open_c0');
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # COALESCE in select list
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
eval EXECUTE IMMEDIATE '$select';
|
||||
eval EXECUTE IMMEDIATE 'EXPLAIN EXTENDED $select';
|
||||
|
||||
let $select= SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
eval EXECUTE IMMEDIATE '$select';
|
||||
eval EXECUTE IMMEDIATE 'EXPLAIN EXTENDED $select';
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # COALESCE in WHERE
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
COALESCE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
COALESCE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
COALESCE(f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # IFNULL in select list
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS cl_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
eval EXECUTE IMMEDIATE '$select';
|
||||
eval EXECUTE IMMEDIATE 'EXPLAIN EXTENDED $select';
|
||||
|
||||
let $select= SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
eval EXECUTE IMMEDIATE '$select';
|
||||
eval EXECUTE IMMEDIATE 'EXPLAIN EXTENDED $select';
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # IFNULL in WHERE
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
IFNULL(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
IFNULL(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
--echo #
|
||||
--echo # LAST_VALUE in select list
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
let $select= SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # LAST_VALUE in WHERE
|
||||
--echo #
|
||||
|
||||
let $select= SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
|
||||
let $select= SELECT
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_0,
|
||||
LAST_VALUE(f1cs1(),f1cs1()) AS c_f1_1,
|
||||
CURSOR_REF_COUNT(0) AS cnt_0,
|
||||
CURSOR_REF_COUNT(1) AS cnt_1,
|
||||
CURSOR_REF_COUNT(2) AS cnt_2,
|
||||
CURSOR_REF_COUNT(3) AS cnt_3,
|
||||
CURSOR_REF_COUNT(4) AS cnt_4,
|
||||
CURSOR_REF_COUNT(5) AS cnt_5,
|
||||
CURSOR_REF_COUNT(6) AS cnt_6,
|
||||
CURSOR_REF_COUNT(7) AS cnt_7,
|
||||
CURSOR_REF_COUNT(8) AS cnt_8
|
||||
FROM seq_1_to_5
|
||||
WHERE
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL AND
|
||||
LAST_VALUE(f1cs1(),f1cs1()) IS NOT NULL;
|
||||
eval $select;
|
||||
eval EXPLAIN EXTENDED $select;
|
||||
|
||||
#
|
||||
# Cleanup
|
||||
#
|
||||
|
||||
DROP FUNCTION f1cs1;
|
@ -0,0 +1,45 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# Hybrid functions
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
SELECT LEAST(c0, c1);
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and sys_refcursor for operation 'least'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
SELECT GREATEST(c0, c1);
|
||||
END;
|
||||
/
|
||||
ERROR HY000: Illegal parameter data types sys_refcursor and sys_refcursor for operation 'greatest'
|
||||
#
|
||||
# This test covers Item::val_ref_from_item() and its DBUG_ASSERT:
|
||||
# A SYS_REFCURSOR expressions is allowed to be mixed only
|
||||
# with another SYS_REFCURSOR expression, or with explicit NULL.
|
||||
#
|
||||
CREATE FUNCTION f1(switch BOOLEAN, f1c0 SYS_REFCURSOR) RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
RETURN IF(switch, NULL, f1c0);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE p1c0 SYS_REFCURSOR;
|
||||
SELECT f1(FALSE, p1c0) AS c1, f1(TRUE, p1c0) AS c2;
|
||||
OPEN p1c0 FOR SELECT 1;
|
||||
SELECT f1(FALSE, p1c0) AS c1, f1(TRUE, p1c0) AS c2;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
c1 c2
|
||||
NULL NULL
|
||||
c1 c2
|
||||
0 NULL
|
||||
DROP FUNCTION f1;
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,55 @@
|
||||
--source include/have_debug.inc
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # Hybrid functions
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
SELECT LEAST(c0, c1);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
DELIMITER /;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
DECLARE c1 SYS_REFCURSOR;
|
||||
SELECT GREATEST(c0, c1);
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # This test covers Item::val_ref_from_item() and its DBUG_ASSERT:
|
||||
--echo # A SYS_REFCURSOR expressions is allowed to be mixed only
|
||||
--echo # with another SYS_REFCURSOR expression, or with explicit NULL.
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION f1(switch BOOLEAN, f1c0 SYS_REFCURSOR) RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
RETURN IF(switch, NULL, f1c0);
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE p1c0 SYS_REFCURSOR;
|
||||
SELECT f1(FALSE, p1c0) AS c1, f1(TRUE, p1c0) AS c2;
|
||||
OPEN p1c0 FOR SELECT 1;
|
||||
SELECT f1(FALSE, p1c0) AS c1, f1(TRUE, p1c0) AS c2;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
CALL p1;
|
||||
DROP FUNCTION f1;
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,40 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
#
|
||||
# String functions
|
||||
#
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CONCAT(c0);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'concat'
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CONCAT_WS(',', c0, c0);
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'concat_ws'
|
||||
SET sql_mode=ORACLE;
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
SELECT c0 || ' ' || ' ' || c0;
|
||||
END;
|
||||
$$
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'concat'
|
||||
SET sql_mode=DEFAULT;
|
||||
#
|
||||
# String sum functions
|
||||
#
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT GROUP_CONCAT(c0) FROM seq_1_to_4;
|
||||
END;
|
||||
/
|
||||
CALL p1;
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'group_concat('
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,65 @@
|
||||
--source include/have_sequence.inc
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
--echo #
|
||||
|
||||
--echo #
|
||||
--echo # String functions
|
||||
--echo #
|
||||
|
||||
# CONCAT
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CONCAT(c0);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
# CONCAT_WS
|
||||
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
BEGIN NOT ATOMIC
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
SELECT CONCAT_WS(',', c0, c0);
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
|
||||
|
||||
# Concatenation operator ||
|
||||
|
||||
SET sql_mode=ORACLE;
|
||||
DELIMITER $$;
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
DECLARE
|
||||
c0 SYS_REFCURSOR;
|
||||
BEGIN
|
||||
SELECT c0 || ' ' || ' ' || c0;
|
||||
END;
|
||||
$$
|
||||
DELIMITER ;$$
|
||||
SET sql_mode=DEFAULT;
|
||||
|
||||
|
||||
--echo #
|
||||
--echo # String sum functions
|
||||
--echo #
|
||||
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE p1()
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
OPEN c0 FOR SELECT 1;
|
||||
SELECT GROUP_CONCAT(c0) FROM seq_1_to_4;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
--error ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION
|
||||
CALL p1;
|
||||
DROP PROCEDURE p1;
|
@ -0,0 +1,74 @@
|
||||
--echo #
|
||||
--echo # Helper routines
|
||||
--echo #
|
||||
|
||||
# Return a string with ref counters for cursors in the given range,
|
||||
# with format '[ cnt0 cnt1 cnt2 cnt 3 cnt4 cnt5 ]', for example:
|
||||
# '[ 2 1 NULL NULL NULL]'
|
||||
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION refs(first INT, last INT) RETURNS TEXT
|
||||
BEGIN
|
||||
DECLARE res TEXT DEFAULT '[';
|
||||
FOR i IN first..last
|
||||
DO
|
||||
SET res= CONCAT(res, COALESCE(CURSOR_REF_COUNT(i), 'NULL'));
|
||||
IF i < last THEN
|
||||
SET res= CONCAT(res, '\t');
|
||||
END IF;
|
||||
END FOR;
|
||||
SET res= CONCAT(res, ']');
|
||||
RETURN res;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
# Show a cursor and ref counters in the given range
|
||||
DELIMITER /;
|
||||
CREATE PROCEDURE show_cursor_and_refs(stage VARCHAR(32),
|
||||
curs VARCHAR(32),
|
||||
first INT, last INT)
|
||||
BEGIN
|
||||
SELECT stage, COALESCE(curs, 'NULL') AS curs, refs(first, last) AS refs;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
|
||||
|
||||
# Returns a new open cursor with logging
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION ff0() RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
DECLARE c0 SYS_REFCURSOR;
|
||||
IF @log <> '' THEN
|
||||
SET @log= CONCAT(@log, '\n');
|
||||
END IF;
|
||||
SET @log= CONCAT(@log, 'ff0-0','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5), '\n');
|
||||
OPEN c0 FOR SELECT 10;
|
||||
SET @log= CONCAT(@log, 'ff0-1','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5));
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SHOW FUNCTION CODE ff0;
|
||||
|
||||
|
||||
# Returns an existing cursor passed to the IN parameter, with logging
|
||||
DELIMITER /;
|
||||
CREATE FUNCTION ff1(c0 SYS_REFCURSOR) RETURNS SYS_REFCURSOR
|
||||
BEGIN
|
||||
IF @log <> '' THEN
|
||||
SET @log= CONCAT(@log, '\n');
|
||||
END IF;
|
||||
SET @log= CONCAT(@log, 'ff1-0','\t',
|
||||
COALESCE(CAST(c0 AS CHAR),'NULL'), '\t',
|
||||
refs(0,5));
|
||||
RETURN c0;
|
||||
END;
|
||||
/
|
||||
DELIMITER ;/
|
||||
SHOW FUNCTION CODE ff1;
|
@ -0,0 +1,7 @@
|
||||
#
|
||||
# Drop helper routines
|
||||
#
|
||||
DROP FUNCTION ff0;
|
||||
DROP FUNCTION ff1;
|
||||
DROP PROCEDURE show_cursor_and_refs;
|
||||
DROP FUNCTION refs;
|
@ -0,0 +1,197 @@
|
||||
#
|
||||
# MDEV-20034 Add support for the pre-defined weak SYS_REFCURSOR
|
||||
#
|
||||
SET default_storage_engine=InnoDB;
|
||||
#
|
||||
# OPEN sys_ref_cursor FOR SELECT ... FOR UPDATE
|
||||
#
|
||||
SELECT @@autocommit;
|
||||
@@autocommit
|
||||
1
|
||||
SELECT @@transaction_isolation;
|
||||
@@transaction_isolation
|
||||
REPEATABLE-READ
|
||||
SELECT @@default_storage_engine;
|
||||
@@default_storage_engine
|
||||
InnoDB
|
||||
CREATE TABLE t1 (
|
||||
id INT PRIMARY KEY,
|
||||
worker VARCHAR(32) DEFAULT '',
|
||||
ts TIMESTAMP(6) NOT NULL DEFAULT CURRENT_TIMESTAMP(6)
|
||||
);
|
||||
SHOW CREATE TABLE t1;
|
||||
Table Create Table
|
||||
t1 CREATE TABLE `t1` (
|
||||
`id` int(11) NOT NULL,
|
||||
`worker` varchar(32) DEFAULT '',
|
||||
`ts` timestamp(6) NOT NULL DEFAULT current_timestamp(6),
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_uca1400_ai_ci
|
||||
CREATE TABLE t2 (a VARCHAR(128)) ENGINE=MEMORY;
|
||||
CREATE PROCEDURE p2(for_update BOOL, do_fetch BOOL)
|
||||
BEGIN
|
||||
DECLARE c SYS_REFCURSOR;
|
||||
DECLARE v INT;
|
||||
START TRANSACTION;
|
||||
IF for_update THEN
|
||||
OPEN c FOR SELECT id FROM t1 WHERE id=0 FOR UPDATE;
|
||||
ELSE
|
||||
OPEN c FOR SELECT id FROM t1 WHERE id=0;
|
||||
END IF;
|
||||
IF do_fetch THEN
|
||||
FETCH c INTO v;
|
||||
END IF;
|
||||
-- signal to the other thread that OPEN happened
|
||||
INSERT INTO t2 VALUES
|
||||
('The exact value does not matter in t2. Only COUNT(*) matters');
|
||||
IF NOT for_update THEN
|
||||
-- If FOR UPDATE is not specified then other thread is not locked
|
||||
-- Let the other thread finish INSERT.
|
||||
DO SLEEP(30); -- This query will be killed by the other thread
|
||||
END IF;
|
||||
INSERT INTO t1 VALUES (12, 'p2', SYSDATE(6));
|
||||
CLOSE c;
|
||||
COMMIT;
|
||||
END;
|
||||
/
|
||||
CREATE PROCEDURE p1(for_update BOOL)
|
||||
BEGIN
|
||||
DECLARE v INT;
|
||||
DECLARE session_id INT;
|
||||
START TRANSACTION;
|
||||
IF for_update THEN
|
||||
SET v=(SELECT id FROM t1 WHERE id=0 FOR UPDATE);
|
||||
ELSE
|
||||
SET v=(SELECT id FROM t1 WHERE id=0);
|
||||
END IF;
|
||||
INSERT INTO t1 VALUES (11, 'p1', SYSDATE(6));
|
||||
COMMIT;
|
||||
-- Check if the other thread is executing the SLEEP
|
||||
-- statement and kill it to avoid waiting
|
||||
SET session_id= (SELECT ID FROM INFORMATION_SCHEMA.PROCESSLIST
|
||||
WHERE INFO LIKE '%SLEEP(%)');
|
||||
SELECT CONCAT('p1: session_id IS NOT NULL:', session_id IS NOT NULL) AS msg;
|
||||
IF session_id IS NOT NULL
|
||||
THEN
|
||||
KILL QUERY session_id;
|
||||
END IF;
|
||||
END;
|
||||
/
|
||||
------------ for_update=0 do_fetch=0
|
||||
TRUNCATE TABLE t1;
|
||||
TRUNCATE TABLE t2;
|
||||
BEGIN;
|
||||
INSERT INTO t1 (id) VALUES (0),(1),(2),(3),(4),(5),(6),(7);
|
||||
COMMIT;
|
||||
connect con2,localhost,root;
|
||||
connection con2;
|
||||
CALL p2(0, 0);
|
||||
connection default;
|
||||
CALL p1(0);
|
||||
msg
|
||||
p1: session_id IS NOT NULL:1
|
||||
connection con2;
|
||||
disconnect con2;
|
||||
connection default;
|
||||
# Without FOR UPDATE: p1 inserted first
|
||||
SELECT id, worker FROM t1 WHERE worker<>'' ORDER BY ts;
|
||||
id worker
|
||||
11 p1
|
||||
12 p2
|
||||
------------ for_update=0 do_fetch=1
|
||||
TRUNCATE TABLE t1;
|
||||
TRUNCATE TABLE t2;
|
||||
BEGIN;
|
||||
INSERT INTO t1 (id) VALUES (0),(1),(2),(3),(4),(5),(6),(7);
|
||||
COMMIT;
|
||||
connect con2,localhost,root;
|
||||
connection con2;
|
||||
CALL p2(0, 1);
|
||||
connection default;
|
||||
CALL p1(0);
|
||||
msg
|
||||
p1: session_id IS NOT NULL:1
|
||||
connection con2;
|
||||
disconnect con2;
|
||||
connection default;
|
||||
# Without FOR UPDATE: p1 inserted first
|
||||
SELECT id, worker FROM t1 WHERE worker<>'' ORDER BY ts;
|
||||
id worker
|
||||
11 p1
|
||||
12 p2
|
||||
------------ for_update=1 do_fetch=0
|
||||
TRUNCATE TABLE t1;
|
||||
TRUNCATE TABLE t2;
|
||||
BEGIN;
|
||||
INSERT INTO t1 (id) VALUES (0),(1),(2),(3),(4),(5),(6),(7);
|
||||
COMMIT;
|
||||
connect con2,localhost,root;
|
||||
connection con2;
|
||||
CALL p2(1, 0);
|
||||
connection default;
|
||||
CALL p1(1);
|
||||
msg
|
||||
p1: session_id IS NOT NULL:0
|
||||
connection con2;
|
||||
disconnect con2;
|
||||
connection default;
|
||||
# With FOR UPDATE: p2 inserted first
|
||||
SELECT id, worker FROM t1 WHERE worker<>'' ORDER BY ts;
|
||||
id worker
|
||||
12 p2
|
||||
11 p1
|
||||
------------ for_update=1 do_fetch=1
|
||||
TRUNCATE TABLE t1;
|
||||
TRUNCATE TABLE t2;
|
||||
BEGIN;
|
||||
INSERT INTO t1 (id) VALUES (0),(1),(2),(3),(4),(5),(6),(7);
|
||||
COMMIT;
|
||||
connect con2,localhost,root;
|
||||
connection con2;
|
||||
CALL p2(1, 1);
|
||||
connection default;
|
||||
CALL p1(1);
|
||||
msg
|
||||
p1: session_id IS NOT NULL:0
|
||||
connection con2;
|
||||
disconnect con2;
|
||||
connection default;
|
||||
# With FOR UPDATE: p2 inserted first
|
||||
SELECT id, worker FROM t1 WHERE worker<>'' ORDER BY ts;
|
||||
id worker
|
||||
12 p2
|
||||
11 p1
|
||||
DROP PROCEDURE p1;
|
||||
DROP PROCEDURE p2;
|
||||
DROP TABLE t1;
|
||||
DROP TABLE t2;
|
||||
SET default_storage_engine=DEFAULT;
|
||||
#
|
||||
# MDEV-36377 Assertion `thd->lex == sp_instr_lex' failed in LEX *sp_lex_instr::parse_expr(THD *, sp_head *, LEX *)
|
||||
#
|
||||
CREATE TABLE t (a INT) ENGINE=INNODB;
|
||||
CREATE PROCEDURE p (OUT c sys_refcursor)
|
||||
BEGIN
|
||||
OPEN c FOR SELECT a FROM t ;
|
||||
END;
|
||||
$
|
||||
CREATE TEMPORARY TABLE t (c INT) ENGINE=INNODB;
|
||||
SET GLOBAL innodb_file_per_table=0;
|
||||
Warnings:
|
||||
Warning 1287 '@@innodb_file_per_table' is deprecated and will be removed in a future release
|
||||
SET innodb_compression_default=ON;
|
||||
CALL p (@a);
|
||||
ERROR 42S22: Unknown column 'a' in 'SELECT'
|
||||
CREATE OR REPLACE TEMPORARY TABLE t (c INT) ENGINE=INNODB;
|
||||
ERROR HY000: Can't create table `test`.`t` (errno: 140 "Wrong create options")
|
||||
PREPARE s FROM 'CALL p(?)';
|
||||
EXECUTE s USING @a;
|
||||
ERROR HY000: Illegal parameter data type sys_refcursor for operation 'SET user_variable'
|
||||
CALL p(@a);
|
||||
CALL p;
|
||||
ERROR 42000: Incorrect number of arguments for PROCEDURE test.p; expected 1, got 0
|
||||
DROP PROCEDURE p;
|
||||
DROP TABLE t;
|
||||
SET GLOBAL innodb_file_per_table=DEFAULT;
|
||||
Warnings:
|
||||
Warning 1287 '@@innodb_file_per_table' is deprecated and will be removed in a future release
|
Some files were not shown because too many files have changed in this diff Show More
Reference in New Issue
Block a user