场景:将用户A的视图查询权限赋予用户B报错,提示ORA-01720: grant option does not exist for ‘xx.xx’
问题:
1.查询视图,是否必须要有视图基表的查询权限?
2.将视图的查询权限赋予其他用户,只需要有基表的查询权限吗?
测试步骤:
1.创建三个用户test1,test2,test3,赋予connect,resource,create view权限。
SQL> create user test1 identified by test1; User created. SQL> create user test2 identified by test2; User created. SQL> create user test3 identified by test3; User created. SQL> grant create view to test2; Grant succeeded.
2.在test1用户下创建表t1,将t1的查询权限赋予test2。test2用户创建视图v_t1,将视图v_t1的查询权限赋予test3。
SQL> create table test1.t1 as select * from dba_objects; SQL> conn test1/test1; Connected. SQL> grant select on t1 to test2; Grant succeeded. SQL> conn test2/test2; Connected. SQL> create view v_t1 as select * from test1.t1 where rownum = 1; SQL> grant select on v_t1 to test3; grant select on v_t1 to test3 * ERROR at line 1: ORA-01720: grant option does not exist for 'TEST1.T1' SQL> conn test1/test1; Connected. SQL> grant select on t1 to test2 with grant option; Grant succeeded. SQL> conn test2/test2; Connected. SQL> grant select on v_t1 to test3; Grant succeeded.
3.test3用户查询视图v_t1,然后查询基表t1。
SQL> conn test3/test3 Connected. SQL> select * from test2.v_t1; --结果省略 SQL> select * from test1.t1 where rownum = 1; select * from test1.t1 where rownum = 1 * ERROR at line 1: ORA-00942: table or view does not exist
结论:
1.查询视图,不需要基表的查询权限。
2.将视图的查询权限赋予其他用户,赋权用户需要基表的with grant option权限。
总结:
视图的权限,有两点需要引起注意:
1.视图中,类似于定义者权限的存储过程,是屏蔽了角色权限的。比如如果TEST1没有显式地将T1表的SELECT权限给予TEST2,那么TEST2在创建视图V_T1时也会报ORA-01031错误,即使TEST2用户拥有DBA角色权限。
2.如果在用户A的视图中,引用了其他用户B的表,用户A将视图的访问权限给予用户C,那么就变相地将用户B的表的访问权限给予了用户C,因此,用户A必须有将用户B的表的访问权限转授用户C的权限,也就是用户B在授予A权限时,必须使用with grant option。