1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950
|
--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 #
--echo #
--echo # MDEV-14415 Add Oracle-style FOR loop to sql_mode=DEFAULT
--echo #
--echo # Explicit cursor
CREATE TABLE t1 (a INT, b VARCHAR(10));
INSERT INTO t1 VALUES (1,'b1'), (2,'b2'), (3,'b3');
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE cur CURSOR FOR SELECT * FROM t1;
FOR rec IN cur
DO
SELECT rec.a AS a, rec.b AS b;
END FOR;
END;
$$
DELIMITER ;$$
DROP TABLE t1;
--echo # Explicit cursor with parameters
CREATE TABLE t1 (a INT, b VARCHAR(10));
INSERT INTO t1 VALUES (1,'b1'), (2,'b2'), (3,'b3');
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE cur CURSOR(pa INT) FOR SELECT * FROM t1 WHERE a>=pa;
FOR rec IN cur(2)
DO
SELECT rec.a AS a, rec.b AS b;
END FOR;
END;
$$
DELIMITER ;$$
DROP TABLE t1;
--echo # Explicit cursor + label
CREATE TABLE t1 (a INT, b VARCHAR(10));
INSERT INTO t1 VALUES ('1','b1'), ('2','b2');
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE cur CURSOR FOR SELECT * FROM t1;
forrec:
FOR rec IN cur
DO
SELECT rec.a AS a, rec.b AS b;
IF rec.a = 2 THEN
LEAVE forrec;
END IF;
END FOR forrec;
END;
$$
DELIMITER ;$$
DROP TABLE t1;
--echo # Explicit cursor + FETCH inside the loop body produce an error on "NOT FOUND"
DELIMITER $$;
--error ER_SP_FETCH_NO_DATA
BEGIN NOT ATOMIC
DECLARE x INT;
DECLARE cur CURSOR FOR SELECT 1 AS x;
FOR rec IN cur
DO
FETCH cur INTO x;
END FOR;
END;
$$
DELIMITER ;$$
--echo # Explicit cursor + FETCH inside the loop body are normally handled by "HANDLER FOR NOT FOUND"
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE done INT DEFAULT 0;
DECLARE cur CURSOR FOR SELECT 1 AS x, 'y1' AS y UNION
SELECT 2,'y2' UNION
SELECT 3,'y3';
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
forrec:
FOR rec IN cur
DO
SELECT CONCAT(rec.x, ' ', rec.y) AS 'Implicit FETCH';
FETCH cur INTO rec;
IF done THEN
SELECT 'NO DATA' AS `Explicit FETCH`;
LEAVE forrec;
ELSE
SELECT CONCAT(rec.x, ' ', rec.y) AS 'Explicit FETCH';
END IF;
END FOR;
END;
$$
DELIMITER ;$$
--echo # Implicit cursor
CREATE TABLE t1 (a INT, b VARCHAR(10));
INSERT INTO t1 VALUES ('1','b1'), ('2','b2');
DELIMITER $$;
BEGIN NOT ATOMIC
FOR rec IN (SELECT * FROM t1)
DO
SELECT rec.a AS a, rec.b AS b;
END FOR;
END;
$$
DELIMITER ;$$
DROP TABLE t1;
--echo # Implicit cursor + label
CREATE TABLE t1 (a INT, b VARCHAR(10));
INSERT INTO t1 VALUES ('1','b1'), ('2','b2');
DELIMITER $$;
BEGIN NOT ATOMIC
forrec:
FOR rec IN (SELECT * FROM t1)
DO
SELECT rec.a AS a, rec.b AS b;
IF rec.a = 2 THEN
LEAVE forrec;
END IF;
END FOR;
END;
$$
DELIMITER ;$$
DROP TABLE t1;
--echo #
--echo # MDEV-15941 Explicit cursor FOR loop does not close the cursor
--echo #
DELIMITER $$;
--error ER_SP_CURSOR_NOT_OPEN
BEGIN NOT ATOMIC
DECLARE v INT;
DECLARE cur CURSOR FOR SELECT 1 AS a FROM DUAL;
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
FETCH cur INTO v;
END;
$$
DELIMITER ;$$
DELIMITER $$;
--error ER_SP_CURSOR_NOT_OPEN
BEGIN NOT ATOMIC
DECLARE v INT;
DECLARE cur CURSOR FOR SELECT 1 AS a FROM DUAL;
label:
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
FETCH cur INTO v;
END;
$$
DELIMITER ;$$
DELIMITER $$;
--error ER_SP_CURSOR_ALREADY_OPEN
BEGIN NOT ATOMIC
DECLARE cur CURSOR FOR SELECT 1 AS a FROM DUAL;
OPEN cur;
FOR rec IN cur DO
SELECT rec.a;
END FOR;
END;
$$
DELIMITER ;$$
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE cur CURSOR FOR SELECT 1 AS a FROM DUAL;
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
END;
$$
DELIMITER ;$$
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE cur CURSOR FOR SELECT 1 AS a FROM DUAL;
label1:
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
label2:
FOR rec IN cur
DO
SELECT rec.a;
END FOR;
END;
$$
DELIMITER ;$$
--echo #
--echo # MDEV-16584 SP with a cursor inside a loop wastes THD memory aggressively
--echo #
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE mem_used_old BIGINT UNSIGNED DEFAULT
(SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.SESSION_STATUS
WHERE VARIABLE_NAME='MEMORY_USED');
DECLARE i INT DEFAULT 1;
WHILE i <= 5000
DO
BEGIN
DECLARE msg TEXT;
DECLARE mem_used_cur BIGINT UNSIGNED DEFAULT
(SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.SESSION_STATUS
WHERE VARIABLE_NAME='MEMORY_USED');
DECLARE cur CURSOR FOR SELECT 1 FROM DUAL;
IF (mem_used_cur >= mem_used_old * 2) THEN
SHOW STATUS LIKE 'Memory_used';
SET msg=CONCAT('Memory leak detected: i=', i, ' mem_used_old=',mem_used_old,' mem_used_cur=', mem_used_cur);
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT=msg;
END IF;
END;
SET i=i+1;
END WHILE;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
--echo #
--echo # MDEV-17278 CURSOR FOR LOOP - ERROR: unexpected end of stream, read 0 bytes (SERVER CRASH)
--echo #
CREATE TABLE t1 (id2 int, id int, en1 enum('aaa','a','b','c'));
INSERT INTO t1 VALUES(1,1,'aaa'),(2,2,'a'),(3,3,'b'),(4,4,'c');
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
FOR rec IN (SELECT en1 FROM t1)
DO
SELECT rec.en1;
END FOR;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;
DROP TABLE t1;
--echo #
--echo # MDEV-26009: Server crash when calling twice procedure using FOR-loop
--echo #
CREATE TABLE t1 ( id int, name varchar(24));
INSERT INTO t1 values (1, 'x'), (2, 'y'), (3, 'z');
create function get_name(_id int) returns varchar(24)
return (select name from t1 where id = _id);
select get_name(id) from t1;
delimiter ^^;
create procedure test_proc()
begin
declare _cur cursor for select get_name(id) from t1;
for row in _cur do select 1; end for;
end;
^^
delimiter ;^^
call test_proc();
call test_proc();
drop procedure test_proc;
drop function get_name;
drop table t1;
CREATE TABLE t1 (id int, name varchar(24));
INSERT INTO t1 (id, name) VALUES (1, 'x'),(2, 'y'),(3, 'z');
create function get_name(_id int) returns varchar(24)
return (select name from t1 where id = _id);
create view v1 as select get_name(id) from t1;
delimiter $$;
create procedure test_proc()
begin
declare _cur cursor for select 1 from v1;
for row in _cur do select 1; end for;
end$$
delimiter ;$$
call test_proc();
call test_proc();
drop procedure test_proc;
drop view v1;
drop function get_name;
drop table t1;
--echo #
--echo # MDEV-28266: Crash in Field_string::type_handler when calling procedures
--echo #
CREATE TABLE t (f INT);
--delimiter $
CREATE TRIGGER tr AFTER INSERT ON t FOR EACH ROW
FOR x IN (SELECT * FROM json_table(NULL, '$' COLUMNS(a CHAR(1) path '$.*')) tmp)
DO set @a=1; END FOR $
--delimiter ;
INSERT INTO t () values ();
# Cleanup
DROP TABLE t;
--echo #
--echo # End of 10.6 tests
--echo #
--echo #
--echo # Start of 10.8 tests
--echo #
--echo #
--echo # MDEV-10654 IN, OUT, INOUT parameters in CREATE FUNCTION
--echo #
DELIMITER $$;
BEGIN NOT ATOMIC
DECLARE va INT;
DECLARE cur CURSOR (IN a INT) FOR SELECT a FROM dual;
OPEN cur(1);
FETCH cur INTO va;
CLOSE cur;
SELECT va;
END;
$$
DELIMITER ;$$
DELIMITER $$;
--error ER_NOT_SUPPORTED_YET
BEGIN NOT ATOMIC
DECLARE va INT;
DECLARE cur CURSOR (OUT a INT) FOR SELECT a FROM dual;
OPEN cur(1);
FETCH cur INTO va;
CLOSE cur;
SELECT va;
END;
$$
DELIMITER ;$$
DELIMITER $$;
--error ER_NOT_SUPPORTED_YET
BEGIN NOT ATOMIC
DECLARE va INT;
DECLARE cur CURSOR (INOUT a INT) FOR SELECT a FROM dual;
OPEN cur(1);
FETCH cur INTO va;
CLOSE cur;
SELECT va;
END;
$$
DELIMITER ;$$
--echo #
--echo # End of 10.8 tests
--echo #
--echo # Start of 11.4 tests
--echo #
--echo # MDEV-36047 Package body variables are not allowed as FETCH targets
--echo #
--source include/sp-cursor-pkg-01.inc
SELECT pkg.f1();
DROP PACKAGE pkg;
--source include/sp-cursor-pkg-02.inc
SELECT pkg.f1();
DROP PACKAGE pkg;
--source include/sp-cursor-pkg-03.inc
SELECT pkg.f1();
DROP PACKAGE pkg;
--echo #
--echo # MDEV-36462: Crash on `DECLARE spvar1 ROW TYPE OF cursor1` after a table recreation
--echo #
--delimiter /
CREATE PROCEDURE p1()
BEGIN
DECLARE c CURSOR FOR SELECT a FROM t1;
BEGIN
DECLARE va ROW TYPE OF c; -- the crash happens here
END;
END;
/
CREATE PROCEDURE p2()
BEGIN
FOR i IN 1..10 DO -- usually it crashes on the third iteration, but not always
SELECT i;
CREATE OR REPLACE TABLE t1 (a INT);
CALL p1;
CALL p1;
END FOR;
END;
/
--delimiter ;
CALL p2;
--echo # Clean up
DROP PROCEDURE p1;
DROP PROCEDURE p2;
DROP TABLE t1;
--echo # The following test is taken from the task MDEV-36114 which is
--echo # partially a duplicate of the task MDEV-36462
--delimiter /
CREATE PROCEDURE p()
BEGIN
DECLARE cur1 CURSOR FOR SELECT * FROM t;
BEGIN
DECLARE rec1 ROW TYPE OF cur1;
END;
END;
/
--delimiter ;
CREATE TABLE t (id INT);
CALL p();
CREATE OR REPLACE TABLE t (id INT);
CALL p();
--echo # Clean up
DROP PROCEDURE p;
DROP TABLE t;
--echo # End of 11.4 tests
|