mirror of
https://github.com/MariaDB/server.git
synced 2025-08-26 20:31:37 +02:00

Lots of different cases, SELECT, SELECT DEFAULT(), UPDATE t SET x=DEFAULT, prepares statements, opening of a table for the I_S, prelocking (so TL_WRITE), insert with subquery (so SQLCOM_SELECT), etc. Don't check NEXTVAL privileges in fix_fields() anymore, it cannot possibly handle all the cases correctly. Make a special method Item_func_nextval::check_access() for that and invoke it from * fix_fields on explicit SELECT NEXTVAL() (but not if NEXTVAL() is used in a DEFAULT clause) * when DEFAULT bareword in used in, say, UPDATE t SET x=DEFAULT (but not if DEFAULT() itself is used in a DEFAULT clause) * in CREATE TABLE * in ALTER TABLE ALGORITHM=INPLACE (that doesn't go CREATE TABLE path) * on INSERT helpers * Virtual_column_info::check_access() to walk the item tree and invoke Item::check_access() * TABLE::check_sequence_privileges() to iterate default expressions and invoke Virtual_column_info::check_access() also, single-table UPDATE in prepared statements now associates value items with fields just as multi-update already did, fixes the case of PREPARE s "UPDATE t SET x=?"; EXECUTE s USING DEFAULT.
225 lines
5.9 KiB
Text
225 lines
5.9 KiB
Text
#
|
|
# Test some grants with sequences
|
|
# Note that replication.test also does some grant testing
|
|
#
|
|
|
|
# Grant tests not performed with embedded server
|
|
-- source include/not_embedded.inc
|
|
|
|
|
|
SET @@SQL_MODE = REPLACE(@@SQL_MODE, 'NO_AUTO_CREATE_USER', '');
|
|
create database mysqltest_1;
|
|
use mysqltest_1;
|
|
grant all on mysqltest_1.* to 'normal'@'%';
|
|
grant select on mysqltest_1.* to 'read_only'@'%';
|
|
grant select,insert on mysqltest_1.* to 'read_write'@'%';
|
|
grant select,insert,alter on mysqltest_1.* to 'alter'@'%';
|
|
grant alter on mysqltest_1.* to only_alter@'%';
|
|
|
|
connect(normal,localhost,normal,,mysqltest_1);
|
|
connect(read_only,localhost,read_only,,mysqltest_1);
|
|
connect(read_write,localhost,read_write,,mysqltest_1);
|
|
connect(alter,localhost,alter,,mysqltest_1);
|
|
connect(only_alter, localhost, only_alter,,mysqltest_1);
|
|
|
|
--disable_ps2_protocol
|
|
connection normal;
|
|
create sequence s1;
|
|
select next value for s1;
|
|
alter sequence s1 restart= 11;
|
|
select * from s1;
|
|
|
|
connection read_only;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
select next value for s1;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
alter sequence s1 restart= 11;
|
|
select * from s1;
|
|
|
|
connection read_write;
|
|
select next value for s1;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
alter sequence s1 restart= 11;
|
|
select * from s1;
|
|
|
|
connection alter;
|
|
select next value for s1;
|
|
alter sequence s1 restart= 11;
|
|
select * from s1;
|
|
|
|
connection only_alter;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
select next value for s1;
|
|
alter sequence s1 restart= 11;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
select * from s1;
|
|
--enable_ps2_protocol
|
|
|
|
#
|
|
# Cleanup
|
|
#
|
|
|
|
connection default;
|
|
drop user 'normal'@'%';
|
|
drop user 'read_only'@'%';
|
|
drop user 'read_write'@'%';
|
|
drop user 'alter'@'%';
|
|
drop user 'only_alter'@'%';
|
|
drop sequence s1;
|
|
|
|
--echo #
|
|
--echo # MDEV-36413 User without any privileges to a sequence can read from
|
|
--echo # it and modify it via column default
|
|
--echo #
|
|
|
|
create sequence s1;
|
|
create sequence s2;
|
|
select * from s2;
|
|
create table t2 (a int not null default(nextval(s1)));
|
|
insert into t2 values();
|
|
|
|
create user u;
|
|
grant create, insert, select, drop on mysqltest_1.t1 to u;
|
|
grant insert, select on mysqltest_1.s1 to u;
|
|
grant select on mysqltest_1.t2 to u;
|
|
|
|
--connect(con1,localhost,u,,mysqltest_1)
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
select nextval(s2);
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
show create sequence s2;
|
|
|
|
create table t1 (a int not null default(nextval(s1)));
|
|
drop table t1;
|
|
create table t1 (a int not null default(nextval(s1))) select a from t2;
|
|
insert into t1 values();
|
|
select * from t1;
|
|
drop table t1;
|
|
create table t1 (a int not null default(nextval(s1))) select a from (select t2.a from t2,t2 as t3 where t2.a=t3.a) as t4;
|
|
drop table t1;
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
create table t1 (a int not null default(nextval(s2)));
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
create table t1 (a int not null default(nextval(s1)),
|
|
b int not null default(nextval(s2)));
|
|
--disconnect con1
|
|
--connection default
|
|
drop user u;
|
|
|
|
# ALTER for table with DEFAULT NEXTVAL(seq) column needs INSERT/SELECT on seq
|
|
# just like CREATE does in the example above
|
|
create user u_alter;
|
|
create table t1 (id int);
|
|
grant alter on t1 to u_alter;
|
|
--connect(con_alter,localhost,u_alter,,mysqltest_1)
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
alter table t1 modify id int default nextval(s1);
|
|
--connection default
|
|
grant insert, select on s1 to u_alter;
|
|
--connection con_alter
|
|
alter table t1 modify id int default nextval(s1);
|
|
--disconnect con_alter
|
|
--connection default
|
|
drop user u_alter;
|
|
drop database mysqltest_1;
|
|
|
|
--echo #
|
|
--echo # MDEV-36870 Spurious unrelated permission error when selecting from table with default that uses nextval(sequence)
|
|
--echo #
|
|
|
|
# various tests for permission checking on sequences
|
|
create database db1;
|
|
use db1;
|
|
create sequence s1 cache 0;
|
|
create table t1 (id int unsigned default (10+nextval(s1)));
|
|
insert t1 values ();
|
|
|
|
create table t2 (id int unsigned default nextval(s1), b int default(default(id)));
|
|
insert t2 values ();
|
|
|
|
# INSERT affects prelocking, but is never actually executed
|
|
delimiter |;
|
|
create function f1(x int) returns int sql security invoker
|
|
begin
|
|
select id+x into x from t1;
|
|
return x;
|
|
insert t1 values ();
|
|
end|
|
|
delimiter ;|
|
|
|
|
create user u1@localhost;
|
|
grant select on db1.* to u1@localhost;
|
|
grant execute on db1.* to u1@localhost;
|
|
|
|
use test;
|
|
create table t3 (id int unsigned default (20+nextval(db1.s1)), b int);
|
|
insert t3 values ();
|
|
|
|
create sequence s2 cache 0;
|
|
create table t4 (id int unsigned default (10+nextval(s2)), b int);
|
|
insert t4 values ();
|
|
|
|
connect u1,localhost,u1,,db1;
|
|
|
|
# table already in the cache. must be re-fixed
|
|
# SELECT * - no error
|
|
select * from t1;
|
|
|
|
# not in cache
|
|
connection default;
|
|
flush tables;
|
|
connection u1;
|
|
# SELECT * - no error
|
|
select * from t1;
|
|
|
|
# SELECT DEFAULT() - error
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
select default(id) from t1;
|
|
|
|
# default(default(nextval))
|
|
select * from t2;
|
|
|
|
# SELECT but table has TL_WRITE because of prelocking
|
|
select f1(100);
|
|
|
|
# opening the table for I_S
|
|
select column_name, data_type, column_default from information_schema.columns where table_schema='db1' and table_name='t1';
|
|
|
|
use test;
|
|
# insert
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
insert t3 values ();
|
|
insert t4 values ();
|
|
#insert select
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
insert t3 (b) select 5;
|
|
insert t4 (b) select 5;
|
|
#update
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
update t3 set id=default;
|
|
update t4 set id=default;
|
|
|
|
# PS UPDATE with ? = DEFAULT
|
|
prepare stmt from "update t3 set id=?";
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
execute stmt using default;
|
|
prepare stmt from "update t4 set id=?";
|
|
execute stmt using default;
|
|
deallocate prepare stmt;
|
|
|
|
# SELECT * in a subquery, like INSERT t3 VALUES ((SELECT * FROM t1));
|
|
# with sequences both on t3 and t1
|
|
insert t4 (b) values ((select * from db1.t1));
|
|
--error ER_TABLEACCESS_DENIED_ERROR
|
|
insert t4 (b) values ((select default(id) from db1.t1));
|
|
|
|
connection default;
|
|
disconnect u1;
|
|
--disable_ps2_protocol
|
|
select nextval(db1.s1) as 'must be 5';
|
|
--enable_ps2_protocol
|
|
drop user u1@localhost;
|
|
drop database db1;
|
|
drop table t3, t4, s2;
|
|
|
|
--echo # End of 10.6 tests
|