Browse Source
MDEV-12011 sql_mode=ORACLE: cursor%ROWTYPE in variable declarations
MDEV-12011 sql_mode=ORACLE: cursor%ROWTYPE in variable declarations
Implementing cursor%ROWTYPE variables, according to the task description. This patch includes a refactoring in how sp_instr_cpush and sp_instr_copen work. This is needed to implement MDEV-10598 later easier, to allow variable declarations go after cursor declarations (which is currently not allowed). Before this patch, sp_instr_cpush worked as a Query_arena associated with the cursor. sp_instr_copen::execute() switched to the sp_instr_cpush's Query_arena when executing the cursor SELECT statement. Now the Query_arena associated with the cursor is stored inside an instance of a new class sp_lex_cursor (a LEX descendand) that contains the cursor SELECT statement. This simplifies the implementation, because: - It's easier to follow the code when everything related to execution of the cursor SELECT statement is stored inside the same sp_lex_cursor object (rather than distributed between LEX and sp_instr_cpush). - It's easier to link an sp_instr_cursor_copy_struct to sp_lex_cursor rather than to sp_instr_cpush. - Also, it allows to perform sp_instr_cursor_copy_struct::exec_core() without having a pointer to sp_instr_cpush, using a pointer to sp_lex_cursor instead. This will be important for MDEV-10598, because sp_instr_cpush will happen *after* sp_instr_cursor_copy_struct. After MDEV-10598 is done, this declaration: DECLARE CURSOR cur IS SELECT * FROM t1; rec cur%ROWTYPE; BEGIN OPEN cur; FETCH cur INTO rec; CLOSE cur; END; will generate about this code: +-----+--------------------------+ | Pos | Instruction | +-----+--------------------------+ | 0 | cursor_copy_struct rec@0 | Points to sp_cursor_lex through m_lex_keeper | 1 | set rec@0 NULL | | 2 | cpush cur@0 | Points to sp_cursor_lex through m_lex_keeper | 3 | copen cur@0 | Points to sp_cursor_lex through m_cursor | 4 | cfetch cur@0 rec@0 | | 5 | cclose cur@0 | | 6 | cpop 1 | +-----+--------------------------+ Notice, "cursor_copy_struct" and "set" will go before "cpush". Instructions at positions 0, 2, 3 point to the same sp_cursor_lex instance.pull/381/head
20 changed files with 2445 additions and 83 deletions
-
34mysql-test/suite/compat/oracle/r/sp-code.result
-
978mysql-test/suite/compat/oracle/r/sp-cursor-rowtype.result
-
25mysql-test/suite/compat/oracle/t/sp-code.test
-
1057mysql-test/suite/compat/oracle/t/sp-cursor-rowtype.test
-
25sql/field.h
-
105sql/sp_head.cc
-
65sql/sp_head.h
-
5sql/sp_pcontext.cc
-
10sql/sp_pcontext.h
-
35sql/sp_rcontext.cc
-
10sql/sp_rcontext.h
-
4sql/sql_cursor.cc
-
5sql/sql_cursor.h
-
67sql/sql_lex.cc
-
9sql/sql_lex.h
-
2sql/sql_select.cc
-
32sql/sql_yacc.yy
-
37sql/sql_yacc_ora.yy
-
22sql/table.cc
-
1sql/table.h
@ -0,0 +1,978 @@ |
|||
SET sql_mode=ORACLE; |
|||
# |
|||
# MDEV-12011 sql_mode=ORACLE: cursor%ROWTYPE in variable declarations |
|||
# |
|||
# |
|||
# A complete working example |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(32)); |
|||
CREATE TABLE t2 LIKE t1; |
|||
INSERT INTO t1 VALUES (10,'b10'); |
|||
INSERT INTO t1 VALUES (20,'b20'); |
|||
INSERT INTO t1 VALUES (30,'b30'); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR c IS SELECT a,b FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec c%ROWTYPE; |
|||
BEGIN |
|||
OPEN c; |
|||
LOOP |
|||
FETCH c INTO rec; |
|||
EXIT WHEN c%NOTFOUND; |
|||
SELECT 'rec=(' || rec.a ||','|| rec.b||')' AS c FROM dual; |
|||
INSERT INTO t2 VALUES (rec.a, rec.b); |
|||
END LOOP; |
|||
CLOSE c; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
c |
|||
rec=(10,b10) |
|||
c |
|||
rec=(20,b20) |
|||
c |
|||
rec=(30,b30) |
|||
SELECT * FROM t2; |
|||
a b |
|||
10 b10 |
|||
20 b20 |
|||
30 b30 |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
# |
|||
# cursor%ROWTYPE referring to a table in a non-existing database |
|||
# |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM tes2.t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
NULL; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'tes2.t1' doesn't exist |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10)); |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'tes2.t1' doesn't exist |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# cursor%ROWTYPE referring to a table in the current database |
|||
# |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
CREATE TABLE t2 AS SELECT rec.a, rec.b, rec.c, rec.d; |
|||
SHOW CREATE TABLE t2; |
|||
DROP TABLE t2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'test.t1' doesn't exist |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10)); |
|||
CALL p1(); |
|||
Table Create Table |
|||
t2 CREATE TABLE "t2" ( |
|||
"rec.a" bigint(11) DEFAULT NULL, |
|||
"rec.b" varchar(10) DEFAULT NULL, |
|||
"rec.c" double DEFAULT NULL, |
|||
"rec.d" decimal(10,0) DEFAULT NULL |
|||
) |
|||
DROP TABLE t1; |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'test.t1' doesn't exist |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# cursor%ROWTYPE referring to a table in an explicitly specified database |
|||
# |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM test.t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
CREATE TABLE t2 AS SELECT rec.a, rec.b, rec.c, rec.d; |
|||
SHOW CREATE TABLE t2; |
|||
DROP TABLE t2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'test.t1' doesn't exist |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10)); |
|||
CALL p1(); |
|||
Table Create Table |
|||
t2 CREATE TABLE "t2" ( |
|||
"rec.a" bigint(11) DEFAULT NULL, |
|||
"rec.b" varchar(10) DEFAULT NULL, |
|||
"rec.c" double DEFAULT NULL, |
|||
"rec.d" decimal(10,0) DEFAULT NULL |
|||
) |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Cursor%ROWTYPE referring to a view in the current database |
|||
# |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM v1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
CREATE TABLE t2 AS SELECT rec.a, rec.b, rec.c, rec.d; |
|||
SHOW CREATE TABLE t2; |
|||
DROP TABLE t2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'test.v1' doesn't exist |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10)); |
|||
CREATE VIEW v1 AS SELECT * FROM t1; |
|||
CALL p1(); |
|||
Table Create Table |
|||
t2 CREATE TABLE "t2" ( |
|||
"rec.a" bigint(11) DEFAULT NULL, |
|||
"rec.b" varchar(10) DEFAULT NULL, |
|||
"rec.c" double DEFAULT NULL, |
|||
"rec.d" decimal(10,0) DEFAULT NULL |
|||
) |
|||
DROP VIEW v1; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# cursor%ROWTYPE referring to a view in an explicitly specified database |
|||
# |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM test.v1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
CREATE TABLE t2 AS SELECT rec.a, rec.b, rec.c, rec.d; |
|||
SHOW CREATE TABLE t2; |
|||
DROP TABLE t2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S02: Table 'test.v1' doesn't exist |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10)); |
|||
CREATE VIEW v1 AS SELECT * FROM t1; |
|||
CALL p1(); |
|||
Table Create Table |
|||
t2 CREATE TABLE "t2" ( |
|||
"rec.a" bigint(11) DEFAULT NULL, |
|||
"rec.b" varchar(10) DEFAULT NULL, |
|||
"rec.c" double DEFAULT NULL, |
|||
"rec.d" decimal(10,0) DEFAULT NULL |
|||
) |
|||
DROP VIEW v1; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Checking that all cursor%ROWTYPE fields are NULL by default |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10,2)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
SELECT rec1.a, rec1.b, rec1.c, rec1.d; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec1.a rec1.b rec1.c rec1.d |
|||
NULL NULL NULL NULL |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# A cursor%ROWTYPE variable with a ROW expression as a default |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE := ROW(10,'bbb'); |
|||
BEGIN |
|||
SELECT rec1.a, rec1.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec1.a rec1.b |
|||
10 bbb |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# A cursor%ROWTYPE variable with an incompatible ROW expression as a default |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE := ROW(10,'bbb','ccc'); |
|||
BEGIN |
|||
SELECT rec1.a, rec1.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 21000: Operand should contain 2 column(s) |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# A cursor%ROWTYPE variable with a ROW variable as a default |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 ROW(a INT, b VARCHAR(10)):= ROW(10,'bbb'); |
|||
rec2 cur%ROWTYPE := rec1; |
|||
BEGIN |
|||
SELECT rec2.a, rec2.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.a rec2.b |
|||
10 bbb |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# A ROW variable using a cursor%ROWTYPE variable as a default |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE := ROW(10,'bbb'); |
|||
rec2 ROW(a INT, b VARCHAR(10)):= rec1; |
|||
BEGIN |
|||
SELECT rec2.a, rec2.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.a rec2.b |
|||
10 bbb |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Assigning cursor%ROWTYPE variables with a different column count |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE); |
|||
CREATE TABLE t2 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
rec2:=rec1; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 21000: Operand should contain 2 column(s) |
|||
DROP PROCEDURE p1; |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
rec1:=rec2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 21000: Operand should contain 3 column(s) |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Assigning compatible cursor%ROWTYPE variables (equal number of fields) |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE TABLE t2 (x INT, y VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
rec1.a:= 10; |
|||
rec1.b:= 'bbb'; |
|||
rec2:=rec1; |
|||
SELECT rec2.x, rec2.y; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.x rec2.y |
|||
10 bbb |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Assigning between incompatible cursor%ROWTYPE and explicit ROW variables |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
rec2 ROW(x INT,y INT,z INT); |
|||
BEGIN |
|||
rec2.x:= 10; |
|||
rec2.y:= 20; |
|||
rec2.z:= 30; |
|||
rec1:= rec2; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 21000: Operand should contain 2 column(s) |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Assigning between compatible cursor%ROWTYPE and explicit ROW variables |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
rec2 ROW(x INT,y INT); |
|||
BEGIN |
|||
rec2.x:= 10; |
|||
rec2.y:= 20; |
|||
rec1:= rec2; |
|||
SELECT rec1.a, rec1.b; |
|||
rec1.a:= 11; |
|||
rec1.b:= 21; |
|||
rec2:= rec1; |
|||
SELECT rec2.x, rec2.y; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec1.a rec1.b |
|||
10 20 |
|||
rec2.x rec2.y |
|||
11 21 |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Assigning cursor%ROWTYPE from a ROW expression |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
rec1:= ROW(10,20); |
|||
SELECT rec1.a, rec1.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec1.a rec1.b |
|||
10 20 |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Fetching a cursor into a cursor%ROWTYPE variable with a wrong field count |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10,2)); |
|||
CREATE TABLE t2 (a INT, b VARCHAR(10)); |
|||
INSERT INTO t1 VALUES (10,'bb1',111.111e2, 12.31); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec2; |
|||
CLOSE cur1; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR HY000: Incorrect number of FETCH variables |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Fetching a cursor into a cursor%ROWTYPE variable |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10,2)); |
|||
CREATE TABLE t2 LIKE t1; |
|||
INSERT INTO t1 VALUES (10,'bb1',111.111e2, 12.31); |
|||
INSERT INTO t1 VALUES (20,'bb2',222.222e2, 12.32); |
|||
INSERT INTO t1 VALUES (30,'bb3',333.333e2, 12.33); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur; |
|||
LOOP |
|||
FETCH cur INTO rec; |
|||
EXIT WHEN cur%NOTFOUND; |
|||
SELECT rec.a, rec.b, rec.c, rec.d; |
|||
INSERT INTO t2 VALUES (rec.a, rec.b, rec.c, rec.d); |
|||
END LOOP; |
|||
CLOSE cur; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec.a rec.b rec.c rec.d |
|||
10 bb1 11111.1 12.31 |
|||
rec.a rec.b rec.c rec.d |
|||
20 bb2 22222.2 12.32 |
|||
rec.a rec.b rec.c rec.d |
|||
30 bb3 33333.3 12.33 |
|||
SELECT * FROM t2; |
|||
a b c d |
|||
10 bb1 11111.1 12.31 |
|||
20 bb2 22222.2 12.32 |
|||
30 bb3 33333.3 12.33 |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Fetching a cursor into a cursor%ROWTYPE variable, cur%ROWTYPE declared inside the LOOP |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10), c DOUBLE, d DECIMAL(10,2)); |
|||
CREATE TABLE t2 LIKE t1; |
|||
INSERT INTO t1 VALUES (10,'bb1',111.111e2, 12.31); |
|||
INSERT INTO t1 VALUES (20,'bb2',222.222e2, 12.32); |
|||
INSERT INTO t1 VALUES (30,'bb3',333.333e2, 12.33); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
OPEN cur; |
|||
LOOP |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
FETCH cur INTO rec; |
|||
EXIT WHEN cur%NOTFOUND; |
|||
SELECT rec.a, rec.b, rec.c, rec.d; |
|||
INSERT INTO t2 VALUES (rec.a, rec.b, rec.c, rec.d); |
|||
END; |
|||
END LOOP; |
|||
CLOSE cur; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec.a rec.b rec.c rec.d |
|||
10 bb1 11111.1 12.31 |
|||
rec.a rec.b rec.c rec.d |
|||
20 bb2 22222.2 12.32 |
|||
rec.a rec.b rec.c rec.d |
|||
30 bb3 33333.3 12.33 |
|||
SELECT * FROM t2; |
|||
a b c d |
|||
10 bb1 11111.1 12.31 |
|||
20 bb2 22222.2 12.32 |
|||
30 bb3 33333.3 12.33 |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Fetching a cursor into a cursor%ROWTYPE variable with different column names |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE TABLE t2 (x INT, y VARCHAR(10)); |
|||
INSERT INTO t1 VALUES (10,'bbb'); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec2; |
|||
SELECT rec2.x, rec2.y; |
|||
CLOSE cur1; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.x rec2.y |
|||
10 bbb |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Fetching a cursor into a cursor%ROWTYPE variable, with truncation |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE TABLE t2 (a INT, b INT); |
|||
INSERT INTO t1 VALUES (10,'11x'); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
CURSOR cur2 IS SELECT * FROM t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec2; |
|||
SELECT rec2.a, rec2.b; |
|||
CLOSE cur1; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.a rec2.b |
|||
10 11 |
|||
Warnings: |
|||
Warning 1265 Data truncated for column 'b' at row 1 |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# cursor%ROWTYPE variables are not allowed in LIMIT |
|||
# |
|||
CREATE TABLE t1 (a INT, b INT); |
|||
INSERT INTO t1 VALUES (1,2); |
|||
CREATE PROCEDURE p1() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE:=(1,2); |
|||
BEGIN |
|||
SELECT * FROM t1 LIMIT rec1.a; |
|||
END; |
|||
END; |
|||
$$ |
|||
ERROR HY000: A variable of a non-integer based type in LIMIT clause |
|||
DROP TABLE t1; |
|||
# |
|||
# cursor%ROWTYPE variable fields as OUT parameters |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1(a OUT INT,b OUT VARCHAR(10)) |
|||
AS |
|||
BEGIN |
|||
a:=10; |
|||
b:='bb'; |
|||
END; |
|||
$$ |
|||
CREATE PROCEDURE p2() |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
CALL p1(rec1.a, rec1.b); |
|||
SELECT rec1.a, rec1.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p2(); |
|||
rec1.a rec1.b |
|||
10 bb |
|||
DROP PROCEDURE p2; |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Passing the entire cursor%ROWTYPE variable |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1(a ROW(a INT, b VARCHAR(10))) |
|||
AS |
|||
BEGIN |
|||
SELECT a.a, a.b; |
|||
END; |
|||
$$ |
|||
CREATE PROCEDURE p2() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur%ROWTYPE:= ROW(10,'bb'); |
|||
BEGIN |
|||
CALL p1(rec1); |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p2(); |
|||
a.a a.b |
|||
10 bb |
|||
DROP PROCEDURE p2; |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Passing the entire cursor%ROWTYPE variable as an OUT parameter |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1(a OUT ROW(a INT, b VARCHAR(10))) |
|||
AS |
|||
BEGIN |
|||
a:= ROW(10,'bb'); |
|||
END; |
|||
$$ |
|||
CREATE PROCEDURE p2() |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur%ROWTYPE; |
|||
BEGIN |
|||
CALL p1(rec1); |
|||
SELECT rec1.a, rec1.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p2(); |
|||
rec1.a rec1.b |
|||
10 bb |
|||
DROP PROCEDURE p2; |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Assigning a cursor%ROWTYPE field to an OUT parameter |
|||
# |
|||
CREATE PROCEDURE p1 (res IN OUT INTEGER) |
|||
AS |
|||
a INT:=10; |
|||
CURSOR cur1 IS SELECT a FROM DUAL; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec1; |
|||
CLOSE cur1; |
|||
res:=rec1.a; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(@res); |
|||
SELECT @res; |
|||
@res |
|||
10 |
|||
SET @res=NULL; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Testing Item_splocal_row_field_by_name::print |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur1%ROWTYPE:=ROW(10,'bb'); |
|||
BEGIN |
|||
EXPLAIN EXTENDED SELECT rec.a, rec.b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL No tables used |
|||
Warnings: |
|||
Note 1003 select rec.a@0["a"] AS "rec.a",rec.b@0["b"] AS "rec.b" |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Run time error in the cursor statement |
|||
# |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur1 IS SELECT |
|||
10 AS a, |
|||
CONCAT(_latin1'a' COLLATE latin1_bin, |
|||
_latin1'a' COLLATE latin1_swedish_ci) AS b; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec1; |
|||
CLOSE cur1; |
|||
SELECT a,b; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR HY000: Illegal mix of collations (latin1_bin,EXPLICIT) and (latin1_swedish_ci,EXPLICIT) for operation '||' |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Non-existing field |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur1 IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur1%ROWTYPE; |
|||
BEGIN |
|||
SELECT rec.c; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR HY000: Row variable 'rec' does not have a field 'c' |
|||
ALTER TABLE t1 ADD c INT; |
|||
ALTER PROCEDURE p1 COMMENT 'test'; |
|||
CALL p1(); |
|||
rec.c |
|||
NULL |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Testing that field names are case insensitive |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE:=ROW(10,'bb'); |
|||
BEGIN |
|||
SELECT rec.A, rec.B; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec.A rec.B |
|||
10 bb |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Testing that cursor%ROWTYPE uses temporary tables vs shadowed real tables |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
CREATE TEMPORARY TABLE t1 (x INT, y VARCHAR(10)); |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE:=ROW(10,'bb'); |
|||
BEGIN |
|||
SELECT rec.A, rec.B; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR HY000: Row variable 'rec' does not have a field 'A' |
|||
DROP TEMPORARY TABLE t1; |
|||
ALTER PROCEDURE p1 COMMENT 'test'; |
|||
CALL p1(); |
|||
rec.A rec.B |
|||
10 bb |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Testing that the structure of cursor%ROWTYPE variables is determined at the CURSOR instantiation time |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(32)); |
|||
INSERT INTO t1 VALUES (10,'b10'); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DROP TABLE t1; |
|||
CREATE TABLE t1 (a INT, b VARCHAR(32), c INT); |
|||
DECLARE |
|||
rec cur%ROWTYPE; -- This has a column "c" |
|||
BEGIN |
|||
rec.c:=10; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
CREATE TABLE t1 (a INT, b VARCHAR(32)); |
|||
INSERT INTO t1 VALUES (10,'b10'); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR cur IS SELECT * FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; -- This does not have a column "c" |
|||
BEGIN |
|||
DROP TABLE t1; |
|||
CREATE TABLE t1 (a INT, b VARCHAR(32), c INT); |
|||
rec.c:=10; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR HY000: Row variable 'rec' does not have a field 'c' |
|||
DROP TABLE t1; |
|||
DROP PROCEDURE p1; |
|||
# |
|||
# Duplicate field nams in a cursor referenced by %ROWTYPE |
|||
# |
|||
CREATE TABLE t1 (a INT); |
|||
CREATE TABLE t2 (a INT); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR cur IS SELECT * FROM t1, t2; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
SELECT rec.a; |
|||
rec.a:=10; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
ERROR 42S21: Duplicate column name 'a' |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t2; |
|||
DROP TABLE t1; |
|||
# |
|||
# Tricky field names a cursor referenced by %ROWTYPE |
|||
# |
|||
SET NAMES utf8; |
|||
CREATE TABLE t1 (a VARCHAR(10)); |
|||
INSERT INTO t1 VALUES ('a'); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR cur IS SELECT a, CONCAT(a,'a'), CONCAT(a,'ö') FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec cur%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur; |
|||
FETCH cur INTO rec; |
|||
CLOSE cur; |
|||
SELECT rec.a, rec."CONCAT(a,'a')", rec."CONCAT(a,'ö')"; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec.a rec."CONCAT(a,'a')" rec."CONCAT(a,'ö')" |
|||
a aa aö |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
SET NAMES latin1; |
|||
# |
|||
# Using definitions recursively (cursor%ROWTYPE variables in another cursor SELECT) |
|||
# |
|||
CREATE TABLE t1 (a INT, b VARCHAR(10)); |
|||
INSERT INTO t1 VALUES (10,'b1'),(20,'b2'),(30,'b3'); |
|||
CREATE PROCEDURE p1 AS |
|||
CURSOR cur1 IS SELECT a,b FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE:=ROW(0,'b0'); |
|||
CURSOR cur2 IS SELECT rec1.a AS a, rec1.b AS b FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec2 cur2%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur2; |
|||
LOOP |
|||
FETCH cur2 INTO rec2; |
|||
EXIT WHEN cur2%NOTFOUND; |
|||
SELECT rec2.a, rec2.b; |
|||
END LOOP; |
|||
CLOSE cur2; |
|||
END; |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
rec2.a rec2.b |
|||
0 b0 |
|||
rec2.a rec2.b |
|||
0 b0 |
|||
rec2.a rec2.b |
|||
0 b0 |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
# |
|||
# Testing queries with auto-generated Items. |
|||
# An instance of Item_func_conv_charset is created during the below SELECT query. |
|||
# We check here that during an implicit cursor OPEN |
|||
# done in sp_instr_cursor_copy_struct::exec_core() |
|||
# all temporary Items are created on a proper memory root and are safely destroyed. |
|||
# |
|||
CREATE TABLE t1 (a VARCHAR(10) CHARACTER SET latin1, b VARCHAR(10) CHARACTER SET utf8); |
|||
INSERT INTO t1 VALUES (0xFF, 'a'); |
|||
CREATE PROCEDURE p1 |
|||
AS |
|||
CURSOR cur1 IS SELECT CONCAT(a,b) AS c FROM t1; |
|||
BEGIN |
|||
DECLARE |
|||
rec1 cur1%ROWTYPE; |
|||
BEGIN |
|||
OPEN cur1; |
|||
FETCH cur1 INTO rec1; |
|||
CLOSE cur1; |
|||
SELECT HEX(rec1.c); |
|||
END; |
|||
END; |
|||
$$ |
|||
CALL p1(); |
|||
HEX(rec1.c) |
|||
C3BF61 |
|||
DROP PROCEDURE p1; |
|||
DROP TABLE t1; |
|||
1057
mysql-test/suite/compat/oracle/t/sp-cursor-rowtype.test
File diff suppressed because it is too large
View File
File diff suppressed because it is too large
View File
Write
Preview
Loading…
Cancel
Save
Reference in new issue