A fix and a test case for Bug#17843 "Certain stored procedures fail to
run at startup" The server returned an error when trying to execute init-file with a stored procedure that could return multiple result sets to the client. A stored procedure can return multiple result sets if it contains PREPARE, SELECT, SHOW and similar statements. The fix is to set client_capabilites|=CLIENT_MULTI_RESULTS in sql_parse.cc:handle_bootstrap(). There is no "client" really, so nothing is ever sent. This makes init-file feature behave consistently: the prepared statements that can be called directly in the init-file can be used in a stored procedure too. Re-committed the patch originally submitted by Per-Erik after review. mysql-test/Makefile.am: Fix re-make without make clean. mysql-test/r/init_connect.result: Updated results (a test case for Bug#17843) mysql-test/r/init_file.result: Updated results (a test case for Bug#17843) mysql-test/std_data/init_file.dat: Add test coverage for new features added in 5.0. Note, that what can be done in init_file is very limited as it does not support any other delimiter except ';' -- only "one liners" and no multiple statement procedures. Also, this is executed with a dummy user "boot@", which calls for the use of DEFINER clause. mysql-test/t/init_connect.test: Add test coverage for new features added in 5.0. mysql-test/t/init_file.test: Add test coverage for new features added in 5.0 -- stored routines, views, triggers. The actual tests are in std_data/init_file.dat, here we just check the results and clean up. sql/sql_class.cc: Initialize Security_context::priv_host to an empty string: when executing an init-file, sql_parse.cc:get_default_definer() will use this for the value of the definer if it's not set in the query. sql/sql_parse.cc: Set CLIENT_MULTI_RESULTS in handle_bootstrap(), to make prepared statements work in stored procedures called from init-file.
This commit is contained in:
parent
6a8f2ee293
commit
c12cc90d12
@ -101,15 +101,15 @@ uninstall-local:
|
|||||||
@RM@ -f -r $(DESTDIR)$(testdir)
|
@RM@ -f -r $(DESTDIR)$(testdir)
|
||||||
|
|
||||||
std_data/client-key.pem: $(top_srcdir)/SSL/$(@F)
|
std_data/client-key.pem: $(top_srcdir)/SSL/$(@F)
|
||||||
@CP@ $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
@CP@ -f $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
||||||
std_data/client-cert.pem: $(top_srcdir)/SSL/$(@F)
|
std_data/client-cert.pem: $(top_srcdir)/SSL/$(@F)
|
||||||
@CP@ $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
@CP@ -f $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
||||||
std_data/cacert.pem: $(top_srcdir)/SSL/$(@F)
|
std_data/cacert.pem: $(top_srcdir)/SSL/$(@F)
|
||||||
@CP@ $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
@CP@ -f $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
||||||
std_data/server-cert.pem: $(top_srcdir)/SSL/$(@F)
|
std_data/server-cert.pem: $(top_srcdir)/SSL/$(@F)
|
||||||
@CP@ $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
@CP@ -f $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
||||||
std_data/server-key.pem: $(top_srcdir)/SSL/$(@F)
|
std_data/server-key.pem: $(top_srcdir)/SSL/$(@F)
|
||||||
@CP@ $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
@CP@ -f $(top_srcdir)/SSL/$(@F) $(srcdir)/std_data
|
||||||
|
|
||||||
SUFFIXES = .sh
|
SUFFIXES = .sh
|
||||||
|
|
||||||
|
@ -22,3 +22,117 @@ set GLOBAL init_connect="adsfsdfsdfs";
|
|||||||
select @a;
|
select @a;
|
||||||
Got one of the listed errors
|
Got one of the listed errors
|
||||||
drop table t1;
|
drop table t1;
|
||||||
|
End of 4.1 tests
|
||||||
|
create table t1 (x int);
|
||||||
|
insert into t1 values (3), (5), (7);
|
||||||
|
create table t2 (y int);
|
||||||
|
create user mysqltest1@localhost;
|
||||||
|
grant all privileges on test.* to mysqltest1@localhost;
|
||||||
|
set global init_connect="create procedure p1() select * from t1";
|
||||||
|
call p1();
|
||||||
|
x
|
||||||
|
3
|
||||||
|
5
|
||||||
|
7
|
||||||
|
drop procedure p1;
|
||||||
|
set global init_connect="create procedure p1(x int)\
|
||||||
|
begin\
|
||||||
|
select count(*) from t1;\
|
||||||
|
select * from t1;\
|
||||||
|
set @x = x;
|
||||||
|
end";
|
||||||
|
call p1(42);
|
||||||
|
count(*)
|
||||||
|
3
|
||||||
|
x
|
||||||
|
3
|
||||||
|
5
|
||||||
|
7
|
||||||
|
select @x;
|
||||||
|
@x
|
||||||
|
42
|
||||||
|
set global init_connect="call p1(4711)";
|
||||||
|
select @x;
|
||||||
|
@x
|
||||||
|
4711
|
||||||
|
set global init_connect="drop procedure if exists p1";
|
||||||
|
call p1();
|
||||||
|
ERROR 42000: PROCEDURE test.p1 does not exist
|
||||||
|
create procedure p1(out sum int)
|
||||||
|
begin
|
||||||
|
declare n int default 0;
|
||||||
|
declare c cursor for select * from t1;
|
||||||
|
declare exit handler for not found
|
||||||
|
begin
|
||||||
|
close c;
|
||||||
|
set sum = n;
|
||||||
|
end;
|
||||||
|
open c;
|
||||||
|
loop
|
||||||
|
begin
|
||||||
|
declare x int;
|
||||||
|
fetch c into x;
|
||||||
|
if x > 3 then
|
||||||
|
set n = n + x;
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
end loop;
|
||||||
|
end|
|
||||||
|
set global init_connect="call p1(@sum)";
|
||||||
|
select @sum;
|
||||||
|
@sum
|
||||||
|
12
|
||||||
|
drop procedure p1;
|
||||||
|
create procedure p1(tbl char(10), v int)
|
||||||
|
begin
|
||||||
|
set @s = concat('insert into ', tbl, ' values (?)');
|
||||||
|
set @v = v;
|
||||||
|
prepare stmt1 from @s;
|
||||||
|
execute stmt1 using @v;
|
||||||
|
deallocate prepare stmt1;
|
||||||
|
end|
|
||||||
|
set global init_connect="call p1('t1', 11)";
|
||||||
|
select * from t1;
|
||||||
|
x
|
||||||
|
3
|
||||||
|
5
|
||||||
|
7
|
||||||
|
11
|
||||||
|
drop procedure p1;
|
||||||
|
create function f1() returns int
|
||||||
|
begin
|
||||||
|
declare n int;
|
||||||
|
select count(*) into n from t1;
|
||||||
|
return n;
|
||||||
|
end|
|
||||||
|
set global init_connect="set @x = f1()";
|
||||||
|
select @x;
|
||||||
|
@x
|
||||||
|
4
|
||||||
|
set global init_connect="create view v1 as select f1()";
|
||||||
|
select * from v1;
|
||||||
|
f1()
|
||||||
|
4
|
||||||
|
set global init_connect="drop view v1";
|
||||||
|
select * from v1;
|
||||||
|
ERROR 42S02: Table 'test.v1' doesn't exist
|
||||||
|
drop function f1;
|
||||||
|
create trigger trg1
|
||||||
|
after insert on t2
|
||||||
|
for each row
|
||||||
|
insert into t1 values (new.y);
|
||||||
|
set global init_connect="insert into t2 values (13), (17), (19)";
|
||||||
|
select * from t1;
|
||||||
|
x
|
||||||
|
3
|
||||||
|
5
|
||||||
|
7
|
||||||
|
11
|
||||||
|
13
|
||||||
|
17
|
||||||
|
19
|
||||||
|
drop trigger trg1;
|
||||||
|
set global init_connect=default;
|
||||||
|
revoke all privileges, grant option from mysqltest1@localhost;
|
||||||
|
drop user mysqltest1@localhost;
|
||||||
|
drop table t1, t2;
|
||||||
|
@ -1 +1,16 @@
|
|||||||
ok
|
ok
|
||||||
|
end of 4.1 tests
|
||||||
|
select * from t1;
|
||||||
|
x
|
||||||
|
3
|
||||||
|
5
|
||||||
|
7
|
||||||
|
11
|
||||||
|
13
|
||||||
|
select * from t2;
|
||||||
|
y
|
||||||
|
30
|
||||||
|
3
|
||||||
|
11
|
||||||
|
13
|
||||||
|
drop table t1, t2;
|
||||||
|
@ -1 +1,29 @@
|
|||||||
select * from mysql.user as t1, mysql.user as t2, mysql.user as t3;
|
select * from mysql.user as t1, mysql.user as t2, mysql.user as t3;
|
||||||
|
use test;
|
||||||
|
|
||||||
|
drop table if exists t1;
|
||||||
|
create table t1 (x int);
|
||||||
|
drop table if exists t2;
|
||||||
|
create table t2 (y int);
|
||||||
|
|
||||||
|
drop procedure if exists p1;
|
||||||
|
create definer=root@localhost procedure p1() select * from t1;
|
||||||
|
call p1();
|
||||||
|
drop procedure p1;
|
||||||
|
|
||||||
|
create definer=root@localhost procedure p1() insert into t1 values (3),(5),(7);
|
||||||
|
call p1();
|
||||||
|
|
||||||
|
drop function if exists f1;
|
||||||
|
create definer=root@localhost function f1() returns int return (select count(*) from t1);
|
||||||
|
insert into t2 set y = f1()*10;
|
||||||
|
|
||||||
|
drop view if exists v1;
|
||||||
|
create definer=root@localhost view v1 as select f1();
|
||||||
|
insert into t2 (y) select * from v1;
|
||||||
|
|
||||||
|
create trigger trg1 after insert on t2 for each row insert into t1 values (new.y);
|
||||||
|
insert into t2 values (11), (13);
|
||||||
|
drop procedure p1;
|
||||||
|
drop function f1;
|
||||||
|
drop view v1;
|
||||||
|
@ -35,4 +35,205 @@ select @a;
|
|||||||
connection con0;
|
connection con0;
|
||||||
drop table t1;
|
drop table t1;
|
||||||
|
|
||||||
# End of 4.1 tests
|
disconnect con1;
|
||||||
|
disconnect con2;
|
||||||
|
disconnect con3;
|
||||||
|
disconnect con4;
|
||||||
|
disconnect con5;
|
||||||
|
|
||||||
|
--echo End of 4.1 tests
|
||||||
|
#
|
||||||
|
# Test 5.* features
|
||||||
|
#
|
||||||
|
|
||||||
|
create table t1 (x int);
|
||||||
|
insert into t1 values (3), (5), (7);
|
||||||
|
create table t2 (y int);
|
||||||
|
|
||||||
|
create user mysqltest1@localhost;
|
||||||
|
grant all privileges on test.* to mysqltest1@localhost;
|
||||||
|
#
|
||||||
|
# Create a simple procedure
|
||||||
|
#
|
||||||
|
set global init_connect="create procedure p1() select * from t1";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
call p1();
|
||||||
|
drop procedure p1;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Create a multi-result set procedure
|
||||||
|
#
|
||||||
|
set global init_connect="create procedure p1(x int)\
|
||||||
|
begin\
|
||||||
|
select count(*) from t1;\
|
||||||
|
select * from t1;\
|
||||||
|
set @x = x;
|
||||||
|
end";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
call p1(42);
|
||||||
|
select @x;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Just call it - this will not generate any output
|
||||||
|
#
|
||||||
|
set global init_connect="call p1(4711)";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select @x;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Drop the procedure
|
||||||
|
#
|
||||||
|
set global init_connect="drop procedure if exists p1";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
--error ER_SP_DOES_NOT_EXIST
|
||||||
|
call p1();
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Execution of a more complex procedure
|
||||||
|
#
|
||||||
|
delimiter |;
|
||||||
|
create procedure p1(out sum int)
|
||||||
|
begin
|
||||||
|
declare n int default 0;
|
||||||
|
declare c cursor for select * from t1;
|
||||||
|
declare exit handler for not found
|
||||||
|
begin
|
||||||
|
close c;
|
||||||
|
set sum = n;
|
||||||
|
end;
|
||||||
|
|
||||||
|
open c;
|
||||||
|
loop
|
||||||
|
begin
|
||||||
|
declare x int;
|
||||||
|
|
||||||
|
fetch c into x;
|
||||||
|
if x > 3 then
|
||||||
|
set n = n + x;
|
||||||
|
end if;
|
||||||
|
end;
|
||||||
|
end loop;
|
||||||
|
end|
|
||||||
|
delimiter ;|
|
||||||
|
# Call the procedure with a cursor
|
||||||
|
set global init_connect="call p1(@sum)";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select @sum;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
drop procedure p1;
|
||||||
|
#
|
||||||
|
# Test Dynamic SQL
|
||||||
|
#
|
||||||
|
delimiter |;
|
||||||
|
create procedure p1(tbl char(10), v int)
|
||||||
|
begin
|
||||||
|
set @s = concat('insert into ', tbl, ' values (?)');
|
||||||
|
set @v = v;
|
||||||
|
prepare stmt1 from @s;
|
||||||
|
execute stmt1 using @v;
|
||||||
|
deallocate prepare stmt1;
|
||||||
|
end|
|
||||||
|
delimiter ;|
|
||||||
|
# Call the procedure with prepared statements
|
||||||
|
set global init_connect="call p1('t1', 11)";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select * from t1;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
drop procedure p1;
|
||||||
|
#
|
||||||
|
# Stored functions
|
||||||
|
#
|
||||||
|
delimiter |;
|
||||||
|
create function f1() returns int
|
||||||
|
begin
|
||||||
|
declare n int;
|
||||||
|
|
||||||
|
select count(*) into n from t1;
|
||||||
|
return n;
|
||||||
|
end|
|
||||||
|
delimiter ;|
|
||||||
|
# Invoke a function
|
||||||
|
set global init_connect="set @x = f1()";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select @x;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Create a view
|
||||||
|
#
|
||||||
|
set global init_connect="create view v1 as select f1()";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select * from v1;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
#
|
||||||
|
# Drop the view
|
||||||
|
#
|
||||||
|
set global init_connect="drop view v1";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
--error ER_NO_SUCH_TABLE
|
||||||
|
select * from v1;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
drop function f1;
|
||||||
|
|
||||||
|
# We can't test "create trigger", since this requires super privileges
|
||||||
|
# in 5.0, but with super privileges, init_connect is not executed.
|
||||||
|
# (However, this can be tested in 5.1)
|
||||||
|
#
|
||||||
|
#set global init_connect="create trigger trg1\
|
||||||
|
# after insert on t2\
|
||||||
|
# for each row\
|
||||||
|
# insert into t1 values (new.y)";
|
||||||
|
#connect (con1,localhost,mysqltest1,,);
|
||||||
|
#connection con1;
|
||||||
|
#insert into t2 values (2), (4);
|
||||||
|
#select * from t1;
|
||||||
|
#
|
||||||
|
#connection con0;
|
||||||
|
#disconnect con1;
|
||||||
|
|
||||||
|
create trigger trg1
|
||||||
|
after insert on t2
|
||||||
|
for each row
|
||||||
|
insert into t1 values (new.y);
|
||||||
|
|
||||||
|
# Invoke trigger
|
||||||
|
set global init_connect="insert into t2 values (13), (17), (19)";
|
||||||
|
connect (con1,localhost,mysqltest1,,);
|
||||||
|
connection con1;
|
||||||
|
select * from t1;
|
||||||
|
|
||||||
|
connection con0;
|
||||||
|
disconnect con1;
|
||||||
|
|
||||||
|
drop trigger trg1;
|
||||||
|
set global init_connect=default;
|
||||||
|
|
||||||
|
revoke all privileges, grant option from mysqltest1@localhost;
|
||||||
|
drop user mysqltest1@localhost;
|
||||||
|
drop table t1, t2;
|
||||||
|
@ -6,5 +6,15 @@
|
|||||||
# mysql-test/t/init_file-master.opt for the actual test
|
# mysql-test/t/init_file-master.opt for the actual test
|
||||||
#
|
#
|
||||||
|
|
||||||
# End of 4.1 tests
|
--echo ok
|
||||||
echo ok;
|
--echo end of 4.1 tests
|
||||||
|
#
|
||||||
|
# Chec 5.x features
|
||||||
|
#
|
||||||
|
# Expected:
|
||||||
|
# 3, 5, 7, 11, 13
|
||||||
|
select * from t1;
|
||||||
|
# Expected:
|
||||||
|
# 30, 3, 11, 13
|
||||||
|
select * from t2;
|
||||||
|
drop table t1, t2;
|
||||||
|
@ -1946,6 +1946,7 @@ void Security_context::init()
|
|||||||
{
|
{
|
||||||
host= user= priv_user= ip= 0;
|
host= user= priv_user= ip= 0;
|
||||||
host_or_ip= "connecting host";
|
host_or_ip= "connecting host";
|
||||||
|
priv_host[0]= '\0';
|
||||||
#ifndef NO_EMBEDDED_ACCESS_CHECKS
|
#ifndef NO_EMBEDDED_ACCESS_CHECKS
|
||||||
db_access= NO_ACCESS;
|
db_access= NO_ACCESS;
|
||||||
#endif
|
#endif
|
||||||
|
@ -1250,6 +1250,12 @@ pthread_handler_t handle_bootstrap(void *arg)
|
|||||||
thd->version=refresh_version;
|
thd->version=refresh_version;
|
||||||
thd->security_ctx->priv_user=
|
thd->security_ctx->priv_user=
|
||||||
thd->security_ctx->user= (char*) my_strdup("boot", MYF(MY_WME));
|
thd->security_ctx->user= (char*) my_strdup("boot", MYF(MY_WME));
|
||||||
|
/*
|
||||||
|
Make the "client" handle multiple results. This is necessary
|
||||||
|
to enable stored procedures with SELECTs and Dynamic SQL
|
||||||
|
in init-file.
|
||||||
|
*/
|
||||||
|
thd->client_capabilities|= CLIENT_MULTI_RESULTS;
|
||||||
|
|
||||||
buff= (char*) thd->net.buff;
|
buff= (char*) thd->net.buff;
|
||||||
thd->init_for_queries();
|
thd->init_for_queries();
|
||||||
|
Loading…
x
Reference in New Issue
Block a user