mirror of
https://github.com/MariaDB/server.git
synced 2025-01-17 20:42:30 +01:00
a809813b0d
In case of database level grant the database name may be a pattern, in case of table|column level grant the database name can not be a pattern. We use 'dont_check_global_grants' as a flag to determine if it's database level grant command (see SQLCOM_GRANT case, mysql_execute_command() function) and set db_is_pattern according to 'dont_check_global_grants' value.
589 lines
19 KiB
Text
589 lines
19 KiB
Text
# Grant tests not performed with embedded server
|
|
-- source include/not_embedded.inc
|
|
|
|
SET NAMES binary;
|
|
|
|
#
|
|
# GRANT tests that require several connections
|
|
# (usually it's GRANT, reconnect as another user, try something)
|
|
#
|
|
|
|
|
|
# prepare playground before tests
|
|
--disable_warnings
|
|
drop database if exists mysqltest;
|
|
drop database if exists mysqltest_1;
|
|
--enable_warnings
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
delete from mysql.tables_priv where user like 'mysqltest\_%';
|
|
delete from mysql.columns_priv where user like 'mysqltest\_%';
|
|
flush privileges;
|
|
|
|
|
|
grant all privileges on `my\_1`.* to mysqltest_1@localhost with grant option;
|
|
grant create user on *.* to mysqltest_1@localhost;
|
|
create user mysqltest_2@localhost;
|
|
connect (user_a,localhost,mysqltest_1,,);
|
|
connection user_a;
|
|
grant select on `my\_1`.* to mysqltest_2@localhost;
|
|
--error 1132
|
|
grant select on `my\_1`.* to mysqltest_2@localhost identified by 'pass';
|
|
disconnect user_a;
|
|
connection default;
|
|
grant update on mysql.* to mysqltest_1@localhost;
|
|
connect (user_b,localhost,mysqltest_1,,);
|
|
connection user_b;
|
|
grant select on `my\_1`.* to mysqltest_2@localhost identified by 'pass';
|
|
grant select on `my\_1`.* to mysqltest_3@localhost;
|
|
disconnect user_b;
|
|
connection default;
|
|
grant insert on mysql.* to mysqltest_1@localhost;
|
|
connect (user_c,localhost,mysqltest_1,,);
|
|
connection user_c;
|
|
grant select on `my\_1`.* to mysqltest_3@localhost;
|
|
grant select on `my\_1`.* to mysqltest_4@localhost identified by 'pass';
|
|
disconnect user_c;
|
|
connection default;
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
delete from mysql.tables_priv where user like 'mysqltest\_%';
|
|
delete from mysql.columns_priv where user like 'mysqltest\_%';
|
|
flush privileges;
|
|
|
|
#
|
|
# wild_compare fun
|
|
#
|
|
|
|
grant all privileges on `my\_%`.* to mysqltest_1@localhost with grant option;
|
|
grant create user on *.* to mysqltest_1@localhost;
|
|
connect (user1,localhost,mysqltest_1,,);
|
|
connection user1;
|
|
select current_user();
|
|
grant all privileges on `my\_1`.* to mysqltest_2@localhost with grant option;
|
|
--error 1044
|
|
grant all privileges on `my_%`.* to mysqltest_3@localhost with grant option;
|
|
|
|
#
|
|
# NO_AUTO_CREATE_USER mode
|
|
#
|
|
set @@sql_mode='NO_AUTO_CREATE_USER';
|
|
select @@sql_mode;
|
|
#
|
|
# GRANT without IDENTIFIED BY does not create new users
|
|
#
|
|
--error 1133
|
|
grant select on `my\_1`.* to mysqltest_4@localhost with grant option;
|
|
grant select on `my\_1`.* to mysqltest_4@localhost identified by 'mypass'
|
|
with grant option;
|
|
disconnect user1;
|
|
connection default;
|
|
show grants for mysqltest_1@localhost;
|
|
show grants for mysqltest_2@localhost;
|
|
--error 1141
|
|
show grants for mysqltest_3@localhost;
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
flush privileges;
|
|
|
|
#
|
|
# wild_compare part two - acl_cache
|
|
#
|
|
create database mysqltest_1;
|
|
grant all privileges on `mysqltest\_1`.* to mysqltest_1@localhost with grant option;
|
|
connect (user2,localhost,mysqltest_1,,);
|
|
connection user2;
|
|
select current_user();
|
|
show databases;
|
|
--error 1044
|
|
grant all privileges on `mysqltest_1`.* to mysqltest_1@localhost with grant option;
|
|
disconnect user2;
|
|
connection default;
|
|
show grants for mysqltest_1@localhost;
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
drop database mysqltest_1;
|
|
flush privileges;
|
|
|
|
#
|
|
# Bug #6173: One can circumvent missing UPDATE privilege if he has SELECT
|
|
# and INSERT privilege for table with primary key
|
|
#
|
|
create database mysqltest;
|
|
grant INSERT, SELECT on mysqltest.* to mysqltest_1@localhost;
|
|
flush privileges;
|
|
use mysqltest;
|
|
create table t1 (id int primary key, data varchar(255));
|
|
|
|
connect (mrbad, localhost, mysqltest_1,,mysqltest);
|
|
connection mrbad;
|
|
show grants for current_user();
|
|
insert into t1 values (1, 'I can''t change it!');
|
|
--error 1142
|
|
update t1 set data='I can change it!' where id = 1;
|
|
# This should not be allowed since it too require UPDATE privilege.
|
|
--error 1142
|
|
insert into t1 values (1, 'XXX') on duplicate key update data= 'I can change it!';
|
|
select * from t1;
|
|
disconnect mrbad;
|
|
|
|
connection default;
|
|
drop table t1;
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
flush privileges;
|
|
#
|
|
#
|
|
create table t1 (a int, b int);
|
|
grant select (a) on t1 to mysqltest_1@localhost with grant option;
|
|
connect (mrugly, localhost, mysqltest_1,,mysqltest);
|
|
connection mrugly;
|
|
--error 1143
|
|
grant select (a,b) on t1 to mysqltest_2@localhost;
|
|
--error 1142
|
|
grant select on t1 to mysqltest_3@localhost;
|
|
disconnect mrugly;
|
|
|
|
connection default;
|
|
drop table t1;
|
|
delete from mysql.user where user like 'mysqltest\_%';
|
|
delete from mysql.db where user like 'mysqltest\_%';
|
|
delete from mysql.tables_priv where user like 'mysqltest\_%';
|
|
delete from mysql.columns_priv where user like 'mysqltest\_%';
|
|
flush privileges;
|
|
|
|
drop database mysqltest;
|
|
use test;
|
|
|
|
|
|
#
|
|
# Bug #15775: "drop user" command does not refresh acl_check_hosts
|
|
#
|
|
|
|
# Create some test users
|
|
create user mysqltest_1@host1;
|
|
create user mysqltest_2@host2;
|
|
create user mysqltest_3@host3;
|
|
create user mysqltest_4@host4;
|
|
create user mysqltest_5@host5;
|
|
create user mysqltest_6@host6;
|
|
create user mysqltest_7@host7;
|
|
flush privileges;
|
|
|
|
# Drop one user
|
|
drop user mysqltest_3@host3;
|
|
|
|
# This connect failed before fix since the acl_check_hosts list was corrupted by the "drop user"
|
|
connect (con8,127.0.0.1,root,,test,$MASTER_MYPORT,);
|
|
disconnect con8;
|
|
connection default;
|
|
|
|
# Clean up - Drop all of the remaining users at once
|
|
drop user mysqltest_1@host1, mysqltest_2@host2, mysqltest_4@host4,
|
|
mysqltest_5@host5, mysqltest_6@host6, mysqltest_7@host7;
|
|
|
|
# Check that it's still possible to connect
|
|
connect (con9,127.0.0.1,root,,test,$MASTER_MYPORT,);
|
|
disconnect con9;
|
|
connection default;
|
|
|
|
#
|
|
# Bug# 16180 - Setting SQL_LOG_OFF without SUPER privilege is silently ignored
|
|
#
|
|
create database mysqltest_1;
|
|
grant select, insert, update on `mysqltest\_1`.* to mysqltest_1@localhost;
|
|
connect (con10,localhost,mysqltest_1,,);
|
|
connection con10;
|
|
--error 1227
|
|
set sql_log_off = 1;
|
|
--error 1227
|
|
set sql_log_bin = 0;
|
|
disconnect con10;
|
|
connection default;
|
|
delete from mysql.user where user like 'mysqltest\_1';
|
|
delete from mysql.db where user like 'mysqltest\_1';
|
|
drop database mysqltest_1;
|
|
flush privileges;
|
|
|
|
# End of 4.1 tests
|
|
# Create and drop user
|
|
#
|
|
set sql_mode='maxdb';
|
|
--disable_warnings
|
|
drop table if exists t1, t2;
|
|
--enable_warnings
|
|
create table t1(c1 int);
|
|
create table t2(c1 int, c2 int);
|
|
#
|
|
# Three forms of CREATE USER
|
|
create user 'mysqltest_1';
|
|
--error 1396
|
|
create user 'mysqltest_1';
|
|
create user 'mysqltest_2' identified by 'Mysqltest-2';
|
|
create user 'mysqltest_3' identified by password 'fffffffffffffffffffffffffffffffffffffffff';
|
|
grant select on *.* to 'mysqltest_2';
|
|
grant insert on test.* to 'mysqltest_2';
|
|
grant update on test.t1 to 'mysqltest_2';
|
|
grant update (c2) on test.t2 to 'mysqltest_2';
|
|
select host,user,password from mysql.user where user like 'mysqltest_%' order by host,user,password;
|
|
select host,db,user from mysql.db where user like 'mysqltest_%' order by host,db,user;
|
|
select host,db,user,table_name from mysql.tables_priv where user like 'mysqltest_%' order by host,db,user,table_name;
|
|
select host,db,user,table_name,column_name from mysql.columns_priv where user like 'mysqltest_%' order by host,db,user,table_name,column_name;
|
|
show grants for 'mysqltest_1';
|
|
show grants for 'mysqltest_2';
|
|
#
|
|
# Drop
|
|
drop user 'mysqltest_1';
|
|
select host,user,password from mysql.user where user like 'mysqltest_%' order by host,user,password;
|
|
select host,db,user from mysql.db where user like 'mysqltest_%' order by host,db,user;
|
|
select host,db,user,table_name from mysql.tables_priv where user like 'mysqltest_%' order by host,db,user,table_name;
|
|
select host,db,user,table_name,column_name from mysql.columns_priv where user like 'mysqltest_%' order by host,db,user,table_name,column_name;
|
|
--error 1141
|
|
show grants for 'mysqltest_1';
|
|
#
|
|
# Rename
|
|
rename user 'mysqltest_2' to 'mysqltest_1';
|
|
select host,user,password from mysql.user where user like 'mysqltest_%' order by host,user,password;
|
|
select host,db,user from mysql.db where user like 'mysqltest_%' order by host,db,user;
|
|
select host,db,user,table_name from mysql.tables_priv where user like 'mysqltest_%' order by host,db,user,table_name;
|
|
select host,db,user,table_name,column_name from mysql.columns_priv where user like 'mysqltest_%' order by host,db,user,table_name,column_name;
|
|
show grants for 'mysqltest_1';
|
|
drop user 'mysqltest_1', 'mysqltest_3';
|
|
--error 1396
|
|
drop user 'mysqltest_1';
|
|
#
|
|
# Cleanup
|
|
drop table t1, t2;
|
|
#
|
|
# Add a stray record
|
|
insert into mysql.db set user='mysqltest_1', db='%', host='%';
|
|
flush privileges;
|
|
--error 1141
|
|
show grants for 'mysqltest_1';
|
|
--error 1269
|
|
revoke all privileges, grant option from 'mysqltest_1';
|
|
drop user 'mysqltest_1';
|
|
select host,db,user from mysql.db where user = 'mysqltest_1' order by host,db,user;
|
|
#
|
|
# Add a stray record
|
|
insert into mysql.tables_priv set host='%', db='test', user='mysqltest_1', table_name='t1';
|
|
flush privileges;
|
|
--error 1141
|
|
show grants for 'mysqltest_1';
|
|
drop user 'mysqltest_1';
|
|
select host,db,user,table_name from mysql.tables_priv where user = 'mysqltest_1' order by host,db,user,table_name;
|
|
#
|
|
# Add a stray record
|
|
insert into mysql.columns_priv set host='%', db='test', user='mysqltest_1', table_name='t1', column_name='c1';
|
|
flush privileges;
|
|
--error 1141
|
|
show grants for 'mysqltest_1';
|
|
drop user 'mysqltest_1';
|
|
select host,db,user,table_name,column_name from mysql.columns_priv where user = 'mysqltest_1' order by host,db,user,table_name,column_name;
|
|
#
|
|
# Handle multi user lists
|
|
create user 'mysqltest_1', 'mysqltest_2', 'mysqltest_3';
|
|
drop user 'mysqltest_1', 'mysqltest_2', 'mysqltest_3';
|
|
create user 'mysqltest_1', 'mysqltest_2' identified by 'Mysqltest-2', 'mysqltest_3' identified by password 'fffffffffffffffffffffffffffffffffffffffff';
|
|
rename user 'mysqltest_1' to 'mysqltest_1a', 'mysqltest_2' TO 'mysqltest_2a', 'mysqltest_3' TO 'mysqltest_3a';
|
|
--error 1396
|
|
drop user 'mysqltest_1', 'mysqltest_2', 'mysqltest_3';
|
|
drop user 'mysqltest_1a', 'mysqltest_2a', 'mysqltest_3a';
|
|
#
|
|
# Let one of multiple users fail
|
|
create user 'mysqltest_1', 'mysqltest_2', 'mysqltest_3';
|
|
--error 1396
|
|
create user 'mysqltest_1a', 'mysqltest_2', 'mysqltest_3a';
|
|
--error 1396
|
|
rename user 'mysqltest_1a' to 'mysqltest_1b', 'mysqltest_2a' TO 'mysqltest_2b', 'mysqltest_3a' TO 'mysqltest_3b';
|
|
drop user 'mysqltest_1', 'mysqltest_2', 'mysqltest_3';
|
|
--error 1396
|
|
drop user 'mysqltest_1b', 'mysqltest_2b', 'mysqltest_3b';
|
|
#
|
|
# Obsolete syntax has been dropped
|
|
create user 'mysqltest_2' identified by 'Mysqltest-2';
|
|
--error 1064
|
|
drop user 'mysqltest_2' identified by 'Mysqltest-2';
|
|
drop user 'mysqltest_2';
|
|
#
|
|
# Strange user names
|
|
create user '%@b'@'b';
|
|
show grants for '%@b'@'b';
|
|
grant select on mysql.* to '%@b'@'b';
|
|
show grants for '%@b'@'b';
|
|
rename user '%@b'@'b' to '%@a'@'a';
|
|
--error 1141
|
|
show grants for '%@b'@'b';
|
|
show grants for '%@a'@'a';
|
|
drop user '%@a'@'a';
|
|
#
|
|
# CREATE USER privilege is enough
|
|
#
|
|
create user mysqltest_2@localhost;
|
|
grant create user on *.* to mysqltest_2@localhost;
|
|
connect (user3,localhost,mysqltest_2,,);
|
|
connection user3;
|
|
--error 1142
|
|
select host,user,password from mysql.user where user like 'mysqltest_%' order by host,user,password;
|
|
create user mysqltest_A@'%';
|
|
rename user mysqltest_A@'%' to mysqltest_B@'%';
|
|
drop user mysqltest_B@'%';
|
|
disconnect user3;
|
|
connection default;
|
|
drop user mysqltest_2@localhost;
|
|
#
|
|
# INSERT/UPDATE/DELETE is ok too
|
|
create user mysqltest_3@localhost;
|
|
grant INSERT,DELETE,UPDATE on mysql.* to mysqltest_3@localhost;
|
|
connect (user4,localhost,mysqltest_3,,);
|
|
connection user4;
|
|
show grants;
|
|
--error 1142
|
|
select host,user,password from mysql.user where user like 'mysqltest_%' order by host,user,password;
|
|
insert into mysql.user set host='%', user='mysqltest_B';
|
|
create user mysqltest_A@'%';
|
|
rename user mysqltest_B@'%' to mysqltest_C@'%';
|
|
drop user mysqltest_C@'%';
|
|
drop user mysqltest_A@'%';
|
|
disconnect user4;
|
|
connection default;
|
|
drop user mysqltest_3@localhost;
|
|
#
|
|
# Bug #3309: Test IP addresses with netmask
|
|
set @@sql_mode='';
|
|
create database mysqltest_1;
|
|
create table mysqltest_1.t1 (i int);
|
|
insert into mysqltest_1.t1 values (1),(2),(3);
|
|
GRANT ALL ON mysqltest_1.t1 TO mysqltest_1@'127.0.0.0/255.0.0.0';
|
|
connect (n1,127.0.0.1,mysqltest_1,,mysqltest_1,$MASTER_MYPORT,$MASTER_MYSOCK);
|
|
connection n1;
|
|
show grants for current_user();
|
|
select * from t1;
|
|
disconnect n1;
|
|
connection default;
|
|
REVOKE ALL ON mysqltest_1.t1 FROM mysqltest_1@'127.0.0.0/255.0.0.0';
|
|
delete from mysql.user where user like 'mysqltest\_1';
|
|
flush privileges;
|
|
drop table mysqltest_1.t1;
|
|
|
|
#
|
|
# Bug #12302: 'SET PASSWORD = ...' didn't work if connecting hostname !=
|
|
# hostname the current user is authenticated as. Note that a test for this
|
|
# was also added to the test above.
|
|
#
|
|
grant all on mysqltest_1.* to mysqltest_1@'127.0.0.1';
|
|
connect (b12302,127.0.0.1,mysqltest_1,,mysqltest_1,$MASTER_MYPORT,);
|
|
connection b12302;
|
|
select current_user();
|
|
set password = password('changed');
|
|
disconnect b12302;
|
|
connection default;
|
|
select host, length(password) from mysql.user where user like 'mysqltest\_1';
|
|
revoke all on mysqltest_1.* from mysqltest_1@'127.0.0.1';
|
|
delete from mysql.user where user like 'mysqltest\_1';
|
|
flush privileges;
|
|
grant all on mysqltest_1.* to mysqltest_1@'127.0.0.0/255.0.0.0';
|
|
connect (b12302_2,127.0.0.1,mysqltest_1,,mysqltest_1,$MASTER_MYPORT,);
|
|
connection b12302_2;
|
|
select current_user();
|
|
set password = password('changed');
|
|
disconnect b12302_2;
|
|
connection default;
|
|
select host, length(password) from mysql.user where user like 'mysqltest\_1';
|
|
revoke all on mysqltest_1.* from mysqltest_1@'127.0.0.0/255.0.0.0';
|
|
delete from mysql.user where user like 'mysqltest\_1';
|
|
flush privileges;
|
|
drop database mysqltest_1;
|
|
|
|
--source include/add_anonymous_users.inc
|
|
|
|
# But anonymous users can't change their password
|
|
connect (n5,localhost,test,,test,$MASTER_MYPORT,$MASTER_MYSOCK);
|
|
connection n5;
|
|
--error 1044
|
|
set password = password("changed");
|
|
disconnect n5;
|
|
connection default;
|
|
|
|
--source include/delete_anonymous_users.inc
|
|
|
|
|
|
# Bug #12423 "Deadlock when doing FLUSH PRIVILEGES and GRANT in
|
|
# multi-threaded environment". We should be able to execute FLUSH
|
|
# PRIVILEGES and SET PASSWORD simultaneously with other account
|
|
# management commands (such as GRANT and REVOKE) without causing
|
|
# deadlocks. To achieve this we should ensure that all account
|
|
# management commands take table and internal locks in the same order.
|
|
connect (con2root,localhost,root,,);
|
|
connect (con3root,localhost,root,,);
|
|
# Check that we can execute FLUSH PRIVILEGES and GRANT simultaneously
|
|
# This will check that locks are taken in proper order during both
|
|
# user/db-level and table/column-level privileges reloading.
|
|
connection default;
|
|
lock table mysql.user write;
|
|
connection con2root;
|
|
send flush privileges;
|
|
connection con3root;
|
|
send grant all on *.* to 'mysqltest_1'@'localhost';
|
|
connection default;
|
|
unlock tables;
|
|
connection con2root;
|
|
reap;
|
|
connection con3root;
|
|
reap;
|
|
# Check for simultaneous SET PASSWORD and REVOKE.
|
|
connection default;
|
|
lock table mysql.user write;
|
|
connection con2root;
|
|
send set password for 'mysqltest_1'@'localhost' = password('');
|
|
connection con3root;
|
|
send revoke all on *.* from 'mysqltest_1'@'localhost';
|
|
connection default;
|
|
unlock tables;
|
|
connection con2root;
|
|
reap;
|
|
connection con3root;
|
|
reap;
|
|
connection default;
|
|
# Clean-up
|
|
drop user 'mysqltest_1'@'localhost';
|
|
disconnect con2root;
|
|
disconnect con3root;
|
|
|
|
# End of 4.1 tests
|
|
|
|
#
|
|
# Bug#17279 user with no global privs and with create
|
|
# priv in db can create databases
|
|
#
|
|
|
|
create database TESTDB;
|
|
create table t2(a int);
|
|
create temporary table t1 as select * from mysql.user;
|
|
delete from mysql.user where host='localhost';
|
|
INSERT INTO mysql.user VALUES
|
|
('%','mysqltest_1',password('password'),'N','N','N','N','N','N',
|
|
'N','N','N','N','N','N','N','N','N','N','N','N','N','N','N','N','N','N','N','N',
|
|
'','','','',0,0,0,0);
|
|
INSERT INTO mysql.db VALUES
|
|
('%','TESTDB','mysqltest_1','Y','Y','Y','Y','Y','Y','N','Y','Y','Y','Y','N','Y','Y','Y','
|
|
Y','N');
|
|
FLUSH PRIVILEGES;
|
|
|
|
connect (con1,localhost,mysqltest_1,password,TESTDB);
|
|
|
|
# The user mysqltest_1 should only be allowed access to
|
|
# database TESTDB, not TEStdb
|
|
# On system with "lowercase names" we get error "1007: Can't create db..."
|
|
--error 1044, 1007
|
|
create database TEStdb;
|
|
|
|
# Clean-up
|
|
connection default;
|
|
delete from mysql.user;
|
|
delete from mysql.db where host='%' and user='mysqltest_1' and db='TESTDB';
|
|
insert into mysql.user select * from t1;
|
|
drop table t1, t2;
|
|
drop database TESTDB;
|
|
flush privileges;
|
|
|
|
#
|
|
# BUG#13310 incorrect user parsing by SP
|
|
#
|
|
|
|
grant all privileges on test.* to `a@`@localhost;
|
|
grant execute on * to `a@`@localhost;
|
|
connect (bug13310,localhost,'a@',,test);
|
|
connection bug13310;
|
|
create table t2 (s1 int);
|
|
insert into t2 values (1);
|
|
--disable_warnings
|
|
drop function if exists f2;
|
|
--enable_warnings
|
|
delimiter //;
|
|
create function f2 () returns int begin declare v int; select s1 from t2
|
|
into v; return v; end//
|
|
delimiter ;//
|
|
select f2();
|
|
|
|
drop function f2;
|
|
drop table t2;
|
|
disconnect bug13310;
|
|
|
|
connection default;
|
|
REVOKE ALL PRIVILEGES, GRANT OPTION FROM `a@`@localhost;
|
|
drop user `a@`@localhost;
|
|
|
|
|
|
#
|
|
# Bug#25578 "CREATE TABLE LIKE does not require any privileges on source table"
|
|
#
|
|
--disable_warnings
|
|
drop database if exists mysqltest_1;
|
|
drop database if exists mysqltest_2;
|
|
--enable_warnings
|
|
--error 0,ER_CANNOT_USER
|
|
drop user mysqltest_u1@localhost;
|
|
|
|
create database mysqltest_1;
|
|
create database mysqltest_2;
|
|
grant all on mysqltest_1.* to mysqltest_u1@localhost;
|
|
use mysqltest_2;
|
|
create table t1 (i int);
|
|
|
|
# Connect as user with all rights on mysqltest_1 but with no rights on mysqltest_2.
|
|
connect (user1,localhost,mysqltest_u1,,mysqltest_1);
|
|
connection user1;
|
|
# As expected error is emitted
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
show create table mysqltest_2.t1;
|
|
# This should emit error as well
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
create table t1 like mysqltest_2.t1;
|
|
|
|
# Now let us check that SELECT privilege on the source is enough
|
|
connection default;
|
|
grant select on mysqltest_2.t1 to mysqltest_u1@localhost;
|
|
connection user1;
|
|
show create table mysqltest_2.t1;
|
|
create table t1 like mysqltest_2.t1;
|
|
|
|
# Clean-up
|
|
connection default;
|
|
use test;
|
|
drop database mysqltest_1;
|
|
drop database mysqltest_2;
|
|
drop user mysqltest_u1@localhost;
|
|
|
|
#
|
|
# Bug#18660 Can't grant any privileges on single table in database
|
|
# with underscore char
|
|
#
|
|
grant all on `mysqltest\_%`.* to mysqltest_1@localhost with grant option;
|
|
grant usage on *.* to mysqltest_2@localhost;
|
|
connect (con18600_1,localhost,mysqltest_1,,);
|
|
|
|
create database mysqltest_1;
|
|
use mysqltest_1;
|
|
create table t1 (f1 int);
|
|
|
|
grant create on `mysqltest\_1`.* to mysqltest_2@localhost;
|
|
grant select on mysqltest_1.t1 to mysqltest_2@localhost;
|
|
connect (con3,localhost,mysqltest_2,,);
|
|
connection con3;
|
|
--error 1044
|
|
create database mysqltest_3;
|
|
use mysqltest_1;
|
|
create table t2(f1 int);
|
|
select * from t1;
|
|
connection default;
|
|
drop database mysqltest_1;
|
|
|
|
revoke all privileges, grant option from mysqltest_1@localhost;
|
|
revoke all privileges, grant option from mysqltest_2@localhost;
|
|
drop user mysqltest_1@localhost;
|
|
drop user mysqltest_2@localhost;
|
|
|
|
|
|
--echo End of 5.0 tests
|
|
|