diff --git a/mysql-test/r/sp-cursor.result b/mysql-test/r/sp-cursor.result new file mode 100644 index 0000000000000..d068c19b22b34 --- /dev/null +++ b/mysql-test/r/sp-cursor.result @@ -0,0 +1,482 @@ +# +# MDEV-12457 Cursors with parameters +# +CREATE TABLE t1 (a INT, b VARCHAR(10)) ENGINE=MyISAM; +INSERT INTO t1 VALUES (1,'old'),(2,'old'),(3,'old'),(4,'old'),(5,'old'); +CREATE PROCEDURE p1(min INT,max INT) +BEGIN +DECLARE done INT DEFAULT FALSE; +DECLARE va INT; +DECLARE cur CURSOR(pmin INT, pmax INT) FOR SELECT a FROM t1 WHERE a BETWEEN pmin AND pmax; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN cur(min,max); +read_loop: LOOP +FETCH cur INTO va; +IF done THEN +LEAVE read_loop; +END IF; +INSERT INTO t1 VALUES (va,'new'); +END LOOP; +CLOSE cur; +END; +$$ +CALL p1(2,4); +SELECT * FROM t1 ORDER BY b DESC,a; +a b +1 old +2 old +3 old +4 old +5 old +2 new +3 new +4 new +DROP PROCEDURE p1; +DROP TABLE t1; +# +# OPEN with a wrong number of parameters +# +CREATE TABLE t1 (a INT, b VARCHAR(10)); +CREATE PROCEDURE p1(a_a INT,a_b VARCHAR(32)) +BEGIN +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT * FROM t1 WHERE a=p_a; +OPEN c(a_a); +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) +BEGIN +DECLARE v_a INT; +DECLARE c CURSOR (p_a INT) FOR SELECT a FROM t1 WHERE a=p_a; +OPEN c(a_a); +SET p_a=10; +END; +$$ +ERROR HY000: Unknown system variable 'p_a' +CREATE PROCEDURE p1(a_a INT) +BEGIN +DECLARE v_a INT; +DECLARE c CURSOR (p_a INT) FOR SELECT a FROM t1 WHERE a=p_a; +SET 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) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a INT DEFAULT NULL; +DECLARE p_a INT DEFAULT NULL; +DECLARE c CURSOR (p_a VARCHAR(32)) FOR SELECT p_a FROM t1; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c(a); +read_loop: LOOP +FETCH c INTO v_a; +IF done THEN +LEAVE read_loop; +END IF; +SELECT v_a; +END LOOP; +CLOSE c; +END; +$$ +CALL p1(1); +v_a +1 +CALL p1(NULL); +v_a +NULL +DROP PROCEDURE p1; +DROP TABLE t1; +# +# Parameters in SELECT list +# +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR(32)) +BEGIN +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT p_a,p_b FROM DUAL; +OPEN c(a_a + 0,a_b); +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +CLOSE c; +OPEN c(a_a + 1,a_b); +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +CLOSE c; +END; +$$ +CALL p1(1,'b1'); +v_a v_b +1 b1 +v_a v_b +2 b1 +DROP PROCEDURE p1; +# +# Parameters in SELECT list + UNION +# +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR(32)) +BEGIN +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR(p_a INT, p_b VARCHAR(32)) FOR +SELECT p_a,p_b FROM DUAL +UNION ALL +SELECT p_a+1,CONCAT(p_b,'b') FROM DUAL; +OPEN c(a_a,a_b); +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +CLOSE c; +END; +$$ +CALL p1(1,'b1'); +v_a v_b +1 b1 +v_a v_b +2 b1b +DROP PROCEDURE p1; +# +# Parameters in SELECT list + type conversion + warnings +# +SET sql_mode=''; +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN +DECLARE v_a INT; +DECLARE c CURSOR (p_a INT) FOR SELECT p_a FROM DUAL; +OPEN c(a_a); +FETCH c INTO v_a; +SELECT v_a; +CLOSE c; +END; +$$ +CALL p1('1b'); +v_a +1 +Warnings: +Warning 1265 Data truncated for column 'p_a' at row 1 +CALL p1('b1'); +v_a +0 +Warnings: +Warning 1366 Incorrect integer value: 'b1' for column 'p_a' at row 1 +DROP PROCEDURE p1; +SET sql_mode=DEFAULT; +# +# One parameter in SELECT list + subselect +# +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN +DECLARE v_a VARCHAR(10); +DECLARE c CURSOR (p_a VARCHAR(32)) FOR +SELECT p_a FROM DUAL UNION SELECT REVERSE(p_a) FROM DUAL; +OPEN c((SELECT a_a)); +FETCH c INTO v_a; +SELECT v_a; +FETCH c INTO v_a; +SELECT v_a; +CLOSE c; +END; +$$ +CALL p1('ab'); +v_a +ab +v_a +ba +DROP PROCEDURE p1; +# +# Two parameters in SELECT list + subselect +# +CREATE PROCEDURE p1() +BEGIN +DECLARE v_a VARCHAR(32); +DECLARE v_b VARCHAR(32); +DECLARE c CURSOR (p_a VARCHAR(32), p_b VARCHAR(32)) FOR +SELECT p_a, p_b FROM DUAL +UNION +SELECT p_b, p_a FROM DUAL; +OPEN c((SELECT 'aaa'),(SELECT 'bbb')); +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +FETCH c INTO v_a, v_b; +SELECT v_a, v_b; +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 +# +CREATE PROCEDURE p1(a_a VARCHAR(32), a_b VARCHAR(32)) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a VARCHAR(32); +DECLARE v_b VARCHAR(32); +DECLARE c CURSOR (value_a VARCHAR(32), value_b VARCHAR(32), +pattern_a VARCHAR(32), pattern_b VARCHAR(32)) FOR +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; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c((SELECT 'aaa'),(SELECT 'bbb'),(SELECT a_a),(SELECT a_b)); +read_loop: LOOP +FETCH c INTO v_a, v_b; +IF done THEN +LEAVE read_loop; +END IF; +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(32)) RETURNS VARCHAR(32) +BEGIN +RETURN CONCAT(a,'y'); +END; +$$ +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a VARCHAR(10); +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_sel_a VARCHAR(32), p_cmp_a VARCHAR(32)) FOR +SELECT p_sel_a, p_cmp_a FROM DUAL; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c(f1(a_a), f1(a_a)); +read_loop: LOOP +FETCH c INTO v_a, v_b; +IF done THEN +LEAVE read_loop; +END IF; +SELECT v_a, v_b; +END LOOP; +CLOSE c; +END; +$$ +CALL p1('x'); +v_a v_b +xy xy +CALL p1(f1(COALESCE(NULL, f1('x')))); +v_a v_b +xyyy 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) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_a INT) FOR SELECT a,b FROM t1 WHERE a=p_a; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c(a_a); +read_loop: LOOP +FETCH c INTO v_a, v_b; +IF done THEN +LEAVE read_loop; +END IF; +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(32)) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT a,b FROM t1 WHERE a=p_a AND b=p_b; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c(a_a, a_b); +read_loop: LOOP +FETCH c INTO v_a, v_b; +IF done THEN +LEAVE read_loop; +END IF; +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(32), arg_total_limit INT) +BEGIN +DECLARE i INT DEFAULT 0; +DECLARE v_name VARCHAR(10); +DECLARE v_total INT; +-- +0 is needed to work around the bug MDEV-11081 +DECLARE c CURSOR(p_v INT) FOR +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; +WHILE i < 2 DO +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +OPEN c(i); +read_loop: LOOP +FETCH c INTO v_name, v_total; +IF done THEN +LEAVE read_loop; +END IF; +SELECT v_name, v_total; +END LOOP; +CLOSE c; +SET i= i + 1; +END; +END WHILE; +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) +BEGIN +DECLARE done INT DEFAULT 0; +DECLARE v_a INT; +DECLARE v_b VARCHAR(10); +DECLARE c CURSOR (p_a INT) FOR SELECT a,b FROM t1 ORDER BY a LIMIT p_a; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; +CREATE TABLE t2 (a INT, b VARCHAR(10)); +OPEN c(a_a); +read_loop: LOOP +FETCH c INTO v_a, v_b; +IF done THEN +LEAVE read_loop; +END IF; +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-12457 Cursors with parameters +# diff --git a/mysql-test/t/sp-cursor.test b/mysql-test/t/sp-cursor.test new file mode 100644 index 0000000000000..394dc56556aec --- /dev/null +++ b/mysql-test/t/sp-cursor.test @@ -0,0 +1,476 @@ + +--echo # +--echo # MDEV-12457 Cursors with parameters +--echo # + +CREATE TABLE t1 (a INT, b VARCHAR(10)) ENGINE=MyISAM; +INSERT INTO t1 VALUES (1,'old'),(2,'old'),(3,'old'),(4,'old'),(5,'old'); +DELIMITER $$; +CREATE PROCEDURE p1(min INT,max INT) +BEGIN + DECLARE done INT DEFAULT FALSE; + DECLARE va INT; + DECLARE cur CURSOR(pmin INT, pmax INT) FOR SELECT a FROM t1 WHERE a BETWEEN pmin AND pmax; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN cur(min,max); + read_loop: LOOP + FETCH cur INTO va; + IF done THEN + LEAVE read_loop; + END IF; + INSERT INTO t1 VALUES (va,'new'); + END LOOP; + CLOSE cur; +END; +$$ +DELIMITER ;$$ +CALL p1(2,4); +SELECT * FROM t1 ORDER BY b DESC,a; +DROP PROCEDURE p1; +DROP TABLE t1; + + +--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(32)) +BEGIN + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT * FROM t1 WHERE a=p_a; + OPEN c(a_a); + 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) +BEGIN + DECLARE v_a INT; + DECLARE c CURSOR (p_a INT) FOR SELECT a FROM t1 WHERE a=p_a; + OPEN c(a_a); + SET p_a=10; +END; +$$ +DELIMITER ;$$ + +DELIMITER $$; +--error ER_UNKNOWN_SYSTEM_VARIABLE +CREATE PROCEDURE p1(a_a INT) +BEGIN + DECLARE v_a INT; + DECLARE c CURSOR (p_a INT) FOR SELECT a FROM t1 WHERE a=p_a; + SET 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) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a INT DEFAULT NULL; + DECLARE p_a INT DEFAULT NULL; + DECLARE c CURSOR (p_a VARCHAR(32)) FOR SELECT p_a FROM t1; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c(a); + read_loop: LOOP + FETCH c INTO v_a; + IF done THEN + LEAVE read_loop; + END IF; + SELECT v_a; + END LOOP; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(1); +CALL p1(NULL); +DROP PROCEDURE p1; +DROP TABLE t1; + + +--echo # +--echo # Parameters in SELECT list +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a INT, a_b VARCHAR(32)) +BEGIN + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT p_a,p_b FROM DUAL; + OPEN c(a_a + 0,a_b); + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + CLOSE c; + OPEN c(a_a + 1,a_b); + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + CLOSE c; +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(32)) +BEGIN + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR(p_a INT, p_b VARCHAR(32)) FOR + SELECT p_a,p_b FROM DUAL + UNION ALL + SELECT p_a+1,CONCAT(p_b,'b') FROM DUAL; + OPEN c(a_a,a_b); + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(1,'b1'); +DROP PROCEDURE p1; + + +--echo # +--echo # Parameters in SELECT list + type conversion + warnings +--echo # + +SET sql_mode=''; +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN + DECLARE v_a INT; + DECLARE c CURSOR (p_a INT) FOR SELECT p_a FROM DUAL; + OPEN c(a_a); + FETCH c INTO v_a; + SELECT v_a; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('1b'); +CALL p1('b1'); +DROP PROCEDURE p1; +SET sql_mode=DEFAULT; + + +--echo # +--echo # One parameter in SELECT list + subselect +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN + DECLARE v_a VARCHAR(10); + DECLARE c CURSOR (p_a VARCHAR(32)) FOR + SELECT p_a FROM DUAL UNION SELECT REVERSE(p_a) FROM DUAL; + OPEN c((SELECT a_a)); + FETCH c INTO v_a; + SELECT v_a; + FETCH c INTO v_a; + SELECT v_a; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1('ab'); +DROP PROCEDURE p1; + + +--echo # +--echo # Two parameters in SELECT list + subselect +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1() +BEGIN + DECLARE v_a VARCHAR(32); + DECLARE v_b VARCHAR(32); + DECLARE c CURSOR (p_a VARCHAR(32), p_b VARCHAR(32)) FOR + SELECT p_a, p_b FROM DUAL + UNION + SELECT p_b, p_a FROM DUAL; + OPEN c((SELECT 'aaa'),(SELECT 'bbb')); + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + FETCH c INTO v_a, v_b; + SELECT v_a, v_b; + CLOSE c; +END; +$$ +DELIMITER ;$$ +CALL p1(); +DROP PROCEDURE p1; + + +--echo # +--echo # Two parameters in SELECT list + two parameters in WHERE + subselects +--echo # + +DELIMITER $$; +CREATE PROCEDURE p1(a_a VARCHAR(32), a_b VARCHAR(32)) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a VARCHAR(32); + DECLARE v_b VARCHAR(32); + DECLARE c CURSOR (value_a VARCHAR(32), value_b VARCHAR(32), + pattern_a VARCHAR(32), pattern_b VARCHAR(32)) FOR + 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; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c((SELECT 'aaa'),(SELECT 'bbb'),(SELECT a_a),(SELECT a_b)); + read_loop: LOOP + FETCH c INTO v_a, v_b; + IF done THEN + LEAVE read_loop; + END IF; + 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(32)) RETURNS VARCHAR(32) +BEGIN + RETURN CONCAT(a,'y'); +END; +$$ +CREATE PROCEDURE p1(a_a VARCHAR(32)) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a VARCHAR(10); + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_sel_a VARCHAR(32), p_cmp_a VARCHAR(32)) FOR + SELECT p_sel_a, p_cmp_a FROM DUAL; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c(f1(a_a), f1(a_a)); + read_loop: LOOP + FETCH c INTO v_a, v_b; + IF done THEN + LEAVE read_loop; + END IF; + SELECT v_a, v_b; + 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) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_a INT) FOR SELECT a,b FROM t1 WHERE a=p_a; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c(a_a); + read_loop: LOOP + FETCH c INTO v_a, v_b; + IF done THEN + LEAVE read_loop; + END IF; + 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(32)) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_a INT, p_b VARCHAR(32)) FOR SELECT a,b FROM t1 WHERE a=p_a AND b=p_b; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c(a_a, a_b); + read_loop: LOOP + FETCH c INTO v_a, v_b; + IF done THEN + LEAVE read_loop; + END IF; + 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(32), arg_total_limit INT) +BEGIN + DECLARE i INT DEFAULT 0; + DECLARE v_name VARCHAR(10); + DECLARE v_total INT; +-- +0 is needed to work around the bug MDEV-11081 + DECLARE c CURSOR(p_v INT) FOR + 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; + WHILE i < 2 DO + BEGIN + DECLARE done INT DEFAULT 0; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + OPEN c(i); + read_loop: LOOP + FETCH c INTO v_name, v_total; + IF done THEN + LEAVE read_loop; + END IF; + SELECT v_name, v_total; + END LOOP; + CLOSE c; + SET i= i + 1; + END; + END WHILE; +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) +BEGIN + DECLARE done INT DEFAULT 0; + DECLARE v_a INT; + DECLARE v_b VARCHAR(10); + DECLARE c CURSOR (p_a INT) FOR SELECT a,b FROM t1 ORDER BY a LIMIT p_a; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE; + CREATE TABLE t2 (a INT, b VARCHAR(10)); + OPEN c(a_a); + read_loop: LOOP + FETCH c INTO v_a, v_b; + IF done THEN + LEAVE read_loop; + END IF; + 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-12457 Cursors with parameters +--echo # diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 4da48acc00992..c3014af7ea7f0 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -784,12 +784,14 @@ Virtual_column_info *add_virtual_expression(THD *thd, Item *expr) Item_param *item_param; Key_part_spec *key_part; LEX *lex; + sp_assignment_lex *assignment_lex; class sp_lex_cursor *sp_cursor_stmt; 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; @@ -1717,6 +1719,14 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); sp_cursor_stmt_lex sp_cursor_stmt +%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 @@ -3023,15 +3033,28 @@ sp_decl_body: $$.vars= $$.conds= $$.curs= 0; $$.hndlrs= 1; } - | ident CURSOR_SYM FOR_SYM sp_cursor_stmt + | ident CURSOR_SYM + { + Lex->sp_block_init(thd); + } + opt_parenthesized_cursor_formal_parameters + FOR_SYM sp_cursor_stmt { - if (Lex->sp_declare_cursor(thd, $1, $4, NULL, true)) + sp_pcontext *param_ctx= Lex->spcont; + if (Lex->sp_block_finalize(thd)) + MYSQL_YYABORT; + if (Lex->sp_declare_cursor(thd, $1, $6, param_ctx, true)) MYSQL_YYABORT; $$.vars= $$.conds= $$.hndlrs= 0; $$.curs= 1; } ; +opt_parenthesized_cursor_formal_parameters: + /* Empty */ + | '(' sp_fdparams ')' + ; + sp_cursor_stmt_lex: { @@ -3597,10 +3620,55 @@ sp_proc_stmt_iterate: } ; +assignment_source_lex: + { + DBUG_ASSERT(Lex->sphead); + if (!($$= new (thd->mem_root) sp_assignment_lex(thd, thd->lex))) + MYSQL_YYABORT; + } + ; + +assignment_source_expr: + assignment_source_lex + { + DBUG_ASSERT(thd->free_list == NULL); + Lex->sphead->reset_lex(thd, $1); + } + expr + { + DBUG_ASSERT($1 == thd->lex); + $$= $1; + $$->sp_lex_in_use= true; + $$->set_item_and_free_list($3, thd->free_list); + thd->free_list= NULL; + if ($$->sphead->restore_lex(thd)) + MYSQL_YYABORT; + } + ; + +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 + OPEN_SYM ident opt_parenthesized_cursor_actual_parameters { - if (Lex->sp_open_cursor(thd, $2, NULL)) + if (Lex->sp_open_cursor(thd, $2, $3)) MYSQL_YYABORT; } ;