2003-01-17 14:38:05 +01:00
|
|
|
#
|
|
|
|
# Basic stored PROCEDURE tests
|
|
|
|
#
|
|
|
|
#
|
|
|
|
|
|
|
|
use test;
|
|
|
|
|
|
|
|
--disable_warnings
|
|
|
|
drop table if exists t1;
|
2003-03-02 19:17:41 +01:00
|
|
|
drop table if exists t2;
|
2003-01-17 14:38:05 +01:00
|
|
|
--enable_warnings
|
|
|
|
|
|
|
|
create table t1 (
|
|
|
|
id char(16) not null,
|
|
|
|
data int not null
|
|
|
|
);
|
2003-03-02 19:17:41 +01:00
|
|
|
create table t2 (
|
|
|
|
s char(16) not null,
|
|
|
|
i int not null,
|
|
|
|
d double not null
|
|
|
|
);
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# Single statement, no params.
|
|
|
|
create procedure foo42()
|
|
|
|
insert into test.t1 values ("foo", 42);
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call foo42();
|
|
|
|
select * from t1;
|
|
|
|
delete from t1;
|
|
|
|
drop procedure foo42;
|
|
|
|
|
|
|
|
|
2003-03-26 15:02:48 +01:00
|
|
|
# USE test: Make sure we remain in the same DB.
|
|
|
|
create procedure u()
|
|
|
|
use sptmp;
|
|
|
|
|
2003-04-02 20:42:28 +02:00
|
|
|
--disable_warnings
|
|
|
|
drop database if exists sptmp;
|
|
|
|
--enable_warnings
|
2003-03-26 15:02:48 +01:00
|
|
|
create database sptmp;
|
|
|
|
use test;
|
|
|
|
call u();
|
|
|
|
select database();
|
|
|
|
drop database sptmp;
|
|
|
|
drop procedure u;
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# Single statement, two IN params.
|
|
|
|
create procedure bar(x char(16), y int)
|
|
|
|
insert into test.t1 values (x, y);
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call bar("bar", 666);
|
|
|
|
select * from t1;
|
|
|
|
delete from t1;
|
|
|
|
# Don't drop procedure yet...
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
# Now for multiple statements...
|
2003-01-17 14:38:05 +01:00
|
|
|
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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call two("one", "two", 3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure two|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call locset("locset", 19)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure locset|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call mixset("mixset", 19)|
|
|
|
|
show variables like 'max_join_size'|
|
|
|
|
select id,data,@z from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure mixset|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call zip("zip", 99)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure zip|
|
|
|
|
drop procedure zap|
|
|
|
|
drop procedure bar|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-05-23 15:32:31 +02:00
|
|
|
# "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|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call iotest("io1", "io2", 1)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure iotest|
|
|
|
|
drop procedure inc2|
|
|
|
|
drop procedure inc|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
|
|
|
# Call-by-value test
|
|
|
|
# The expected result is:
|
|
|
|
# ("cbv2", 4)
|
|
|
|
# ("cbv1", 4711)
|
|
|
|
create procedure cbv1()
|
|
|
|
begin
|
2003-03-30 13:25:43 +02:00
|
|
|
declare y int default 3;
|
2003-01-17 14:38:05 +01:00
|
|
|
|
|
|
|
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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call cbv1()|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure cbv1|
|
|
|
|
drop procedure cbv2|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-04-27 17:35:54 +02:00
|
|
|
# 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|
|
|
|
|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
# Basic tests of the flow control constructs
|
2003-01-17 14:38:05 +01:00
|
|
|
|
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call a0(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure a0|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call a(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure a|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# REPEAT
|
|
|
|
create procedure b(x int)
|
2003-01-23 14:00:31 +01:00
|
|
|
repeat
|
|
|
|
insert into test.t1 values (repeat("b",3), x);
|
2003-01-17 14:38:05 +01:00
|
|
|
set x = x-1;
|
2003-01-23 14:00:31 +01:00
|
|
|
until x = 0 end repeat|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call b(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure b|
|
|
|
|
|
|
|
|
|
2003-01-23 14:00:32 +01:00
|
|
|
# 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|
|
2003-02-19 12:42:32 +01:00
|
|
|
|
2003-01-23 14:00:32 +01:00
|
|
|
# We don't actually want to call it.
|
|
|
|
drop procedure b2|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call c(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure c|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call d(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure d|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call e(3)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure e|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call f(-2)|
|
|
|
|
call f(0)|
|
|
|
|
call f(4)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure f|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call g(-42)|
|
|
|
|
call g(0)|
|
|
|
|
call g(1)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure g|
|
|
|
|
|
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call h(0)|
|
|
|
|
call h(1)|
|
|
|
|
call h(17)|
|
|
|
|
select * from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure h|
|
|
|
|
|
|
|
|
|
|
|
|
# SELECT INTO local variables
|
2003-02-02 17:41:21 +01:00
|
|
|
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|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
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
|
2003-02-02 17:41:21 +01:00
|
|
|
create procedure into_test2(x char(16), y int)
|
2003-01-18 17:21:13 +01:00
|
|
|
begin
|
|
|
|
insert into test.t1 values (x, y);
|
2003-02-02 17:41:21 +01:00
|
|
|
select id,data into x,@z from test.t1 limit 1;
|
|
|
|
insert into test.t1 values (concat(x, "2"), y+2);
|
2003-01-18 17:21:13 +01:00
|
|
|
end|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
call into_test2("into", 100)|
|
|
|
|
select id,data,@z from t1|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure into_test2|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
# These two (and the two procedures above) caused an assert() to fail in
|
|
|
|
# sql_base.cc:lock_tables() at some point.
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
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|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
system rm -f /tmp/spout|
|
|
|
|
call into_outfile("ofile", 1)|
|
|
|
|
system rm -f /tmp/spout|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure into_outfile|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
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|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
system rm -f /tmp/spdump|
|
|
|
|
call into_dumpfile("dfile", 1)|
|
|
|
|
system rm -f /tmp/spdump|
|
|
|
|
delete from t1|
|
|
|
|
drop procedure into_dumpfile|
|
2003-02-02 17:41:21 +01:00
|
|
|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
create procedure create_select(x char(16), y int)
|
|
|
|
begin
|
|
|
|
insert into test.t1 values (x, y);
|
2003-04-04 15:47:43 +02:00
|
|
|
create table test.t3 select * from test.t1;
|
|
|
|
insert into test.t3 values (concat(x, "2"), y+2);
|
2003-02-19 12:42:32 +01:00
|
|
|
end|
|
2003-02-02 17:41:21 +01:00
|
|
|
|
2003-04-04 15:47:43 +02:00
|
|
|
--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|
|
2003-02-19 12:42:32 +01:00
|
|
|
drop procedure create_select|
|
2003-01-17 14:38:05 +01:00
|
|
|
|
2003-04-04 15:47:43 +02:00
|
|
|
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
# A minimal, constant FUNCTION.
|
|
|
|
create function e() returns double
|
|
|
|
return 2.7182818284590452354|
|
|
|
|
|
2003-02-27 19:08:52 +01:00
|
|
|
set @e = e()|
|
|
|
|
select e(), @e|
|
2003-02-26 19:22:29 +01:00
|
|
|
|
|
|
|
# A minimal function with one argument
|
|
|
|
create function inc(i int) returns int
|
|
|
|
return i+1|
|
|
|
|
|
|
|
|
select inc(1), inc(99), inc(-71)|
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
|
2003-02-26 19:22:29 +01:00
|
|
|
# A minimal function with two arguments
|
|
|
|
create function mul(x int, y int) returns int
|
|
|
|
return x*y|
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
|
2003-02-26 19:22:29 +01:00
|
|
|
select mul(1,1), mul(3,5), mul(4711, 666)|
|
|
|
|
|
2003-02-27 19:08:52 +01:00
|
|
|
# A minimal string function
|
|
|
|
create function append(s1 char(8), s2 char(8)) returns char(16)
|
|
|
|
return concat(s1, s2)|
|
|
|
|
|
|
|
|
select append("foo", "bar")|
|
|
|
|
|
2003-02-26 19:22:29 +01:00
|
|
|
# A function with flow control
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
create function fac(n int unsigned) returns bigint unsigned
|
|
|
|
begin
|
2003-03-30 13:25:43 +02:00
|
|
|
declare f bigint unsigned default 1;
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
|
|
|
|
while n > 1 do
|
|
|
|
set f = f * n;
|
|
|
|
set n = n - 1;
|
|
|
|
end while;
|
|
|
|
return f;
|
|
|
|
end|
|
|
|
|
|
2003-02-27 19:08:52 +01:00
|
|
|
select fac(1), fac(2), fac(5), fac(10)|
|
2003-02-26 19:22:29 +01:00
|
|
|
|
2003-03-02 19:17:41 +01:00
|
|
|
# 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|
|
|
|
|
|
2003-02-26 19:22:29 +01:00
|
|
|
drop function e|
|
|
|
|
drop function inc|
|
|
|
|
drop function mul|
|
2003-02-27 19:08:52 +01:00
|
|
|
drop function append|
|
2003-03-02 19:17:41 +01:00
|
|
|
drop function fun|
|
Most of the groundwork for sprint task 729 (implement FUNCTIONs).
Expanded the mysql.proc table, reworked the find/create/drop functions
completely, added new functions for FUNCTIONs (lotta functions here :),
got rid of some unnecessary use of Item_strings while at it. Extended
the parser correspondingly, and fiddled around a bit to make SP FUNCTIONs
coexist with UDFs.
Can now CREATE and DROP FUNCTIONs. Invoking yet to come...
Docs/sp-implemented.txt:
Updated with info about CASCADE/RESTICT and METHOD, and some answers to questions.
include/mysqld_error.h:
New error message for misuse of RETURN.
mysql-test/install_test_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
mysql-test/r/sp.result:
New test for creating and dropping FUNCTIONS.
mysql-test/t/sp.test:
New test for creating and dropping FUNCTIONS.
scripts/mysql_install_db.sh:
Added enum field to mysql.proc to distinguish between FUNCTION and PROCEDURE.
sql/lex.h:
De-UDFed some symbol names, as they are now used for SPs as well.
Added RETURN_SYM.
sql/share/czech/errmsg.txt:
New error message for misuse of RETURN.
sql/share/danish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/dutch/errmsg.txt:
New error message for misuse of RETURN.
sql/share/english/errmsg.txt:
New error message for misuse of RETURN.
sql/share/estonian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/french/errmsg.txt:
New error message for misuse of RETURN.
sql/share/german/errmsg.txt:
New error message for misuse of RETURN.
sql/share/greek/errmsg.txt:
New error message for misuse of RETURN.
sql/share/hungarian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/italian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/japanese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/korean/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian-ny/errmsg.txt:
New error message for misuse of RETURN.
sql/share/norwegian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/polish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/portuguese/errmsg.txt:
New error message for misuse of RETURN.
sql/share/romanian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/russian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/serbian/errmsg.txt:
New error message for misuse of RETURN.
sql/share/slovak/errmsg.txt:
New error message for misuse of RETURN.
sql/share/spanish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/swedish/errmsg.txt:
New error message for misuse of RETURN.
sql/share/ukrainian/errmsg.txt:
New error message for misuse of RETURN.
sql/sp.cc:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp.h:
Major rehack to accomodate FUNCTIONs, and to make it easier to add
future in-memory cache of prepared SPs.
sql/sp_head.cc:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sp_head.h:
Now creates FUNCTIONs too. (And got rid of some unnecessary Item_string use.)
sql/sql_lex.h:
New stored FUNCTION commands.
sql/sql_parse.cc:
Added FUNCTION support ("drop" merged with the old UDF code), and made some
additional changes for better error handling (following the sp.cc rehacking).
sql/sql_yacc.yy:
Some former UDF specific symbols renamed.
Added CREATE FUNCTION parsing.
DROP FUNCTION had to be partly merged with the old UDF code, because of the similar
syntax.
RETURN statement added, but still a no-op.
2003-02-21 17:37:05 +01:00
|
|
|
|
2003-03-03 15:03:19 +01:00
|
|
|
|
2003-09-16 14:26:08 +02:00
|
|
|
#
|
|
|
|
# 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|
|
|
|
|
|
|
|
|
|
2003-03-06 19:16:46 +01:00
|
|
|
#
|
|
|
|
# Some "real" examples
|
|
|
|
#
|
|
|
|
|
|
|
|
# fac
|
2003-03-03 15:03:19 +01:00
|
|
|
|
|
|
|
--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
|
2003-03-30 13:25:43 +02:00
|
|
|
declare i int unsigned default 1;
|
|
|
|
|
2003-03-03 15:03:19 +01:00
|
|
|
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|
|
|
|
|
|
2003-03-06 19:16:46 +01:00
|
|
|
|
|
|
|
# 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;
|
2003-03-30 13:25:43 +02:00
|
|
|
declare b, s bigint unsigned default 0;
|
2003-03-06 19:16:46 +01:00
|
|
|
|
|
|
|
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
|
2003-03-30 13:25:43 +02:00
|
|
|
declare pp bool default 0;
|
2003-03-06 19:16:46 +01:00
|
|
|
|
|
|
|
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
|
2003-04-04 15:47:43 +02:00
|
|
|
# don't be too ambitious. ;-)
|
2003-03-20 11:57:05 +01:00
|
|
|
call ip(200)|
|
2003-03-06 19:16:46 +01:00
|
|
|
# We don't want to select the entire table here, just pick a few
|
|
|
|
# examples.
|
2003-03-20 11:57:05 +01:00
|
|
|
select * from primes where i=45 or i=100 or i=199|
|
2003-03-06 19:16:46 +01:00
|
|
|
drop table primes|
|
|
|
|
drop procedure opp|
|
|
|
|
drop procedure ip|
|
|
|
|
|
2003-02-19 12:42:32 +01:00
|
|
|
delimiter ;|
|
2003-01-17 14:38:05 +01:00
|
|
|
drop table t1;
|
2003-03-02 19:17:41 +01:00
|
|
|
drop table t2;
|