sp.test 14 KB
Newer Older
1 2 3 4 5 6 7 8 9
#
# Basic stored PROCEDURE tests
#
#

use test;

--disable_warnings
drop table if exists t1;
10
drop table if exists t2;
11 12 13 14 15 16
--enable_warnings

create table t1 (
	id   char(16) not null,
        data int not null
);
17 18 19 20 21
create table t2 (
	s   char(16) not null,
        i   int not null,
	d   double not null
);
22

23

24 25 26 27
# Single statement, no params.
create procedure foo42()
  insert into test.t1 values ("foo", 42);

28 29 30 31 32 33
call foo42();
select * from t1;
delete from t1;
drop procedure foo42;


34 35 36 37
# USE test: Make sure we remain in the same DB.
create procedure u()
  use sptmp;

38 39 40
--disable_warnings
drop database if exists sptmp;
--enable_warnings
41 42 43 44 45 46 47 48
create database sptmp;
use test;
call u();
select database();
drop database sptmp;
drop procedure u;


49 50 51 52
# Single statement, two IN params.
create procedure bar(x char(16), y int)
  insert into test.t1 values (x, y);

53 54 55 56 57
call bar("bar", 666);
select * from t1;
delete from t1;
# Don't drop procedure yet...

58

59
# Now for multiple statements...
60 61 62 63 64 65 66 67 68
delimiter |;

# Two statements.
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|

69 70 71 72 73 74
call two("one", "two", 3)|
select * from t1|
delete from t1|
drop procedure two|


75 76 77 78 79 80 81 82 83
# Simple test of local variables and SET.
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|

84 85 86 87 88 89
call locset("locset", 19)|
select * from t1|
delete from t1|
drop procedure locset|


90 91 92 93 94 95 96 97 98
# The peculiar (non-standard) mixture of variables types in SET.
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|

99 100 101 102 103 104 105
call mixset("mixset", 19)|
show variables like 'max_join_size'|
select id,data,@z from t1|
delete from t1|
drop procedure mixset|


106 107 108 109 110 111 112 113 114 115 116 117 118 119 120
# Multiple CALL statements, one with OUT parameter.
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.
create procedure zap(x int, out y int)
begin
  declare z int;
  set z = x+1, y = z;
end|

121 122 123 124 125 126 127
call zip("zip", 99)|
select * from t1|
delete from t1|
drop procedure zip|
drop procedure zap|
drop procedure bar|

128

129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146
# "Deep" calls...
create procedure c1(x int)
  call c2("c", x)|
create procedure c2(s char(16), x int)
  call c3(x, s)|
create procedure c3(x int, s char(16))
  call c4("level", x, s)|
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|

147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162
# INOUT test
create procedure iotest(x1 char(16), x2 char(16), y int)
begin
  call inc2(x2, y);
  insert into test.t1 values (x1, y);
end|

create procedure inc2(x char(16), y int)
begin
  call inc(y);
  insert into test.t1 values (x, y);
end|

create procedure inc(inout io int)
  set io = io + 1|

163 164 165 166 167 168 169
call iotest("io1", "io2", 1)|
select * from t1|
delete from t1|
drop procedure iotest|
drop procedure inc2|
drop procedure inc|

170 171 172 173 174 175 176

# Call-by-value test
#  The expected result is:
#    ("cbv2", 4)
#    ("cbv1", 4711)
create procedure cbv1()
begin
177
  declare y int default 3;
178 179 180 181 182 183 184 185 186 187 188

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

create procedure cbv2(y1 int, inout y2 int)
begin
  set y2 = 4711;
  insert into test.t1 values ("cbv2", y1);
end|

189 190 191 192 193 194
call cbv1()|
select * from t1|
delete from t1|
drop procedure cbv1|
drop procedure cbv2|

195

pem@mysql.com's avatar
pem@mysql.com committed
196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225
# Subselect arguments

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

create procedure sub1(id char(16), x int)
  insert into test.t1 values (id, x)|

# QQ This doesn't work yet
#create procedure sub2(id char(16))
#begin
#  declare x int;
#  set x = (select sum(t.x) from test.t2 t);
#  insert into test.t1 values (id, x);
#end|

create function sub3(i int) returns int
  return i+1|

call sub1("sub1a", (select 7))|
call sub1("sub1b", (select max(i) from t2))|
call sub1("sub1c", (select i,d from t2 limit 1))|
call sub1("sub1d", (select 1 from (select 1) a))|
#call sub2("sub2");
select * from t1|
select sub3((select max(i) from t2))|
drop procedure sub1|
#drop procedure sub2|
drop function sub3|


226
# Basic tests of the flow control constructs
227 228 229 230 231 232 233 234

# Just test on 'x'...
create procedure a0(x int)
while x do
  set x = x-1;
  insert into test.t1 values ("a0", x);
end while|

235 236 237 238 239 240
call a0(3)|
select * from t1|
delete from t1|
drop procedure a0|


241 242 243 244 245 246 247
# The same, but with a more traditional test.
create procedure a(x int)
while x > 0 do
  set x = x-1;
  insert into test.t1 values ("a", x);
end while|

248 249 250 251 252 253
call a(3)|
select * from t1|
delete from t1|
drop procedure a|


254 255
# REPEAT
create procedure b(x int)
256 257
repeat
  insert into test.t1 values (repeat("b",3), x);
258
  set x = x-1;
259
until x = 0 end repeat|
260

261 262 263 264 265 266
call b(3)|
select * from t1|
delete from t1|
drop procedure b|


267 268 269 270 271 272
# Check that repeat isn't parsed the wrong way
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|
273

274 275 276
# We don't actually want to call it.
drop procedure b2|

277

278 279 280 281 282 283 284 285 286
# Labelled WHILE with ITERATE (pointless really)
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|

287 288 289 290 291 292
call c(3)|
select * from t1|
delete from t1|
drop procedure c|


293 294 295 296 297 298 299 300 301
# Labelled WHILE with LEAVE
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);
end while hmm|

302 303 304 305 306 307
call d(3)|
select * from t1|
delete from t1|
drop procedure d|


308 309 310 311 312 313 314 315 316 317
# LOOP, with simple IF statement
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|

318 319 320 321 322 323
call e(3)|
select * from t1|
delete from t1|
drop procedure e|


324 325 326 327 328 329 330 331 332 333
# A full IF statement
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|

334 335 336 337 338 339 340 341
call f(-2)|
call f(0)|
call f(4)|
select * from t1|
delete from t1|
drop procedure f|


342 343 344 345 346 347 348 349 350 351 352
# This form of CASE is really just syntactic sugar for IF-ELSEIF-...
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|

353 354 355 356 357 358 359 360
call g(-42)|
call g(0)|
call g(1)|
select * from t1|
delete from t1|
drop procedure g|


361 362 363 364 365 366 367 368 369 370 371
# The "simple CASE"
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|

372 373 374 375 376 377 378 379 380
call h(0)|
call h(1)|
call h(17)|
select * from t1|
delete from t1|
drop procedure h|


# SELECT INTO local variables
381 382 383 384 385 386 387
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|

388 389 390 391 392 393 394
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
395
create procedure into_test2(x char(16), y int)
396 397
begin
  insert into test.t1 values (x, y);
398 399
  select id,data into x,@z from test.t1 limit 1;
  insert into test.t1 values (concat(x, "2"), y+2);
400 401
end|

402 403 404 405
call into_test2("into", 100)|
select id,data,@z from t1|
delete from t1|
drop procedure into_test2|
406 407


408 409
# These two (and the two procedures above) caused an assert() to fail in
# sql_base.cc:lock_tables() at some point.
410

411 412 413 414 415 416
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|
417

418 419 420 421 422
system rm -f /tmp/spout|
call into_outfile("ofile", 1)|
system rm -f /tmp/spout|
delete from t1|
drop procedure into_outfile|
423

424 425 426 427 428 429
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|
430

431 432 433 434 435
system rm -f /tmp/spdump|
call into_dumpfile("dfile", 1)|
system rm -f /tmp/spdump|
delete from t1|
drop procedure into_dumpfile|
436

437

438 439 440
create procedure create_select(x char(16), y int)
begin
  insert into test.t1 values (x, y);
pem@mysql.com's avatar
pem@mysql.com committed
441 442
  create table test.t3 select * from test.t1;
  insert into test.t3 values (concat(x, "2"), y+2);
443
end|
444

pem@mysql.com's avatar
pem@mysql.com committed
445 446 447 448 449 450 451 452 453
--disable_warnings
drop table if exists t3|
--enable_warnings
call create_select("cs", 90)|
select * from t1, t3|
--disable_warnings
drop table if exists t3|
--enable_warnings
delete from t1|
454
drop procedure create_select|
455

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

457 458 459 460
# A minimal, constant FUNCTION.
create function e() returns double
  return 2.7182818284590452354|

461 462
set @e = e()|
select e(), @e|
463 464 465 466 467 468

# A minimal function with one argument
create function inc(i int) returns int
  return i+1|

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

470 471 472
# A minimal function with two arguments
create function mul(x int, y int) returns int
  return x*y|
473

474 475
select mul(1,1), mul(3,5), mul(4711, 666)|

476 477 478 479 480 481
# A minimal string function
create function append(s1 char(8), s2 char(8)) returns char(16)
  return concat(s1, s2)|

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

482
# A function with flow control
483 484
create function fac(n int unsigned) returns bigint unsigned
begin
485
  declare f bigint unsigned default 1;
486 487 488 489 490 491 492 493

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

494
select fac(1), fac(2), fac(5), fac(10)|
495

496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514
# Nested calls
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))|

# These don't work yet.
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|
delete from t2|

515 516 517
drop function e|
drop function inc|
drop function mul|
518
drop function append|
519
drop function fun|
520

521

522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591
#
# CONDITIONs and HANDLERs
#

create procedure hndlr1(val int)
begin
  declare x int default 0;
  declare foo condition for 1146;
  declare continue handler for foo set x = 1;

  insert into test.t666 values ("hndlr1", val);   # Non-existing table
  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|

create procedure hndlr2(val int)
begin
  declare x int default 0;

  begin
    declare exit handler for '42S02' set x = 1;

    insert into test.t666 values ("hndlr2", val); # Non-existing table
  end;

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

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


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;
      insert into test.t666 values ("hndlr3", y);  # Non-existing table
      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|


592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608
create procedure bug822(a_id char(16), a_data int)
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|

call bug822('foo', 42)|
call bug822('foo', 42)|
call bug822('bar', 666)|
select * from t1|
delete from t1|
drop procedure bug822|


609 610 611 612 613
#
# Some "real" examples
#

# fac
614 615 616 617 618 619 620 621

--disable_warnings
drop table if exists fac|
--enable_warnings
create table fac (n int unsigned not null primary key, f bigint unsigned)|

create procedure ifac(n int unsigned)
begin
622 623
  declare i int unsigned default 1;

624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640
  if n > 20 then
    set n = 20;		# bigint overflow otherwise
  end if;
  while i <= n do
    begin
      insert into test.fac values (i, fac(i));
      set i = i + 1;
    end;
  end while;
end|

call ifac(20)|
select * from fac|
drop table fac|
drop procedure ifac|
drop function fac|

641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666

# primes

--disable_warnings
drop table if exists primes|
--enable_warnings

create table primes (
  i int unsigned not null primary key,
  p bigint unsigned not null
)|

insert into primes values
 ( 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)|

create procedure opp(n bigint unsigned, out pp bool)
begin
  declare r double;
667
  declare b, s bigint unsigned default 0;
668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702

  set r = sqrt(n);

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

        select t.p into p from test.primes t where t.i = s;
        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 again;
end|

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
703
      declare pp bool default 0;
704 705 706 707 708 709 710 711 712 713 714 715

      call opp(p, pp);
      if pp then
        insert into test.primes values (i, p);
        set i = i+1;
      end if;
      set p = p+2;
    end;
  end while;
end|

# This isn't the fastest way in the world to compute prime numbers, so
pem@mysql.com's avatar
pem@mysql.com committed
716
# don't be too ambitious. ;-)
717
call ip(200)|
718 719
# We don't want to select the entire table here, just pick a few
# examples.
720
select * from primes where i=45 or i=100 or i=199|
721 722 723 724
drop table primes|
drop procedure opp|
drop procedure ip|

725
delimiter ;|
726
drop table t1;
727
drop table t2;