Oracle赋权的回收权限是使用grant和revoke语句,但是赋权和回收权限语句执行完成后就会立即生效么?另外Oracle的权限又分为系统权限、角色权限和对象权限,这三种权限的grant和revoke生效时间又是怎样的呢。我们来看官方文档是如何说的:

Depending on what is granted or revoked, a grant or revoke takes effect at different times:

All grants and revokes of system and object privileges to anything (users, roles, andPUBLIC) take immediate effect.

All grants and revokes of roles to anything (users, other roles,PUBLIC) take effect only when a current user session issues aSET ROLEstatement to reenable the role after the grant and revoke, or when a new user session is created after the grant or revoke.

You can see which roles are currently enabled by examining theSESSION_ROLESdata dictionary view.

从上面的描述中我们可以知道,grant和revoke系统权限和对象权限时会立即生效,而grant或revoke角色时对当前会话不会立即生效,除非使用set role语句启用角色或重新连接会话后设置才会生效。

下面以11.2.0.4为例做一个测试,是否与官方文档描述的一致。

一、首先创建一个测试用户,赋予connect角色

sys@ORCL>createuserzhaoxuidentifiedbyzhaoxu;Usercreated.sys@ORCL>grantconnecttozhaoxu;Grantsucceeded.sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU';GRANTEEGRANTED_ROLEADMIN_OPTDEFAULT_R------------------------------------------------------------------------------ZHAOXUCONNECTNOYESsys@ORCL>select*fromdba_sys_privswheregrantee='ZHAOXU';norowsselectedsys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU';norowsselectedsys@ORCL>connzhaoxu/zhaoxuConnected.zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------CONNECTzhaoxu@ORCL>select*fromsession_privs;PRIVILEGE------------------------------------------------------------CREATESESSIONzhaoxu@ORCL>createtablet(idnumber)segmentcreationimmediate;createtablet(idnumber)*ERRORatline1:ORA-01031:insufficientprivileges

现在的zhaoxu用户只有CONNECT角色,只能连接到数据库,其他基本什么都做不了。

二、测试系统权限和对象权限的grant和revoke

现在打开另一个会话赋予system privilege给zhaoxu用户

--session2sys@ORCL>grantcreatetable,unlimitedtablespacetozhaoxu;Grantsucceeded.--session1zhaoxu@ORCL>select*fromsession_privs;PRIVILEGE------------------------------------------------------------------------------------------------------------------------CREATESESSIONUNLIMITEDTABLESPACECREATETABLEzhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECTzhaoxu@ORCL>createtablet(idnumber)segmentcreationimmediate;Tablecreated.--使用segmentcreationimmediate是因为要避免11g的新特性段延迟创建造成影响

在赋予zhaoxu用户create table和unlimited tablespace系统权限全会话1没有做任何操作,权限就会立即生效。

再测试revoke权限的情况

--session2sys@ORCL>revokeunlimitedtablespacefromzhaoxu;Revokesucceeded.--session1zhaoxu@ORCL>createtablet1(idnumber)segmentcreationimmediate;createtablet1(idnumber)segmentcreationimmediate*ERRORatline1:ORA-01950:noprivilegesontablespace'USERS'zhaoxu@ORCL>select*fromsession_privs;PRIVILEGE------------------------------------------------------------------------------------------------------------------------CREATESESSIONCREATETABLE

同样可以看到回收操作可以立即生效,现有session无需做任何操作。

测试对象权限的grant和revoke

--grant测试--session1zhaoxu@ORCL>selectcount(*)fromzx.t;selectcount(*)fromzx.t*ERRORatline1:ORA-00942:tableorviewdoesnotexist--session2sys@ORCL>grantselectonzx.ttozhaoxu;Grantsucceeded.sys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU';GRANTEEOWNERTABLE_NAMEGRANTORPRIVILEGEGRANTABLEHIERARCHY------------------------------------------------------------------------------------------------------------ZHAOXUZXTZXSELECTNONO--session1zhaoxu@ORCL>selectcount(*)fromzx.t;COUNT(*)----------99999zhaoxu@ORCL>select*fromsession_privs;PRIVILEGE------------------------------------------------------------------------------------------------------------------------CREATESESSIONCREATETABLE--revoke测试--session2sys@ORCL>revokeselectonzx.tfromzhaoxu;Revokesucceeded.sys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU';norowsselected--session1zhaoxu@ORCL>selectcount(*)fromzx.t;selectcount(*)fromzx.t*ERRORatline1:ORA-00942:tableorviewdoesnotexist

对对象权限的grant和revoke操作与系统权限的一致,所有的命令都是立即生效,包括对已经连接的会话。

三、测试角色的grant和revoke

现在的zhaoxu用户仍然只有connect角色,并且已经打开一个会话

--session2sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU';GRANTEEGRANTED_ROLEADMIN_OPTDEFAULT_R------------------------------------------------------------------------------ZHAOXUCONNECTNOYES--session1zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------CONNECT

测试grant DBA权限

--session1查看会话中的角色zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECT--session2赋予zhaoxu用户dba角色sys@ORCL>grantdbatozhaoxu;Grantsucceeded.sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU';GRANTEEGRANTED_ROLEADMIN_OPTDEFAULT_R------------------------------------------------------------------------------ZHAOXUDBANOYESZHAOXUCONNECTNOYES--session1再次查看会话中的角色,没有dba角色,也没有查看v$session的权限zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECTzhaoxu@ORCL>selectcount(*)fromv$session;selectcount(*)fromv$session*ERRORatline1:ORA-00942:tableorviewdoesnotexist--session1执行setrole命令,可以看到DBA及相关的角色已经加载到session1中了,也可以查询v$sessionzhaoxu@ORCL>setroledba;Roleset.zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------DBASELECT_CATALOG_ROLEHS_ADMIN_SELECT_ROLE......19rowsselected.zhaoxu@ORCL>selectcount(*)fromv$session;COUNT(*)----------29--使用zhaoxu用户打开session3,可以看到新会话中默认会加载DBA及相关角色[oracle@rhel6~]$sqlpluszhaoxu/zhaoxuSQL*Plus:Release11.2.0.4.0ProductiononSatJan2116:22:012017Copyright(c)1982,2013,Oracle.Allrightsreserved.Connectedto:OracleDatabase11gEnterpriseEditionRelease11.2.0.4.0-64bitProductionWiththePartitioning,OLAP,DataMiningandRealApplicationTestingoptionszhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECTDBASELECT_CATALOG_ROLE......20rowsselected.

测试revoke DBA角色

--session2回收DBA角色sys@ORCL>revokedbafromzhaoxu;Revokesucceeded.sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU';GRANTEEGRANTED_ROLEADMIN_OPTDEFAULT_R------------------------------------------------------------------------------ZHAOXUCONNECTNOYES--session3查看会话的角色,仍然有DBA及相关角色zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECTDBASELECT_CATALOG_ROLE......20rowsselected.--使用zhaoxu用户打开session4,查看只有CONNECT角色[oracle@rhel6~]$sqlpluszhaoxu/zhaoxuSQL*Plus:Release11.2.0.4.0ProductiononSatJan2116:30:192017Copyright(c)1982,2013,Oracle.Allrightsreserved.Connectedto:OracleDatabase11gEnterpriseEditionRelease11.2.0.4.0-64bitProductionWiththePartitioning,OLAP,DataMiningandRealApplicationTestingoptionszhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECT--session3执行setrole命令zhaoxu@ORCL>setroledba;setroledba*ERRORatline1:ORA-01924:role'DBA'notgrantedordoesnotexistzhaoxu@ORCL>setroleall;Roleset.zhaoxu@ORCL>select*fromsession_roles;ROLE------------------------------------------------------------------------------------------CONNECT

从上面的测试中可以总结出,grant和revoke系统权限和对象权限时会立即生效,而grant或revoke角色时对当前会话不会立即生效,除非使用set role语句启用角色或重新连接会话后设置才会生效。与官方文档的描述一致。

但是有一个问题是如果查看已经连接的其他会话所拥有的role呢?


官方文档:http://docs.oracle.com/cd/E11882_01/network.112/e36292/authorization.htm#DBSEG99974

system privilege:http://docs.oracle.com/cd/E11882_01/server.112/e41084/statements_9013.htm#BABEFFEE

object privilege:http://docs.oracle.com/cd/E11882_01/server.112/e41084/statements_9013.htm#BGBCIIEG

set role:http://docs.oracle.com/cd/E11882_01/server.112/e41084/statements_10004.htm#SQLRF01704