现象
这个问题来自于朋友工作中遇到的一个真实场景:
Oracle 11.2.0.4数据库
数据库用户A:create any view,select any table
数据库用户B:select any table
数据库用户C: 只读用户,有且仅有create session权限
执行步骤:
- 数据库用户A在数据库用户B中创建了一张VIEW,VIEW的基表来自于多个数据库用户。
- 使用SYS用户将VIEW的select权限授权给数据库用户C。
- 数据库用户B和数据库用户C均可正常查询该VIEW。
- 数据库用户A再次执行:create or replace view语句,结果报出:
ORA-01720: grant option does not exist for 'TEST.T_OBJ'。 - 数据库用户A新建一个VIEW(和老VIEW定义完全一致),可以成功执行。
重演过程
创建测试用户
SQL> create user test0 identified by test;
grant create session to test0;
grant select any table to test0;
grant create any view to test0;
User created.
SQL>
Grant succeeded.
SQL>
Grant succeeded.
SQL>
Grant succeeded.
SQL>create user test2 identified by test;
grant create session to test2;
grant select any table to test2;
SQL>
User created.
SQL>
Grant succeeded.
SQL>
Grant succeeded.
SQL> create user test3 identified by test;
grant create session to test3;
SQL>
Grant succeeded.
SQL>
User created.
系统权限查询:
SQL> select * from dba_sys_privs where grantee like 'TEST%' order by grantee,privilege;
GRANTEE PRIVILEGE ADMIN_OPTION
------------------------------ ---------------------------------------- ------------
TEST0 CREATE ANY VIEW NO
TEST0 CREATE SESSION NO
TEST0 SELECT ANY TABLE NO
TEST2 CREATE SESSION NO
TEST2 SELECT ANY TABLE NO
TEST3 CREATE SESSION NO
为简化测试,测试视图仅仅引用了test.t_obj表,记录有800多万条。
SQL> connect test0/test;
Connected.
SQL> create or replace view test2.v_t_obj as select * from test.t_obj;
View created.
SQL> connect test2/test;
Connected.
SQL> select count(*) from v_t_obj;
COUNT(*)
----------
8053248
SQL> connect /as sysdba;
Connected.
SQL> grant select on test2.v_t_obj to test3;
Grant succeeded.
SQL> connect test3/test
Connected.
SQL> select count(*) from test2.v_t_obj;
COUNT(*)
----------
8053248
至此,一切看起来均很正常。
表的权限如下:
SQL> select * from dba_tab_privs where grantee like 'TEST%';
GRANT OWNER TABLE_NAME GRANT PRIVILEGE GRANTABLE HIERARCHY
----- ----- ------------------------------ ----- ---------- --------- ---------
TEST3 TEST2 V_T_OBJ TEST2 SELECT NO NO
SQL> select * from dba_sys_privs where grantee like 'TEST%' order by grantee,privilege;
GRANT PRIVILEGE ADMIN_OPTION
----- ------------------------------ ------------
TEST0 CREATE ANY VIEW NO
TEST0 CREATE SESSION NO
TEST0 SELECT ANY TABLE NO
TEST2 CREATE SESSION NO
TEST2 SELECT ANY TABLE NO
TEST3 CREATE SESSION NO
重建视图,问题发生了:
SQL> connect test0/test;
Connected.
SQL> create or replace view test2.v_t_obj as select * from test.t_obj;
create or replace view test2.v_t_obj as select * from test.t_obj
*
ERROR at line 1:
ORA-01720: grant option does not exist for 'TEST.T_OBJ'
SQL> create view test2.v_t_obj_new as select * from test.t_obj;
View created.
测试到这里,结合常规场景中的视图授权问题,初步可以断定和表的select grant option策略有关。
进一步继续测试:
SQL> connect /as sysdba
Connected.
SQL> revoke select on test2.v_t_obj from test3;
Revoke succeeded.
SQL> connect test0/test
Connected.
SQL> create or replace view test2.v_t_obj as select * from test.t_obj;
View created.
到这里时,可以思考一下,以上的操作里,有一步操作值得关注:
SQL> connect /as sysdba;
Connected.
SQL> grant select on test2.v_t_obj to test3;
Grant succeeded.
按照正常操作,一般view的授权会以VIEW的owner登录数据库,然后直接grant。
SQL> connect test2/test
Connected.
SQL> grant select on test2.v_t_obj to test3;
grant select on test2.v_t_obj to test3
*
ERROR at line 1:
ORA-01720: grant option does not exist for 'TEST.T_OBJ'
问题还是出在多用户的级联授权上,继续往下探:
SQL> connect system
Enter password:
Connected.
SQL> grant select on test2.v_t_obj to test3;
grant select on test2.v_t_obj to test3
*
ERROR at line 1:
ORA-01720: grant option does not exist for 'TEST.T_OBJ'
SQL> select * from dba_sys_privs where grantee like 'SYS%' and privilege = 'SELECT ANY TABLE' order by grantee,privilege;
GRANTEE PRIVILEGE ADMIN_OPTION
---------- ------------------------------ ------------
SYS SELECT ANY TABLE YES
SYSTEM SELECT ANY TABLE NO
到了这里,问题原因浮出水面:
with admin option
根据查询官方文档,发现有这么一段话:
You will get this ORA-1720 error when REPLACING a view that selects from some other user's tables and both of the following conditions are true:
- you have already granted select or other privileges on the VIEW to some other user
- the view owner does not have the GRANT option on the tables being selected from (or view owner may have some privilege with grant option but not others)
-
The code was changed in 11.2.0.4 so that create view behavior is similar to grant. If you try to make a GRANT on an existing view and the view owner does not have the grant option, then ORA-1720 is the expected result (even in 11.2.0.3). In 11.2.0.4, we have simply made CREATE VIEW consistent with the GRANT behavior, i.e. if an incompatible grant exists, then the new view definition must not be allowed (even with FORCE). In other words, we do not allow incompatible grants to coexist with the view definition and so an error must be thrown. The behavior in release 11.2.0.3 (and earlier) was incorrect; the new behavior in 11.2.0.4 is intentional and correct.
为了解决这一问题,建议对多用户表或者视图进行级联授权时:
1. 不要使用SYS用户执行类似操作
2. 使用常规方式进行相关授权