From 3c88ebdc9dec478a44de8f6d55a22c105f1d20f0 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 19 Feb 2003 12:42:32 +0100 Subject: [PATCH] Fixed SELECT INTO OUTFILE/DUMPFILE and stored procedures, and extended and reorganized the sp.test file. mysql-test/r/sp.result: New results from the reorganized sp.test file. mysql-test/t/sp.test: Reorganized the tests, and added a few new ones. ("fac" and more "select into") sql/sql_class.cc: Unlock tables and set thd->lock=0 in select_export::send_eof() and select_dump::send_eof(). This fixes a problem with an assert() in lock_tables(), and made SELECT ... INTO OUTFILE and ... INTO DUMPFILE work in stored procedures. --- mysql-test/r/sp.result | 354 +++++++++++++++++++++++++---------------- mysql-test/t/sp.test | 330 +++++++++++++++++++++++++------------- sql/sql_class.cc | 18 +++ 3 files changed, 451 insertions(+), 251 deletions(-) diff --git a/mysql-test/r/sp.result b/mysql-test/r/sp.result index 35b35e91777..ddc8c805f78 100644 --- a/mysql-test/r/sp.result +++ b/mysql-test/r/sp.result @@ -6,13 +6,31 @@ data int not null ); create procedure foo42() insert into test.t1 values ("foo", 42); +call foo42(); +select * from t1; +id data +foo 42 +delete from t1; +drop procedure foo42; create procedure bar(x char(16), y int) insert into test.t1 values (x, y); +call bar("bar", 666); +select * from t1; +id data +bar 666 +delete from t1; 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; +call two("one", "two", 3); +select * from t1; +id data +one 3 +two 3 +delete from t1; +drop procedure two; create procedure locset(x char(16), y int) begin declare z1, z2 int; @@ -20,12 +38,27 @@ set z1 = y; set z2 = z1+2; insert into test.t1 values (x, z2); end; +call locset("locset", 19); +select * from t1; +id data +locset 21 +delete from t1; +drop procedure locset; 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; +call mixset("mixset", 19); +show variables like 'max_join_size'; +Variable_name Value +max_join_size 100 +select id,data,@z from t1; +id data @z +mixset 666 19 +delete from t1; +drop procedure mixset; create procedure zip(x char(16), y int) begin declare z int; @@ -37,6 +70,14 @@ begin declare z int; set z = x+1, y = z; end; +call zip("zip", 99); +select * from t1; +id data +zip 100 +delete from t1; +drop procedure zip; +drop procedure zap; +drop procedure bar; create procedure iotest(x1 char(16), x2 char(16), y int) begin call inc2(x2, y); @@ -49,6 +90,15 @@ insert into test.t1 values (x, y); end; create procedure inc(inout io int) set io = io + 1; +call iotest("io1", "io2", 1); +select * from t1; +id data +io2 2 +io1 1 +delete from t1; +drop procedure iotest; +drop procedure inc2; +drop procedure inc; create procedure cbv1() begin declare y int; @@ -61,21 +111,53 @@ begin set y2 = 4711; insert into test.t1 values ("cbv2", y1); end; +call cbv1(); +select * from t1; +id data +cbv2 4 +cbv1 4711 +delete from t1; +drop procedure cbv1; +drop procedure cbv2; create procedure a0(x int) while x do set x = x-1; insert into test.t1 values ("a0", x); end while; +call a0(3); +select * from t1; +id data +a0 2 +a0 1 +a0 0 +delete from t1; +drop procedure a0; create procedure a(x int) while x > 0 do set x = x-1; insert into test.t1 values ("a", x); end while; +call a(3); +select * from t1; +id data +a 2 +a 1 +a 0 +delete from t1; +drop procedure a; create procedure b(x int) repeat insert into test.t1 values (repeat("b",3), x); set x = x-1; until x = 0 end repeat; +call b(3); +select * from t1; +id data +bbb 3 +bbb 2 +bbb 1 +delete from t1; +drop procedure b; create procedure b2(x int) repeat(select 1 into outfile 'b2'); insert into test.t1 values (repeat("b2",3), x); @@ -96,6 +178,14 @@ set x = x-1; iterate hmm; insert into test.t1 values ("x", x); end while hmm; +call c(3); +select * from t1; +id data +c 3 +c 2 +c 1 +delete from t1; +drop procedure c; create procedure d(x int) hmm: while x > 0 do insert into test.t1 values ("d", x); @@ -103,6 +193,12 @@ set x = x-1; leave hmm; insert into test.t1 values ("x", x); end while hmm; +call d(3); +select * from t1; +id data +d 3 +delete from t1; +drop procedure d; create procedure e(x int) foo: loop if x = 0 then @@ -111,6 +207,14 @@ end if; insert into test.t1 values ("e", x); set x = x-1; end loop foo; +call e(3); +select * from t1; +id data +e 3 +e 2 +e 1 +delete from t1; +drop procedure e; create procedure f(x int) if x < 0 then insert into test.t1 values ("f", 0); @@ -119,122 +223,6 @@ insert into test.t1 values ("f", 1); else insert into test.t1 values ("f", 2); end if; -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; -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; -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; -create procedure into_test2(x char(16), y int) -begin -insert into test.t1 values (x, y); -select id,data into x,@z from test.t1 limit 1; -insert into test.t1 values (concat(x, "2"), y+2); -end; -call foo42(); -select * from t1; -id data -foo 42 -delete from t1; -call bar("bar", 666); -select * from t1; -id data -bar 666 -delete from t1; -call two("one", "two", 3); -select * from t1; -id data -one 3 -two 3 -delete from t1; -call locset("locset", 19); -select * from t1; -id data -locset 21 -delete from t1; -call mixset("mixset", 19); -show variables like 'max_join_size'; -Variable_name Value -max_join_size 100 -select id,data,@z from t1; -id data @z -mixset 666 19 -delete from t1; -call zip("zip", 99); -select * from t1; -id data -zip 100 -delete from t1; -call iotest("io1", "io2", 1); -select * from t1; -id data -io2 2 -io1 1 -delete from t1; -call cbv1(); -select * from t1; -id data -cbv2 4 -cbv1 4711 -delete from t1; -call a0(3); -select * from t1; -id data -a0 2 -a0 1 -a0 0 -delete from t1; -call a(3); -select * from t1; -id data -a 2 -a 1 -a 0 -delete from t1; -call b(3); -select * from t1; -id data -bbb 3 -bbb 2 -bbb 1 -delete from t1; -call c(3); -select * from t1; -id data -c 3 -c 2 -c 1 -delete from t1; -call d(3); -select * from t1; -id data -d 3 -delete from t1; -call e(3); -select * from t1; -id data -e 3 -e 2 -e 1 -delete from t1; call f(-2); call f(0); call f(4); @@ -244,6 +232,16 @@ f 0 f 1 f 2 delete from t1; +drop procedure f; +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; call g(-42); call g(0); call g(1); @@ -253,6 +251,16 @@ g 0 g 1 g 2 delete from t1; +drop procedure g; +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; call h(0); call h(1); call h(17); @@ -262,39 +270,109 @@ h0 0 h1 1 h? 17 delete from t1; +drop procedure h; +drop table if exists fac; +create table fac (n int unsigned not null primary key, f bigint unsigned); +create procedure ifac(n int unsigned) +begin +declare i int unsigned; +set i = 1; +if n > 20 then +set n = 20; +end if; +while i <= n do +begin +declare f bigint unsigned; +set f = 0; # Temp. fix, this should not be needed in the future. +call fac(i, f); +insert into test.fac values (i, f); +set i = i + 1; +end; +end while; +end; +create procedure fac(n int unsigned, out f bigint unsigned) +begin +set f = 1; +while n > 1 do +set f = f * n; +set n = n - 1; +end while; +end; +call ifac(20); +select * from fac; +n f +1 1 +2 2 +3 6 +4 24 +5 120 +6 720 +7 5040 +8 40320 +9 362880 +10 3628800 +11 39916800 +12 479001600 +13 6227020800 +14 87178291200 +15 1307674368000 +16 20922789888000 +17 355687428096000 +18 6402373705728000 +19 121645100408832000 +20 2432902008176640000 +drop table fac; +drop procedure ifac; +drop procedure fac; +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; call into_test("into", 100); select * from t1; id data into 100 into2 102 delete from t1; +drop procedure into_test; +create procedure into_test2(x char(16), y int) +begin +insert into test.t1 values (x, y); +select id,data into x,@z from test.t1 limit 1; +insert into test.t1 values (concat(x, "2"), y+2); +end; call into_test2("into", 100); select id,data,@z from t1; id data @z into 100 100 into2 102 100 delete from t1; -drop procedure foo42; -drop procedure bar; -drop procedure two; -drop procedure locset; -drop procedure mixset; -drop procedure zip; -drop procedure zap; -drop procedure iotest; -drop procedure inc2; -drop procedure inc; -drop procedure cbv1; -drop procedure cbv2; -drop procedure a0; -drop procedure a; -drop procedure b; -drop procedure c; -drop procedure d; -drop procedure e; -drop procedure f; -drop procedure g; -drop procedure h; -drop procedure into_test; drop procedure into_test2; +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; +call into_outfile("ofile", 1); +delete from t1; +drop procedure into_outfile; +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; +call into_dumpfile("dfile", 1); +delete from t1; +drop procedure into_dumpfile; +create procedure create_select(x char(16), y int) +begin +insert into test.t1 values (x, y); +create table test.t2 select * from test.t1; +insert into test.t2 values (concat(x, "2"), y+2); +end; +drop procedure create_select; drop table t1; diff --git a/mysql-test/t/sp.test b/mysql-test/t/sp.test index 48919ff1d6e..55aa287b8b0 100644 --- a/mysql-test/t/sp.test +++ b/mysql-test/t/sp.test @@ -14,16 +14,28 @@ create table t1 ( data int not null ); + # Single statement, no params. create procedure foo42() insert into test.t1 values ("foo", 42); +call foo42(); +select * from t1; +delete from t1; +drop procedure foo42; + + # Single statement, two IN params. create procedure bar(x char(16), y int) insert into test.t1 values (x, y); -# Now for multiple statements... +call bar("bar", 666); +select * from t1; +delete from t1; +# Don't drop procedure yet... + +# Now for multiple statements... delimiter |; # Two statements. @@ -33,6 +45,12 @@ begin insert into test.t1 values (x2, y); end| +call two("one", "two", 3)| +select * from t1| +delete from t1| +drop procedure two| + + # Simple test of local variables and SET. create procedure locset(x char(16), y int) begin @@ -42,6 +60,12 @@ begin insert into test.t1 values (x, z2); end| +call locset("locset", 19)| +select * from t1| +delete from t1| +drop procedure locset| + + # The peculiar (non-standard) mixture of variables types in SET. create procedure mixset(x char(16), y int) begin @@ -51,6 +75,13 @@ begin insert into test.t1 values (x, z); end| +call mixset("mixset", 19)| +show variables like 'max_join_size'| +select id,data,@z from t1| +delete from t1| +drop procedure mixset| + + # Multiple CALL statements, one with OUT parameter. create procedure zip(x char(16), y int) begin @@ -66,6 +97,13 @@ begin set z = x+1, y = z; end| +call zip("zip", 99)| +select * from t1| +delete from t1| +drop procedure zip| +drop procedure zap| +drop procedure bar| + # INOUT test create procedure iotest(x1 char(16), x2 char(16), y int) @@ -83,6 +121,13 @@ end| create procedure inc(inout io int) set io = io + 1| +call iotest("io1", "io2", 1)| +select * from t1| +delete from t1| +drop procedure iotest| +drop procedure inc2| +drop procedure inc| + # Call-by-value test # The expected result is: @@ -103,8 +148,14 @@ begin insert into test.t1 values ("cbv2", y1); end| +call cbv1()| +select * from t1| +delete from t1| +drop procedure cbv1| +drop procedure cbv2| -# Minimal tests of the flow control construts + +# Basic tests of the flow control constructs # Just test on 'x'... create procedure a0(x int) @@ -113,6 +164,12 @@ while x do insert into test.t1 values ("a0", x); end while| +call a0(3)| +select * from t1| +delete from t1| +drop procedure a0| + + # The same, but with a more traditional test. create procedure a(x int) while x > 0 do @@ -120,6 +177,12 @@ while x > 0 do insert into test.t1 values ("a", x); end while| +call a(3)| +select * from t1| +delete from t1| +drop procedure a| + + # REPEAT create procedure b(x int) repeat @@ -127,16 +190,24 @@ repeat set x = x-1; until x = 0 end repeat| +call b(3)| +select * from t1| +delete from t1| +drop procedure b| + + # 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| + # We don't actually want to call it. drop procedure b2| -# Btw, this should generate an error + +# Btw, this should generate an error (for now; this might change in the future) --error 1259 create procedure b3(x int) repeat @@ -145,6 +216,7 @@ repeat set x = x-1; until x = 0 end repeat| + # Labelled WHILE with ITERATE (pointless really) create procedure c(x int) hmm: while x > 0 do @@ -154,6 +226,12 @@ hmm: while x > 0 do insert into test.t1 values ("x", x); end while hmm| +call c(3)| +select * from t1| +delete from t1| +drop procedure c| + + # Labelled WHILE with LEAVE create procedure d(x int) hmm: while x > 0 do @@ -163,6 +241,12 @@ hmm: while x > 0 do insert into test.t1 values ("x", x); end while hmm| +call d(3)| +select * from t1| +delete from t1| +drop procedure d| + + # LOOP, with simple IF statement create procedure e(x int) foo: loop @@ -173,6 +257,12 @@ foo: loop set x = x-1; end loop foo| +call e(3)| +select * from t1| +delete from t1| +drop procedure e| + + # A full IF statement create procedure f(x int) if x < 0 then @@ -183,6 +273,14 @@ else insert into test.t1 values ("f", 2); end if| +call f(-2)| +call f(0)| +call f(4)| +select * from t1| +delete from t1| +drop procedure f| + + # This form of CASE is really just syntactic sugar for IF-ELSEIF-... create procedure g(x int) case @@ -194,6 +292,14 @@ else insert into test.t1 values ("g", 2); end case| +call g(-42)| +call g(0)| +call g(1)| +select * from t1| +delete from t1| +drop procedure g| + + # The "simple CASE" create procedure h(x int) case x @@ -205,6 +311,56 @@ else insert into test.t1 values ("h?", x); end case| +call h(0)| +call h(1)| +call h(17)| +select * from t1| +delete from t1| +drop procedure h| + + +# A "real" procedure example + +--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 + declare i int unsigned; + set i = 1; + if n > 20 then + set n = 20; + end if; + while i <= n do + begin + declare f bigint unsigned; + set f = 0; # Temp. fix, this should not be needed in the future. + call fac(i, f); + insert into test.fac values (i, f); + set i = i + 1; + end; + end while; +end| + +create procedure fac(n int unsigned, out f bigint unsigned) +begin + set f = 1; + while n > 1 do + set f = f * n; + set n = n - 1; + end while; +end| + +call ifac(20)| +select * from fac| +drop table fac| +drop procedure ifac| +drop procedure fac| + + +# SELECT INTO local variables create procedure into_test(x char(16), y int) begin insert into test.t1 values (x, y); @@ -212,7 +368,13 @@ begin insert into test.t1 values (concat(x, "2"), y+2); end| -# Test INTO with a mix of local and global variables +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 create procedure into_test2(x char(16), y int) begin insert into test.t1 values (x, y); @@ -220,114 +382,56 @@ begin insert into test.t1 values (concat(x, "2"), y+2); end| +call into_test2("into", 100)| +select id,data,@z from t1| +delete from t1| +drop procedure into_test2| + + +# These two (and the two procedures above) caused an assert() to fail in +# sql_base.cc:lock_tables() at some point. + +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| + +system rm -f /tmp/spout| +call into_outfile("ofile", 1)| +system rm -f /tmp/spout| +delete from t1| +drop procedure into_outfile| + +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| + +system rm -f /tmp/spdump| +call into_dumpfile("dfile", 1)| +system rm -f /tmp/spdump| +delete from t1| +drop procedure into_dumpfile| + + +create procedure create_select(x char(16), y int) +begin + insert into test.t1 values (x, y); + create table test.t2 select * from test.t1; + insert into test.t2 values (concat(x, "2"), y+2); +end| + +# This doesn't work right now. It suffers from the same problem as the ones +# above, but the fix caused create.test to hang. :-( +#call create_select("cs", 90)| +#select * from t1, t2| +#delete from t1| +#drop table t2| +drop procedure create_select| + delimiter ;| - -# Now, the CALL tests... -call foo42(); -select * from t1; -delete from t1; - -call bar("bar", 666); -select * from t1; -delete from t1; - -call two("one", "two", 3); -select * from t1; -delete from t1; - -call locset("locset", 19); -select * from t1; -delete from t1; - -call mixset("mixset", 19); -show variables like 'max_join_size'; -select id,data,@z from t1; -delete from t1; - -call zip("zip", 99); -select * from t1; -delete from t1; - -call iotest("io1", "io2", 1); -select * from t1; -delete from t1; - -call cbv1(); -select * from t1; -delete from t1; - -call a0(3); -select * from t1; -delete from t1; - -call a(3); -select * from t1; -delete from t1; - -call b(3); -select * from t1; -delete from t1; - -call c(3); -select * from t1; -delete from t1; - -call d(3); -select * from t1; -delete from t1; - -call e(3); -select * from t1; -delete from t1; - -call f(-2); -call f(0); -call f(4); -select * from t1; -delete from t1; - -call g(-42); -call g(0); -call g(1); -select * from t1; -delete from t1; - -call h(0); -call h(1); -call h(17); -select * from t1; -delete from t1; - -call into_test("into", 100); -select * from t1; -delete from t1; - -call into_test2("into", 100); -select id,data,@z from t1; -delete from t1; - -drop procedure foo42; -drop procedure bar; -drop procedure two; -drop procedure locset; -drop procedure mixset; -drop procedure zip; -drop procedure zap; -drop procedure iotest; -drop procedure inc2; -drop procedure inc; -drop procedure cbv1; -drop procedure cbv2; -drop procedure a0; -drop procedure a; -drop procedure b; -drop procedure c; -drop procedure d; -drop procedure e; -drop procedure f; -drop procedure g; -drop procedure h; -drop procedure into_test; -drop procedure into_test2; - drop table t1; diff --git a/sql/sql_class.cc b/sql/sql_class.cc index 7ea9bfc1ba6..ac82996600f 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -801,6 +801,15 @@ void select_export::send_error(uint errcode, const char *err) bool select_export::send_eof() { + /* This mimics select_send::send_eof(), which unlocks this way. + * It appears to be necessary, since tables aren't unlock after + * selects otherwise. + */ + if (thd->lock) + { + mysql_unlock_tables(thd, thd->lock); + thd->lock=0; + } int error=test(end_io_cache(&cache)); if (my_close(file,MYF(MY_WME))) error=1; @@ -911,6 +920,15 @@ void select_dump::send_error(uint errcode,const char *err) bool select_dump::send_eof() { + /* This mimics select_send::send_eof(), which unlocks this way. + * It appears to be necessary, since tables aren't unlock after + * selects otherwise. + */ + if (thd->lock) + { + mysql_unlock_tables(thd, thd->lock); + thd->lock=0; + } int error=test(end_io_cache(&cache)); if (my_close(file,MYF(MY_WME))) error=1;