sp.test 109 KB
Newer Older
1 2 3
#
# Basic stored PROCEDURE tests
#
4 5 6
# Please keep this file free of --error cases and other
# things that will not run in a single debugged mysqld
# process (e.g. master-slave things).
7 8 9 10 11 12 13 14
#
# Test cases for bugs are added at the end. See template there.
#
# Tests that require --error go into sp-error.test
# Tests that require inndb go into sp_trans.test
# Tests that check privilege and security issues go to sp-security.test.
# Tests that require multiple connections, except security/privilege tests,
#   go to sp-thread.
15
# Tests that uses 'goto' to into sp-goto.test (currently disabled)
16 17
# Tests that destroys system tables (e.g. mysql.proc) for error testing
#   go to sp-destruct.
Sinisa@sinisa.nasamreza.org's avatar
Sinisa@sinisa.nasamreza.org committed
18

19 20
use test;

21 22 23 24 25
# Test tables
#
# t1 and t2 are reused throughout the file, and dropped at the end.
# t3 and up are created and dropped when needed.
#
26
--disable_warnings
27
drop table if exists t1,t2,t3,t4;
28 29
--enable_warnings
create table t1 (
30
	id   char(16) not null default '',
31 32
        data int not null
);
33
create table t2 (
34 35 36
	s   char(16),
        i   int,
	d   double
37
);
38

39

40
# Single statement, no params.
41 42 43
--disable_warnings
drop procedure if exists foo42;
--enable_warnings
44 45 46
create procedure foo42()
  insert into test.t1 values ("foo", 42);

47 48 49 50 51 52
call foo42();
select * from t1;
delete from t1;
drop procedure foo42;


53
# Single statement, two IN params.
54 55 56
--disable_warnings
drop procedure if exists bar;
--enable_warnings
57 58 59
create procedure bar(x char(16), y int)
  insert into test.t1 values (x, y);

60 61 62 63 64
call bar("bar", 666);
select * from t1;
delete from t1;
# Don't drop procedure yet...

65

66
# Now for multiple statements...
67 68
delimiter |;

pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
69
# Empty statement
70 71 72
--disable_warnings
drop procedure if exists empty|
--enable_warnings
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
73 74 75 76 77 78 79 80 81
create procedure empty()
begin
end|

call empty()|
drop procedure empty|

# Scope test. This is legal (warnings might be possible in the future,
# but for the time being, we just accept it).
82 83 84
--disable_warnings
drop procedure if exists scope|
--enable_warnings
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
85 86 87 88 89 90 91 92 93 94 95 96
create procedure scope(a int, b float)
begin
  declare b int;
  declare c float;

  begin
    declare c int;
  end;
end|

drop procedure scope|

97
# Two statements.
98 99 100
--disable_warnings
drop procedure if exists two|
--enable_warnings
101 102 103 104 105 106
create procedure two(x1 char(16), x2 char(16), y int)
begin
  insert into test.t1 values (x1, y);
  insert into test.t1 values (x2, y);
end|

107 108 109 110 111 112
call two("one", "two", 3)|
select * from t1|
delete from t1|
drop procedure two|


113
# Simple test of local variables and SET.
114 115 116
--disable_warnings
drop procedure if exists locset|
--enable_warnings
117 118 119 120 121 122 123 124
create procedure locset(x char(16), y int)
begin
  declare z1, z2 int;
  set z1 = y;
  set z2 = z1+2;
  insert into test.t1 values (x, z2);
end|

125 126 127 128 129 130
call locset("locset", 19)|
select * from t1|
delete from t1|
drop procedure locset|


131 132
# In some contexts local variables are not recognized
# (and in some, you have to qualify the identifier).
133 134 135
--disable_warnings
drop procedure if exists setcontext|
--enable_warnings
136 137 138 139 140 141 142 143 144 145 146 147 148 149 150
create procedure setcontext()
begin
  declare data int default 2;

  insert into t1 (id, data) values ("foo", 1);
  replace t1 set data = data, id = "bar";
  update t1 set id = "kaka", data = 3 where t1.data = data;
end|

call setcontext()|
select * from t1|
delete from t1|
drop procedure setcontext|


151 152 153
# Set things to null
create table t3 ( d date, i int, f double, s varchar(32) )|

154 155 156
--disable_warnings
drop procedure if exists nullset|
--enable_warnings
157 158 159 160 161 162 163 164 165
create procedure nullset()
begin
  declare ld date;
  declare li int;
  declare lf double;
  declare ls varchar(32);

  set ld = null, li = null, lf = null, ls = null;
  insert into t3 values (ld, li, lf, ls);
166 167 168 169 170 171 172

  insert into t3 (i, f, s) values ((ld is null), 1,    "ld is null"),
                                  ((li is null), 1,    "li is null"),
				  ((li = 0),     null, "li = 0"),
				  ((lf is null), 1,    "lf is null"),
				  ((lf = 0),     null, "lf = 0"),
				  ((ls is null), 1,    "ls is null");
173 174 175 176 177 178 179 180
end|

call nullset()|
select * from t3|
drop table t3|
drop procedure nullset|


181
# The peculiar (non-standard) mixture of variables types in SET.
182 183 184
--disable_warnings
drop procedure if exists mixset|
--enable_warnings
185 186 187 188 189 190 191 192
create procedure mixset(x char(16), y int)
begin
  declare z int;

  set @z = y, z = 666, max_join_size = 100;
  insert into test.t1 values (x, z);
end|

193 194 195 196 197 198 199
call mixset("mixset", 19)|
show variables like 'max_join_size'|
select id,data,@z from t1|
delete from t1|
drop procedure mixset|


200
# Multiple CALL statements, one with OUT parameter.
201 202 203
--disable_warnings
drop procedure if exists zip|
--enable_warnings
204 205 206 207 208 209 210 211
create procedure zip(x char(16), y int)
begin
  declare z int;
  call zap(y, z);
  call bar(x, z);
end|

# SET local variables and OUT parameter.
212 213 214
--disable_warnings
drop procedure if exists zap|
--enable_warnings
215 216 217 218 219 220
create procedure zap(x int, out y int)
begin
  declare z int;
  set z = x+1, y = z;
end|

221 222 223 224 225 226
call zip("zip", 99)|
select * from t1|
delete from t1|
drop procedure zip|
drop procedure bar|

227 228 229 230 231 232
# Top-level OUT parameter
call zap(7, @zap)|
select @zap|

drop procedure zap|

233

234
# "Deep" calls...
235 236 237
--disable_warnings
drop procedure if exists c1|
--enable_warnings
238 239
create procedure c1(x int)
  call c2("c", x)|
240 241 242
--disable_warnings
drop procedure if exists c2|
--enable_warnings
243 244
create procedure c2(s char(16), x int)
  call c3(x, s)|
245 246 247
--disable_warnings
drop procedure if exists c3|
--enable_warnings
248 249
create procedure c3(x int, s char(16))
  call c4("level", x, s)|
250 251 252
--disable_warnings
drop procedure if exists c4|
--enable_warnings
253 254 255 256 257 258 259 260 261 262 263
create procedure c4(l char(8), x int, s char(16))
  insert into t1 values (concat(l,s), x)|

call c1(42)|
select * from t1|
delete from t1|
drop procedure c1|
drop procedure c2|
drop procedure c3|
drop procedure c4|

264
# INOUT test
265 266 267
--disable_warnings
drop procedure if exists iotest|
--enable_warnings
268 269 270 271 272 273
create procedure iotest(x1 char(16), x2 char(16), y int)
begin
  call inc2(x2, y);
  insert into test.t1 values (x1, y);
end|

274 275 276
--disable_warnings
drop procedure if exists inc2|
--enable_warnings
277 278 279 280 281 282
create procedure inc2(x char(16), y int)
begin
  call inc(y);
  insert into test.t1 values (x, y);
end|

283 284 285
--disable_warnings
drop procedure if exists inc|
--enable_warnings
286 287 288
create procedure inc(inout io int)
  set io = io + 1|

289 290 291 292 293 294
call iotest("io1", "io2", 1)|
select * from t1|
delete from t1|
drop procedure iotest|
drop procedure inc2|

295
# Propagating top-level @-vars
296 297 298
--disable_warnings
drop procedure if exists incr|
--enable_warnings
299 300 301 302 303 304 305 306 307 308 309
create procedure incr(inout x int)
  call inc(x)|

# Before
select @zap|
call incr(@zap)|
# After
select @zap|

drop procedure inc|
drop procedure incr|
310 311 312 313 314

# Call-by-value test
#  The expected result is:
#    ("cbv2", 4)
#    ("cbv1", 4711)
315 316 317
--disable_warnings
drop procedure if exists cbv1|
--enable_warnings
318 319
create procedure cbv1()
begin
320
  declare y int default 3;
321 322 323 324 325

  call cbv2(y+1, y);
  insert into test.t1 values ("cbv1", y);
end|

326 327 328
--disable_warnings
drop procedure if exists cbv2|
--enable_warnings
329 330 331 332 333 334
create procedure cbv2(y1 int, inout y2 int)
begin
  set y2 = 4711;
  insert into test.t1 values ("cbv2", y1);
end|

335 336 337 338 339 340
call cbv1()|
select * from t1|
delete from t1|
drop procedure cbv1|
drop procedure cbv2|

341

pem@mysql.com's avatar
pem@mysql.com committed
342 343 344 345
# Subselect arguments

insert into t2 values ("a", 1, 1.1), ("b", 2, 1.2), ("c", 3, 1.3)|

346 347 348
--disable_warnings
drop procedure if exists sub1|
--enable_warnings
pem@mysql.com's avatar
pem@mysql.com committed
349 350 351
create procedure sub1(id char(16), x int)
  insert into test.t1 values (id, x)|

352 353 354 355 356 357 358 359 360
--disable_warnings
drop procedure if exists sub2|
--enable_warnings
create procedure sub2(id char(16))
begin
  declare x int;
  set x = (select sum(t.i) from test.t2 t);
  insert into test.t1 values (id, x);
end|
pem@mysql.com's avatar
pem@mysql.com committed
361

362 363 364
--disable_warnings
drop procedure if exists sub3|
--enable_warnings
pem@mysql.com's avatar
pem@mysql.com committed
365 366 367 368 369
create function sub3(i int) returns int
  return i+1|

call sub1("sub1a", (select 7))|
call sub1("sub1b", (select max(i) from t2))|
370
--error ER_OPERAND_COLUMNS
pem@mysql.com's avatar
pem@mysql.com committed
371 372
call sub1("sub1c", (select i,d from t2 limit 1))|
call sub1("sub1d", (select 1 from (select 1) a))|
373
call sub2("sub2")|
pem@mysql.com's avatar
pem@mysql.com committed
374 375 376
select * from t1|
select sub3((select max(i) from t2))|
drop procedure sub1|
377
drop procedure sub2|
pem@mysql.com's avatar
pem@mysql.com committed
378
drop function sub3|
379
delete from t1|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
380
delete from t2|
pem@mysql.com's avatar
pem@mysql.com committed
381

382
# Basic tests of the flow control constructs
383 384

# Just test on 'x'...
385 386 387
--disable_warnings
drop procedure if exists a0|
--enable_warnings
388 389 390 391 392 393
create procedure a0(x int)
while x do
  set x = x-1;
  insert into test.t1 values ("a0", x);
end while|

394 395 396 397 398 399
call a0(3)|
select * from t1|
delete from t1|
drop procedure a0|


400
# The same, but with a more traditional test.
401 402 403
--disable_warnings
drop procedure if exists a|
--enable_warnings
404 405 406 407 408 409
create procedure a(x int)
while x > 0 do
  set x = x-1;
  insert into test.t1 values ("a", x);
end while|

410 411 412 413 414 415
call a(3)|
select * from t1|
delete from t1|
drop procedure a|


416
# REPEAT
417 418 419
--disable_warnings
drop procedure if exists b|
--enable_warnings
420
create procedure b(x int)
421 422
repeat
  insert into test.t1 values (repeat("b",3), x);
423
  set x = x-1;
424
until x = 0 end repeat|
425

426 427 428 429 430 431
call b(3)|
select * from t1|
delete from t1|
drop procedure b|


432
# Check that repeat isn't parsed the wrong way
433 434 435
--disable_warnings
drop procedure if exists b2|
--enable_warnings
436 437 438 439 440
create procedure b2(x int)
repeat(select 1 into outfile 'b2');
  insert into test.t1 values (repeat("b2",3), x);
  set x = x-1;
until x = 0 end repeat|
441

442 443 444
# We don't actually want to call it.
drop procedure b2|

445

446
# Labelled WHILE with ITERATE (pointless really)
447 448 449
--disable_warnings
drop procedure if exists c|
--enable_warnings
450 451 452 453 454 455 456 457
create procedure c(x int)
hmm: while x > 0 do
  insert into test.t1 values ("c", x);
  set x = x-1;
  iterate hmm;
  insert into test.t1 values ("x", x);
end while hmm|

458 459 460 461 462 463
call c(3)|
select * from t1|
delete from t1|
drop procedure c|


464
# Labelled WHILE with LEAVE
465 466 467
--disable_warnings
drop procedure if exists d|
--enable_warnings
468 469 470 471 472 473
create procedure d(x int)
hmm: while x > 0 do
  insert into test.t1 values ("d", x);
  set x = x-1;
  leave hmm;
  insert into test.t1 values ("x", x);
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
474
end while|
475

476 477 478 479 480 481
call d(3)|
select * from t1|
delete from t1|
drop procedure d|


482
# LOOP, with simple IF statement
483 484 485
--disable_warnings
drop procedure if exists e|
--enable_warnings
486 487 488 489 490 491 492 493 494
create procedure e(x int)
foo: loop
  if x = 0 then
    leave foo;
  end if;
  insert into test.t1 values ("e", x);
  set x = x-1;
end loop foo|

495 496 497 498 499 500
call e(3)|
select * from t1|
delete from t1|
drop procedure e|


501
# A full IF statement
502 503 504
--disable_warnings
drop procedure if exists f|
--enable_warnings
505 506 507 508 509 510 511 512 513
create procedure f(x int)
if x < 0 then
  insert into test.t1 values ("f", 0);
elseif x = 0 then
  insert into test.t1 values ("f", 1);
else
  insert into test.t1 values ("f", 2);
end if|

514 515 516 517 518 519 520 521
call f(-2)|
call f(0)|
call f(4)|
select * from t1|
delete from t1|
drop procedure f|


522
# This form of CASE is really just syntactic sugar for IF-ELSEIF-...
523 524 525
--disable_warnings
drop procedure if exists g|
--enable_warnings
526 527 528 529 530 531 532 533 534 535
create procedure g(x int)
case
when x < 0 then
  insert into test.t1 values ("g", 0);
when x = 0 then
  insert into test.t1 values ("g", 1);
else
  insert into test.t1 values ("g", 2);
end case|

536 537 538 539 540 541 542 543
call g(-42)|
call g(0)|
call g(1)|
select * from t1|
delete from t1|
drop procedure g|


544
# The "simple CASE"
545 546 547
--disable_warnings
drop procedure if exists h|
--enable_warnings
548 549 550 551 552 553 554 555 556 557
create procedure h(x int)
case x
when 0 then
  insert into test.t1 values ("h0", x);
when 1 then
  insert into test.t1 values ("h1", x);
else
  insert into test.t1 values ("h?", x);
end case|

558 559 560 561 562 563 564 565
call h(0)|
call h(1)|
call h(17)|
select * from t1|
delete from t1|
drop procedure h|


pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
566
# It's actually possible to LEAVE a BEGIN-END block
567 568 569
--disable_warnings
drop procedure if exists i|
--enable_warnings
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585
create procedure i(x int)
foo:
begin
  if x = 0 then
    leave foo;
  end if;
  insert into test.t1 values ("i", x);
end foo|

call i(0)|
call i(3)|
select * from t1|
delete from t1|
drop procedure i|


pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
586 587 588 589
# SELECT with one of more result set sent back to the clinet
insert into t1 values ("foo", 3), ("bar", 19)|
insert into t2 values ("x", 9, 4.1), ("y", -1, 19.2), ("z", 3, 2.2)|

590 591 592
--disable_warnings
drop procedure if exists sel1|
--enable_warnings
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
593 594 595 596 597 598 599 600
create procedure sel1()
begin
  select * from t1;
end|

call sel1()|
drop procedure sel1|

601 602 603
--disable_warnings
drop procedure if exists sel2|
--enable_warnings
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
604 605 606 607 608 609 610 611 612 613 614
create procedure sel2()
begin
  select * from t1;
  select * from t2;
end|

call sel2()|
drop procedure sel2|
delete from t1|
delete from t2|

615
# SELECT INTO local variables
616 617 618
--disable_warnings
drop procedure if exists into_test|
--enable_warnings
619 620 621 622 623 624 625
create procedure into_test(x char(16), y int)
begin
  insert into test.t1 values (x, y);
  select id,data into x,y from test.t1 limit 1;
  insert into test.t1 values (concat(x, "2"), y+2);
end|

626 627 628 629 630 631 632
call into_test("into", 100)|
select * from t1|
delete from t1|
drop procedure into_test|


# SELECT INTO with a mix of local and global variables
633 634 635
--disable_warnings
drop procedure if exists into_tes2|
--enable_warnings
636
create procedure into_test2(x char(16), y int)
637 638
begin
  insert into test.t1 values (x, y);
639 640
  select id,data into x,@z from test.t1 limit 1;
  insert into test.t1 values (concat(x, "2"), y+2);
641 642
end|

643 644 645 646
call into_test2("into", 100)|
select id,data,@z from t1|
delete from t1|
drop procedure into_test2|
647 648


649
# SELECT * INTO ... (bug test)
650 651 652
--disable_warnings
drop procedure if exists into_test3|
--enable_warnings
653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673
create procedure into_test3()
begin
  declare x char(16);
  declare y int;

  select * into x,y from test.t1 limit 1;
  insert into test.t2 values (x, y, 0.0);
end|

insert into t1 values ("into3", 19)|
# Two call needed for bug test
call into_test3()|
call into_test3()|
select * from t2|
delete from t1|
delete from t2|
drop procedure into_test3|


# SELECT INTO with no data is a warning ("no data", which we will
# not see normally). When not caught, execution proceeds.
674 675 676
--disable_warnings
drop procedure if exists into_test4|
--enable_warnings
677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696
create procedure into_test4()
begin
  declare x int;

  select data into x from test.t1 limit 1;
  insert into test.t3 values ("into4", x);
end|

delete from t1|
create table t3 ( s char(16), d int)|
call into_test4()|
select * from t3|
insert into t1 values ("i4", 77)|
call into_test4()|
select * from t3|
delete from t1|
drop table t3|
drop procedure into_test4|


697 698
# These two (and the two procedures above) caused an assert() to fail in
# sql_base.cc:lock_tables() at some point.
699 700 701
--disable_warnings
drop procedure if exists into_outfile|
--enable_warnings
702 703 704 705 706 707
create procedure into_outfile(x char(16), y int)
begin
  insert into test.t1 values (x, y);
  select * into outfile "/tmp/spout" from test.t1;
  insert into test.t1 values (concat(x, "2"), y+2);
end|
708

709 710 711 712 713
system rm -f /tmp/spout|
call into_outfile("ofile", 1)|
system rm -f /tmp/spout|
delete from t1|
drop procedure into_outfile|
714

715 716 717
--disable_warnings
drop procedure if exists into_dumpfile|
--enable_warnings
718 719 720 721 722 723
create procedure into_dumpfile(x char(16), y int)
begin
  insert into test.t1 values (x, y);
  select * into dumpfile "/tmp/spdump" from test.t1 limit 1;
  insert into test.t1 values (concat(x, "2"), y+2);
end|
724

725 726 727 728 729
system rm -f /tmp/spdump|
call into_dumpfile("dfile", 1)|
system rm -f /tmp/spdump|
delete from t1|
drop procedure into_dumpfile|
730

731 732 733
--disable_warnings
drop procedure if exists create_select|
--enable_warnings
734 735 736
create procedure create_select(x char(16), y int)
begin
  insert into test.t1 values (x, y);
737
  create temporary table test.t3 select * from test.t1;
pem@mysql.com's avatar
pem@mysql.com committed
738
  insert into test.t3 values (concat(x, "2"), y+2);
739
end|
740

pem@mysql.com's avatar
pem@mysql.com committed
741 742
call create_select("cs", 90)|
select * from t1, t3|
743
drop table t3|
pem@mysql.com's avatar
pem@mysql.com committed
744
delete from t1|
745
drop procedure create_select|
746

pem@mysql.com's avatar
pem@mysql.com committed
747

748
# A minimal, constant FUNCTION.
749 750 751
--disable_warnings
drop function if exists e|
--enable_warnings
752 753 754
create function e() returns double
  return 2.7182818284590452354|

755 756
set @e = e()|
select e(), @e|
757 758

# A minimal function with one argument
759 760 761
--disable_warnings
drop function if exists inc|
--enable_warnings
762 763 764 765
create function inc(i int) returns int
  return i+1|

select inc(1), inc(99), inc(-71)|
766

767
# A minimal function with two arguments
768 769 770
--disable_warnings
drop function if exists mul|
--enable_warnings
771 772
create function mul(x int, y int) returns int
  return x*y|
773

774 775
select mul(1,1), mul(3,5), mul(4711, 666)|

776
# A minimal string function
777 778 779
--disable_warnings
drop function if exists append|
--enable_warnings
780 781 782 783 784
create function append(s1 char(8), s2 char(8)) returns char(16)
  return concat(s1, s2)|

select append("foo", "bar")|

785
# A function with flow control
786 787 788
--disable_warnings
drop function if exists fac|
--enable_warnings
789 790
create function fac(n int unsigned) returns bigint unsigned
begin
791
  declare f bigint unsigned default 1;
792 793 794 795 796 797 798 799

  while n > 1 do
    set f = f * n;
    set n = n - 1;
  end while;
  return f;
end|

800
select fac(1), fac(2), fac(5), fac(10)|
801

802
# Nested calls
803 804 805
--disable_warnings
drop function if exists fun|
--enable_warnings
806 807 808 809 810 811 812 813 814 815 816
create function fun(d double, i int, u int unsigned) returns double
  return mul(inc(i), fac(u)) / e()|

select fun(2.3, 3, 5)|


# Various function calls in differen statements

insert into t2 values (append("xxx", "yyy"), mul(4,3), e())|
insert into t2 values (append("a", "b"), mul(2,mul(3,4)), fun(1.7, 4, 6))|

monty@mysql.com's avatar
monty@mysql.com committed
817
# Disable PS because double's give a bit different values
818
--disable_ps_protocol
819 820 821 822
select * from t2 where s = append("a", "b")|
select * from t2 where i = mul(4,3) or i = mul(mul(3,4),2)|
select * from t2 where d = e()|
select * from t2|
823
--enable_ps_protocol
824 825
delete from t2|

826 827 828
drop function e|
drop function inc|
drop function mul|
829
drop function append|
830
drop function fun|
831

832

833 834 835 836
#
# CONDITIONs and HANDLERs
#

837 838 839
--disable_warnings
drop procedure if exists hndlr1|
--enable_warnings
840 841 842
create procedure hndlr1(val int)
begin
  declare x int default 0;
843
  declare foo condition for 1136;
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
844 845
  declare bar condition for sqlstate '42S98';        # Just for testing syntax
  declare zip condition for sqlstate value '42S99';  # Just for testing syntax
846 847
  declare continue handler for foo set x = 1;

848
  insert into test.t1 values ("hndlr1", val, 2);  # Too many values
849 850 851 852 853 854 855 856 857 858
  if (x) then
    insert into test.t1 values ("hndlr1", val);   # This instead then
  end if;
end|

call hndlr1(42)|
select * from t1|
delete from t1|
drop procedure hndlr1|

859 860 861
--disable_warnings
drop procedure if exists hndlr2|
--enable_warnings
862 863 864 865 866
create procedure hndlr2(val int)
begin
  declare x int default 0;

  begin
867
    declare exit handler for sqlstate '21S01' set x = 1;
868

869
    insert into test.t1 values ("hndlr2", val, 2); # Too many values
870 871 872 873 874 875 876 877 878 879 880
  end;

  insert into test.t1 values ("hndlr2", x);
end|

call hndlr2(42)|
select * from t1|
delete from t1|
drop procedure hndlr2|


881 882 883
--disable_warnings
drop procedure if exists hndlr3|
--enable_warnings
884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899
create procedure hndlr3(val int)
begin
  declare x int default 0;
  declare continue handler for sqlexception        # Any error
  begin
    declare z int;

    set z = 2 * val;
    set x = 1;
  end;

  if val < 10 then
    begin
      declare y int;

      set y = val + 10;
900
      insert into test.t1 values ("hndlr3", y, 2);  # Too many values
901 902 903 904 905 906 907 908 909 910 911 912
      if x then
        insert into test.t1 values ("hndlr3", y);
      end if;
    end;
  end if;
end|

call hndlr3(3)|
select * from t1|
delete from t1|
drop procedure hndlr3|

913 914 915 916

# Variables might be uninitialized when using handlers
# (Otherwise the compiler can detect if a variable is not set, but
#  not in this case.)
917 918
create table t3 ( id   char(16), data int )|

919 920 921
--disable_warnings
drop procedure if exists hndlr4|
--enable_warnings
922 923 924 925
create procedure hndlr4()
begin
  declare x int default 0;
  declare val int;	                           # No default
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
926
  declare continue handler for sqlstate '02000' set x=1;
927

928
  select data into val from test.t3 where id='z' limit 1;  # No hits
929

930
  insert into test.t3 values ('z', val);
931 932 933
end|

call hndlr4()|
934 935
select * from t3|
drop table t3|
936 937 938
drop procedure hndlr4|


939 940 941
#
# Cursors
#
942 943 944
--disable_warnings
drop procedure if exists cur1|
--enable_warnings
945 946 947 948 949
create procedure cur1()
begin
  declare a char(16);
  declare b int;
  declare c double;
950 951 952
  declare done int default 0;
  declare c cursor for select * from test.t2;
  declare continue handler for sqlstate '02000' set done = 1;
953 954 955 956 957 958 959 960 961 962 963 964 965 966

  open c;
  repeat
    fetch c into a, b, c;
    if not done then
       insert into test.t1 values (a, b+c);
    end if;
  until done end repeat;
  close c;
end|

insert into t2 values ("foo", 42, -1.9), ("bar", 3, 12.1), ("zap", 666, -3.14)|
call cur1()|
select * from t1|
967 968 969 970
drop procedure cur1|

create table t3 ( s char(16), i int )|

971 972 973
--disable_warnings
drop procedure if exists cur2|
--enable_warnings
974 975 976 977 978
create procedure cur2()
begin
  declare done int default 0;
  declare c1 cursor for select id,data from test.t1;
  declare c2 cursor for select i from test.t2;
979
  declare continue handler for sqlstate '02000' set done = 1;
980 981 982 983 984 985 986 987

  open c1;
  open c2;
  repeat
  begin
    declare a char(16);
    declare b,c int;

988 989
    fetch from c1 into a, b;
    fetch next from c2 into c;
990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004
    if not done then
      if b < c then
        insert into test.t3 values (a, b);
      else
        insert into test.t3 values (a, c);
      end if;
    end if;
  end;
  until done end repeat;
  close c1;
  close c2;
end|

call cur2()|
select * from t3|
1005 1006
delete from t1|
delete from t2|
1007 1008
drop table t3|
drop procedure cur2|
1009

1010

1011
# The few characteristics we parse
1012 1013 1014
--disable_warnings
drop procedure if exists chistics|
--enable_warnings
1015
create procedure chistics()
1016 1017 1018 1019 1020 1021 1022 1023
    language sql
    modifies sql data
    not deterministic
    sql security definer
    comment 'Characteristics procedure test'
  insert into t1 values ("chistics", 1)|

show create procedure chistics|
1024 1025 1026 1027
# Call it, just to make sure.
call chistics()|
select * from t1|
delete from t1|
1028 1029 1030
alter procedure chistics sql security invoker|
show create procedure chistics|
drop procedure chistics|
1031

1032 1033 1034
--disable_warnings
drop function if exists chistics|
--enable_warnings
1035
create function chistics() returns int
1036 1037 1038 1039 1040
    language sql
    deterministic
    sql security invoker
    comment 'Characteristics procedure test'
  return 42|
1041

1042
show create function chistics|
1043 1044
# Call it, just to make sure.
select chistics()|
1045
alter function chistics
1046 1047
   no sql
   comment 'Characteristics function test'|
1048 1049
show create function chistics|
drop function chistics|
1050 1051


1052 1053 1054 1055 1056
# Check mode settings
insert into t1 values ("foo", 1), ("bar", 2), ("zip", 3)|

set @@sql_mode = 'ANSI'|
delimiter $|
1057 1058 1059
--disable_warnings
drop procedure if exists modes$
--enable_warnings
1060 1061 1062 1063 1064
create procedure modes(out c1 int, out c2 int)
begin
  declare done int default 0;
  declare x int;
  declare c cursor for select data from t1;
1065
  declare continue handler for sqlstate '02000' set done = 1;
1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089

  select 1 || 2 into c1;
  set c2 = 0;
  open c;
  repeat
    fetch c into x;
    if not done then
      set c2 = c2 + 1;
    end if;
  until done end repeat;
  close c;
end$
delimiter |$
set @@sql_mode = ''|

set sql_select_limit = 1|
call modes(@c1, @c2)|
set sql_select_limit = default|

select @c1, @c2|
delete from t1|
drop procedure modes|


1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107
# Check that dropping a database without routines works.
# (Dropping with routines is tested in sp-security.test)
# First an empty db.
create database sp_db1|
drop database sp_db1|

# Again, with a table.
create database sp_db2|
use sp_db2|
# Just put something in here...
create table t3 ( s char(4), t int )|
insert into t3 values ("abcd", 42), ("dcba", 666)|
use test|
drop database sp_db2|

# And yet again, with just a procedure.
create database sp_db3|
use sp_db3|
1108 1109 1110
--disable_warnings
drop procedure if exists dummy|
--enable_warnings
1111 1112 1113 1114 1115 1116 1117 1118
create procedure dummy(out x int)
  set x = 42|
use test|
drop database sp_db3|
# Check that it's gone
select type,db,name from mysql.proc where db = 'sp_db3'|


1119 1120
# ROW_COUNT() function after a CALL
# We test the other cases here too, although it's not strictly SP specific
1121 1122 1123
--disable_warnings
drop procedure if exists rc|
--enable_warnings
1124 1125 1126 1127 1128 1129 1130 1131
create procedure rc()
begin
  delete from t1;
  insert into t1 values ("a", 1), ("b", 2), ("c", 3);
end|

call rc()|
select row_count()|
1132
--disable_ps_protocol
1133 1134
update t1 set data=42 where id = "b";
select row_count()|
1135
--enable_ps_protocol
1136 1137 1138 1139
delete from t1|
select row_count()|
delete from t1|
select row_count()|
1140 1141
select * from t1|
select row_count()|
1142 1143 1144
drop procedure rc|


1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159
#
# Let us test how well new locking scheme works.
#

# Let us prepare playground
--disable_warnings
drop function if exists f0|
drop function if exists f1|
drop function if exists f2|
drop function if exists f3|
drop function if exists f4|
drop function if exists f5|
drop function if exists f6|
drop function if exists f7|
drop function if exists f8|
1160 1161 1162 1163 1164
drop function if exists f9|
drop function if exists f10|
drop function if exists f11|
drop function if exists f12_1|
drop function if exists f12_2|
1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221
drop view if exists v0|
drop view if exists v1|
drop view if exists v2|
--enable_warnings
delete from t1|
delete from t2|
insert into t1 values ("a", 1), ("b", 2) |
insert into t2 values ("a", 1, 1.0), ("b", 2, 2.0), ("c", 3, 3.0) |

# Test the simplest function using tables
create function f1() returns int
  return (select sum(data) from t1)|
select f1()|
# This should work too (and give 2 rows as result)
select id, f1() from t1|

# Function which uses two instances of table simultaneously
create function f2() returns int
  return (select data from t1 where data <= (select sum(data) from t1) limit 1)|
select f2()|
select id, f2() from t1|

# Function which uses the same table twice in different queries
create function f3() returns int
begin
  declare n int;
  declare m int;
  set n:= (select min(data) from t1);
  set m:= (select max(data) from t1);
  return n < m;
end|
select f3()|
select id, f3() from t1|

# Calling two functions using same table
select f1(), f3()|
select id, f1(), f3() from t1|

# Function which uses two different tables
create function f4() returns double 
  return (select d from t1, t2 where t1.data = t2.i and t1.id= "b")|
select f4()|
select s, f4() from t2|

# Recursive functions which due to this recursion require simultaneous
# access to several instance of the same table won't work
create function f5(i int) returns int
begin
  if i <= 0 then
    return 0;
  elseif i = 1  then
    return (select count(*) from t1 where data = i);
  else
    return (select count(*) + f5( i - 1) from t1 where data = i);
  end if;
end|
select f5(1)|
1222 1223 1224 1225
# Since currently recursive functions are disallowed ER_SP_NO_RECURSION
# error will be returned, once we will allow them error about
# insufficient number of locked tables will be returned instead.
--error ER_SP_NO_RECURSION
1226
select f5(2)|
1227
--error ER_SP_NO_RECURSION
1228
select f5(3)|
1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271

# OTOH this should work 
create function f6() returns int
begin
  declare n int;
  set n:= f1();
  return (select count(*) from t1 where data <= f7() and data <= n);
end|
create function f7() returns int
  return (select sum(data) from t1 where data <= f1())|
select f6()|
select id, f6() from t1|

#
# Let us test how new locking work with views
#
# The most trivial view
create view v1 (a) as select f1()|
select * from v1|
select id, a from t1, v1|
select * from v1, v1 as v|
# A bit more complex construction
create view v2 (a) as select a*10 from v1|
select * from v2|
select id, a from t1, v2|
select * from v1, v2|

# Nice example where the same view is used on
# on different expression levels
create function f8 () returns int
  return (select count(*) from v2)|

select *, f8() from v1|

# Let us test what will happen if function is missing
drop function f1|
--error 1356
select * from v1|

# And what will happen if we have recursion which involves
# views and functions ?
create function f1() returns int
  return (select sum(data) from t1) + (select sum(data) from v1)|
1272
--error ER_SP_NO_RECURSION
1273
select f1()|
1274
--error ER_SP_NO_RECURSION
1275
select * from v1|
1276
--error ER_SP_NO_RECURSION
1277
select * from v2|
1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294
# Back to the normal cases
drop function f1|
create function f1() returns int
  return (select sum(data) from t1)|

# Let us also test some weird cases where no real tables is used
create function f0() returns int
  return (select * from (select 100) as r)|
select f0()|
select *, f0() from (select 1) as t|
create view v0 as select f0()|
select * from v0|
select *, f0() from v0|

#
# Let us test how well prelocking works with explicit LOCK TABLES.
#
1295
lock tables t1 read, t1 as t11 read|
1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316
# These should work well
select f3()|
select id, f3() from t1 as t11|
# Degenerate cases work too :)
select f0()|
select * from v0|
select *, f0() from v0, (select 123) as d1|
# But these should not !
--error 1100
select id, f3() from t1|
--error 1100
select f4()|
unlock tables|

# Let us test how LOCK TABLES which implicitly depends on functions
# works
lock tables v2 read, mysql.proc read|
select * from v2|
select * from v1|
# These should not work as we have too little instances of tables locked
--error 1100
1317
select * from v1, t1|
1318 1319 1320 1321
--error 1100
select f4()|
unlock tables|

1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388
# Tests for handling of temporary tables in functions.
#
# Unlike for permanent tables we should be able to create, use
# and drop such tables in functions.
# 
# Simplest function using temporary table. It is also test case for bug 
# #12198 "Temporary table aliasing does not work inside stored functions"
create function f9() returns int
begin
  declare a, b int;
  drop temporary table if exists t3;
  create temporary table t3 (id int);
  insert into t3 values (1), (2), (3);
  set a:= (select count(*) from t3);
  set b:= (select count(*) from t3 t3_alias);
  return a + b;
end|
# This will emit warning as t3 was not existing before.
select f9()|
select f9() from t1 limit 1|

# Function which uses both temporary and permanent tables.
create function f10() returns int
begin
  drop temporary table if exists t3;
  create temporary table t3 (id int);
  insert into t3 select id from t4;
  return (select count(*) from t3);
end|
# Check that we don't ignore completely tables used in function
--error ER_NO_SUCH_TABLE
select f10()|
create table t4 as select 1 as id|
select f10()|

# Practical cases which we don't handle well (yet)
#
# Function which does not work because of well-known and documented
# limitation of MySQL. We can't use the several instances of the
# same temporary table in statement.
create function f11() returns int
begin
  drop temporary table if exists t3;
  create temporary table t3 (id int);
  insert into t3 values (1), (2), (3);
  return (select count(*) from t3 as a, t3 as b);
end|
--error ER_CANT_REOPEN_TABLE
select f11()|
--error ER_CANT_REOPEN_TABLE
select f11() from t1|
# We don't handle temporary tables used by nested functions well
create function f12_1() returns int
begin
  drop temporary table if exists t3;
  create temporary table t3 (id int);
  insert into t3 values (1), (2), (3);
  return f12_2();
end|
create function f12_2() returns int
  return (select count(*) from t3)|
# We need clean start to get error
drop temporary table t3|
--error ER_NO_SUCH_TABLE
select f12_1()|
--error ER_NO_SUCH_TABLE
select f12_1() from t1 limit 1|
1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399

# Cleanup
drop function f0|
drop function f1|
drop function f2|
drop function f3|
drop function f4|
drop function f5|
drop function f6|
drop function f7|
drop function f8|
1400 1401 1402 1403 1404
drop function f9|
drop function f10|
drop function f11|
drop function f12_1|
drop function f12_2|
1405 1406 1407 1408 1409
drop view v0|
drop view v1|
drop view v2|
delete from t1 |
delete from t2 |
1410
drop table t4|
1411 1412 1413 1414

# End of non-bug tests


1415 1416 1417 1418 1419 1420 1421
#
# Some "real" examples
#

# fac

--disable_warnings
1422
drop table if exists t3|
1423
--enable_warnings
1424
create table t3 (n int unsigned not null primary key, f bigint unsigned)|
1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437

--disable_warnings
drop procedure if exists ifac|
--enable_warnings
create procedure ifac(n int unsigned)
begin
  declare i int unsigned default 1;

  if n > 20 then
    set n = 20;		# bigint overflow otherwise
  end if;
  while i <= n do
    begin
1438
      insert into test.t3 values (i, fac(i));
1439 1440 1441 1442 1443 1444
      set i = i + 1;
    end;
  end while;
end|

call ifac(20)|
1445 1446
select * from t3|
drop table t3|
1447
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1448 1449 1450
show function status like '%f%'|
drop procedure ifac|
drop function fac|
1451
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1452 1453 1454 1455 1456 1457
show function status like '%f%'|


# primes

--disable_warnings
1458
drop table if exists t3|
1459 1460
--enable_warnings

1461
create table t3 (
1462 1463 1464 1465
  i int unsigned not null primary key,
  p bigint unsigned not null
)|

1466
insert into t3 values
1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494
 ( 0,   3), ( 1,   5), ( 2,   7), ( 3,  11), ( 4,  13),
 ( 5,  17), ( 6,  19), ( 7,  23), ( 8,  29), ( 9,  31),
 (10,  37), (11,  41), (12,  43), (13,  47), (14,  53),
 (15,  59), (16,  61), (17,  67), (18,  71), (19,  73),
 (20,  79), (21,  83), (22,  89), (23,  97), (24, 101),
 (25, 103), (26, 107), (27, 109), (28, 113), (29, 127),
 (30, 131), (31, 137), (32, 139), (33, 149), (34, 151),
 (35, 157), (36, 163), (37, 167), (38, 173), (39, 179),
 (40, 181), (41, 191), (42, 193), (43, 197), (44, 199)|

--disable_warnings
drop procedure if exists opp|
--enable_warnings
create procedure opp(n bigint unsigned, out pp bool)
begin
  declare r double;
  declare b, s bigint unsigned default 0;

  set r = sqrt(n);

 again:
  loop
    if s = 45 then
      set b = b+200, s = 0;
    else
      begin
        declare p bigint unsigned;

1495
        select t.p into p from test.t3 t where t.i = s;
1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525
        if b+p > r then
          set pp = 1;
          leave again;
        end if;
        if mod(n, b+p) = 0 then
          set pp = 0;
          leave again;
        end if;
        set s = s+1;
      end;
    end if;
  end loop;
end|

--disable_warnings
drop procedure if exists ip|
--enable_warnings
create procedure ip(m int unsigned)
begin
  declare p bigint unsigned;
  declare i int unsigned;

  set i=45, p=201;

  while i < m do
    begin
      declare pp bool default 0;

      call opp(p, pp);
      if pp then
1526
        insert into test.t3 values (i, p);
1527 1528 1529 1530 1531 1532 1533
        set i = i+1;
      end if;
      set p = p+2;
    end;
  end while;
end|
show create procedure opp|
1534
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547
show procedure status like '%p%'|

# This isn't the fastest way in the world to compute prime numbers, so
# don't be too ambitious. ;-)
call ip(200)|
# We don't want to select the entire table here, just pick a few
# examples.
# The expected result is:
#    i      p
#   ---   ----
#    45    211
#   100    557
#   199   1229
1548 1549
select * from t3 where i=45 or i=100 or i=199|
drop table t3|
1550 1551
drop procedure opp|
drop procedure ip|
1552
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1553 1554 1555 1556
show procedure status like '%p%'|


# Fibonacci, for recursion test. (Yet Another Numerical series :)
1557
#
1558
--disable_warnings
1559
drop table if exists t3|
1560
--enable_warnings
1561
create table t3 ( f bigint unsigned not null )|
1562

1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573
# We deliberately do it the awkward way, fetching the last two
# values from the table, in order to exercise various statements
# and table accesses at each turn.
--disable_warnings
drop procedure if exists fib|
--enable_warnings
create procedure fib(n int unsigned)
begin
  if n > 1 then
    begin
      declare x, y bigint unsigned;
1574
      declare c cursor for select f from t3 order by f desc limit 2;
1575 1576 1577 1578 1579

      open c;
      fetch c into y;
      fetch c into x;
      close c;
1580
      insert into t3 values (x+y);
1581 1582 1583 1584 1585
      call fib(n-1);
    end;
  end if;
end|

1586 1587 1588
# Enable recursion
set @@max_sp_recursion_depth= 20|

1589 1590
# Minimum test: recursion of 3 levels

1591
insert into t3 values (0), (1)|
1592 1593 1594

call fib(3)|

1595
select * from t3 order by f asc|
1596

1597
delete from t3|
1598

1599 1600
# The original test, 20 levels, ran into memory limits on some machines
# and builds. Try 10 instead...
1601

1602
insert into t3 values (0), (1)|
1603

1604
call fib(10)|
1605

1606 1607
select * from t3 order by f asc|
drop table t3|
1608
drop procedure fib|
1609
set @@max_sp_recursion_depth= 0|
1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620

#
# Comment & suid
#

--disable_warnings
drop procedure if exists bar|
--enable_warnings
create procedure bar(x char(16), y int)
 comment "111111111111" sql security invoker
 insert into test.t1 values (x, y)|
1621
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1622 1623 1624 1625 1626
show procedure status like 'bar'|
alter procedure bar comment "2222222222" sql security definer|
alter procedure bar comment "3333333333"|
alter procedure bar|
show create procedure bar|
1627
--replace_column 4 'root@localhost' 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706
show procedure status like 'bar'|
drop procedure bar|

#
# rexecution
#
--disable_warnings
drop procedure if exists p1|
--enable_warnings
create procedure p1 ()
  select (select s1 from t3) from t3|

create table t3 (s1 int)|

call p1()|
insert into t3 values (1)|
call p1()|
drop procedure p1|
drop table t3|

#
# backticks
#
--disable_warnings
drop function if exists foo|
--enable_warnings
create function `foo` () returns int
  return 5|
select `foo` ()|
drop function `foo`|

#
# Implicit LOCK/UNLOCK TABLES for table access in functions
#

--disable_warning
drop function if exists t1max|
--enable_warnings
create function t1max() returns int
begin
  declare x int;
  select max(data) into x from t1;
  return x;
end|

insert into t1 values ("foo", 3), ("bar", 2), ("zip", 5), ("zap", 1)|
select t1max()|
drop function t1max|

create table t3 (
  v char(16) not null primary key,
  c int unsigned not null
)|

create function getcount(s char(16)) returns int
begin
  declare x int;

  select count(*) into x from t3 where v = s;
  if x = 0 then
    insert into t3 values (s, 1);
  else
    update t3 set c = c+1 where v = s;
  end if;
  return x;
end|

select * from t1 where data = getcount("bar")|
select * from t3|
select getcount("zip")|
select getcount("zip")|
select * from t3|
select getcount(id) from t1 where data = 3|
select getcount(id) from t1 where data = 5|
select * from t3|
drop table t3|
drop function getcount|


1707 1708 1709 1710
#
# Test cases for old bugs
#

1711 1712 1713
#
# BUG#822
#
1714 1715 1716 1717
--disable_warnings
drop procedure if exists bug822|
--enable_warnings
create procedure bug822(a_id char(16), a_data int)
1718 1719 1720 1721 1722 1723 1724 1725
begin
  declare n int;
  select count(*) into n from t1 where id = a_id and data = a_data;
  if n = 0 then
    insert into t1 (id, data) values (a_id, a_data);
  end if;
end|

1726
delete from t1|
1727 1728 1729
call bug822('foo', 42)|
call bug822('foo', 42)|
call bug822('bar', 666)|
1730 1731
select * from t1|
delete from t1|
1732
drop procedure bug822|
1733

1734 1735 1736
#
# BUG#1495
#
1737 1738 1739 1740
--disable_warnings
drop procedure if exists bug1495|
--enable_warnings
create procedure bug1495()
1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752
begin
  declare x int;

  select data into x from t1 order by id limit 1;
  if x > 10 then
    insert into t1 values ("less", x-10);
  else
    insert into t1 values ("more", x+10);
  end if;
end|

insert into t1 values ('foo', 12)|
1753
call bug1495()|
1754 1755
delete from t1 where id='foo'|
insert into t1 values ('bar', 7)|
1756
call bug1495()|
1757 1758 1759
delete from t1 where id='bar'|
select * from t1|
delete from t1|
1760
drop procedure bug1495|
1761

1762 1763 1764
#
# BUG#1547
#
1765 1766 1767 1768
--disable_warnings
drop procedure if exists bug1547|
--enable_warnings
create procedure bug1547(s char(16))
1769 1770 1771 1772 1773 1774 1775 1776 1777 1778 1779 1780
begin
  declare x int;

  select data into x from t1 where s = id limit 1;
  if x > 10 then
    insert into t1 values ("less", x-10);
  else
    insert into t1 values ("more", x+10);
  end if;
end|

insert into t1 values ("foo", 12), ("bar", 7)|
1781 1782
call bug1547("foo")|
call bug1547("bar")|
1783 1784
select * from t1|
delete from t1|
1785
drop procedure bug1547|
1786

1787 1788 1789 1790 1791 1792 1793 1794 1795
#
# BUG#1656
#
--disable_warnings
drop table if exists t70|
--enable_warnings
create table t70 (s1 int,s2 int)|
insert into t70 values (1,2)|

1796 1797 1798 1799
--disable_warnings
drop procedure if exists bug1656|
--enable_warnings
create procedure bug1656(out p1 int, out p2 int)
1800 1801
  select * into p1, p1 from t70|

1802
call bug1656(@1, @2)|
1803 1804
select @1, @2|
drop table t70|
1805
drop procedure bug1656|
1806

1807 1808 1809 1810 1811
#
# BUG#1862
#
create table t3(a int)|

1812 1813 1814 1815
--disable_warnings
drop procedure if exists bug1862|
--enable_warnings
create procedure bug1862()
1816 1817 1818 1819 1820
begin
  insert into t3 values(2);    
  flush tables;
end|

1821
call bug1862()|
1822
# the second call caused a segmentation
1823
call bug1862()|
1824 1825
select * from t3|
drop table t3|
1826
drop procedure bug1862|
1827

1828 1829 1830
#
# BUG#1874
#
1831 1832 1833 1834
--disable_warnings
drop procedure if exists bug1874|
--enable_warnings
create procedure bug1874()
1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848
begin
  declare x int;
  declare y double;
  select max(data) into x from t1;
  insert into t2 values ("max", x, 0);
  select min(data) into x from t1;
  insert into t2 values ("min", x, 0);
  select sum(data) into x from t1;
  insert into t2 values ("sum", x, 0);
  select avg(data) into y from t1;
  insert into t2 values ("avg", 0, y);
end|

insert into t1 (data) values (3), (1), (5), (9), (4)|
1849
call bug1874()|
1850 1851 1852
select * from t2|
delete from t1|
delete from t2|
1853
drop procedure bug1874|
1854

1855 1856 1857
#
# BUG#2260
#
1858 1859 1860 1861
--disable_warnings
drop procedure if exists bug2260|
--enable_warnings
create procedure bug2260()
1862 1863 1864
begin
  declare v1 int;
  declare c1 cursor for select data from t1;
1865
  declare continue handler for not found set @x2 = 1;
1866 1867 1868 1869 1870 1871 1872

  open c1;
  fetch c1 into v1;
  set @x2 = 2;
  close c1;
end|

1873
call bug2260()|
1874
select @x2|
1875
drop procedure bug2260|
1876

1877
#
1878
# BUG#2267 "Lost connect if stored procedure has SHOW FUNCTION STATUS"
1879
#
1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905
--disable_warnings
drop procedure if exists bug2267_1|
--enable_warnings
create procedure bug2267_1()
begin
  show procedure status;
end|

--disable_warnings
drop procedure if exists bug2267_2|
--enable_warnings
create procedure bug2267_2()
begin
  show function status;
end|

--disable_warnings
drop procedure if exists bug2267_3|
--enable_warnings
create procedure bug2267_3()
begin
  show create procedure bug2267_1;
end|

--disable_warnings
drop procedure if exists bug2267_4|
1906
drop function if exists bug2267_4|
1907 1908 1909
--enable_warnings
create procedure bug2267_4()
begin
1910
  show create function bug2267_4;
1911
end|
1912
create function bug2267_4() returns int return 100|
1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924

--replace_column 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
call bug2267_1()|
--replace_column 5 '0000-00-00 00:00:00' 6 '0000-00-00 00:00:00'
call bug2267_2()|
call bug2267_3()|
call bug2267_4()|

drop procedure bug2267_1|
drop procedure bug2267_2|
drop procedure bug2267_3|
drop procedure bug2267_4|
1925
drop function bug2267_4|
1926

1927 1928 1929
#
# BUG#2227
#
1930 1931 1932 1933
--disable_warnings
drop procedure if exists bug2227|
--enable_warnings
create procedure bug2227(x int)
1934 1935 1936 1937 1938 1939 1940
begin
  declare y float default 2.6;
  declare z char(16) default "zzz";

  select 1.3, x, y, 42, z;
end|

1941 1942
call bug2227(9)|
drop procedure bug2227|
1943

1944
#
1945 1946
# BUG#2614 "Stored procedure with INSERT ... SELECT that does not
#           contain any tables crashes server"
1947
#
1948 1949 1950 1951 1952
--disable_warnings
drop procedure if exists bug2614|
--enable_warnings
create procedure bug2614()
begin
1953 1954
  drop table if exists t3;
  create table t3 (id int default '0' not null);
1955 1956 1957 1958 1959 1960 1961 1962
  insert into t3 select 12;
  insert into t3 select * from t3;
end|

--disable_warnings
call bug2614()|
--enable_warnings
call bug2614()|
1963
drop table t3|
1964
drop procedure bug2614|
1965

1966 1967 1968
#
# BUG#2674
#
1969 1970 1971 1972
--disable_warnings
drop function if exists bug2674|
--enable_warnings
create function bug2674() returns int
1973 1974
  return @@sort_buffer_size|

1975 1976
set @osbs = @@sort_buffer_size|
set @@sort_buffer_size = 262000|
1977 1978
select bug2674()|
drop function bug2674|
1979
set @@sort_buffer_size = @osbs|
1980

1981 1982 1983
#
# BUG#3259
#
1984 1985 1986
--disable_warnings
drop procedure if exists bug3259_1 |
--enable_warnings
1987
create procedure bug3259_1 () begin end|
1988 1989 1990
--disable_warnings
drop procedure if exists BUG3259_2 |
--enable_warnings
1991
create procedure BUG3259_2 () begin end|
1992 1993 1994
--disable_warnings
drop procedure if exists Bug3259_3 |
--enable_warnings
1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007
create procedure Bug3259_3 () begin end|

call BUG3259_1()|
call BUG3259_1()|
call bug3259_2()|
call Bug3259_2()|
call bug3259_3()|
call bUG3259_3()|

drop procedure bUg3259_1|
drop procedure BuG3259_2|
drop procedure BUG3259_3|

2008
#
2009
# BUG#2772
2010
#
2011 2012 2013 2014
--disable_warnings
drop function if exists bug2772|
--enable_warnings
create function bug2772() returns char(10) character set latin2
2015 2016
  return 'a'|

2017 2018
select bug2772()|
drop function bug2772|
2019

2020 2021 2022
#
# BUG#2776
#
2023 2024 2025 2026
--disable_warnings
drop procedure if exists bug2776_1|
--enable_warnings
create procedure bug2776_1(out x int)
2027 2028 2029 2030 2031 2032 2033
begin
  declare v int;

  set v = default;
  set x = v;
end|

2034 2035 2036 2037
--disable_warnings
drop procedure if exists bug2776_2|
--enable_warnings
create procedure bug2776_2(out x int)
2038 2039 2040 2041 2042 2043 2044 2045
begin
  declare v int default 42;

  set v = default;
  set x = v;
end|

set @x = 1|
2046
call bug2776_1(@x)|
2047
select @x|
2048
call bug2776_2(@x)|
2049
select @x|
2050 2051
drop procedure bug2776_1|
drop procedure bug2776_2|
2052

2053 2054 2055 2056 2057 2058 2059
#
# BUG#2780
#
create table t3 (s1 smallint)|

insert into t3 values (123456789012)|

2060 2061 2062 2063
--disable_warnings
drop procedure if exists bug2780|
--enable_warnings
create procedure bug2780()
2064 2065 2066 2067 2068 2069 2070 2071
begin
  declare exit handler for sqlwarning set @x = 1; 

  set @x = 0;
  insert into t3 values (123456789012);
  insert into t3 values (0);
end|

2072
call bug2780()|
2073 2074 2075
select @x|
select * from t3|

2076
drop procedure bug2780|
2077 2078
drop table t3|

2079 2080 2081 2082 2083 2084 2085 2086
#
# BUG#1863
#
create table t3 (content varchar(10) )|
insert into t3 values ("test1")|
insert into t3 values ("test2")|
create table t4 (f1 int, rc int, t3 int)|

2087 2088 2089
--disable_warnings
drop procedure if exists bug1863|
--enable_warnings
2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100
create procedure bug1863(in1 int)
begin 

  declare ind int default 0;
  declare t1 int;
  declare t2 int;
  declare t3 int;

  declare rc int default 0;
  declare continue handler for 1065 set rc = 1;

2101
  drop temporary table if exists temp_t1;
2102 2103 2104 2105 2106 2107 2108 2109 2110 2111 2112 2113 2114 2115 2116 2117 2118 2119 2120 2121 2122
  create temporary table temp_t1 (
    f1 int auto_increment, f2 varchar(20), primary key (f1)
  );

  insert into temp_t1 (f2) select content from t3;

  select f2 into t3 from temp_t1 where f1 = 10;

  if (rc) then
       insert into t4 values (1, rc, t3);
  end if;

  insert into t4 values (2, rc, t3);

end|

call bug1863(10)|
call bug1863(10)|
select * from t4|

drop procedure bug1863|
2123
drop temporary table temp_t1;
2124 2125 2126 2127 2128 2129 2130 2131 2132 2133 2134 2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147
drop table t3, t4|

#
# BUG#2656
#

create table t3 ( 
  OrderID  int not null,
  MarketID int,
  primary key (OrderID)
)|

create table t4 ( 
  MarketID int not null,
  Market varchar(60),
  Status char(1),
  primary key (MarketID)
)|

insert t3 (OrderID,MarketID) values (1,1)|
insert t3 (OrderID,MarketID) values (2,2)|
insert t4 (MarketID,Market,Status) values (1,"MarketID One","A")|
insert t4 (MarketID,Market,Status) values (2,"MarketID Two","A")|

2148 2149 2150
--disable_warnings
drop procedure if exists bug2656_1|
--enable_warnings
2151 2152 2153 2154 2155 2156 2157 2158
create procedure bug2656_1()
begin 
  select
    m.Market
  from  t4 m JOIN t3 o 
        ON o.MarketID != 1 and o.MarketID = m.MarketID;
end |

2159 2160 2161
--disable_warnings
drop procedure if exists bug2656_2|
--enable_warnings
2162 2163 2164 2165 2166 2167 2168 2169 2170 2171 2172 2173 2174 2175 2176 2177 2178 2179 2180 2181 2182 2183 2184
create procedure bug2656_2()
begin 
  select
    m.Market
  from  
    t4 m, t3 o
  where       
    m.MarketID != 1 and m.MarketID = o.MarketID;
        
end |

call bug2656_1()|
call bug2656_1()|
call bug2656_2()|
call bug2656_2()|
drop procedure bug2656_1|
drop procedure bug2656_2|
drop table t3, t4|


#
# BUG#3426
#
2185 2186 2187
--disable_warnings
drop procedure if exists bug3426|
--enable_warnings
2188 2189 2190 2191 2192 2193 2194 2195 2196 2197 2198 2199 2200 2201 2202 2203 2204 2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 2223 2224
create procedure bug3426(in_time int unsigned, out x int)
begin
  if in_time is null then
    set @stamped_time=10;
    set x=1;
  else
    set @stamped_time=in_time;
    set x=2;
  end if;
end|

call bug3426(1000, @i)|
select @i, from_unixtime(@stamped_time, '%d-%m-%Y %h:%i:%s') as time|
call bug3426(NULL, @i)|
select @i, from_unixtime(@stamped_time, '%d-%m-%Y %h:%i:%s') as time|
# Clear SP cache
alter procedure bug3426 sql security invoker|
call bug3426(NULL, @i)|
select @i, from_unixtime(@stamped_time, '%d-%m-%Y %h:%i:%s') as time|
call bug3426(1000, @i)|
select @i, from_unixtime(@stamped_time, '%d-%m-%Y %h:%i:%s') as time|

drop procedure bug3426|

#
# BUG#3448
#
--disable_warnings
create table t3 (
  a int primary key, 
  ach char(1)
) engine = innodb|

create table t4 (
  b int  primary key , 
  bch char(1)
) engine = innodb|
2225
--enable_warnings
2226 2227 2228 2229

insert into t3 values (1 , 'aCh1' ) , ('2' , 'aCh2')|
insert into t4 values (1 , 'bCh1' )|

2230 2231 2232
--disable_warnings
drop procedure if exists bug3448|
--enable_warnings
2233 2234 2235 2236 2237 2238 2239 2240 2241 2242 2243 2244 2245 2246 2247 2248 2249 2250 2251 2252 2253 2254 2255 2256 2257 2258 2259 2260 2261
create procedure bug3448()
  select * from t3 inner join t4 on t3.a = t4.b|

select * from t3 inner join t4 on t3.a = t4.b|
call bug3448()|
call bug3448()|

drop procedure bug3448|
drop table t3, t4|


#
# BUG#3734
#
create table t3 (
  id int unsigned auto_increment not null primary key,
  title VARCHAR(200),
  body text,
  fulltext (title,body)
)|

insert into t3 (title,body) values
  ('MySQL Tutorial','DBMS stands for DataBase ...'),
  ('How To Use MySQL Well','After you went through a ...'),
  ('Optimizing MySQL','In this tutorial we will show ...'),
  ('1001 MySQL Tricks','1. Never run mysqld as root. 2. ...'),
  ('MySQL vs. YourSQL','In the following database comparison ...'),
  ('MySQL Security','When configured properly, MySQL ...')|

2262 2263 2264
--disable_warnings
drop procedure if exists bug3734 |
--enable_warnings
2265 2266 2267 2268 2269 2270 2271 2272 2273 2274 2275 2276
create procedure bug3734 (param1 varchar(100))
  select * from t3 where match (title,body) against (param1)|

call bug3734('database')|
call bug3734('Security')|

drop procedure bug3734|
drop table t3|

#
# BUG#3863
#
2277 2278 2279
--disable_warnings
drop procedure if exists bug3863|
--enable_warnings
2280 2281 2282 2283 2284 2285 2286 2287 2288 2289 2290 2291 2292 2293 2294
create procedure bug3863()
begin
  set @a = 0;
  while @a < 5 do
    set @a = @a + 1;
  end while;
end|

call bug3863()|
select @a|
call bug3863()|
select @a|

drop procedure bug3863|

2295 2296 2297
#
# BUG#2460
#
2298

2299 2300 2301 2302 2303 2304 2305 2306
create table t3 (
  id int(10) unsigned not null default 0,
  rid int(10) unsigned not null default 0,
  msg text not null,
  primary key (id),
  unique key rid (rid, id)
)|

2307 2308 2309
--disable_warnings
drop procedure if exists bug2460_1|
--enable_warnings
2310 2311 2312 2313 2314 2315 2316 2317 2318 2319 2320 2321 2322 2323 2324 2325 2326
create procedure bug2460_1(in v int)
begin
    ( select n0.id from t3 as n0 where n0.id = v )
  union
    ( select n0.id from t3 as n0, t3 as n1
        where n0.id = n1.rid and n1.id = v )
  union
    ( select n0.id from t3 as n0, t3 as n1, t3 as n2
        where n0.id = n1.rid and n1.id = n2.rid and n2.id = v );
end|

call bug2460_1(2)|
call bug2460_1(2)|
insert into t3 values (1, 1, 'foo'), (2, 1, 'bar'), (3, 1, 'zip zap')|
call bug2460_1(2)|
call bug2460_1(2)|

2327 2328 2329
--disable_warnings
drop procedure if exists bug2460_2|
--enable_warnings
2330 2331 2332
create procedure bug2460_2()
begin
  drop table if exists t3;
2333
  create temporary table t3 (s1 int);
2334 2335 2336 2337 2338 2339 2340 2341 2342 2343 2344
  insert into t3 select 1 union select 1;
end|

call bug2460_2()|
call bug2460_2()|
select * from t3|

drop procedure bug2460_1|
drop procedure bug2460_2|
drop table t3|

2345

2346 2347 2348 2349
#
# BUG#2564
#
set @@sql_mode = ''|
2350 2351 2352
--disable_warnings
drop procedure if exists bug2564_1|
--enable_warnings
2353 2354 2355 2356 2357
create procedure bug2564_1()
    comment 'Joe''s procedure'
  insert into `t1` values ("foo", 1)|

set @@sql_mode = 'ANSI_QUOTES'|
2358 2359 2360
--disable_warnings
drop procedure if exists bug2564_2|
--enable_warnings
2361 2362 2363 2364 2365
create procedure bug2564_2()
  insert into "t1" values ('foo', 1)|

delimiter $|
set @@sql_mode = ''$
2366 2367 2368
--disable_warnings
drop function if exists bug2564_3$
--enable_warnings
2369 2370 2371 2372
create function bug2564_3(x int, y int) returns int
  return x || y$

set @@sql_mode = 'ANSI'$
2373 2374 2375
--disable_warnings
drop function if exists bug2564_4$
--enable_warnings
2376 2377 2378 2379 2380 2381 2382 2383 2384 2385 2386 2387 2388 2389 2390
create function bug2564_4(x int, y int) returns int
  return x || y$
delimiter |$

set @@sql_mode = ''|
show create procedure bug2564_1|
show create procedure bug2564_2|
show create function bug2564_3|
show create function bug2564_4|

drop procedure bug2564_1|
drop procedure bug2564_2|
drop function bug2564_3|
drop function bug2564_4|

2391 2392 2393
#
# BUG#3132
#
2394 2395 2396
--disable_warnings
drop function if exists bug3132|
--enable_warnings
2397 2398 2399 2400 2401 2402
create function bug3132(s char(20)) returns char(50)
  return concat('Hello, ', s, '!')|

select bug3132('Bob') union all select bug3132('Judy')|
drop function bug3132|

2403 2404 2405
#
# BUG#3843
#
2406 2407 2408
--disable_warnings
drop procedure if exists bug3843|
--enable_warnings
2409 2410 2411 2412 2413 2414 2415 2416 2417 2418
create procedure bug3843()
  analyze table t1|

# Testing for packets out of order
call bug3843()|
call bug3843()|
select 1+2|

drop procedure bug3843|

2419 2420 2421 2422 2423 2424
#
# BUG#3368
#
create table t3 ( s1 char(10) )|
insert into t3 values ('a'), ('b')|

2425 2426 2427
--disable_warnings
drop procedure if exists bug3368|
--enable_warnings
2428 2429 2430 2431 2432 2433 2434 2435 2436 2437
create procedure bug3368(v char(10))
begin
  select group_concat(v) from t3;
end|

call bug3368('x')|
call bug3368('yz')|
drop procedure bug3368|
drop table t3|

2438 2439 2440
#
# BUG#4579
#
2441 2442
create table t3 (f1 int, f2 int)|
insert into t3 values (1,1)|
2443

2444 2445 2446
--disable_warnings
drop procedure if exists bug4579_1|
--enable_warnings
2447 2448 2449 2450 2451 2452 2453 2454 2455
create procedure bug4579_1 ()
begin
  declare sf1 int;

  select f1 into sf1 from t3 where f1=1 and f2=1;
  update t3 set f2 = f2 + 1 where f1=1 and f2=1;
  call bug4579_2();
end|

2456 2457 2458
--disable_warnings
drop procedure if exists bug4579_2|
--enable_warnings
2459 2460 2461 2462 2463 2464 2465 2466 2467 2468 2469 2470
create procedure bug4579_2 ()
begin
end|

call bug4579_1()|
call bug4579_1()|
call bug4579_1()|

drop procedure bug4579_1|
drop procedure bug4579_2|
drop table t3|

2471 2472 2473 2474 2475 2476 2477 2478 2479 2480 2481 2482 2483 2484 2485 2486 2487 2488 2489 2490 2491 2492 2493 2494
#
# BUG#2773: Function's data type ignored in stored procedures
#
--disable_warnings
drop procedure if exists bug2773|
--enable_warnings

create function bug2773() returns int return null|
create table t3 as select bug2773()|
show create table t3|
drop table t3|
drop function bug2773|

#
# BUG#3788: Stored procedure packet error
#
--disable_warnings
drop procedure if exists bug3788|
--enable_warnings

create function bug3788() returns date return cast("2005-03-04" as date)|
select bug3788()|
drop function bug3788|

2495
create function bug3788() returns binary(1) return 5|
2496 2497 2498
select bug3788()|
drop function bug3788|
 
2499

2500 2501 2502 2503 2504 2505
#
# BUG#4726
#
create table t3 (f1 int, f2 int, f3 int)|
insert into t3 values (1,1,1)|

2506 2507 2508
--disable_warnings
drop procedure if exists bug4726|
--enable_warnings
2509 2510 2511 2512 2513 2514 2515 2516 2517 2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528
create procedure bug4726()
begin
   declare tmp_o_id INT;
   declare tmp_d_id INT default 1;

   while tmp_d_id <= 2 do
   begin
     select f1 into tmp_o_id from t3 where f2=1 and f3=1;
     set tmp_d_id = tmp_d_id + 1;
   end;
   end while;
end|

call bug4726()|
call bug4726()|
call bug4726()|

drop procedure bug4726|
drop table t3|

2529 2530 2531
#
# BUG#4318
#
2532

2533
--disable_parsing # Don't know if HANDLER commands can work with SPs, or at all..
2534 2535 2536 2537 2538 2539 2540 2541 2542 2543 2544 2545 2546 2547 2548 2549 2550 2551
create table t3 (s1 int)|
insert into t3 values (3), (4)|

--disable_warnings
drop procedure if exists bug4318|
--enable_warnings
create procedure bug4318()
  handler t3 read next|

handler t3 open|
# Expect no results, as tables are closed, but there shouldn't be any errors
call bug4318()|
call bug4318()|
handler t3 close|

drop procedure bug4318|
drop table t3|
--enable_parsing
2552

2553 2554 2555 2556 2557 2558 2559 2560 2561 2562 2563
#
# BUG#4902: Stored procedure with SHOW WARNINGS leads to packet error
#
# Added tests for most other show commands we could find too.
# (Skipping those already tested, and the ones depending on optional handlers.)
#
# Note: This will return a large number of results of different formats,
#       which makes it impossible to filter with --replace_column.
#       It's possible that some of these are not deterministic across
#       platforms. If so, just remove the offending command.
#
2564 2565 2566
--disable_warnings
drop procedure if exists bug4902|
--enable_warnings
2567 2568 2569 2570 2571 2572 2573 2574 2575 2576 2577 2578 2579 2580 2581 2582 2583 2584
create procedure bug4902()
begin
  show charset like 'foo';
  show collation like 'foo';
  show column types;
  show create table t1;
  show create database test;
  show databases like 'foo';
  show errors;
  show columns from t1;
  show keys from t1;
  show open tables like 'foo';
  show privileges;
  show status like 'foo';
  show tables like 'foo';
  show variables like 'foo';
  show warnings;
end|
2585 2586 2587 2588 2589 2590 2591
--disable_parsing
show binlog events;
show storage engines;
show master status;
show slave hosts;
show slave status;
--enable_parsing
2592 2593 2594 2595 2596 2597

call bug4902()|
call bug4902()|

drop procedure bug4902|

2598 2599 2600
#
# BUG#4904
#
2601 2602 2603
--disable_warnings
drop procedure if exists bug4904|
--enable_warnings
2604 2605 2606 2607
create procedure bug4904()
begin
  declare continue handler for sqlstate 'HY000' begin end;

2608
  create table t2 as select * from t3;
2609 2610
end|

2611
-- error 1146
2612 2613 2614 2615
call bug4904()|

drop procedure bug4904|

2616 2617
create table t3 (s1 char character set latin1, s2 char character set latin2)|

2618 2619 2620
--disable_warnings
drop procedure if exists bug4904|
--enable_warnings
2621 2622 2623 2624 2625 2626 2627
create procedure bug4904 ()
begin
  declare continue handler for sqlstate 'HY000' begin end;

  select s1 from t3 union select s2 from t3; 
end|

2628
call bug4904()|
2629

2630
drop procedure bug4904|
2631 2632
drop table t3|

2633
#
2634
# BUG#336
2635 2636
#
--disable_warnings
2637
drop procedure if exists bug336|
2638
--enable_warnings
2639
create procedure bug336(out y int)
2640
begin
2641 2642 2643
  declare x int;
  set x = (select sum(t.data) from test.t1 t);
  set y = x;
2644 2645
end|

2646 2647 2648 2649 2650
insert into t1 values ("a", 2), ("b", 3)|
call bug336(@y)|
select @y|
delete from t1|
drop procedure bug336|
2651

2652
#
2653
# BUG#3157
2654 2655
#
--disable_warnings
2656
drop procedure if exists bug3157|
2657
--enable_warnings
2658
create procedure bug3157()
2659
begin
2660 2661 2662 2663 2664 2665
  if exists(select * from t1) then
    set @n= @n + 1;
  end if;
  if (select count(*) from t1) then
    set @n= @n + 1;
  end if;
2666 2667
end|

2668 2669 2670 2671 2672 2673
set @n = 0|
insert into t1 values ("a", 1)|
call bug3157()|
select @n|
delete from t1|
drop procedure bug3157|
2674

2675
#
2676
# BUG#5251: mysql changes creation time of a procedure/function when altering
2677 2678
#
--disable_warnings
2679
drop procedure if exists bug5251|
2680
--enable_warnings
2681
create procedure bug5251()
2682 2683 2684
begin
end|

2685 2686 2687 2688 2689 2690 2691 2692
select created into @c1 from mysql.proc
  where db='test' and name='bug5251'|
--sleep 2
alter procedure bug5251 comment 'foobar'|
select count(*) from mysql.proc
  where  db='test' and name='bug5251' and created = @c1|

drop procedure bug5251|
2693

pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2694
#
2695
# BUG#5279: Stored procedure packets out of order if CHECKSUM TABLE
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2696 2697
#
--disable_warnings
2698
drop procedure if exists bug5251|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2699
--enable_warnings
2700 2701 2702 2703 2704 2705
create procedure bug5251()
  checksum table t1|

call bug5251()|
call bug5251()|
drop procedure bug5251|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2706

2707 2708 2709
#
# BUG#5287: Stored procedure crash if leave outside loop
#
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2710
--disable_warnings
2711
drop procedure if exists bug5287|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2712
--enable_warnings
2713 2714 2715 2716
create procedure bug5287(param1 int)
label1:
  begin
    declare c cursor for select 5;
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2717

2718 2719 2720 2721 2722 2723 2724 2725
    loop
      if param1 >= 0 then
        leave label1;
      end if;
    end loop;
end|
call bug5287(1)|
drop procedure bug5287|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2726 2727 2728


#
2729
# BUG#5307: Stored procedure allows statement after BEGIN ... END
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2730 2731
#
--disable_warnings
2732
drop procedure if exists bug5307|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2733
--enable_warnings
2734 2735 2736 2737 2738 2739 2740
create procedure bug5307()
begin
end; set @x = 3|

call bug5307()|
select @x|
drop procedure bug5307|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2741 2742

#
2743 2744
# BUG#5258: Stored procedure modified date is 0000-00-00
# (This was a design flaw)
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2745
--disable_warnings
2746
drop procedure if exists bug5258|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2747
--enable_warnings
2748 2749 2750
create procedure bug5258()
begin
end|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2751 2752

--disable_warnings
2753
drop procedure if exists bug5258_aux|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2754
--enable_warnings
2755
create procedure bug5258_aux()
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2756
begin
2757
  declare c, m char(19);
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2758

2759 2760 2761 2762 2763 2764
  select created,modified into c,m from mysql.proc where name = 'bug5258';
  if c = m then
    select 'Ok';
  else
    select c, m;
  end if;
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2765 2766
end|

2767
call bug5258_aux()|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2768

2769 2770
drop procedure bug5258|
drop procedure bug5258_aux|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2771 2772

#
2773
# BUG#4487: Stored procedure connection aborted if uninitialized char
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2774 2775
#
--disable_warnings
2776
drop function if exists bug4487|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2777
--enable_warnings
2778 2779 2780 2781 2782
create function bug4487() returns char
begin
  declare v char;
  return v;
end|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2783

2784 2785
select bug4487()|
drop function bug4487|
pem@mysql.comhem.se's avatar
pem@mysql.comhem.se committed
2786 2787


2788
#
2789
# BUG#4941: Stored procedure crash fetching null value into variable.
2790 2791
#
--disable_warnings
2792
drop procedure if exists bug4941|
2793
--enable_warnings
2794 2795 2796 2797
--disable_warnings
drop procedure if exists bug4941|
--enable_warnings
create procedure bug4941(out x int)
2798
begin
2799 2800 2801 2802
  declare c cursor for select i from t2 limit 1;
  open c;
  fetch c into x;
  close c;
2803 2804
end|

2805 2806 2807 2808 2809 2810
insert into t2 values (null, null, null)|
set @x = 42|
call bug4941(@x)|
select @x|
delete from t1|
drop procedure bug4941|
2811

2812
#
2813 2814
# BUG#4905: Stored procedure doesn't clear for "Rows affected"
#
2815
--disable_warnings
2816
drop procedure if exists bug4905|
2817 2818
--enable_warnings

2819
create table t3 (s1 int,primary key (s1))|
2820

2821 2822 2823 2824 2825 2826 2827
--disable_warnings
drop procedure if exists bug4905|
--enable_warnings
create procedure bug4905()
begin
  declare v int;
  declare continue handler for sqlstate '23000' set v = 5;
2828

2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841
  insert into t3 values (1);
end|

call bug4905()|
select row_count()|
call bug4905()|
select row_count()|
call bug4905()|
select row_count()|
select * from t3|

drop procedure bug4905|
drop table t3|
2842

2843 2844 2845
#
# BUG#6022: Stored procedure shutdown problem with self-calling function.
#
2846

2847
--disable_parsing # until we implement support for recursive stored functions.
2848 2849 2850 2851 2852 2853 2854 2855 2856 2857 2858 2859 2860 2861 2862 2863 2864 2865 2866
--disable_warnings
drop function if exists bug6022|
--enable_warnings

--disable_warnings
drop function if exists bug6022|
--enable_warnings
create function bug6022(x int) returns int
begin
  if x < 0 then
    return 0;
  else
    return bug6022(x-1);
  end if;
end|

select bug6022(5)|
drop function bug6022|
--enable_parsing
2867

2868 2869 2870
#
# BUG#6029: Stored procedure specific handlers should have priority
#
2871
--disable_warnings
2872
drop procedure if exists bug6029|
2873 2874
--enable_warnings

2875
--disable_warnings
2876
drop procedure if exists bug6029|
2877
--enable_warnings
2878
create procedure bug6029()
2879
begin
2880 2881 2882
  declare exit handler for 1136  select '1136';
  declare exit handler for sqlstate '23000'  select 'sqlstate 23000';
  declare continue handler for sqlexception  select 'sqlexception';
2883

2884 2885
  insert into t3 values (1);
  insert into t3 values (1,2);
2886
end|
2887 2888 2889 2890 2891 2892
 
create table t3 (s1 int, primary key (s1))|
insert into t3 values (1)|
call bug6029()|
delete from t3|
call bug6029()|
2893

2894 2895 2896 2897 2898 2899
drop procedure bug6029|
drop table t3|

#
# BUG#8540: Local variable overrides an alias
#
2900
--disable_warnings
2901
drop procedure if exists bug8540|
2902
--enable_warnings
2903

2904 2905 2906 2907 2908
create procedure bug8540()
begin
  declare x int default 1;
  select x as y, x+0 as z;
end|
2909

2910 2911
call bug8540()|
drop procedure bug8540|
2912

2913 2914 2915 2916
#
# BUG#6642: Stored procedure crash if expression with set function
#
create table t3 (s1 int)|
2917

2918 2919 2920
--disable_warnings
drop procedure if exists bug6642|
--enable_warnings
2921

2922 2923
create procedure bug6642()
  select abs(count(s1)) from t3|
2924

2925 2926 2927
call bug6642()|
call bug6642()|
drop procedure bug6642|
2928

2929 2930 2931 2932
#
# BUG#7013: Stored procedure crash if group by ... with rollup
#
insert into t3 values (0),(1)|
2933
--disable_warnings
2934
drop procedure if exists bug7013|
2935
--enable_warnings
2936 2937 2938 2939 2940
create procedure bug7013()
  select s1,count(s1) from t3 group by s1 with rollup|
call bug7013()|
call bug7013()|
drop procedure bug7013|
2941

2942 2943 2944 2945 2946 2947 2948 2949 2950 2951 2952 2953 2954 2955
#
# BUG#7743: 'Lost connection to MySQL server during query' on Stored Procedure
#
--disable_warnings
drop table if exists t4|
--enable_warnings
create table t4 (
  a mediumint(8) unsigned not null auto_increment,
  b smallint(5) unsigned not null,
  c char(32) not null,
  primary key  (a)
) engine=myisam default charset=latin1|
insert into t4 values (1, 2, 'oneword')|
insert into t4 values (2, 2, 'anotherword')|
2956

2957
--disable_warnings
2958
drop procedure if exists bug7743|
2959
--enable_warnings
2960
create procedure bug7743 ( searchstring char(28) )
2961
begin
2962 2963 2964
  declare var mediumint(8) unsigned;
  select a into var from t4 where b = 2 and c = binary searchstring limit 1;
  select var;
2965 2966
end|

2967 2968 2969 2970 2971 2972
call bug7743("oneword")|
call bug7743("OneWord")|
call bug7743("anotherword")|
call bug7743("AnotherWord")|
drop procedure bug7743|
drop table t4|
2973 2974

#
2975 2976
# BUG#7992: SELECT .. INTO variable .. within Stored Procedure crashes
#           the server
2977
#
2978 2979 2980 2981 2982 2983 2984 2985 2986 2987 2988
delete from t3|
insert into t3 values(1)|
drop procedure if exists bug7992_1|
drop procedure if exists bug7992_2|
create procedure bug7992_1()
begin
  declare i int;
  select max(s1)+1 into i from t3;
end|
create procedure bug7992_2()
  insert into t3 (s1) select max(t4.s1)+1 from t3 as t4|
2989

2990 2991 2992 2993 2994 2995 2996 2997
call bug7992_1()|
call bug7992_1()|
call bug7992_2()|
call bug7992_2()|

drop procedure bug7992_1|
drop procedure bug7992_2|
drop table t3|
2998 2999

#
3000 3001
# BUG#8116: calling simple stored procedure twice in a row results
#           in server crash
3002
#
3003
create table t3 (  userid bigint(20) not null default 0 )|
3004

3005 3006 3007 3008 3009
--disable_warnings
drop procedure if exists bug8116|
--enable_warnings
create procedure bug8116(in _userid int)
   select * from t3 where userid = _userid|
3010

3011 3012 3013
call bug8116(42)|
call bug8116(42)|
drop procedure bug8116|
3014
drop table t3|
3015

3016
#
3017
# BUG#6857: current_time() in STORED PROCEDURES
3018
#
3019
--disable_warnings
3020
drop procedure if exists bug6857|
3021
--enable_warnings
3022
create procedure bug6857(counter int)
3023
begin
3024 3025 3026 3027 3028 3029 3030 3031 3032 3033 3034 3035
  declare t0, t1 int;
  declare plus bool default 0;

  set t0 = current_time();
  while counter > 0 do
    set counter = counter - 1;
  end while;
  set t1 = current_time();
  if t1 > t0 then
    set plus = 1;
  end if;
  select plus;
3036 3037
end|

3038 3039 3040 3041 3042 3043 3044 3045
# QQ: This is currently disabled. Not only does it slow down a normal test
#     run, it makes running with valgrind (or similar tools) extremely
#     painful.
# Make sure this takes at least one second on all machines in all builds.
# 30000 makes it about 3 seconds on an old 1.1GHz linux.
#call bug6857(300000)|

drop procedure bug6857|
3046

3047 3048 3049
#
# BUG#8757: Stored Procedures: Scope of Begin and End Statements do not
#           work properly.
3050
--disable_warnings
3051
drop procedure if exists bug8757|
3052
--enable_warnings
3053
create procedure bug8757()
3054 3055
begin
  declare x int;
3056
  declare c1 cursor for select data from t1 limit 1;
3057

3058 3059 3060 3061 3062 3063 3064 3065 3066 3067 3068 3069 3070
  begin
    declare y int;
    declare c2 cursor for select i from t2 limit 1;

    open c2;
    fetch c2 into y;
    close c2;
    select 2,y;
  end;
  open c1;
  fetch c1 into x;
  close c1;
  select 1,x;
3071 3072
end|

3073 3074 3075 3076 3077 3078 3079 3080 3081 3082 3083 3084 3085 3086 3087 3088 3089 3090 3091 3092 3093 3094 3095 3096
delete from t1|
delete from t2|
insert into t1 values ("x", 1)|
insert into t2 values ("y", 2, 0.0)|

call bug8757()|

delete from t1|
delete from t2|
drop procedure bug8757|


#
# BUG#8762: Stored Procedures: Inconsistent behavior
#           of DROP PROCEDURE IF EXISTS statement.
--disable_warnings
drop procedure if exists bug8762|
--enable_warnings
# Doesn't exist
drop procedure if exists bug8762; create procedure bug8762() begin end|
# Does exist
drop procedure if exists bug8762; create procedure bug8762() begin end|
drop procedure bug8762|

3097 3098 3099 3100 3101 3102 3103 3104 3105 3106 3107 3108 3109 3110 3111 3112 3113 3114 3115 3116 3117 3118 3119

#
# BUG#5240: Stored procedure crash if function has cursor declaration
#
--disable_warnings
drop function if exists bug5240|
--enable_warnings
create function bug5240 () returns int
begin
  declare x int;
  declare c cursor for select data from t1 limit 1;

  open c;
  fetch c into x;
  close c;
  return x;
end|

delete from t1|
insert into t1 values ("answer", 42)|
select id, bug5240() from t1|
drop function bug5240|

3120
#
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
3121
# BUG#7992: rolling back temporary Item tree changes in SP
3122 3123
#
--disable_warnings
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
3124
drop procedure if exists p1|
3125
--enable_warnings
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
3126 3127 3128
create table t3(id int)|
insert into t3 values(1)|
create procedure bug7992()
3129 3130
begin
  declare i int;
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
3131 3132 3133 3134 3135 3136 3137
  select max(id)+1 into i from t3;
end|

call bug7992()|
call bug7992()|
drop procedure bug7992|
drop table t3|
3138
delimiter ;|
bell@sanja.is.com.ua's avatar
bell@sanja.is.com.ua committed
3139

3140
#
3141 3142 3143
# BUG#8849: problem with insert statement with table alias's
#
# Rolling back changes to AND/OR structure of ON and WHERE clauses  in SP
3144 3145
# 

3146
delimiter |;
3147 3148 3149 3150
create table t3 (
  lpitnumber int(11) default null,
  lrecordtype int(11) default null
)|
3151

3152 3153 3154 3155 3156 3157 3158
create table t4 (
  lbsiid int(11) not null default '0',
  ltradingmodeid int(11) not null default '0',
  ltradingareaid int(11) not null default '0',
  csellingprice decimal(19,4) default null,
  primary key  (lbsiid,ltradingmodeid,ltradingareaid)
)|
3159

3160 3161 3162 3163 3164
create table t5 (
  lbsiid int(11) not null default '0',
  ltradingareaid int(11) not null default '0',
  primary key  (lbsiid,ltradingareaid)
)|
3165

3166 3167 3168 3169
--disable_warnings
drop procedure if exists bug8849|
--enable_warnings
create procedure bug8849()
3170
begin
3171
  insert into t5
3172
  (
3173 3174
   t5.lbsiid,
   t5.ltradingareaid
3175
  )
3176
  select distinct t3.lpitnumber, t4.ltradingareaid
3177
  from
3178 3179 3180 3181 3182
    t4 join t3 on
      t3.lpitnumber = t4.lbsiid
      and t3.lrecordtype = 1
    left join t4 as price01 on
      price01.lbsiid = t4.lbsiid and
3183
      price01.ltradingmodeid = 1 and
3184
      t4.ltradingareaid = price01.ltradingareaid;
3185 3186
end|

3187 3188 3189 3190 3191 3192
call bug8849()|
call bug8849()|
call bug8849()|
drop procedure bug8849|
drop tables t3,t4,t5|

3193 3194 3195 3196 3197 3198 3199 3200 3201 3202 3203 3204 3205 3206 3207 3208 3209 3210 3211 3212 3213 3214 3215 3216
#
# BUG#8937: Stored Procedure: AVG() works as SUM() in SELECT ... INTO statement
#
--disable_warnings
drop procedure if exists bug8937|
--enable_warnings
create procedure bug8937()
begin
  declare s,x,y,z int;
  declare a float;

  select sum(data),avg(data),min(data),max(data) into s,x,y,z from t1;
  select s,x,y,z;
  select avg(data) into a from t1;
  select a;
end|

delete from t1|
insert into t1 (data) values (1), (2), (3), (4), (6)|
call bug8937()|

drop procedure bug8937|
delete from t1|

3217

3218 3219 3220 3221 3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232 3233 3234 3235 3236 3237 3238 3239 3240 3241 3242 3243 3244 3245 3246 3247 3248 3249 3250 3251 3252 3253 3254 3255 3256 3257 3258 3259 3260 3261 3262 3263 3264 3265 3266 3267 3268 3269 3270 3271 3272 3273 3274 3275 3276 3277 3278 3279 3280 3281 3282 3283 3284 3285 3286 3287 3288 3289 3290 3291 3292 3293 3294 3295 3296 3297 3298 3299
#
# BUG#6900: Stored procedure inner handler ignored
# BUG#9074: STORED PROC: The scope of every handler declared is not
#                        properly applied
#
--disable_warnings
drop procedure if exists bug6900|
drop procedure if exists bug9074|
drop procedure if exists bug6900_9074|
--enable_warnings

create table t3 (w char unique, x char)|
insert into t3 values ('a', 'b')|

create procedure bug6900()
begin
  declare exit handler for sqlexception select '1';

  begin
    declare exit handler for sqlexception select '2';

    insert into t3 values ('x', 'y', 'z');
  end;
end|

create procedure bug9074()
begin
  declare x1, x2, x3, x4, x5, x6 int default 0;

  begin    
    declare continue handler for sqlstate '23000' set x5 = 1;      

    insert into t3 values ('a', 'b');      
    set x6 = 1;      
  end;

 begin1_label:
  begin
    declare continue handler for sqlstate '23000' set x1 = 1;      

    insert into t3 values ('a', 'b');      
    set x2 = 1;      
				
   begin2_label:
    begin  
      declare exit handler for sqlstate '23000' set x3 = 1;         

      set x4= 1;         
      insert into t3 values ('a','b');
      set x4= 0;
    end begin2_label;
  end begin1_label;

  select x1, x2, x3, x4, x5, x6;
end|

create procedure bug6900_9074(z int)
begin
  declare exit handler for sqlstate '23000' select '23000';

  begin
    declare exit handler for sqlexception select 'sqlexception';

    if z = 1 then
      insert into t3 values ('a', 'b');
    else
      insert into t3 values ('x', 'y', 'z');
    end if;
  end;
end|

call bug6900()|
call bug9074()|
call bug6900_9074(0)|
call bug6900_9074(1)|

drop procedure bug6900|
drop procedure bug9074|
drop procedure bug6900_9074|
drop table t3|


3300 3301 3302 3303 3304 3305 3306 3307 3308 3309 3310 3311 3312 3313
#
# BUG#7185: Stored procedure crash if identifier is AVG
#
--disable_warnings
drop procedure if exists avg|
--enable_warnings
create procedure avg ()
begin
end|

call avg ()|
drop procedure avg|


3314 3315 3316 3317 3318 3319
#
# BUG#6129: Stored procedure won't display @@sql_mode value
#
--disable_warnings
drop procedure if exists bug6129|
--enable_warnings
3320
set @old_mode= @@sql_mode;
3321
set @@sql_mode= "ERROR_FOR_DIVISION_BY_ZERO";
3322 3323 3324 3325 3326 3327 3328 3329
create procedure bug6129()
  select @@sql_mode|
call bug6129()|
set @@sql_mode= "NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO"|
call bug6129()|
set @@sql_mode= "NO_ZERO_IN_DATE"|
call bug6129()|
set @@sql_mode=@old_mode;
3330 3331 3332 3333

drop procedure bug6129|


3334 3335 3336 3337 3338 3339 3340 3341 3342 3343 3344 3345 3346 3347 3348 3349 3350 3351 3352 3353 3354 3355 3356
#
# BUG#9856: Stored procedures: crash if handler for sqlexception, not found
#
--disable_warnings
drop procedure if exists bug9856|
--enable_warnings
create procedure bug9856()
begin
  declare v int;
  declare c cursor for select data from t1;
  declare exit handler for sqlexception, not found select '16';

  open c;
  fetch c into v;
  select v;
end|

delete from t1|
call bug9856()|
call bug9856()|
drop procedure bug9856|


3357 3358 3359 3360 3361 3362 3363 3364 3365 3366 3367 3368 3369 3370 3371 3372 3373 3374 3375 3376 3377 3378 3379 3380 3381 3382 3383 3384 3385 3386 3387 3388 3389 3390
#
# BUG##9674: Stored Procs: Using declared vars in algebric operation causes
#            system crash.
#
--disable_warnings
drop procedure if exists bug9674_1|
drop procedure if exists bug9674_2|
--enable_warnings
create procedure bug9674_1(out arg int)
begin
  declare temp_in1 int default 0;
  declare temp_fl1 int default 0;

  set temp_in1 = 100;
  set temp_fl1 = temp_in1/10;
  set arg = temp_fl1;
end|

create procedure bug9674_2()
begin
  declare v int default 100;

  select v/10;
end|

call bug9674_1(@sptmp)|
call bug9674_1(@sptmp)|
select @sptmp|
call bug9674_2()|
call bug9674_2()|
drop procedure bug9674_1|
drop procedure bug9674_2|


3391 3392 3393 3394 3395 3396 3397 3398 3399 3400 3401 3402 3403 3404 3405 3406 3407 3408 3409 3410 3411 3412 3413 3414 3415 3416 3417 3418 3419 3420 3421 3422
#
# BUG#9598: stored procedure call within stored procedure overwrites IN variable
#
--disable_warnings
drop procedure if exists bug9598_1|
drop procedure if exists bug9598_2|
--enable_warnings
create procedure bug9598_1(in var_1 char(16),
                           out var_2 integer, out var_3 integer)
begin
  set var_2 = 50;
  set var_3 = 60;
end|

create procedure bug9598_2(in v1 char(16),
                           in v2 integer,
                           in v3 integer,
                           in v4 integer,
                           in v5 integer)
begin
  select v1,v2,v3,v4,v5;
  call bug9598_1(v1,@tmp1,@tmp2);
  select v1,v2,v3,v4,v5;
end|

call bug9598_2('Test',2,3,4,5)|
select @tmp1, @tmp2|

drop procedure bug9598_1|
drop procedure bug9598_2|


3423 3424 3425 3426 3427 3428 3429 3430 3431 3432 3433 3434 3435 3436 3437 3438 3439 3440 3441 3442 3443 3444 3445 3446 3447
#
# BUG#9902: Crash with simple stored function using user defined variables
#
--disable_warnings
drop procedure if exists bug9902|
--enable_warnings
create function bug9902() returns int(11)
begin
  set @x = @x + 1;
  return @x;
end|

set @qcs1 = @@query_cache_size|
set global query_cache_size = 100000|
set @x = 1|
insert into t1 values ("qc", 42)|
select bug9902() from t1|
select bug9902() from t1|
select @x|

set global query_cache_size = @qcs1|
delete from t1|
drop function bug9902|


3448
#
3449
# BUG#9102: Stored proccedures: function which returns blob causes crash
3450 3451 3452 3453 3454
#
--disable_warnings
drop function if exists bug9102|
--enable_warnings
create function bug9102() returns blob return 'a'|
3455
select bug9102()|
3456
drop function bug9102|
3457

3458 3459 3460 3461 3462

#
# BUG#7648: Stored procedure crash when invoking a function that returns a bit
#
--disable_warnings
3463
drop function if exists bug7648|
3464 3465 3466 3467 3468 3469
--enable_warnings
create function bug7648() returns bit(8) return 'a'|
select bug7648()|
drop function bug7648|


3470 3471 3472 3473 3474 3475 3476 3477 3478 3479 3480 3481 3482 3483 3484 3485 3486 3487 3488 3489 3490
#
# BUG#9775: crash if create function that returns enum or set
#
--disable_warnings
drop function if exists bug9775|
--enable_warnings
create function bug9775(v1 char(1)) returns enum('a','b') return v1|
select bug9775('a'),bug9775('b'),bug9775('c')|
drop function bug9775|
create function bug9775(v1 int) returns enum('a','b') return v1|
select bug9775(1),bug9775(2),bug9775(3)|
drop function bug9775|

create function bug9775(v1 char(1)) returns set('a','b') return v1|
select bug9775('a'),bug9775('b'),bug9775('a,b'),bug9775('c')|
drop function bug9775|
create function bug9775(v1 int) returns set('a','b') return v1|
select bug9775(1),bug9775(2),bug9775(3),bug9775(4)|
drop function bug9775|


3491 3492 3493 3494 3495 3496 3497 3498 3499 3500 3501 3502 3503
#
# BUG#8861: If Return is a YEAR data type, value is not shown in year format
#
--disable_warnings
drop function if exists bug8861|
--enable_warnings
create function bug8861(v1 int) returns year return v1|
select bug8861(05)|
set @x = bug8861(05)|
select @x|
drop function bug8861|


3504 3505 3506 3507 3508 3509 3510 3511 3512 3513 3514 3515 3516 3517 3518 3519 3520 3521 3522 3523 3524 3525 3526
#
# BUG#9004: Inconsistent behaviour of SP re. warnings
#
--disable_warnings
drop procedure if exists bug9004_1|
drop procedure if exists bug9004_2|
--enable_warnings
create procedure bug9004_1(x char(16))
begin
  insert into t1 values (x, 42);
  insert into t1 values (x, 17);
end|
create procedure bug9004_2(x char(16))
  call bug9004_1(x)|

# Truncation warnings expected...
call bug9004_1('12345678901234567')|
call bug9004_2('12345678901234567890')|

delete from t1|
drop procedure bug9004_1|
drop procedure bug9004_2|

3527 3528 3529 3530 3531 3532 3533 3534 3535 3536 3537 3538 3539 3540 3541 3542 3543
#
# BUG#7293: Stored procedure crash with soundex
#
--disable_warnings
drop procedure if exists bug7293|
--enable_warnings
insert into t1 values ('secret', 0)| 
create procedure bug7293(p1 varchar(100))
begin
  if exists (select id from t1 where soundex(p1)=soundex(id)) then
    select 'yes';
  end if;
end;| 
call bug7293('secret')| 
call bug7293 ('secrete')| 
drop procedure bug7293|
delete from t1|
3544

3545 3546 3547 3548 3549 3550 3551 3552 3553 3554 3555 3556 3557 3558 3559 3560 3561 3562 3563

#
# BUG#9841: Unexpected read lock when trying to update a view in a
#           stored procedure
#
--disable_warnings
drop procedure if exists bug9841|
drop view if exists v1|
--enable_warnings

create view v1 as select * from t1, t2 where id = s|
create procedure bug9841 ()
  update v1 set data = 10| 
call bug9841()|

drop view v1|
drop procedure bug9841|


3564 3565 3566 3567 3568 3569 3570 3571 3572 3573 3574 3575 3576 3577 3578 3579 3580 3581 3582 3583 3584 3585 3586 3587 3588 3589 3590 3591 3592
#
# BUG#5963 subqueries in SET/IF
#
--disable_warnings
drop procedure if exists bug5963|
--enable_warnings

create procedure bug5963_1 () begin declare v int; set v = (select s1 from t3); select v; end;|
create table t3 (s1 int)|
insert into t3 values (5)|
call bug5963_1()|
call bug5963_1()|
drop procedure bug5963_1|
drop table t3|

create procedure bug5963_2 (cfk_value int) 
begin 
  if cfk_value in (select cpk from t3) then 
    set @x = 5; 
  end if; 
  end; 
| 
create table t3 (cpk int)| 
insert into t3 values (1)| 
call bug5963_2(1)|
call bug5963_2(1)|
drop procedure bug5963_2|
drop table t3|

3593

3594 3595 3596 3597 3598 3599 3600 3601 3602 3603 3604 3605 3606 3607 3608 3609 3610 3611 3612
#
# BUG#9559: Functions: Numeric Operations using -ve value gives incorrect
#           results.
#
--disable_warnings
drop function if exists bug9559|
--enable_warnings
create function bug9559()
  returns int
begin
  set @y = -6/2;
  return @y;
end|

select bug9559()|

drop function bug9559|


3613 3614 3615 3616 3617 3618 3619 3620 3621 3622 3623 3624 3625 3626 3627 3628 3629 3630 3631 3632 3633 3634 3635 3636 3637 3638 3639
#
# BUG#10961: Stored procedures: crash if select * from dual
#
--disable_warnings
drop procedure if exists bug10961|
--enable_warnings
# "select * from dual" results in an error, so the cursor will not open
create procedure bug10961()
begin
  declare v char;
  declare x int;
  declare c cursor for select * from dual;
  declare continue handler for sqlexception select x;

  set x = 1;
  open c;
  set x = 2;
  fetch c into v;
  set x = 3;
  close c;
end|

call bug10961()|
call bug10961()|

drop procedure bug10961|

igor@rurik.mysql.com's avatar
igor@rurik.mysql.com committed
3640 3641 3642 3643 3644 3645 3646 3647 3648 3649 3650 3651 3652 3653 3654 3655 3656 3657 3658 3659 3660 3661 3662 3663 3664 3665 3666 3667 3668 3669 3670 3671 3672 3673 3674 3675 3676 3677 3678 3679 3680 3681 3682 3683
#
# BUG #6866: Second call of a stored procedure using a view with on expressions
#

--disable_warnings
DROP PROCEDURE IF EXISTS bug6866|
--enable_warnings

DROP VIEW IF EXISTS tv|
DROP TABLE IF EXISTS tt1,tt2,tt3|

CREATE TABLE tt1 (a1 int, a2 int, a3 int, data varchar(10))|
CREATE TABLE tt2 (a2 int, data2 varchar(10))|
CREATE TABLE tt3 (a3 int, data3 varchar(10))|

INSERT INTO tt1 VALUES (1, 1, 4, 'xx')|

INSERT INTO tt2 VALUES (1, 'a')|
INSERT INTO tt2 VALUES (2, 'b')|
INSERT INTO tt2 VALUES (3, 'c')|

INSERT INTO tt3 VALUES (4, 'd')|
INSERT INTO tt3 VALUES (5, 'e')|
INSERT INTO tt3 VALUES (6, 'f')|

CREATE VIEW tv AS
SELECT tt1.*, tt2.data2, tt3.data3
  FROM tt1 INNER JOIN tt2 ON tt1.a2 = tt2.a2
         LEFT JOIN tt3 ON tt1.a3 = tt3.a3
    ORDER BY tt1.a1, tt2.a2, tt3.a3|

CREATE PROCEDURE bug6866 (_a1 int)
BEGIN
SELECT * FROM tv WHERE a1 = _a1;
END|

CALL bug6866(1)|
CALL bug6866(1)|
CALL bug6866(1)|

DROP PROCEDURE bug6866;

DROP VIEW tv|
DROP TABLE tt1, tt2, tt3|
3684

3685 3686 3687 3688 3689 3690 3691 3692 3693 3694 3695 3696 3697 3698 3699 3700 3701 3702 3703 3704 3705 3706 3707 3708
#
# BUG#10136: items cleunup
#
--disable_warnings
DROP PROCEDURE IF EXISTS bug10136|
--enable_warnings
create table t3 ( name char(5) not null primary key, val float not null)|
insert into t3 values ('aaaaa', 1), ('bbbbb', 2), ('ccccc', 3)|
create procedure bug10136()
begin
  declare done int default 3;

  repeat
    select * from t3;
    set done = done - 1;
  until done <= 0 end repeat;

end|
call bug10136()|
call bug10136()|
call bug10136()|
drop procedure bug10136|
drop table t3|

3709 3710 3711 3712 3713 3714 3715 3716 3717 3718 3719 3720 3721 3722 3723 3724 3725 3726 3727 3728 3729 3730 3731 3732 3733 3734 3735 3736 3737 3738 3739 3740 3741 3742 3743 3744
#
# BUG#11529: crash server after use stored procedure
#
--disable_warnings
drop procedure if exists bug11529|
--enable_warnings
create procedure bug11529()
begin
  declare c cursor for select id, data from t1 where data in (10,13);

  open c;
  begin
    declare vid char(16);
    declare vdata int;
    declare exit handler for not found begin end;

    while true do
      fetch c into vid, vdata;
    end while;
  end;
  close c;
end|

insert into t1 values
  ('Name1', 10),
  ('Name2', 11),
  ('Name3', 12),
  ('Name4', 13),
  ('Name5', 14)|

call bug11529()|
call bug11529()|
delete from t1|
drop procedure bug11529|


3745 3746 3747 3748 3749 3750 3751 3752 3753 3754
#
# BUG#6063: Stored procedure labels are subject to restrictions (partial)
# BUG#7088: Stored procedures: labels won't work if character set is utf8
#
--disable_warnings
drop procedure if exists bug6063|
drop procedure if exists bug7088_1|
drop procedure if exists bug7088_2|
--enable_warnings

3755
--disable_parsing # temporarily disabled until Bar fixes BUG#11986
3756
create procedure bug6063()
3757
  lâbel: begin end|
3758 3759 3760 3761 3762 3763 3764 3765 3766 3767 3768 3769 3770 3771 3772 3773 3774 3775 3776
call bug6063()|
# QQ Known bug: this will not show the label correctly.
show create procedure bug6063|

set character set utf8|
create procedure bug7088_1()
  label1: begin end label1|
create procedure bug7088_2()
  läbel1: begin end|
call bug7088_1()|
call bug7088_2()|
set character set default|
show create procedure bug7088_1|
show create procedure bug7088_2|

drop procedure bug6063|
drop procedure bug7088_1|
drop procedure bug7088_2|
--enable_parsing
3777

3778 3779 3780 3781 3782 3783 3784 3785 3786 3787 3788 3789 3790 3791 3792 3793 3794 3795 3796 3797 3798 3799
#
# BUG#9565: "Wrong locking in stored procedure if a sub-sequent procedure
#           is called".
#
--disable_warnings
drop procedure if exists bug9565_sub|
drop procedure if exists bug9565|
--enable_warnings
create procedure bug9565_sub()
begin
  select * from t1;
end|
create procedure bug9565()
begin
  insert into t1 values ("one", 1);
  call bug9565_sub();
end|
call bug9565()|
delete from t1|
drop procedure bug9565_sub|
drop procedure bug9565|

3800

3801 3802 3803 3804 3805 3806 3807 3808 3809 3810 3811
#
# BUG#9538: SProc: Creation fails if we try to SET system variable
#           using @@var_name in proc
#
--disable_warnings
drop procedure if exists bug9538|
--enable_warnings
create procedure bug9538()
  set @@sort_buffer_size = 1000000|

set @x = @@sort_buffer_size|
3812
set @@sort_buffer_size = 2000000|
3813 3814 3815 3816 3817 3818 3819 3820
select @@sort_buffer_size|
call bug9538()|
select @@sort_buffer_size|
set @@sort_buffer_size = @x|

drop procedure bug9538|


georg@lmy002.wdf.sap.corp's avatar
georg@lmy002.wdf.sap.corp committed
3821 3822 3823 3824 3825 3826 3827 3828 3829 3830 3831 3832 3833 3834 3835 3836 3837 3838 3839 3840 3841 3842 3843 3844 3845 3846 3847 3848
#
# BUG#8692: Cursor fetch of empty string
#
--disable_warnings
drop procedure if exists bug8692|
--enable_warnings
create table t3 (c1 varchar(5), c2 char(5), c3 enum('one','two'), c4 text, c5 blob, c6 char(5), c7 varchar(5))|
insert into t3 values ('', '', '', '', '', '', NULL)|

create procedure bug8692()
begin 
    declare v1 VARCHAR(10); 
    declare v2 VARCHAR(10); 
    declare v3 VARCHAR(10); 
    declare v4 VARCHAR(10); 
    declare v5 VARCHAR(10); 
    declare v6 VARCHAR(10); 
    declare v7 VARCHAR(10); 
    declare c8692 cursor for select c1,c2,c3,c4,c5,c6,c7 from t3; 
    open c8692; 
    fetch c8692 into v1,v2,v3,v4,v5,v6,v7;
    select v1, v2, v3, v4, v5, v6, v7;
end|

call bug8692()|
drop procedure bug8692|
drop table t3|

3849 3850 3851 3852 3853 3854 3855 3856 3857 3858 3859 3860 3861 3862
#
# Bug#10055 "Using stored function with information_schema causes empty
#            result set"
#
--disable_warnings
drop function if exists bug10055|
--enable_warnings
create function bug10055(v char(255)) returns char(255) return lower(v)|
# This select should not crash server and should return all fields in t1
select t.column_name, bug10055(t.column_name)
from information_schema.columns as t
where t.table_schema = 'test' and t.table_name = 't1'|
drop function bug10055|

3863 3864 3865 3866 3867 3868 3869 3870
#
# Bug #12297 "SP crashes the server if data inserted inside a lon loop"
# The test for memleak bug, so actually there is no way to test it
# from the suite. The test below could be used to check SP memory
# consumption by passing large input parameter.
#

--disable_warnings
3871
drop procedure if exists bug12297|
3872 3873
--enable_warnings

3874 3875 3876 3877 3878 3879 3880 3881 3882 3883
create procedure bug12297(lim int)
begin
  set @x = 0;
  repeat
    insert into t1(id,data)
    values('aa', @x);
    set @x = @x + 1;
  until @x >= lim
  end repeat;
end|
3884

3885 3886
call bug12297(10)|
drop procedure bug12297|
3887 3888 3889 3890 3891 3892 3893 3894 3895 3896 3897 3898 3899 3900 3901 3902 3903 3904 3905 3906 3907 3908 3909 3910 3911 3912 3913 3914

#
# Bug #11247 "Stored procedures: Function calls in long loops leak memory"
# One more memleak bug test. One could use this test to check that the memory
# isn't leaking by increasing the input value for p_bug11247.
#

--disable_warnings
drop function if exists f_bug11247|
drop procedure if exists p_bug11247|
--enable_warnings

create function f_bug11247(param int)
  returns int
return param + 1|

create procedure p_bug11247(lim int)
begin
  declare v int default 0;

  while v < lim do
    set v= f_bug11247(v);
  end while;
end|

call p_bug11247(10)|
drop function f_bug11247|
drop procedure p_bug11247|
3915 3916 3917 3918 3919 3920
#
# BUG#12168: "'DECLARE CONTINUE HANDLER FOR NOT FOUND ...' in conditional
# handled incorrectly"
#
--disable_warnings
drop procedure if exists bug12168|
3921
drop table if exists t3, t4|
3922 3923
--enable_warnings

3924 3925
create table t3 (a int)|
insert into t3 values (1),(2),(3),(4)|
3926

3927
create table t4 (a int)|
3928 3929 3930 3931 3932 3933

create procedure bug12168(arg1 char(1))
begin
  declare b, c integer;
  if arg1 = 'a' then
    begin
3934
      declare c1 cursor for select a from t3 where a % 2;
3935 3936 3937 3938 3939 3940 3941 3942 3943
      declare continue handler for not found set b = 1;
      set b = 0;
      open c1;
      c1_repeat: repeat
        fetch c1 into c;
        if (b = 1) then
          leave c1_repeat;
        end if;

3944
        insert into t4 values (c);
3945 3946 3947 3948 3949 3950
        until b = 1
      end repeat;
    end;
  end if;
  if arg1 = 'b' then
    begin
3951
      declare c2 cursor for select a from t3 where not a % 2;
3952 3953 3954 3955 3956 3957 3958 3959 3960
      declare continue handler for not found set b = 1;
      set b = 0;
      open c2;
      c2_repeat: repeat
        fetch c2 into c;
        if (b = 1) then
          leave c2_repeat;
        end if;

3961
        insert into t4 values (c);
3962 3963 3964 3965 3966 3967 3968
        until b = 1
      end repeat;
    end;
  end if;
end|

call bug12168('a')|
3969 3970
select * from t4|
truncate t4|
3971
call bug12168('b')|
3972 3973
select * from t4|
truncate t4|
3974
call bug12168('a')|
3975 3976
select * from t4|
truncate t4|
3977
call bug12168('b')|
3978 3979 3980
select * from t4|
truncate t4|
drop table t3, t4|
3981
drop procedure if exists bug12168|
3982

3983 3984 3985 3986 3987 3988 3989 3990 3991 3992 3993 3994 3995 3996 3997 3998 3999 4000 4001 4002 4003 4004 4005 4006 4007 4008 4009 4010 4011 4012 4013 4014 4015 4016
#
# Bug #11333 "Stored Procedure: Memory blow up on repeated SELECT ... INTO
# query"
# One more memleak bug. Use the test to check memory consumption.
#

--disable_warnings
drop table if exists t3|
drop procedure if exists bug11333|
--enable_warnings

create table t3 (c1 char(128))|

insert into t3 values 
  ('AAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAA')|


create procedure bug11333(i int)
begin
    declare tmp varchar(128);
    set @x = 0;
    repeat
        select c1 into tmp from t3
          where c1 = 'AAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAAA';
        set @x = @x + 1;
        until @x >= i
    end repeat;
end|

call bug11333(10)|

drop procedure bug11333|
drop table t3|

acurtis@xiphis.org's avatar
acurtis@xiphis.org committed
4017 4018 4019 4020 4021 4022 4023 4024 4025 4026 4027 4028 4029
#
# BUG#9048: Creating a function with char binary IN parameter fails
#
--disable_warnings
drop function if exists bug9048|
--enable_warnings
create function bug9048(f1 char binary) returns char binary
begin
  set f1= concat( 'hello', f1 );
  return f1;
end|
drop function bug9048|

4030 4031 4032 4033 4034 4035 4036 4037 4038 4039 4040 4041 4042 4043 4044 4045 4046 4047 4048 4049 4050 4051 4052 4053 4054
# Bug #12849 Stored Procedure: Crash on procedure call with CHAR type
# 'INOUT' parameter
#

--disable_warnings
drop procedure if exists bug12849_1|
--enable_warnings
create procedure bug12849_1(inout x char) select x into x|
set @var='a'|
call bug12849_1(@var)|
select @var|
drop procedure bug12849_1|

--disable_warnings
drop procedure if exists bug12849_2|
--enable_warnings
create procedure bug12849_2(inout foo varchar(15))
begin
select concat(foo, foo) INTO foo;
end|
set @var='abcd'|
call bug12849_2(@var)|
select @var|
drop procedure bug12849_2|

4055 4056 4057 4058 4059 4060 4061 4062 4063 4064 4065 4066 4067 4068 4069 4070 4071 4072 4073 4074 4075 4076 4077 4078 4079 4080 4081 4082 4083 4084 4085 4086 4087 4088 4089 4090 4091 4092 4093 4094 4095 4096 4097 4098
#
# BUG#13133: Local variables in stored procedures are not initialized correctly.
#
--disable_warnings
drop procedure if exists bug131333|
drop function if exists bug131333|
--enable_warnings
create procedure bug131333()
begin
  begin
    declare a int;

    select a;
    set a = 1;
    select a;
  end;
  begin
    declare b int;

    select b;
  end;
end|

create function bug131333()
  returns int
begin
  begin
    declare a int;

    set a = 1;
  end;
  begin
    declare b int;

    return b;
  end;
end|

call bug131333()|
select bug131333()|

drop procedure bug131333|
drop function bug131333|

4099 4100 4101 4102 4103 4104 4105 4106 4107 4108 4109 4110 4111 4112 4113 4114 4115 4116 4117 4118 4119 4120 4121 4122 4123 4124 4125 4126 4127 4128 4129 4130 4131 4132 4133 4134 4135 4136 4137 4138 4139 4140
#
# BUG#12379: PROCEDURE with HANDLER calling FUNCTION with error get
#            strange result
#
--disable_warnings
drop function if exists bug12379|
drop procedure if exists bug12379_1|
drop procedure if exists bug12379_2|
drop procedure if exists bug12379_3|
drop table if exists t3|
--enable_warnings

create table t3 (c1 char(1) primary key not null)|

create function bug12379()
  returns integer
begin
   insert into t3 values('X');
   insert into t3 values('X');
   return 0;
end|

create procedure bug12379_1()
begin
   declare exit handler for sqlexception select 42;

   select bug12379();
END|
create procedure bug12379_2()
begin
   declare exit handler for sqlexception begin end;

   select bug12379();
end|
create procedure bug12379_3()
begin
   select bug12379();
end|

--error 1062
select bug12379()|
select 1|
4141 4142 4143
# statement-based binlogging will show warning which row-based won't;
# so we hide it (this warning is already tested in rpl_stm_sp.test)
--disable_warnings
4144 4145 4146
call bug12379_1()|
select 2|
call bug12379_2()|
4147
--enable_warnings
4148 4149 4150 4151 4152 4153 4154 4155 4156
select 3|
--error 1062
call bug12379_3()|
select 4|

drop function bug12379|
drop procedure bug12379_1|
drop procedure bug12379_2|
drop procedure bug12379_3|
4157
drop table t3|
4158

petr@mysql.com's avatar
petr@mysql.com committed
4159 4160 4161 4162 4163 4164 4165 4166 4167 4168 4169 4170 4171 4172 4173
#
# Bug #13124    Stored Procedure using SELECT INTO crashes server
#

--disable_warnings
drop procedure if exists bug13124|
--enable_warnings
create procedure bug13124()
begin
  declare y integer;
  set @x=y;
end|
call bug13124()|
drop procedure  bug13124|

4174 4175 4176 4177 4178 4179 4180 4181 4182 4183 4184 4185 4186 4187 4188 4189 4190 4191 4192 4193 4194 4195 4196 4197 4198 4199 4200 4201 4202
#
# Bug #12979  Stored procedures: crash if inout decimal parameter
#

# check NULL inout parameters processing

--disable_warnings
drop procedure if exists bug12979_1|
--enable_warnings
create procedure bug12979_1(inout d decimal(5)) set d = d / 2|
set @bug12979_user_var = NULL|
call bug12979_1(@bug12979_user_var)|
drop procedure bug12979_1|

# check NULL local variables processing

--disable_warnings
drop procedure if exists bug12979_2|
--enable_warnings
create procedure bug12979_2()
begin
declare internal_var decimal(5);
set internal_var= internal_var / 2;
select internal_var;
end|
call bug12979_2()|
drop procedure bug12979_2|


4203 4204 4205 4206 4207 4208 4209 4210 4211 4212 4213 4214 4215 4216 4217 4218 4219 4220 4221 4222 4223 4224 4225 4226 4227 4228 4229 4230 4231 4232 4233 4234 4235 4236 4237 4238
#
# BUG#6127: Stored procedure handlers within handlers don't work
#
--disable_warnings
drop table if exists t3|
drop procedure if exists bug6127|
--enable_warnings
create table t3 (s1 int unique)|

set @sm=@@sql_mode|
set sql_mode='traditional'|

create procedure bug6127()
begin
  declare continue handler for sqlstate '23000'
    begin
      declare continue handler for sqlstate '22003'
        insert into t3 values (0);

      insert into t3 values (1000000000000000);
    end;

  insert into t3 values (1);
  insert into t3 values (1);
end|

call bug6127()|
select * from t3|
--error ER_DUP_ENTRY
call bug6127()|
select * from t3|
set sql_mode=@sm|
drop table t3|
drop procedure bug6127|


4239 4240 4241 4242 4243 4244 4245 4246 4247 4248 4249 4250 4251 4252 4253 4254 4255 4256 4257 4258 4259 4260 4261 4262 4263 4264 4265 4266 4267 4268 4269 4270 4271 4272 4273 4274 4275 4276 4277 4278 4279 4280 4281 4282 4283 4284 4285 4286 4287
#
# BUG#12589: Assert when creating temp. table from decimal stored procedure
#            variable
#
--disable_warnings
drop procedure if exists bug12589_1|
drop procedure if exists bug12589_2|
drop procedure if exists bug12589_3|
--enable_warnings
create procedure bug12589_1()
begin
  declare spv1 decimal(3,3);
  set spv1= 123.456;

  set spv1 = 'test';
  create temporary table tm1 as select spv1;
  show create table tm1;
  drop temporary table tm1;
end|

create procedure bug12589_2()
begin
  declare spv1 decimal(6,3);
  set spv1= 123.456;

  create temporary table tm1 as select spv1;
  show create table tm1;
  drop temporary table tm1;
end|

create procedure bug12589_3()
begin
  declare spv1 decimal(6,3);
  set spv1= -123.456;

  create temporary table tm1 as select spv1;
  show create table tm1;
  drop temporary table tm1;
end|

# Note: The type of the field will match the value, not the declared
#       type of the variable. (This is a type checking issue which
#       might be changed later.)

# Warning expected from "set spv1 = 'test'", the value is set to decimal "0".
call bug12589_1()|
# No warnings here
call bug12589_2()|
call bug12589_3()|
4288 4289 4290
drop procedure bug12589_1|
drop procedure bug12589_2|
drop procedure bug12589_3|
4291

4292 4293 4294 4295 4296 4297 4298 4299 4300 4301 4302 4303 4304 4305 4306 4307 4308 4309 4310 4311 4312 4313 4314 4315 4316 4317 4318 4319 4320 4321 4322 4323 4324 4325 4326 4327 4328 4329 4330 4331 4332 4333 4334 4335 4336 4337 4338 4339 4340 4341 4342 4343 4344 4345 4346 4347 4348 4349 4350 4351 4352 4353 4354 4355 4356 4357 4358 4359 4360 4361 4362 4363 4364 4365 4366 4367 4368
#
# BUG#7049: Stored procedure CALL errors are ignored
#
--disable_warnings
drop table if exists t3|
drop procedure if exists bug7049_1|
drop procedure if exists bug7049_2|
drop procedure if exists bug7049_3|
drop procedure if exists bug7049_4|
drop function if exists bug7049_1|
drop function if exists bug7049_2|
--enable_warnings

create table t3 ( x int unique )|

create procedure bug7049_1()
begin
  insert into t3 values (42);
  insert into t3 values (42);
end|

create procedure bug7049_2()
begin
  declare exit handler for sqlexception
    select 'Caught it' as 'Result';

  call bug7049_1();
  select 'Missed it' as 'Result';
end|

create procedure bug7049_3()
  call bug7049_1()|

create procedure bug7049_4()
begin
  declare exit handler for sqlexception
    select 'Caught it' as 'Result';

  call bug7049_3();
  select 'Missed it' as 'Result';
end|

create function bug7049_1()
  returns int
begin
  insert into t3 values (42);
  insert into t3 values (42);
  return 42;
end|

create function bug7049_2()
  returns int
begin
  declare x int default 0;
  declare continue handler for sqlexception
    set x = 1;

  set x = bug7049_1();
  return x;
end|

call bug7049_2()|
select * from t3|
delete from t3|
call bug7049_4()|
select * from t3|
select bug7049_2()|

drop table t3|
drop procedure bug7049_1|
drop procedure bug7049_2|
drop procedure bug7049_3|
drop procedure bug7049_4|
drop function bug7049_1|
drop function bug7049_2|


4369 4370 4371 4372 4373 4374 4375 4376 4377 4378 4379 4380 4381 4382 4383 4384 4385 4386 4387 4388 4389 4390 4391 4392 4393 4394 4395 4396 4397 4398 4399 4400 4401 4402 4403 4404 4405 4406 4407 4408 4409 4410 4411
#
# BUG#13941: replace() string fuction behaves badly inside stored procedure
# (BUG#13914: IFNULL is returning garbage in stored procedure)
#
--disable_warnings
drop function if exists bug13941|
drop procedure if exists bug13941|
--enable_warnings

create function bug13941(p_input_str text)
  returns text
begin
  declare p_output_str text;

  set p_output_str = p_input_str;

  set p_output_str = replace(p_output_str, 'xyzzy', 'plugh');
  set p_output_str = replace(p_output_str, 'test', 'prova');
  set p_output_str = replace(p_output_str, 'this', 'questo');
  set p_output_str = replace(p_output_str, ' a ', 'una ');
  set p_output_str = replace(p_output_str, 'is', '');

  return p_output_str;
end|

create procedure bug13941(out sout varchar(128))
begin
  set sout = 'Local';
  set sout = ifnull(sout, 'DEF');
end|

# Note: The bug showed different behaviour in different types of builds,
#  giving garbage results in some, and seemingly working in others.
#  Running with valgrind (or purify) is the safe way to check that it's
#  really working correctly.
select bug13941('this is a test')|
call bug13941(@a)|
select @a|

drop function bug13941|
drop procedure bug13941|


4412 4413 4414 4415 4416 4417 4418 4419 4420 4421 4422 4423 4424 4425 4426 4427 4428 4429 4430 4431 4432 4433 4434 4435 4436 4437 4438 4439 4440 4441 4442 4443 4444 4445 4446 4447 4448 4449 4450 4451 4452 4453 4454 4455 4456 4457 4458 4459 4460 4461 4462 4463 4464 4465 4466
#
# BUG#13095: Cannot create VIEWs in prepared statements
#

delimiter ;|

--disable_warnings
DROP PROCEDURE IF EXISTS bug13095;
DROP TABLE IF EXISTS bug13095_t1;
DROP VIEW IF EXISTS bug13095_v1;
--enable_warnings

delimiter |;

CREATE PROCEDURE bug13095(tbl_name varchar(32))
BEGIN
  SET @str =
    CONCAT("CREATE TABLE ", tbl_name, "(stuff char(15))");
  SELECT @str;
  PREPARE stmt FROM @str;
  EXECUTE stmt;

  SET @str =
    CONCAT("INSERT INTO ", tbl_name, " VALUES('row1'),('row2'),('row3')" );
  SELECT @str;
  PREPARE stmt FROM @str;
  EXECUTE stmt;

  SET @str =
    CONCAT("CREATE VIEW bug13095_v1(c1) AS SELECT stuff FROM ", tbl_name);
  SELECT @str;
  PREPARE stmt FROM @str;
  EXECUTE stmt;

  SELECT * FROM bug13095_v1;

  SET @str =
    "DROP VIEW bug13095_v1";
  SELECT @str;
  PREPARE stmt FROM @str;
  EXECUTE stmt;
END|

delimiter ;|

CALL bug13095('bug13095_t1');

--disable_warnings
DROP PROCEDURE IF EXISTS bug13095;
DROP VIEW IF EXISTS bug13095_v1;
DROP TABLE IF EXISTS bug13095_t1;
--enable_warnings

delimiter |;

4467 4468 4469 4470 4471 4472 4473 4474 4475 4476 4477 4478 4479 4480 4481 4482 4483 4484 4485 4486 4487 4488 4489 4490 4491 4492 4493 4494 4495 4496 4497 4498 4499 4500 4501 4502 4503 4504 4505 4506 4507 4508 4509 4510 4511 4512 4513 4514 4515 4516 4517 4518
#
# BUG#14210: "Simple query with > operator on large table gives server
# crash"
# Check that cursors work in case when HEAP tables are converted to
# MyISAM
#
--disable_warnings
drop procedure if exists bug14210|
--enable_warnings
set @@session.max_heap_table_size=16384|
select @@session.max_heap_table_size|
# To trigger the memory corruption the original table must be InnoDB.
# No harm if it's not, so don't warn if the suite is run with --skip-innodb
--disable_warnings
create table t3 (a char(255)) engine=InnoDB|
--enable_warnings
create procedure bug14210_fill_table()
begin
  declare table_size, max_table_size int default 0;
  select @@session.max_heap_table_size into max_table_size;
  delete from t3;
  insert into t3 (a) values (repeat('a', 255));
  repeat
    insert into t3 select a from t3;
    select count(*)*255 from t3 into table_size;
  until table_size > max_table_size*2 end repeat;
end|
call bug14210_fill_table()|
drop procedure bug14210_fill_table|
create table t4 like t3|

create procedure bug14210()
begin
  declare a char(255);
  declare done int default 0;
  declare c cursor for select * from t3;
  declare continue handler for sqlstate '02000' set done = 1;
  open c;
  repeat
    fetch c into a;
    if not done then
       insert into t4 values (upper(a));
    end if;
  until done end repeat;
  close c;
end|
call bug14210()|
select count(*) from t4|

drop table t3, t4|
drop procedure bug14210|
set @@session.max_heap_table_size=default|
4519

4520 4521 4522 4523 4524 4525 4526 4527 4528 4529 4530 4531 4532 4533 4534 4535 4536 4537 4538 4539 4540 4541 4542 4543 4544 4545 4546 4547 4548 4549 4550

#
# BUG#1473: Dumping of stored functions seems to cause corruption in
#           the function body
#
--disable_warnings
drop function if exists bug14723|
drop procedure if exists bug14723|
--enable_warnings

delimiter ;;|
/*!50003 create function bug14723()
 returns bigint(20)
main_loop: begin
  return 42;
end */;;
show create function bug14723;;
select bug14723();;

/*!50003 create procedure bug14723()
main_loop: begin
  select 42;
end */;;
show create procedure bug14723;;
call bug14723();;

delimiter |;;

drop function bug14723|
drop procedure bug14723|

4551 4552 4553 4554 4555 4556 4557 4558 4559 4560 4561 4562 4563 4564 4565 4566 4567 4568 4569 4570 4571
#
# Bug#14845 "mysql_stmt_fetch returns MYSQL_NO_DATA when COUNT(*) is 0"
# Check that when fetching from a cursor, COUNT(*) works properly.
#
create procedure bug14845()
begin
  declare a char(255);
  declare done int default 0;
  declare c cursor for select count(*) from t1 where 1 = 0;
  declare continue handler for sqlstate '02000' set done = 1;
  open c;
  repeat
    fetch c into a;
    if not done then
      select a;
    end if;
  until done end repeat;
  close c;
end|
call bug14845()|
drop procedure bug14845|
4572

4573 4574 4575 4576 4577 4578 4579 4580 4581 4582 4583 4584 4585 4586 4587 4588 4589 4590 4591 4592 4593 4594 4595 4596
#
# BUG#13549 "Server crash with nested stored procedures".
# Server should not crash when during execution of stored procedure
# we have to parse trigger/function definition and this new trigger/
# function has more local variables declared than invoking stored
# procedure and last of these variables is used in argument of NOT
# operator.
#
--disable_warnings
drop procedure if exists bug13549_1|
drop procedure if exists bug13549_2|
--enable_warnings
CREATE PROCEDURE `bug13549_2`()
begin
  call bug13549_1();
end|
CREATE PROCEDURE `bug13549_1`()
begin
  declare done int default 0;
  set done= not done;
end|
CALL bug13549_2()|
drop procedure bug13549_2|
drop procedure bug13549_1|
4597

4598 4599 4600 4601 4602 4603 4604 4605 4606 4607 4608 4609 4610 4611 4612 4613 4614 4615 4616 4617 4618 4619 4620 4621 4622 4623 4624 4625 4626 4627 4628 4629 4630 4631 4632 4633 4634 4635 4636 4637 4638 4639 4640 4641 4642 4643 4644 4645 4646 4647 4648 4649 4650 4651 4652 4653 4654 4655 4656 4657 4658 4659 4660 4661 4662 4663 4664 4665 4666 4667 4668 4669 4670 4671 4672 4673 4674 4675 4676 4677 4678 4679 4680 4681 4682 4683 4684 4685 4686 4687 4688 4689 4690 4691 4692 4693 4694 4695 4696 4697 4698 4699 4700 4701 4702 4703 4704 4705 4706 4707 4708 4709 4710 4711 4712 4713 4714 4715 4716 4717 4718 4719 4720 4721 4722 4723 4724 4725 4726 4727 4728 4729 4730
#
# BUG#10100: function (and stored procedure?) recursivity problem
#
--disable_warnings
drop function if exists bug10100f|
drop procedure if exists bug10100p|
drop procedure if exists bug10100t|
drop procedure if exists bug10100pt|
drop procedure if exists bug10100pv|
drop procedure if exists bug10100pd|
drop procedure if exists bug10100pc|
--enable_warnings
# routines with simple recursion
create function bug10100f(prm int) returns int
begin
  if prm > 1 then
    return prm * bug10100f(prm - 1);
  end if;
  return 1;
end|
create procedure bug10100p(prm int, inout res int)
begin
  set res = res * prm;
  if prm > 1 then
    call bug10100p(prm - 1, res);  
  end if;
end|
create procedure bug10100t(prm int)
begin
  declare res int;
  set res = 1;
  call bug10100p(prm, res);
  select res;
end|

# a procedure which use tables and recursion
create table t3 (a int)|
insert into t3 values (0)|
create view v1 as select a from t3;
create procedure bug10100pt(level int, lim int)
begin
  if level < lim then
    update t3 set a=level;
    FLUSH TABLES;
    call bug10100pt(level+1, lim);
  else
    select * from t3;
  end if;
end|
# view & recursion
create procedure bug10100pv(level int, lim int)
begin
  if level < lim then
    update v1 set a=level;
    FLUSH TABLES;
    call bug10100pv(level+1, lim);
  else
    select * from v1;
  end if;
end|
# dynamic sql & recursion
prepare stmt2 from "select * from t3;";
create procedure bug10100pd(level int, lim int)
begin
  if level < lim then
    select level;
    prepare stmt1 from "update t3 set a=a+2";
    execute stmt1;
    FLUSH TABLES;
    execute stmt1;
    FLUSH TABLES;
    execute stmt1;
    FLUSH TABLES;
    deallocate prepare stmt1;
    execute stmt2;
    select * from t3;
    call bug10100pd(level+1, lim);
  else
    execute stmt2;
  end if;
end|
# cursor & recursion
create procedure bug10100pc(level int, lim int)
begin
  declare lv int;
  declare c cursor for select a from t3;
  open c;
  if level < lim then
    select level;
    fetch c into lv;
    select lv;
    update t3 set a=level+lv;
    FLUSH TABLES;
    call bug10100pc(level+1, lim);
  else
    select * from t3;
  end if;
  close c;
end|

set @@max_sp_recursion_depth=4|
select @@max_sp_recursion_depth|
-- error ER_SP_NO_RECURSION
select bug10100f(3)|
-- error ER_SP_NO_RECURSION
select bug10100f(6)|
call bug10100t(5)|
call bug10100pt(1,5)|
call bug10100pv(1,5)|
update t3 set a=1|
call bug10100pd(1,5)|
select * from t3|
update t3 set a=1|
call bug10100pc(1,5)|
select * from t3|
set @@max_sp_recursion_depth=0|
select @@max_sp_recursion_depth|
-- error ER_SP_NO_RECURSION
select bug10100f(5)|
-- error ER_SP_RECURSION_LIMIT
call bug10100t(5)|

#end of the stack checking
deallocate prepare stmt2|

drop function bug10100f|
drop procedure bug10100p|
drop procedure bug10100t|
drop procedure bug10100pt|
drop procedure bug10100pv|
drop procedure bug10100pd|
drop procedure bug10100pc|
drop view v1|
4731 4732

#
4733 4734 4735 4736 4737 4738 4739 4740 4741 4742 4743 4744 4745 4746 4747 4748 4749 4750 4751 4752 4753 4754 4755
# BUG#13729: Stored procedures: packet error after exception handled
#
--disable_warnings
drop procedure if exists bug13729|
drop table if exists t3|
--enable_warnings

create table t3 (s1 int, primary key (s1))|

insert into t3 values (1),(2)|

create procedure bug13729()
begin
  declare continue handler for sqlexception select 55;

  update t3 set s1 = 1;
end|

call bug13729()|
# Used to cause Packets out of order
select * from t3|

drop procedure bug13729|
4756 4757
drop table t3|

4758 4759 4760 4761 4762 4763 4764 4765 4766 4767 4768 4769 4770 4771
#
# BUG#14643: Stored Procedure: Continuing after failed var. initialization
#            crashes server.
#
--disable_warnings
drop procedure if exists bug14643_1|
drop procedure if exists bug14643_2|
--enable_warnings

create procedure bug14643_1()
begin
  declare continue handler for sqlexception select 'boo' as 'Handler';

  begin
4772
    declare v int default undefined_var;
4773 4774 4775 4776

    if v = 1 then
      select 1;
    else
4777
      select v, isnull(v);
4778 4779 4780 4781 4782 4783 4784 4785
    end if;
  end;
end|

create procedure bug14643_2()
begin
  declare continue handler for sqlexception select 'boo' as 'Handler';

4786
  case undefined_var
4787 4788 4789 4790 4791
  when 1 then
    select 1;
  else
    select 2;
  end case;
4792 4793

  select undefined_var;
4794 4795 4796 4797 4798 4799 4800 4801
end|

call bug14643_1()|
call bug14643_2()|

drop procedure bug14643_1|
drop procedure bug14643_2|

4802 4803 4804 4805 4806 4807 4808 4809 4810 4811 4812 4813 4814 4815 4816 4817 4818 4819 4820 4821 4822 4823 4824 4825 4826 4827 4828 4829 4830 4831 4832
#
# BUG#14304: auto_increment field incorrect set in SP
#
--disable_warnings
drop procedure if exists bug14304|
drop table if exists t3, t4|
--enable_warnings

create table t3(a int primary key auto_increment)|
create table t4(a int primary key auto_increment)|

create procedure bug14304()
begin
  insert into t3 set a=null;
  insert into t4 set a=null;
  insert into t4 set a=null;
  insert into t4 set a=null;
  insert into t4 set a=null;
  insert into t4 set a=null;
  insert into t4 select null as a;
  
  insert into t3 set a=null;
  insert into t3 set a=null;
  
  select * from t3;
end|

call bug14304()|

drop procedure bug14304|
drop table t3, t4|
4833

4834 4835 4836 4837 4838 4839 4840 4841 4842 4843 4844 4845 4846 4847 4848 4849 4850 4851 4852 4853 4854 4855 4856 4857 4858 4859 4860 4861 4862 4863 4864 4865 4866 4867 4868 4869 4870 4871 4872 4873 4874 4875 4876
#
# BUG#14376: MySQL crash on scoped variable (re)initialization
#
--disable_warnings
drop procedure if exists bug14376|
--enable_warnings

create procedure bug14376()
begin
  declare x int default x;
end|

# Not the error we want, but that's what we got for now...
--error ER_BAD_FIELD_ERROR
call bug14376()|
drop procedure bug14376|

create procedure bug14376()
begin
  declare x int default 42;

  begin
    declare x int default x;

    select x;
  end;
end|

call bug14376()|

drop procedure bug14376|

create procedure bug14376(x int)
begin
  declare x int default x;

  select x;
end|

call bug14376(4711)|

drop procedure bug14376|

4877 4878 4879 4880 4881 4882 4883 4884 4885
#
# Bug#5967 "Stored procedure declared variable used instead of column"
# The bug should be fixed later.
# Test precedence of names of parameters, variable declarations, 
# variable declarations in nested compound statements, table columns,
# table columns in cursor declarations.
# According to the standard, table columns take precedence over
# variable declarations. In MySQL 5.0 it's vice versa.
#
4886

4887
--disable_warnings
4888 4889
drop procedure if exists bug5967|
drop table if exists t3|
4890
--enable_warnings
4891 4892 4893
create table t3 (a varchar(255))|
insert into t3 (a) values ("a - table column")|
create procedure bug5967(a varchar(255))
4894 4895
begin
  declare i varchar(255);
4896
  declare c cursor for select a from t3;
4897
  select a;
4898
  select a from t3 into i;
4899 4900 4901 4902 4903 4904
  select i as 'Parameter takes precedence over table column';                     open c;
  fetch c into i;
  close c;
  select i as 'Parameter takes precedence over table column in cursors';
  begin
    declare a varchar(255) default 'a - local variable';
4905
    declare c1 cursor for select a from t3;
4906 4907 4908 4909 4910 4911 4912
    select a as 'A local variable takes precedence over parameter';
    open c1;
    fetch c1 into i;
    close c1;
    select i as 'A local variable takes precedence over parameter in cursors';
    begin
      declare a varchar(255) default 'a - local variable in a nested compound statement';
4913
      declare c2 cursor for select a from t3;
4914
      select a as 'A local variable in a nested compound statement takes precedence over a local variable in the outer statement';
4915
      select a from t3 into i;
4916 4917 4918 4919 4920 4921 4922 4923
      select i as  'A local variable in a nested compound statement takes precedence over table column';
      open c2;
      fetch c2 into i;
      close c2;
      select i as  'A local variable in a nested compound statement takes precedence over table column in cursors';
    end;
  end;
end|
4924 4925
call bug5967("a - stored procedure parameter")|
drop procedure bug5967|
4926 4927 4928 4929 4930 4931

#
# Bug#13012 "SP: REPAIR/BACKUP/RESTORE TABLE crashes the server"
#
--disable_warnings
drop procedure if exists bug13012|
4932
# Disable warnings also for BACKUP/RESTORE: they are deprecated.
4933 4934 4935 4936 4937 4938 4939 4940
create procedure bug13012()
BEGIN
  REPAIR TABLE t1;
  BACKUP TABLE t1 to '../tmp';
  DROP TABLE t1;
  RESTORE TABLE t1 FROM '../tmp';
END|
call bug13012()|
4941
--enable_warnings
4942
drop procedure bug13012|
4943 4944 4945 4946 4947 4948 4949 4950 4951 4952 4953 4954
create view v1 as select * from t1|
create procedure bug13012()
BEGIN
  REPAIR TABLE t1,t2,t3,v1;
  OPTIMIZE TABLE t1,t2,t3,v1;
  ANALYZE TABLE t1,t2,t3,v1;
END|
call bug13012()|
call bug13012()|
call bug13012()|
drop procedure bug13012|
drop view v1;
4955
select * from t1|
4956

4957 4958 4959 4960 4961 4962 4963 4964 4965 4966 4967 4968 4969 4970 4971 4972 4973 4974 4975 4976 4977 4978 4979 4980 4981 4982 4983 4984 4985 4986 4987 4988 4989 4990 4991 4992 4993 4994 4995 4996 4997 4998 4999 5000 5001 5002
#
# A test case for Bug#15392 "Server crashes during prepared statement
# execute": make sure that stored procedure check for error conditions
# properly and do not continue execution if an error has been set. 
#
# It's necessary to use several DBs because in the original code
# the successful return of mysql_change_db overrode the error from
# execution.
drop schema if exists mysqltest1|
drop schema if exists mysqltest2|
drop schema if exists mysqltest3|
create schema mysqltest1|
create schema mysqltest2|
create schema mysqltest3|
use mysqltest3|

create procedure mysqltest1.p1 (out prequestid varchar(100))
begin
  call mysqltest2.p2('call mysqltest3.p3(1, 2)');
end|

create procedure mysqltest2.p2(in psql text)
begin
  declare lsql text;
  set @lsql= psql;
  prepare lstatement from @lsql;
  execute lstatement;
  deallocate prepare lstatement;
end|

create procedure mysqltest3.p3(in p1 int)
begin
  select p1;
end|

--error ER_SP_WRONG_NO_OF_ARGS
call mysqltest1.p1(@rs)|
--error ER_SP_WRONG_NO_OF_ARGS
call mysqltest1.p1(@rs)|
--error ER_SP_WRONG_NO_OF_ARGS
call mysqltest1.p1(@rs)|
drop schema if exists mysqltest1|
drop schema if exists mysqltest2|
drop schema if exists mysqltest3|
use test|

5003 5004 5005 5006 5007 5008 5009 5010 5011 5012 5013 5014 5015 5016 5017 5018 5019 5020 5021 5022 5023 5024 5025 5026 5027 5028 5029 5030 5031 5032 5033 5034 5035 5036 5037 5038 5039 5040 5041 5042 5043 5044 5045 5046 5047 5048 5049 5050 5051 5052
#
# Bug#15441 "Running SP causes Server to Crash": check that an SP variable
# can not be used in VALUES() function.
#
--disable_warnings
drop table if exists t3|
drop procedure if exists bug15441|
--enable_warnings
create table t3 (id int not null primary key, county varchar(25))|
insert into t3 (id, county) values (1, 'York')|

# First check that a stored procedure that refers to a parameter in VALUES()
# function won't parse.

create procedure bug15441(c varchar(25))
begin
  update t3 set id=2, county=values(c);
end|
--error ER_BAD_FIELD_ERROR
call bug15441('county')|
drop procedure bug15441|

# Now check the case when there is an ambiguity between column names
# and stored procedure parameters: the parser shall resolve the argument
# of VALUES() function to the column name.

# It's hard to deduce what county refers to in every case (INSERT statement):
# 1st county refers to the column
# 2nd county refers to the procedure parameter
# 3d and 4th county refers to the column, again, but
# for 4th county it has the value of SP parameter

# In UPDATE statement, just check that values() function returns NULL for
# non- INSERT...UPDATE statements, as stated in the manual.

create procedure bug15441(county varchar(25))
begin
  declare c varchar(25) default "hello";

  insert into t3 (id, county) values (1, county)
  on duplicate key update county= values(county);
  select * from t3;

  update t3 set id=2, county=values(id);
  select * from t3;
end|
call bug15441('Yale')|
drop table t3|
drop procedure bug15441|

5053 5054 5055 5056 5057 5058 5059 5060 5061 5062 5063 5064 5065 5066 5067 5068 5069 5070 5071 5072 5073 5074 5075 5076 5077 5078 5079 5080 5081 5082 5083 5084 5085 5086 5087 5088 5089 5090 5091 5092 5093 5094 5095 5096 5097 5098 5099 5100 5101 5102 5103 5104 5105 5106 5107 5108 5109 5110 5111 5112 5113 5114 5115 5116 5117 5118 5119 5120 5121 5122 5123 5124 5125 5126 5127 5128
#
# BUG#14498: Stored procedures: hang if undefined variable and exception
#
--disable_warnings
drop procedure if exists bug14498_1|
drop procedure if exists bug14498_2|
drop procedure if exists bug14498_3|
drop procedure if exists bug14498_4|
drop procedure if exists bug14498_5|
--enable_warnings

create procedure bug14498_1()
begin
  declare continue handler for sqlexception select 'error' as 'Handler';

  if v then
    select 'yes' as 'v';
  else
    select 'no' as 'v';
  end if;
  select 'done' as 'End';
end|

create procedure bug14498_2()
begin
  declare continue handler for sqlexception select 'error' as 'Handler';

  while v do
    select 'yes' as 'v';
  end while;
  select 'done' as 'End';
end|

create procedure bug14498_3()
begin
  declare continue handler for sqlexception select 'error' as 'Handler';

  repeat
    select 'maybe' as 'v';
  until v end repeat;
  select 'done' as 'End';
end|

create procedure bug14498_4()
begin
  declare continue handler for sqlexception select 'error' as 'Handler';

  case v
  when 1 then
    select '1' as 'v';
  when 2 then
    select '2' as 'v';
  else
    select '?' as 'v';
  end case;
  select 'done' as 'End';
end|

create procedure bug14498_5()
begin
  declare continue handler for sqlexception select 'error' as 'Handler';

  case
  when v = 1 then
    select '1' as 'v';
  when v = 2 then
    select '2' as 'v';
  else
    select '?' as 'v';
  end case;
  select 'done' as 'End';
end|

call bug14498_1()|
call bug14498_2()|
call bug14498_3()|
5129
call bug14498_4()|
5130 5131 5132 5133 5134 5135 5136
call bug14498_5()|

drop procedure bug14498_1|
drop procedure bug14498_2|
drop procedure bug14498_3|
drop procedure bug14498_4|
drop procedure bug14498_5|
5137 5138

#
5139
# BUG#15231: Stored procedure bug with not found condition handler
5140 5141 5142 5143 5144 5145 5146 5147 5148 5149 5150 5151 5152 5153 5154 5155 5156 5157 5158 5159 5160 5161 5162 5163 5164 5165 5166 5167 5168 5169 5170 5171 5172 5173 5174 5175 5176 5177 5178 5179 5180 5181 5182 5183 5184 5185 5186 5187 5188 5189 5190 5191 5192 5193 5194 5195 5196 5197 5198
#
--disable_warnings
drop table if exists t3|
drop procedure if exists bug15231_1|
drop procedure if exists bug15231_2|
drop procedure if exists bug15231_3|
drop procedure if exists bug15231_4|
--enable_warnings

create table t3 (id int not null)|
  
create procedure bug15231_1()
begin
  declare xid integer;
  declare xdone integer default 0;
  declare continue handler for not found set xdone = 1;

  set xid=null;
  call bug15231_2(xid);
  select xid, xdone;
end|

create procedure bug15231_2(inout ioid integer)
begin
  select "Before NOT FOUND condition is triggered" as '1';
  select id into ioid from t3 where id=ioid;
  select "After NOT FOUND condtition is triggered" as '2';

  if ioid is null then
    set ioid=1;
  end if;
end|

create procedure bug15231_3()
begin
  declare exit handler for sqlwarning
    select 'Caught it (wrong)' as 'Result';

  call bug15231_4();
end|

create procedure bug15231_4()
begin
  declare x decimal(2,1);

  set x = 'zap';
  select 'Missed it (correct)' as 'Result';
end|

call bug15231_1()|
call bug15231_3()|

drop table if exists t3|
drop procedure if exists bug15231_1|
drop procedure if exists bug15231_2|
drop procedure if exists bug15231_3|
drop procedure if exists bug15231_4|


5199 5200 5201 5202 5203 5204 5205 5206 5207 5208 5209 5210 5211 5212 5213 5214 5215 5216 5217 5218 5219 5220 5221 5222 5223 5224 5225 5226 5227 5228 5229
#
# BUG#15011: error handler in nested block not activated
#
--disable_warnings
drop procedure if exists bug15011|
--enable_warnings

create table t3 (c1 int primary key)|

insert into t3 values (1)|

create procedure bug15011()
  deterministic
begin
  declare continue handler for 1062
    select 'Outer' as 'Handler';

  begin
    declare continue handler for 1062
      select 'Inner' as 'Handler';

    insert into t3 values (1);
  end;
end|

call bug15011()|

drop procedure bug15011|
drop table t3|


5230 5231 5232 5233 5234 5235 5236 5237
#
# BUG#NNNN: New bug synopsis
#
#--disable_warnings
#drop procedure if exists bugNNNN|
#--enable_warnings
#create procedure bugNNNN...

5238
# Add bugs above this line. Use existing tables t1 and t2 when
5239
# practical, or create table t3, t4 etc temporarily (and drop them).
5240 5241
delimiter ;|
drop table t1,t2;