From f8a714c84858ae63514afe769ff52fac919e918b Mon Sep 17 00:00:00 2001 From: Alexander Barkov Date: Fri, 21 Oct 2016 11:51:49 +0400 Subject: [PATCH] MDEV-10597 Cursors with parameters --- .../suite/compat/oracle/r/sp-code.result | 60 +++ .../suite/compat/oracle/r/sp-cursor.result | 463 ++++++++++++++++++ mysql-test/suite/compat/oracle/t/sp-code.test | 42 ++ .../suite/compat/oracle/t/sp-cursor.test | 456 +++++++++++++++++ sql/share/errmsg-utf8.txt | 3 + sql/sp_head.cc | 99 ++-- sql/sp_head.h | 111 ++++- sql/sp_pcontext.cc | 16 +- sql/sp_pcontext.h | 49 +- sql/sql_class.cc | 13 +- sql/sql_class.h | 25 + sql/sql_lex.cc | 244 +++++---- sql/sql_lex.h | 99 +++- sql/sql_yacc.yy | 50 +- sql/sql_yacc_ora.yy | 98 +++- 15 files changed, 1606 insertions(+), 222 deletions(-) diff --git a/mysql-test/suite/compat/oracle/r/sp-code.result b/mysql-test/suite/compat/oracle/r/sp-code.result index f9691d18cccfd..5a67e8c3c1d05 100644 --- a/mysql-test/suite/compat/oracle/r/sp-code.result +++ b/mysql-test/suite/compat/oracle/r/sp-code.result @@ -827,3 +827,63 @@ SELECT f1(3), f1(4), f1(5), f1(6) FROM DUAL; f1(3) f1(4) f1(5) f1(6) 3 4 4 5 DROP FUNCTION f1; +# +# Start of MDEV-10597 Cursors with parameters +# +CREATE PROCEDURE p1(arg_value_a VARCHAR, arg_value_b VARCHAR, +arg_pattern_a VARCHAR, arg_pattern_b VARCHAR) +AS +v_a VARCHAR(10); +v_b VARCHAR(20); +CURSOR c (p_value_a VARCHAR, +p_value_b VARCHAR, +p_pattern_a VARCHAR, +p_pattern_b VARCHAR, +p_limit_a INT, +p_limit_b INT, +p_unused TEXT) IS +(SELECT p_value_a, p_value_b FROM DUAL +WHERE p_value_a LIKE p_pattern_a LIMIT p_limit_a) +UNION +(SELECT p_value_b, p_value_a FROM DUAL +WHERE p_value_b LIKE p_pattern_b LIMIT p_limit_b); +BEGIN +OPEN c(arg_value_a, (SELECT arg_value_b), +arg_pattern_a, arg_pattern_b, 100, 101, 'x'); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT v_a, v_b; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('aaa','bbb','aaa','bbb'); +v_a v_b +aaa bbb +v_a v_b +bbb aaa +SHOW PROCEDURE CODE p1; +Pos Instruction +0 set v_a@4 NULL +1 set v_b@5 NULL +2 cpush c@0 +3 set p_value_a@6 arg_value_a@0 +4 set p_value_b@7 (select arg_value_b@1) +5 set p_pattern_a@8 arg_pattern_a@2 +6 set p_pattern_b@9 arg_pattern_b@3 +7 set p_limit_a@10 100 +8 set p_limit_b@11 101 +9 set p_unused@12 'x' +10 copen c@0 +11 cfetch c@0 v_a@4 v_b@5 +12 jump_if_not 14(0) "c"%NOTFOUND +13 jump 16 +14 stmt 0 "SELECT v_a, v_b" +15 jump 11 +16 cclose c@0 +17 cpop 1 +DROP PROCEDURE p1; +# +# End of MDEV-10597 Cursors with parameters +# diff --git a/mysql-test/suite/compat/oracle/r/sp-cursor.result b/mysql-test/suite/compat/oracle/r/sp-cursor.result index 1458d820f7877..800839eeee47f 100644 --- a/mysql-test/suite/compat/oracle/r/sp-cursor.result +++ b/mysql-test/suite/compat/oracle/r/sp-cursor.result @@ -289,3 +289,466 @@ a 30 DROP PROCEDURE p1; DROP TABLE t1; +# +# End of MDEV-10582 sql_mode=ORACLE: explicit cursor attributes %ISOPEN, %ROWCOUNT, %FOUND, %NOTFOUND +# +# +# MDEV-10597 Cursors with parameters +# +# +# OPEN with a wrong number of parameters +# +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE PROCEDURE p1(a_a INT,a_b VARCHAR) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT, p_b VARCHAR) IS SELECT * FROM t1 WHERE a=p_a; +BEGIN +OPEN c(a_a); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +DBMS_OUTPUT.PUT_LINE('Fetched a record a='||TO_CHAR(v_a)||' b='||v_b); +END LOOP; +CLOSE c; +END; +$$ +ERROR 42000: Incorrect parameter count to cursor 'c' +DROP TABLE t1; +# +# Cursor parameters are not visible outside of the cursor +# +CREATE PROCEDURE p1(a_a INT) +AS +v_a INT; +CURSOR c (p_a INT) IS SELECT a FROM t1 WHERE a=p_a; +BEGIN +OPEN c(a_a); +p_a:=10; +END; +$$ +ERROR HY000: Unknown system variable 'p_a' +CREATE PROCEDURE p1(a_a INT) +AS +v_a INT; +CURSOR c (p_a INT) IS SELECT a FROM t1 WHERE a=p_a; +BEGIN +p_a:=10; +OPEN c(a_a); +END; +$$ +ERROR HY000: Unknown system variable 'p_a' +# +# Cursor parameter shadowing a local variable +# +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1); +CREATE PROCEDURE p1(a INT) +AS +v_a INT:=NULL; +p_a INT:=NULL; +CURSOR c (p_a VARCHAR2) IS SELECT a FROM t1 WHERE p_a IS NOT NULL; +BEGIN +OPEN c(a); +FETCH c INTO v_a; +IF c%NOTFOUND THEN +BEGIN +SELECT 'No records found' AS msg; +RETURN; +END; +END IF; +CLOSE c; +SELECT 'Fetched a record a='||v_a AS msg; +INSERT INTO t1 VALUES (v_a); +END; +$$ +CALL p1(1); +msg +Fetched a record a=1 +SELECT * FROM t1; +a +1 +1 +CALL p1(NULL); +msg +No records found +SELECT * FROM t1; +a +1 +1 +DROP PROCEDURE p1; +DROP TABLE t1; +# +# Parameters in SELECT list +# +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT, p_b VARCHAR) IS SELECT p_a,p_b FROM DUAL; +BEGIN +FOR i IN 0..1 +LOOP +OPEN c(a_a + i,a_b); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT 'Fetched a record a=' || v_a || ' b=' || v_b AS msg; +END LOOP; +CLOSE c; +END LOOP; +END; +$$ +CALL p1(1,'b1'); +msg +Fetched a record a=1 b=b1 +msg +Fetched a record a=2 b=b1 +DROP PROCEDURE p1; +# +# Parameters in SELECT list + UNION +# +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT, p_b VARCHAR) IS +SELECT p_a,p_b FROM DUAL +UNION ALL +SELECT p_a+1,p_b||'b' FROM DUAL; +BEGIN +OPEN c(a_a,a_b); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT 'Fetched a record a=' || v_a || ' b=' || v_b AS msg; +END LOOP; +CLOSE c; +END; +$$ +CALL p1(1,'b1'); +msg +Fetched a record a=1 b=b1 +msg +Fetched a record a=2 b=b1b +DROP PROCEDURE p1; +# +# Parameters in SELECT list + type conversion + warnings +# +CREATE PROCEDURE p1(a_a VARCHAR) +AS +v_a INT; +CURSOR c (p_a INT) IS SELECT p_a FROM DUAL; +BEGIN +OPEN c(a_a); +LOOP +FETCH c INTO v_a; +EXIT WHEN c%NOTFOUND; +SELECT 'Fetched a record a=' || v_a AS msg; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('1b'); +msg +Fetched a record a=1 +Warnings: +Warning 1265 Data truncated for column 'p_a' at row 1 +CALL p1('b1'); +msg +Fetched a record a=0 +Warnings: +Warning 1366 Incorrect integer value: 'b1' for column 'p_a' at row 1 +DROP PROCEDURE p1; +# +# One parameter in SELECT list + subselect +# +CREATE PROCEDURE p1(a_a VARCHAR) +AS +v_a VARCHAR(10); +CURSOR c (p_a VARCHAR) IS +SELECT p_a FROM DUAL UNION SELECT REVERSE(p_a) FROM DUAL; +BEGIN +OPEN c((SELECT a_a)); +LOOP +FETCH c INTO v_a; +EXIT WHEN c%NOTFOUND; +SELECT v_a; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('ab'); +v_a +ab +v_a +ba +DROP PROCEDURE p1; +# +# Two parameters in SELECT list + subselect +# +SET sql_mode=ORACLE; +CREATE PROCEDURE p1() +AS +v_a VARCHAR(10); +v_b VARCHAR(20); +CURSOR c (p_a VARCHAR, p_b VARCHAR) IS +SELECT p_a, p_b FROM DUAL +UNION +SELECT p_b, p_a FROM DUAL; +BEGIN +OPEN c((SELECT 'aaa'),(SELECT 'bbb')); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT v_a, v_b; +END LOOP; +CLOSE c; +END; +$$ +CALL p1(); +v_a v_b +aaa bbb +v_a v_b +bbb aaa +DROP PROCEDURE p1; +# +# Two parameters in SELECT list + two parameters in WHERE + subselects +# +SET sql_mode=ORACLE; +CREATE PROCEDURE p1(a_a VARCHAR, a_b VARCHAR) +AS +v_a VARCHAR(10); +v_b VARCHAR(20); +CURSOR c (value_a VARCHAR, value_b VARCHAR, +pattern_a VARCHAR, pattern_b VARCHAR) IS +SELECT value_a, value_b FROM DUAL WHERE value_a LIKE pattern_a +UNION +SELECT value_b, value_a FROM DUAL WHERE value_b LIKE pattern_b; +BEGIN +OPEN c((SELECT 'aaa'),(SELECT 'bbb'),(SELECT a_a),(SELECT a_b)); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT v_a, v_b; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('%','%'); +v_a v_b +aaa bbb +v_a v_b +bbb aaa +CALL p1('aaa','xxx'); +v_a v_b +aaa bbb +CALL p1('xxx','bbb'); +v_a v_b +bbb aaa +CALL p1('xxx','xxx'); +DROP PROCEDURE p1; +# +# Parameters in SELECT list + stored function +# +CREATE FUNCTION f1 (a VARCHAR) RETURN VARCHAR +AS +BEGIN +RETURN a || 'y'; +END; +$$ +CREATE PROCEDURE p1(a_a VARCHAR) +AS +v_a VARCHAR(10); +v_b VARCHAR(10); +CURSOR c (p_sel_a VARCHAR, p_cmp_a VARCHAR) IS +SELECT p_sel_a, p_cmp_a FROM DUAL; +BEGIN +OPEN c(f1(a_a), f1(a_a)); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +SELECT v_a; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('x'); +v_a +xy +CALL p1(f1(COALESCE(NULL, f1('x')))); +v_a +xyyy +DROP PROCEDURE p1; +DROP FUNCTION f1; +# +# One parameter in WHERE clause +# +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE TABLE t2 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'11'); +INSERT INTO t1 VALUES (1,'12'); +INSERT INTO t1 VALUES (2,'21'); +INSERT INTO t1 VALUES (2,'22'); +INSERT INTO t1 VALUES (3,'31'); +INSERT INTO t1 VALUES (3,'32'); +CREATE PROCEDURE p1(a_a INT) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT) IS SELECT a,b FROM t1 WHERE a=p_a; +BEGIN +OPEN c(a_a); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +INSERT INTO t2 VALUES (v_a,v_b); +END LOOP; +CLOSE c; +END; +$$ +CALL p1(1); +SELECT * FROM t2; +a b +1 11 +1 12 +DROP TABLE t1; +DROP TABLE t2; +DROP PROCEDURE p1; +# +# Two parameters in WHERE clause +# +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE TABLE t2 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'11'); +INSERT INTO t1 VALUES (1,'12'); +INSERT INTO t1 VALUES (2,'21'); +INSERT INTO t1 VALUES (2,'22'); +INSERT INTO t1 VALUES (3,'31'); +INSERT INTO t1 VALUES (3,'32'); +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT, p_b VARCHAR) IS SELECT a,b FROM t1 WHERE a=p_a AND b=p_b; +BEGIN +OPEN c(a_a, a_b); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +INSERT INTO t2 VALUES (v_a,v_b); +END LOOP; +CLOSE c; +END; +$$ +CALL p1(1,'11'); +SELECT * FROM t2; +a b +1 11 +DROP TABLE t1; +DROP TABLE t2; +DROP PROCEDURE p1; +# +# Parameters in WHERE and HAVING clauses +# +CREATE TABLE t1 (name VARCHAR(10), value INT); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('bin',1); +INSERT INTO t1 VALUES ('bin',1); +INSERT INTO t1 VALUES ('bot',1); +CREATE PROCEDURE p1 (arg_name_limit VARCHAR, arg_total_limit INT) +AS +v_name VARCHAR(10); +v_total INT; +-- +0 is needed to work around the bug MDEV-11081 +CURSOR c(p_v INT) IS +SELECT name, SUM(value + p_v) + 0 AS total FROM t1 +WHERE name LIKE arg_name_limit +GROUP BY name HAVING total>=arg_total_limit; +BEGIN +FOR i IN 0..1 +LOOP +OPEN c(i); +LOOP +FETCH c INTO v_name, v_total; +EXIT WHEN c%NOTFOUND; +SELECT v_name, v_total; +END LOOP; +CLOSE c; +END LOOP; +END; +$$ +CALL p1('%', 2); +v_name v_total +bin 2 +v_name v_total +but 3 +v_name v_total +bin 4 +v_name v_total +bot 2 +v_name v_total +but 6 +CALL p1('b_t', 0); +v_name v_total +bot 1 +v_name v_total +but 3 +v_name v_total +bot 2 +v_name v_total +but 6 +DROP PROCEDURE p1; +DROP TABLE t1; +# +# One parameter in LIMIT clause +# +CREATE TABLE t1 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'b1'); +INSERT INTO t1 VALUES (2,'b2'); +INSERT INTO t1 VALUES (3,'b3'); +INSERT INTO t1 VALUES (4,'b4'); +INSERT INTO t1 VALUES (5,'b5'); +INSERT INTO t1 VALUES (6,'b6'); +CREATE PROCEDURE p1(a_a INT) +AS +v_a INT; +v_b VARCHAR(10); +CURSOR c (p_a INT) IS SELECT a,b FROM t1 ORDER BY a LIMIT p_a; +BEGIN +CREATE TABLE t2 (a INT, b VARCHAR(10)); +OPEN c(a_a); +LOOP +FETCH c INTO v_a, v_b; +EXIT WHEN c%NOTFOUND; +INSERT INTO t2 VALUES (v_a,v_b); +END LOOP; +CLOSE c; +SELECT * FROM t2; +DROP TABLE t2; +END; +$$ +CALL p1(1); +a b +1 b1 +CALL p1(3); +a b +1 b1 +2 b2 +3 b3 +CALL p1(6); +a b +1 b1 +2 b2 +3 b3 +4 b4 +5 b5 +6 b6 +DROP TABLE t1; +DROP PROCEDURE p1; +# +# End of MDEV-10597 Cursors with parameters +# diff --git a/mysql-test/suite/compat/oracle/t/sp-code.test b/mysql-test/suite/compat/oracle/t/sp-code.test index 5dacd9cb48314..637251af96c15 100644 --- a/mysql-test/suite/compat/oracle/t/sp-code.test +++ b/mysql-test/suite/compat/oracle/t/sp-code.test @@ -615,3 +615,45 @@ SHOW FUNCTION CODE f1; SELECT f1(3), f1(4), f1(5), f1(6) FROM DUAL; DROP FUNCTION f1; +--echo # +--echo # Start of MDEV-10597 Cursors with parameters +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(arg_value_a VARCHAR, arg_value_b VARCHAR, + arg_pattern_a VARCHAR, arg_pattern_b VARCHAR) +AS + v_a VARCHAR(10); + v_b VARCHAR(20); + CURSOR c (p_value_a VARCHAR, + p_value_b VARCHAR, + p_pattern_a VARCHAR, + p_pattern_b VARCHAR, + p_limit_a INT, + p_limit_b INT, + p_unused TEXT) IS + (SELECT p_value_a, p_value_b FROM DUAL + WHERE p_value_a LIKE p_pattern_a LIMIT p_limit_a) + UNION + (SELECT p_value_b, p_value_a FROM DUAL + WHERE p_value_b LIKE p_pattern_b LIMIT p_limit_b); +BEGIN + OPEN c(arg_value_a, (SELECT arg_value_b), + arg_pattern_a, arg_pattern_b, 100, 101, 'x'); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT v_a, v_b; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('aaa','bbb','aaa','bbb'); +SHOW PROCEDURE CODE p1; +DROP PROCEDURE p1; + + +--echo # +--echo # End of MDEV-10597 Cursors with parameters +--echo # diff --git a/mysql-test/suite/compat/oracle/t/sp-cursor.test b/mysql-test/suite/compat/oracle/t/sp-cursor.test index e69ae5d85a8a9..53852bd09ad21 100644 --- a/mysql-test/suite/compat/oracle/t/sp-cursor.test +++ b/mysql-test/suite/compat/oracle/t/sp-cursor.test @@ -294,3 +294,459 @@ DELIMITER ;$$ CALL p1(); DROP PROCEDURE p1; DROP TABLE t1; + +--echo # +--echo # End of MDEV-10582 sql_mode=ORACLE: explicit cursor attributes %ISOPEN, %ROWCOUNT, %FOUND, %NOTFOUND +--echo # + +--echo # +--echo # MDEV-10597 Cursors with parameters +--echo # + +--echo # +--echo # OPEN with a wrong number of parameters +--echo # + +CREATE TABLE t1 (a INT, b VARCHAR(10)); +DELIMITER $$; +--error ER_WRONG_PARAMCOUNT_TO_CURSOR +CREATE PROCEDURE p1(a_a INT,a_b VARCHAR) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT, p_b VARCHAR) IS SELECT * FROM t1 WHERE a=p_a; +BEGIN + OPEN c(a_a); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + DBMS_OUTPUT.PUT_LINE('Fetched a record a='||TO_CHAR(v_a)||' b='||v_b); + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +DROP TABLE t1; + + +--echo # +--echo # Cursor parameters are not visible outside of the cursor +--echo # + +DELIMITER $$; +--error ER_UNKNOWN_SYSTEM_VARIABLE +CREATE PROCEDURE p1(a_a INT) +AS + v_a INT; + CURSOR c (p_a INT) IS SELECT a FROM t1 WHERE a=p_a; +BEGIN + OPEN c(a_a); + p_a:=10; +END; +$$ +DELIMITER ;$$ + +DELIMITER $$; +--error ER_UNKNOWN_SYSTEM_VARIABLE +CREATE PROCEDURE p1(a_a INT) +AS + v_a INT; + CURSOR c (p_a INT) IS SELECT a FROM t1 WHERE a=p_a; +BEGIN + p_a:=10; + OPEN c(a_a); +END; +$$ +DELIMITER ;$$ + + +--echo # +--echo # Cursor parameter shadowing a local variable +--echo # + +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1); +DELIMITER $$; +CREATE PROCEDURE p1(a INT) +AS + v_a INT:=NULL; + p_a INT:=NULL; + CURSOR c (p_a VARCHAR2) IS SELECT a FROM t1 WHERE p_a IS NOT NULL; +BEGIN + OPEN c(a); + FETCH c INTO v_a; + IF c%NOTFOUND THEN + BEGIN + SELECT 'No records found' AS msg; + RETURN; + END; + END IF; + CLOSE c; + SELECT 'Fetched a record a='||v_a AS msg; + INSERT INTO t1 VALUES (v_a); +END; +$$ +DELIMITER ;$$ +CALL p1(1); +SELECT * FROM t1; +CALL p1(NULL); +SELECT * FROM t1; +DROP PROCEDURE p1; +DROP TABLE t1; + + +--echo # +--echo # Parameters in SELECT list +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT, p_b VARCHAR) IS SELECT p_a,p_b FROM DUAL; +BEGIN + FOR i IN 0..1 + LOOP + OPEN c(a_a + i,a_b); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT 'Fetched a record a=' || v_a || ' b=' || v_b AS msg; + END LOOP; + CLOSE c; + END LOOP; +END; +$$ +DELIMITER ;$$ +CALL p1(1,'b1'); +DROP PROCEDURE p1; + + +--echo # +--echo # Parameters in SELECT list + UNION +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT, p_b VARCHAR) IS + SELECT p_a,p_b FROM DUAL + UNION ALL + SELECT p_a+1,p_b||'b' FROM DUAL; +BEGIN + OPEN c(a_a,a_b); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT 'Fetched a record a=' || v_a || ' b=' || v_b AS msg; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(1,'b1'); +DROP PROCEDURE p1; + + +--echo # +--echo # Parameters in SELECT list + type conversion + warnings +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR) +AS + v_a INT; + CURSOR c (p_a INT) IS SELECT p_a FROM DUAL; +BEGIN + OPEN c(a_a); + LOOP + FETCH c INTO v_a; + EXIT WHEN c%NOTFOUND; + SELECT 'Fetched a record a=' || v_a AS msg; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('1b'); +CALL p1('b1'); +DROP PROCEDURE p1; + + +--echo # +--echo # One parameter in SELECT list + subselect +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR) +AS + v_a VARCHAR(10); + CURSOR c (p_a VARCHAR) IS + SELECT p_a FROM DUAL UNION SELECT REVERSE(p_a) FROM DUAL; +BEGIN + OPEN c((SELECT a_a)); + LOOP + FETCH c INTO v_a; + EXIT WHEN c%NOTFOUND; + SELECT v_a; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('ab'); +DROP PROCEDURE p1; + + +--echo # +--echo # Two parameters in SELECT list + subselect +--echo # + +SET sql_mode=ORACLE; +DELIMITER $$; +CREATE PROCEDURE p1() +AS + v_a VARCHAR(10); + v_b VARCHAR(20); + CURSOR c (p_a VARCHAR, p_b VARCHAR) IS + SELECT p_a, p_b FROM DUAL + UNION + SELECT p_b, p_a FROM DUAL; +BEGIN + OPEN c((SELECT 'aaa'),(SELECT 'bbb')); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT v_a, v_b; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(); +DROP PROCEDURE p1; + + +--echo # +--echo # Two parameters in SELECT list + two parameters in WHERE + subselects +--echo # + +SET sql_mode=ORACLE; +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR, a_b VARCHAR) +AS + v_a VARCHAR(10); + v_b VARCHAR(20); + CURSOR c (value_a VARCHAR, value_b VARCHAR, + pattern_a VARCHAR, pattern_b VARCHAR) IS + SELECT value_a, value_b FROM DUAL WHERE value_a LIKE pattern_a + UNION + SELECT value_b, value_a FROM DUAL WHERE value_b LIKE pattern_b; +BEGIN + OPEN c((SELECT 'aaa'),(SELECT 'bbb'),(SELECT a_a),(SELECT a_b)); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT v_a, v_b; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('%','%'); +CALL p1('aaa','xxx'); +CALL p1('xxx','bbb'); +CALL p1('xxx','xxx'); +DROP PROCEDURE p1; + + +--echo # +--echo # Parameters in SELECT list + stored function +--echo # + +DELIMITER $$; +CREATE FUNCTION f1 (a VARCHAR) RETURN VARCHAR +AS +BEGIN + RETURN a || 'y'; +END; +$$ +CREATE PROCEDURE p1(a_a VARCHAR) +AS + v_a VARCHAR(10); + v_b VARCHAR(10); + CURSOR c (p_sel_a VARCHAR, p_cmp_a VARCHAR) IS + SELECT p_sel_a, p_cmp_a FROM DUAL; +BEGIN + OPEN c(f1(a_a), f1(a_a)); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + SELECT v_a; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('x'); +# A complex expression +CALL p1(f1(COALESCE(NULL, f1('x')))); +DROP PROCEDURE p1; +DROP FUNCTION f1; + + +--echo # +--echo # One parameter in WHERE clause +--echo # + +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE TABLE t2 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'11'); +INSERT INTO t1 VALUES (1,'12'); +INSERT INTO t1 VALUES (2,'21'); +INSERT INTO t1 VALUES (2,'22'); +INSERT INTO t1 VALUES (3,'31'); +INSERT INTO t1 VALUES (3,'32'); +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT) IS SELECT a,b FROM t1 WHERE a=p_a; +BEGIN + OPEN c(a_a); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + INSERT INTO t2 VALUES (v_a,v_b); + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(1); +SELECT * FROM t2; +DROP TABLE t1; +DROP TABLE t2; +DROP PROCEDURE p1; + + +--echo # +--echo # Two parameters in WHERE clause +--echo # + +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE TABLE t2 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'11'); +INSERT INTO t1 VALUES (1,'12'); +INSERT INTO t1 VALUES (2,'21'); +INSERT INTO t1 VALUES (2,'22'); +INSERT INTO t1 VALUES (3,'31'); +INSERT INTO t1 VALUES (3,'32'); +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT, p_b VARCHAR) IS SELECT a,b FROM t1 WHERE a=p_a AND b=p_b; +BEGIN + OPEN c(a_a, a_b); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + INSERT INTO t2 VALUES (v_a,v_b); + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(1,'11'); +SELECT * FROM t2; +DROP TABLE t1; +DROP TABLE t2; +DROP PROCEDURE p1; + +--echo # +--echo # Parameters in WHERE and HAVING clauses +--echo # +CREATE TABLE t1 (name VARCHAR(10), value INT); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('but',1); +INSERT INTO t1 VALUES ('bin',1); +INSERT INTO t1 VALUES ('bin',1); +INSERT INTO t1 VALUES ('bot',1); +DELIMITER $$; +CREATE PROCEDURE p1 (arg_name_limit VARCHAR, arg_total_limit INT) +AS + v_name VARCHAR(10); + v_total INT; +-- +0 is needed to work around the bug MDEV-11081 + CURSOR c(p_v INT) IS + SELECT name, SUM(value + p_v) + 0 AS total FROM t1 + WHERE name LIKE arg_name_limit + GROUP BY name HAVING total>=arg_total_limit; +BEGIN + FOR i IN 0..1 + LOOP + OPEN c(i); + LOOP + FETCH c INTO v_name, v_total; + EXIT WHEN c%NOTFOUND; + SELECT v_name, v_total; + END LOOP; + CLOSE c; + END LOOP; +END; +$$ +DELIMITER ;$$ +CALL p1('%', 2); +CALL p1('b_t', 0); +DROP PROCEDURE p1; +DROP TABLE t1; + + +--echo # +--echo # One parameter in LIMIT clause +--echo # + +CREATE TABLE t1 (a INT, b VARCHAR(10)); +INSERT INTO t1 VALUES (1,'b1'); +INSERT INTO t1 VALUES (2,'b2'); +INSERT INTO t1 VALUES (3,'b3'); +INSERT INTO t1 VALUES (4,'b4'); +INSERT INTO t1 VALUES (5,'b5'); +INSERT INTO t1 VALUES (6,'b6'); +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT) +AS + v_a INT; + v_b VARCHAR(10); + CURSOR c (p_a INT) IS SELECT a,b FROM t1 ORDER BY a LIMIT p_a; +BEGIN + CREATE TABLE t2 (a INT, b VARCHAR(10)); + OPEN c(a_a); + LOOP + FETCH c INTO v_a, v_b; + EXIT WHEN c%NOTFOUND; + INSERT INTO t2 VALUES (v_a,v_b); + END LOOP; + CLOSE c; + SELECT * FROM t2; + DROP TABLE t2; +END; +$$ +DELIMITER ;$$ +CALL p1(1); +CALL p1(3); +CALL p1(6); +DROP TABLE t1; +DROP PROCEDURE p1; + + +--echo # +--echo # End of MDEV-10597 Cursors with parameters +--echo # diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index b2ac422862c56..3f4299e216694 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7457,3 +7457,6 @@ ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION eng "Illegal parameter data types %s and %s for operation '%s'" ER_ILLEGAL_PARAMETER_DATA_TYPE_FOR_OPERATION eng "Illegal parameter data type %s for operation '%s'" +ER_WRONG_PARAMCOUNT_TO_CURSOR 42000 + eng "Incorrect parameter count to cursor '%-.192s'" + rus "Некорректное количество параметров для курсора '%-.192s'" diff --git a/sql/sp_head.cc b/sql/sp_head.cc index 05ef6f02063dd..d63b5700a28da 100644 --- a/sql/sp_head.cc +++ b/sql/sp_head.cc @@ -2066,29 +2066,15 @@ bool sp_head::reset_lex(THD *thd) { DBUG_ENTER("sp_head::reset_lex"); - LEX *sublex; LEX *oldlex= thd->lex; - sublex= new (thd->mem_root)st_lex_local; + sp_lex_local *sublex= new (thd->mem_root) sp_lex_local(thd, oldlex); if (sublex == 0) DBUG_RETURN(TRUE); - thd->lex= sublex; - (void)m_lex.push_front(oldlex); - - /* Reset most stuff. */ - lex_start(thd); - - /* And keep the SP stuff too */ - sublex->sphead= oldlex->sphead; - sublex->spcont= oldlex->spcont; - /* And trigger related stuff too */ - sublex->trg_chistics= oldlex->trg_chistics; - sublex->trg_table_fields.empty(); - sublex->sp_lex_in_use= FALSE; + thd->set_local_lex(sublex); - /* Reset part of parser state which needs this. */ - thd->m_parser_state->m_yacc.reset_before_substatement(); + (void)m_lex.push_front(oldlex); DBUG_RETURN(FALSE); } @@ -2098,6 +2084,8 @@ sp_head::reset_lex(THD *thd) Restore lex during parsing, after we have parsed a sub statement. @param thd Thread handle + @param oldlex The upper level lex we're near to restore to + @param sublex The local lex we're near to restore from @return @retval TRUE failure @@ -2105,23 +2093,17 @@ sp_head::reset_lex(THD *thd) */ bool -sp_head::restore_lex(THD *thd) +sp_head::merge_lex(THD *thd, LEX *oldlex, LEX *sublex) { - DBUG_ENTER("sp_head::restore_lex"); - LEX *sublex= thd->lex; - LEX *oldlex; + DBUG_ENTER("sp_head::merge_lex"); sublex->set_trg_event_type_for_tables(); - oldlex= (LEX *)m_lex.pop(); - if (! oldlex) - DBUG_RETURN(FALSE); // Nothing to restore - oldlex->trg_table_fields.push_back(&sublex->trg_table_fields); /* If this substatement is unsafe, the entire routine is too. */ - DBUG_PRINT("info", ("lex->get_stmt_unsafe_flags: 0x%x", - thd->lex->get_stmt_unsafe_flags())); + DBUG_PRINT("info", ("sublex->get_stmt_unsafe_flags: 0x%x", + sublex->get_stmt_unsafe_flags())); unsafe_flags|= sublex->get_stmt_unsafe_flags(); /* @@ -2143,13 +2125,6 @@ sp_head::restore_lex(THD *thd) /* Merge lists of PS parameters. */ oldlex->param_list.append(&sublex->param_list); - if (! sublex->sp_lex_in_use) - { - sublex->sphead= NULL; - lex_end(sublex); - delete sublex; - } - thd->lex= oldlex; DBUG_RETURN(FALSE); } @@ -4197,3 +4172,59 @@ sp_add_to_query_tables(THD *thd, LEX *lex, return table; } + +/** + Helper action for a SET statement. + Used to push a SP local variable into the assignment list. + + @param var_type the SP local variable + @param val the value being assigned to the variable + + @return TRUE if error, FALSE otherwise. +*/ + +bool +sp_head::set_local_variable(THD *thd, sp_pcontext *spcont, + sp_variable *spv, Item *val, LEX *lex) +{ + Item *it; + + if (val) + it= val; + else if (spv->default_value) + it= spv->default_value; + else + { + it= new (thd->mem_root) Item_null(thd); + if (it == NULL) + return TRUE; + } + + sp_instr_set *sp_set= new (thd->mem_root) + sp_instr_set(instructions(), spcont, + spv->offset, it, spv->sql_type(), + lex, true); + + return sp_set == NULL || add_instr(sp_set); +} + + +bool sp_head::add_open_cursor(THD *thd, sp_pcontext *spcont, uint offset, + sp_pcontext *param_spcont, + List *parameters) +{ + /* + The caller must make sure that the number of formal parameters matches + the number of actual parameters. + */ + DBUG_ASSERT((param_spcont ? param_spcont->context_var_count() : 0) == + (parameters ? parameters->elements : 0)); + + if (parameters && + add_set_cursor_param_variables(thd, param_spcont, parameters)) + return true; + + sp_instr_copen *i= new (thd->mem_root) + sp_instr_copen(instructions(), spcont, offset); + return i == NULL || add_instr(i); +} diff --git a/sql/sp_head.h b/sql/sp_head.h index fe83c27c76915..cdf2dd94f3a8b 100644 --- a/sql/sp_head.h +++ b/sql/sp_head.h @@ -353,6 +353,85 @@ class sp_head :private Query_arena, spcont->last_label()); } + bool set_local_variable(THD *thd, sp_pcontext *spcont, + sp_variable *spv, Item *val, LEX *lex); + +private: + /** + Generate a code to set a single cursor parameter variable. + @param thd - current thd, for mem_root allocations. + @param param_spcont - the context of the parameter block + @param idx - the index of the parameter + @param prm - the actual parameter (contains information about + the assignment source expression Item, + its free list, and its LEX) + */ + bool add_set_cursor_param_variable(THD *thd, + sp_pcontext *param_spcont, uint idx, + sp_assignment_lex *prm) + { + DBUG_ASSERT(idx < param_spcont->context_var_count()); + sp_variable *spvar= param_spcont->find_context_variable(idx); + /* + add_instr() gets free_list from m_thd->free_list. + Initialize it before the set_local_variable() call. + */ + DBUG_ASSERT(m_thd->free_list == NULL); + m_thd->free_list= prm->get_free_list(); + if (set_local_variable(thd, param_spcont, spvar, prm->get_item(), prm)) + return true; + /* + Safety: + The item and its free_list are now fully owned by the sp_instr_set + instance, created by set_local_variable(). The sp_instr_set instance + is now responsible for freeing the item and the free_list. + Reset the "item" and the "free_list" members of "prm", + to avoid double pointers to the same objects from "prm" and + from the sp_instr_set instance. + */ + prm->set_item_and_free_list(NULL, NULL); + return false; + } + + /** + Generate a code to set all cursor parameter variables. + This method is called only when parameters exists, + and the number of formal parameters matches the number of actual + parameters. See also comments to add_open_cursor(). + */ + bool add_set_cursor_param_variables(THD *thd, sp_pcontext *param_spcont, + List *parameters) + { + DBUG_ASSERT(param_spcont->context_var_count() == parameters->elements); + sp_assignment_lex *prm; + List_iterator li(*parameters); + for (uint idx= 0; (prm= li++); idx++) + { + if (add_set_cursor_param_variable(thd, param_spcont, idx, prm)) + return true; + } + return false; + } + + +public: + /** + Generate a code for an "OPEN cursor" statement. + @param thd - current thd, for mem_root allocations + @param spcont - the context of the cursor + @param offset - the offset of the cursor + @param param_spcont - the context of the cursor parameter block + @param parameters - the list of the OPEN actual parameters + + The caller must make sure that the number of local variables + in "param_spcont" (formal parameters) matches the number of list elements + in "parameters" (actual parameters). + NULL in either of them means 0 parameters. + */ + bool add_open_cursor(THD *thd, sp_pcontext *spcont, + uint offset, + sp_pcontext *param_spcont, + List *parameters); /** Returns true if any substatement in the routine directly @@ -385,6 +464,20 @@ class sp_head :private Query_arena, bool reset_lex(THD *thd); + /** + Merge two LEX instances. + @param oldlex - the upper level LEX we're going to restore to. + @param sublex - the local lex that have just parsed some substatement. + @returns - false on success, true on error (e.g. failed to + merge the routine list or the table list). + This method is shared by: + - restore_lex(), when the old LEX is popped by sp_head::m_lex.pop() + - THD::restore_from_local_lex_to_old_lex(), when the old LEX + is stored in the caller's local variable. + */ + bool + merge_lex(THD *thd, LEX *oldlex, LEX *sublex); + /** Restores lex in 'thd' from our copy, but keeps some status from the one in 'thd', like ptr, tables, fields, etc. @@ -392,7 +485,23 @@ class sp_head :private Query_arena, @todo Conflicting comment in sp_head.cc */ bool - restore_lex(THD *thd); + restore_lex(THD *thd) + { + DBUG_ENTER("sp_head::restore_lex"); + LEX *oldlex= (LEX *) m_lex.pop(); + if (!oldlex) + DBUG_RETURN(false); // Nothing to restore + LEX *sublex= thd->lex; + if (thd->restore_from_local_lex_to_old_lex(oldlex))// This restores thd->lex + DBUG_RETURN(true); + if (!sublex->sp_lex_in_use) + { + sublex->sphead= NULL; + lex_end(sublex); + delete sublex; + } + DBUG_RETURN(false); + } /// Put the instruction on the backpatch list, associated with the label. int diff --git a/sql/sp_pcontext.cc b/sql/sp_pcontext.cc index 047d0f50aaa05..fb162501ebc11 100644 --- a/sql/sp_pcontext.cc +++ b/sql/sp_pcontext.cc @@ -498,18 +498,18 @@ sp_pcontext::find_handler(const Sql_condition_identity &value) const } -bool sp_pcontext::add_cursor(const LEX_STRING name) +bool sp_pcontext::add_cursor(const LEX_STRING name, sp_pcontext *param_ctx) { if (m_cursors.elements() == m_max_cursor_index) ++m_max_cursor_index; - return m_cursors.append(name); + return m_cursors.append(sp_pcursor(name, param_ctx)); } -bool sp_pcontext::find_cursor(const LEX_STRING name, - uint *poff, - bool current_scope_only) const +const sp_pcursor *sp_pcontext::find_cursor(const LEX_STRING name, + uint *poff, + bool current_scope_only) const { uint i= m_cursors.elements(); @@ -522,13 +522,13 @@ bool sp_pcontext::find_cursor(const LEX_STRING name, (const uchar *) n.str, n.length) == 0) { *poff= m_cursor_offset + i; - return true; + return &m_cursors.at(i); } } return (!current_scope_only && m_parent) ? m_parent->find_cursor(name, poff, false) : - false; + NULL; } @@ -551,7 +551,7 @@ void sp_pcontext::retrieve_field_definitions( } -const LEX_STRING *sp_pcontext::find_cursor(uint offset) const +const sp_pcursor *sp_pcontext::find_cursor(uint offset) const { if (m_cursor_offset <= offset && offset < m_cursor_offset + m_cursors.elements()) diff --git a/sql/sp_pcontext.h b/sql/sp_pcontext.h index f30596cc02b29..33a7bffca7c89 100644 --- a/sql/sp_pcontext.h +++ b/sql/sp_pcontext.h @@ -247,6 +247,36 @@ class sp_condition : public Sql_alloc } }; + +/////////////////////////////////////////////////////////////////////////// + +/** + class sp_pcursor. + Stores information about a cursor: + - Cursor's name in LEX_STRING. + - Cursor's formal parameter descriptions. + + Formal parameter descriptions reside in a separate context block, + pointed by the "m_param_context" member. + + m_param_context can be NULL. This means a cursor with no parameters. + Otherwise, the number of variables in m_param_context means + the number of cursor's formal parameters. + + Note, m_param_context can be not NULL, but have no variables. + This is also means a cursor with no parameters (similar to NULL). +*/ +class sp_pcursor: public LEX_STRING +{ + class sp_pcontext *m_param_context; // Formal parameters +public: + sp_pcursor(const LEX_STRING &name, class sp_pcontext *param_ctx) + :LEX_STRING(name), m_param_context(param_ctx) + { } + class sp_pcontext *param_context() const { return m_param_context; } +}; + + /////////////////////////////////////////////////////////////////////////// /// This class represents 'DECLARE HANDLER' statement. @@ -383,6 +413,13 @@ class sp_pcontext : public Sql_alloc uint context_var_count() const { return m_vars.elements(); } + /// return the i-th variable on the current context + sp_variable *find_context_variable(uint i) const + { + DBUG_ASSERT(i < m_vars.elements()); + return m_vars.at(i); + } + /// @return map index in this parsing context to runtime offset. uint var_context2runtime(uint i) const { return m_var_offset + i; } @@ -558,14 +595,14 @@ class sp_pcontext : public Sql_alloc // Cursors. ///////////////////////////////////////////////////////////////////////// - bool add_cursor(const LEX_STRING name); + bool add_cursor(const LEX_STRING name, sp_pcontext *param_ctx); /// See comment for find_variable() above. - bool find_cursor(const LEX_STRING name, - uint *poff, bool current_scope_only) const; + const sp_pcursor *find_cursor(const LEX_STRING name, + uint *poff, bool current_scope_only) const; - /// Find cursor by offset (for debugging only). - const LEX_STRING *find_cursor(uint offset) const; + /// Find cursor by offset (for SHOW {PROCEDURE|FUNCTION} CODE only). + const sp_pcursor *find_cursor(uint offset) const; uint max_cursor_index() const { return m_max_cursor_index + m_cursors.elements(); } @@ -641,7 +678,7 @@ class sp_pcontext : public Sql_alloc Dynamic_array m_conditions; /// Stack of cursors. - Dynamic_array m_cursors; + Dynamic_array m_cursors; /// Stack of SQL-handlers. Dynamic_array m_handlers; diff --git a/sql/sql_class.cc b/sql/sql_class.cc index 25052e84e9698..65a4dabb85bc7 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -55,6 +55,7 @@ #include #include +#include "sp_head.h" #include "sp_rcontext.h" #include "sp_cache.h" #include "transaction.h" @@ -1323,7 +1324,17 @@ void THD::init(void) DBUG_VOID_RETURN; } - + +bool THD::restore_from_local_lex_to_old_lex(LEX *oldlex) +{ + DBUG_ASSERT(lex->sphead); + if (lex->sphead->merge_lex(this, oldlex, lex)) + return true; + lex= oldlex; + return false; +} + + /* Updates some status variables to be used by update_global_user_stats */ void THD::update_stats(void) diff --git a/sql/sql_class.h b/sql/sql_class.h index 86cb6036be3cb..1b8d8ff0b378c 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -4358,6 +4358,31 @@ class THD :public Statement, current_linfo= 0; mysql_mutex_unlock(&LOCK_thread_count); } + + /** + Switch to a sublex, to parse a substatement or an expression. + */ + void set_local_lex(sp_lex_local *sublex) + { + DBUG_ASSERT(lex->sphead); + lex= sublex; + /* Reset part of parser state which needs this. */ + m_parser_state->m_yacc.reset_before_substatement(); + } + + /** + Switch back from a sublex (currently pointed by this->lex) to the old lex. + Sublex is merged to "oldlex" and this->lex is set to "oldlex". + + This method is called after parsing a substatement or an expression. + set_local_lex() must be previously called. + @param oldlex - The old lex which was active before set_local_lex(). + @returns - false on success, true on error (failed to merge LEX's). + + See also sp_head::merge_lex(). + */ + bool restore_from_local_lex_to_old_lex(LEX *oldlex); + }; inline void add_to_active_threads(THD *thd) diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 08e1920a4887e..3a34ca9e64e27 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -652,116 +652,121 @@ void Lex_input_stream::reduce_digest_token(uint token_left, uint token_right) } } +void lex_start(THD *thd) +{ + DBUG_ENTER("lex_start"); + thd->lex->start(thd); + DBUG_VOID_RETURN; +} + + /* This is called before every query that is to be parsed. Because of this, it's critical to not do too much things here. (We already do too much here) */ -void lex_start(THD *thd) +void LEX::start(THD *thd_arg) { - LEX *lex= thd->lex; - DBUG_ENTER("lex_start"); + DBUG_ENTER("LEX::start"); - lex->thd= lex->unit.thd= thd; + thd= unit.thd= thd_arg; - DBUG_ASSERT(!lex->explain); + DBUG_ASSERT(!explain); - lex->context_stack.empty(); - lex->unit.init_query(); - lex->unit.init_select(); - lex->select_lex.linkage= UNSPECIFIED_TYPE; + context_stack.empty(); + unit.init_query(); + unit.init_select(); + select_lex.linkage= UNSPECIFIED_TYPE; /* 'parent_lex' is used in init_query() so it must be before it. */ - lex->select_lex.parent_lex= lex; - lex->select_lex.init_query(); - lex->curr_with_clause= 0; - lex->with_clauses_list= 0; - lex->with_clauses_list_last_next= &lex->with_clauses_list; - lex->value_list.empty(); - lex->update_list.empty(); - lex->set_var_list.empty(); - lex->param_list.empty(); - lex->view_list.empty(); - lex->with_column_list.empty(); - lex->with_persistent_for_clause= FALSE; - lex->column_list= NULL; - lex->index_list= NULL; - lex->prepared_stmt_params.empty(); - lex->auxiliary_table_list.empty(); - lex->unit.next= lex->unit.master= - lex->unit.link_next= lex->unit.return_to= 0; - lex->unit.prev= lex->unit.link_prev= 0; - lex->unit.slave= lex->current_select= - lex->all_selects_list= &lex->select_lex; - lex->select_lex.master= &lex->unit; - lex->select_lex.prev= &lex->unit.slave; - lex->select_lex.link_next= lex->select_lex.slave= lex->select_lex.next= 0; - lex->select_lex.link_prev= (st_select_lex_node**)&(lex->all_selects_list); - lex->select_lex.options= 0; - lex->select_lex.sql_cache= SELECT_LEX::SQL_CACHE_UNSPECIFIED; - lex->select_lex.init_order(); - lex->select_lex.group_list.empty(); - if (lex->select_lex.group_list_ptrs) - lex->select_lex.group_list_ptrs->clear(); - lex->describe= 0; - lex->analyze_stmt= 0; - lex->explain_json= false; - lex->subqueries= FALSE; - lex->context_analysis_only= 0; - lex->derived_tables= 0; - lex->safe_to_cache_query= 1; - lex->parsing_options.reset(); - lex->empty_field_list_on_rset= 0; - lex->select_lex.select_number= 1; - lex->part_info= 0; - lex->select_lex.in_sum_expr=0; - lex->select_lex.ftfunc_list_alloc.empty(); - lex->select_lex.ftfunc_list= &lex->select_lex.ftfunc_list_alloc; - lex->select_lex.group_list.empty(); - lex->select_lex.order_list.empty(); - lex->select_lex.gorder_list.empty(); - lex->m_sql_cmd= NULL; - lex->duplicates= DUP_ERROR; - lex->ignore= 0; - lex->spname= NULL; - lex->spcont= NULL; - lex->proc_list.first= 0; - lex->escape_used= FALSE; - lex->query_tables= 0; - lex->reset_query_tables_list(FALSE); - lex->expr_allows_subselect= TRUE; - lex->use_only_table_context= FALSE; - lex->parse_vcol_expr= FALSE; - lex->check_exists= FALSE; - lex->create_info.lex_start(); - lex->verbose= 0; - - lex->name= null_lex_str; - lex->event_parse_data= NULL; - lex->profile_options= PROFILE_NONE; - lex->nest_level=0 ; - lex->select_lex.nest_level_base= &lex->unit; - lex->allow_sum_func= 0; - lex->in_sum_func= NULL; - - lex->used_tables= 0; - lex->only_view= FALSE; - lex->reset_slave_info.all= false; - lex->limit_rows_examined= 0; - lex->limit_rows_examined_cnt= ULONGLONG_MAX; - lex->var_list.empty(); - lex->stmt_var_list.empty(); - lex->proc_list.elements=0; - - lex->save_group_list.empty(); - lex->save_order_list.empty(); - lex->win_ref= NULL; - lex->win_frame= NULL; - lex->frame_top_bound= NULL; - lex->frame_bottom_bound= NULL; - lex->win_spec= NULL; - - lex->is_lex_started= TRUE; + select_lex.parent_lex= this; + select_lex.init_query(); + curr_with_clause= 0; + with_clauses_list= 0; + with_clauses_list_last_next= &with_clauses_list; + value_list.empty(); + update_list.empty(); + set_var_list.empty(); + param_list.empty(); + view_list.empty(); + with_column_list.empty(); + with_persistent_for_clause= FALSE; + column_list= NULL; + index_list= NULL; + prepared_stmt_params.empty(); + auxiliary_table_list.empty(); + unit.next= unit.master= unit.link_next= unit.return_to= 0; + unit.prev= unit.link_prev= 0; + unit.slave= current_select= all_selects_list= &select_lex; + select_lex.master= &unit; + select_lex.prev= &unit.slave; + select_lex.link_next= select_lex.slave= select_lex.next= 0; + select_lex.link_prev= (st_select_lex_node**)&(all_selects_list); + select_lex.options= 0; + select_lex.sql_cache= SELECT_LEX::SQL_CACHE_UNSPECIFIED; + select_lex.init_order(); + select_lex.group_list.empty(); + if (select_lex.group_list_ptrs) + select_lex.group_list_ptrs->clear(); + describe= 0; + analyze_stmt= 0; + explain_json= false; + subqueries= FALSE; + context_analysis_only= 0; + derived_tables= 0; + safe_to_cache_query= 1; + parsing_options.reset(); + empty_field_list_on_rset= 0; + select_lex.select_number= 1; + part_info= 0; + select_lex.in_sum_expr=0; + select_lex.ftfunc_list_alloc.empty(); + select_lex.ftfunc_list= &select_lex.ftfunc_list_alloc; + select_lex.group_list.empty(); + select_lex.order_list.empty(); + select_lex.gorder_list.empty(); + m_sql_cmd= NULL; + duplicates= DUP_ERROR; + ignore= 0; + spname= NULL; + spcont= NULL; + proc_list.first= 0; + escape_used= FALSE; + query_tables= 0; + reset_query_tables_list(FALSE); + expr_allows_subselect= TRUE; + use_only_table_context= FALSE; + parse_vcol_expr= FALSE; + check_exists= FALSE; + create_info.lex_start(); + verbose= 0; + + name= null_lex_str; + event_parse_data= NULL; + profile_options= PROFILE_NONE; + nest_level=0 ; + select_lex.nest_level_base= &unit; + allow_sum_func= 0; + in_sum_func= NULL; + + used_tables= 0; + only_view= FALSE; + reset_slave_info.all= false; + limit_rows_examined= 0; + limit_rows_examined_cnt= ULONGLONG_MAX; + var_list.empty(); + stmt_var_list.empty(); + proc_list.elements=0; + + save_group_list.empty(); + save_order_list.empty(); + win_ref= NULL; + win_frame= NULL; + frame_top_bound= NULL; + frame_bottom_bound= NULL; + win_spec= NULL; + + is_lex_started= TRUE; DBUG_VOID_RETURN; } @@ -5355,7 +5360,8 @@ bool LEX::sp_for_loop_increment(THD *thd, const Lex_for_loop_st &loop) if (!inc) return true; Item *expr= new (thd->mem_root) Item_func_plus(thd, splocal, inc); - if (!expr || set_local_variable(loop.m_index, expr)) + if (!expr || + sphead->set_local_variable(thd, spcont, loop.m_index, expr, this)) return true; return false; } @@ -5379,7 +5385,8 @@ bool LEX::sp_for_loop_finalize(THD *thd, const Lex_for_loop_st &loop) /***************************************************************************/ -bool LEX::sp_declare_cursor(THD *thd, const LEX_STRING name, LEX *cursor_stmt) +bool LEX::sp_declare_cursor(THD *thd, const LEX_STRING name, LEX *cursor_stmt, + sp_pcontext *param_ctx) { uint offp; sp_instr_cpush *i; @@ -5392,7 +5399,38 @@ bool LEX::sp_declare_cursor(THD *thd, const LEX_STRING name, LEX *cursor_stmt) i= new (thd->mem_root) sp_instr_cpush(sphead->instructions(), spcont, cursor_stmt, spcont->current_cursor_count()); - return i == NULL || sphead->add_instr(i) || spcont->add_cursor(name); + return i == NULL || + sphead->add_instr(i) || + spcont->add_cursor(name, param_ctx); +} + + +/** + Generate an SP code for an "OPEN cursor_name" statement. + @param thd + @param name - Name of the cursor + @param parameters - Cursor parameters, e.g. OPEN c(1,2,3) + @returns - false on success, true on error +*/ +bool LEX::sp_open_cursor(THD *thd, const LEX_STRING name, + List *parameters) +{ + uint offset; + const sp_pcursor *pcursor; + if (!(pcursor= spcont->find_cursor(name, &offset, false))) + { + my_error(ER_SP_CURSOR_MISMATCH, MYF(0), name.str); + return true; + } + if ((pcursor->param_context() ? + pcursor->param_context()->context_var_count() : 0) != + (parameters ? parameters->elements : 0)) + { + my_error(ER_WRONG_PARAMCOUNT_TO_CURSOR, MYF(0), name.str); + return true; + } + return sphead->add_open_cursor(thd, spcont, offset, + pcursor->param_context(), parameters); } @@ -5947,7 +5985,7 @@ bool LEX::set_variable(struct sys_var_with_base *variable, Item *item) sp_variable *spv= spcont->find_variable(variable->base_name, false); DBUG_ASSERT(spv); /* It is a local variable. */ - return set_local_variable(spv, item); + return sphead->set_local_variable(thd, spcont, spv, item, this); } diff --git a/sql/sql_lex.h b/sql/sql_lex.h index ee4c4687ef36b..7a531fb761f43 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -84,6 +84,7 @@ class sp_name; class sp_instr; class sp_pcontext; class sp_variable; +class sp_assignment_lex; class st_alter_tablespace; class partition_info; class Event_parse_data; @@ -765,7 +766,7 @@ class st_select_lex_unit: public st_select_lex_node { void set_unique_exclude(); - friend void lex_start(THD *thd); + friend struct LEX; friend int subselect_union_engine::exec(); List *get_column_types(bool for_cursor); @@ -1072,7 +1073,7 @@ class st_select_lex: public st_select_lex_node */ ha_rows get_limit(); - friend void lex_start(THD *thd); + friend struct LEX; st_select_lex() : group_list_ptrs(NULL), braces(0), automatic_brackets(0), n_sum_items(0), n_child_sum_items(0) {} @@ -2920,6 +2921,8 @@ struct LEX: public Query_tables_list delete_dynamic(&plugins); } + void start(THD *thd); + inline bool is_ps_or_view_context_analysis() { return (context_analysis_only & @@ -3112,8 +3115,10 @@ struct LEX: public Query_tables_list bool sp_handler_declaration_init(THD *thd, int type); bool sp_handler_declaration_finalize(THD *thd, int type); - bool sp_declare_cursor(THD *thd, const LEX_STRING name, LEX *cursor_stmt); - bool set_local_variable(sp_variable *spv, Item *val); + bool sp_declare_cursor(THD *thd, const LEX_STRING name, LEX *cursor_stmt, + sp_pcontext *param_ctx); + bool sp_open_cursor(THD *thd, const LEX_STRING name, + List *parameters); Item_splocal *create_item_for_sp_var(LEX_STRING name, sp_variable *spvar, const char *start_in_q, const char *end_in_q); @@ -3507,6 +3512,92 @@ struct st_lex_local: public LEX, public Sql_alloc { }; + +/** + An st_lex_local extension with automatic initialization for SP purposes. + Used to parse sub-expressions and SP sub-statements. + + This class is reused for: + 1. sp_head::reset_lex() based constructs + - SP variable assignments (e.g. SET x=10;) + - FOR loop conditions and index variable increments + - Cursor statements + - SP statements + - SP function RETURN statements + - CASE statements + - REPEAT..UNTIL expressions + - WHILE expressions + - EXIT..WHEN and CONTINUE..WHEN statements + 2. sp_assignment_lex based constructs: + - CURSOR parameter assignments +*/ +class sp_lex_local: public st_lex_local +{ +public: + sp_lex_local(THD *thd, const LEX *oldlex) + { + /* Reset most stuff. */ + start(thd); + /* Keep the parent SP stuff */ + sphead= oldlex->sphead; + spcont= oldlex->spcont; + /* Keep the parent trigger stuff too */ + trg_chistics= oldlex->trg_chistics; + trg_table_fields.empty(); + sp_lex_in_use= false; + } +}; + + +/** + An assignment specific LEX, which additionally has an Item (an expression) + and an associated with the Item free_list, which is usually freed + after the expression is calculated. + + Note, consider changing some of sp_lex_local to sp_assignment_lex, + as the latter allows to use a simpler grammar in sql_yacc.yy (IMO). + + If the expression is simple (e.g. does not have function calls), + then m_item and m_free_list point to the same Item. + + If the expressions is complex (e.g. have function calls), + then m_item points to the leftmost Item, while m_free_list points + to the rightmost item. + For example: + f1(COALESCE(f2(10), f2(20))) + - m_item points to Item_func_sp for f1 (the leftmost Item) + - m_free_list points to Item_int for 20 (the rightmost Item) + + Note, we could avoid storing m_item at all, as we can always reach + the leftmost item from the rightmost item by iterating through m_free_list. + But with a separate m_item the code should be faster. +*/ +class sp_assignment_lex: public sp_lex_local +{ + Item *m_item; // The expression + Item *m_free_list; // The associated free_list (sub-expressions) +public: + sp_assignment_lex(THD *thd, LEX *oldlex) + :sp_lex_local(thd, oldlex), + m_item(NULL), + m_free_list(NULL) + { } + void set_item_and_free_list(Item *item, Item *free_list) + { + m_item= item; + m_free_list= free_list; + } + Item *get_item() const + { + return m_item; + } + Item *get_free_list() const + { + return m_free_list; + } +}; + + extern void lex_init(void); extern void lex_free(void); extern void lex_start(THD *thd); diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 7e134338d6238..0aaec9e6cd52d 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -309,42 +309,6 @@ LEX::set_system_variable(struct sys_var_with_base *tmp, } -/** - Helper action for a SET statement. - Used to push a SP local variable into the assignment list. - - @param var_type the SP local variable - @param val the value being assigned to the variable - - @return TRUE if error, FALSE otherwise. -*/ - -bool -LEX::set_local_variable(sp_variable *spv, Item *val) -{ - Item *it; - sp_instr_set *sp_set; - - if (val) - it= val; - else if (spv->default_value) - it= spv->default_value; - else - { - it= new (thd->mem_root) Item_null(thd); - if (it == NULL) - return TRUE; - } - - sp_set= new (thd->mem_root) - sp_instr_set(sphead->instructions(), spcont, - spv->offset, it, spv->sql_type(), - this, true); - - return (sp_set == NULL || sphead->add_instr(sp_set)); -} - - /** Helper action for a SET statement. Used to SET a field of NEW row. @@ -3001,7 +2965,7 @@ sp_decl_body: } | ident CURSOR_SYM FOR_SYM sp_cursor_stmt { - if (Lex->sp_declare_cursor(thd, $1, $4)) + if (Lex->sp_declare_cursor(thd, $1, $4, NULL)) MYSQL_YYABORT; $$.vars= $$.conds= $$.hndlrs= 0; $$.curs= 1; @@ -3570,17 +3534,7 @@ sp_proc_stmt_iterate: sp_proc_stmt_open: OPEN_SYM ident { - LEX *lex= Lex; - sp_head *sp= lex->sphead; - uint offset; - sp_instr_copen *i; - - if (! lex->spcont->find_cursor($2, &offset, false)) - my_yyabort_error((ER_SP_CURSOR_MISMATCH, MYF(0), $2.str)); - i= new (thd->mem_root) - sp_instr_copen(sp->instructions(), lex->spcont, offset); - if (i == NULL || - sp->add_instr(i)) + if (Lex->sp_open_cursor(thd, $2, NULL)) MYSQL_YYABORT; } ; diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy index db1a20e110bab..8926e49f67b1f 100644 --- a/sql/sql_yacc_ora.yy +++ b/sql/sql_yacc_ora.yy @@ -195,11 +195,13 @@ void ORAerror(THD *thd, const char *s) Item_param *item_param; Key_part_spec *key_part; LEX *lex; + sp_assignment_lex *assignment_lex; LEX_STRING *lex_str_ptr; LEX_USER *lex_user; List *cond_info_list; List *dyncol_def_list; List *item_list; + List *sp_assignment_lex_list; List *stmt_info_list; List *string_list; List *lex_str_list; @@ -266,10 +268,10 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); %parse-param { THD *thd } %lex-param { THD *thd } /* - Currently there are 103 shift/reduce conflicts. + Currently there are 102 shift/reduce conflicts. We should not introduce new conflicts any more. */ -%expect 103 +%expect 102 /* Comments for TOKENS. @@ -1131,6 +1133,14 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); ident_list ident_list_arg opt_expr_list decode_when_list +%type + assignment_source_lex + assignment_source_expr + +%type + cursor_actual_parameters + opt_parenthesized_cursor_actual_parameters + %type option_type opt_var_type opt_var_ident_type @@ -1302,7 +1312,7 @@ END_OF_INPUT %type sp_instr_addr %type sp_cursor_name_and_offset %type opt_exception_clause exception_handlers -%type sp_cursor_stmt +%type sp_cursor_stmt remember_lex %type sp_name %type sp_param_name sp_param_name_and_type %type sp_for_loop_index_and_bounds @@ -2438,15 +2448,29 @@ sp_decl_body: $$.vars= $$.conds= $$.curs= 0; $$.hndlrs= 1; } - | CURSOR_SYM ident_directly_assignable IS sp_cursor_stmt + | CURSOR_SYM ident_directly_assignable { - if (Lex->sp_declare_cursor(thd, $2, $4)) + Lex->sp_block_init(thd); + } + opt_parenthesized_cursor_formal_parameters + IS sp_cursor_stmt + { + sp_pcontext *param_ctx= Lex->spcont; + if (Lex->sp_block_finalize(thd)) + MYSQL_YYABORT; + if (Lex->sp_declare_cursor(thd, $2, $6, param_ctx)) MYSQL_YYABORT; $$.vars= $$.conds= $$.hndlrs= 0; $$.curs= 1; } ; +opt_parenthesized_cursor_formal_parameters: + /* Empty */ + | '(' sp_fdparams ')' + ; + + sp_cursor_stmt: { Lex->sphead->reset_lex(thd); @@ -3095,20 +3119,60 @@ sp_proc_stmt_iterate: } ; -sp_proc_stmt_open: - OPEN_SYM ident +remember_lex: { - LEX *lex= Lex; - sp_head *sp= lex->sphead; - uint offset; - sp_instr_copen *i; + $$= thd->lex; + } + ; - if (! lex->spcont->find_cursor($2, &offset, false)) - my_yyabort_error((ER_SP_CURSOR_MISMATCH, MYF(0), $2.str)); - i= new (thd->mem_root) - sp_instr_copen(sp->instructions(), lex->spcont, offset); - if (i == NULL || - sp->add_instr(i)) +assignment_source_lex: + { + DBUG_ASSERT(Lex->sphead); + if (!($$= new (thd->mem_root) sp_assignment_lex(thd, thd->lex))) + MYSQL_YYABORT; + } + ; + +assignment_source_expr: + remember_lex assignment_source_lex + { + DBUG_ASSERT(thd->free_list == NULL); + thd->set_local_lex($2); // This changes thd->lex to $2 + } + expr + { + DBUG_ASSERT($2 == thd->lex); + if (thd->restore_from_local_lex_to_old_lex($1)) // Restores thd->lex + MYSQL_YYABORT; + $$= $2; + $$->set_item_and_free_list($4, thd->free_list); + thd->free_list= NULL; + } + ; + +cursor_actual_parameters: + assignment_source_expr + { + if (!($$= new (thd->mem_root) List)) + MYSQL_YYABORT; + $$->push_back($1, thd->mem_root); + } + | cursor_actual_parameters ',' assignment_source_expr + { + $$= $1; + $$->push_back($3, thd->mem_root); + } + ; + +opt_parenthesized_cursor_actual_parameters: + /* Empty */ { $$= NULL; } + | '(' cursor_actual_parameters ')' { $$= $2; } + ; + +sp_proc_stmt_open: + OPEN_SYM ident opt_parenthesized_cursor_actual_parameters + { + if (Lex->sp_open_cursor(thd, $2, $3)) MYSQL_YYABORT; } ;