Oracle 赋权和回收权限的生效时间
Oracle赋权的回收权限是使用grant和revoke语句,但是赋权和回收权限语句执行完成后就会立即生效么?另外Oracle的权限又分为系统权限、角色权限和对象权限,这三种权限的grant和revoke生效时间又是怎样的呢。我们来看官方文档是如何说的: Depending on what is granted or revoked,a grant or revoke takes effect at different times:
You can see which roles are currently enabled by examining the 从上面的描述中我们可以知道,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'; GRANTEE GRANTED_ROLE ADMIN_OPTDEFAULT_R ------------------------------------------------------------------------------ ZHAOXU CONNECT NO YES sys@ORCL>select*fromdba_sys_privswheregrantee='ZHAOXU'; norowsselected sys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU'; norowsselected sys@ORCL>connzhaoxu/zhaoxu Connected. zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------ CONNECT zhaoxu@ORCL>select*fromsession_privs; PRIVILEGE ------------------------------------------------------------ CREATESESSION zhaoxu@ORCL>createtablet(idnumber)segmentcreationimmediate; createtablet(idnumber) * ERRORatline1: ORA-01031:insufficientprivileges 现在的zhaoxu用户只有CONNECT角色,只能连接到数据库,其他基本什么都做不了。 二、测试系统权限和对象权限的grant和revoke 现在打开另一个会话赋予system privilege给zhaoxu用户 --session2 sys@ORCL>grantcreatetable,unlimitedtablespacetozhaoxu; Grantsucceeded. --session1 zhaoxu@ORCL>select*fromsession_privs; PRIVILEGE ------------------------------------------------------------------------------------------------------------------------ CREATESESSION UNLIMITEDTABLESPACE CREATETABLE zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ CONNECT zhaoxu@ORCL>createtablet(idnumber)segmentcreationimmediate; Tablecreated. --使用segmentcreationimmediate是因为要避免11g的新特性段延迟创建造成影响 在赋予zhaoxu用户create table和unlimited tablespace系统权限全会话1没有做任何操作,权限就会立即生效。 再测试revoke权限的情况 --session2 sys@ORCL>revokeunlimitedtablespacefromzhaoxu; Revokesucceeded. --session1 zhaoxu@ORCL>createtablet1(idnumber)segmentcreationimmediate; createtablet1(idnumber)segmentcreationimmediate * ERRORatline1: ORA-01950:noprivilegesontablespace'USERS' zhaoxu@ORCL>select*fromsession_privs; PRIVILEGE ------------------------------------------------------------------------------------------------------------------------ CREATESESSION CREATETABLE 同样可以看到回收操作可以立即生效,现有session无需做任何操作。 测试对象权限的grant和revoke --grant测试 --session1 zhaoxu@ORCL>selectcount(*)fromzx.t; selectcount(*)fromzx.t * ERRORatline1: ORA-00942:tableorviewdoesnotexist --session2 sys@ORCL>grantselectonzx.ttozhaoxu; Grantsucceeded. sys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU'; GRANTEE OWNER TABLE_NAMEGRANTORPRIVILEGEGRANTABLEHIERARCHY ------------------------------------------------------------------------------------------------------------ ZHAOXU ZX T ZX SELECTNO NO --session1 zhaoxu@ORCL>selectcount(*)fromzx.t; COUNT(*) ---------- 99999 zhaoxu@ORCL>select*fromsession_privs; PRIVILEGE ------------------------------------------------------------------------------------------------------------------------ CREATESESSION CREATETABLE --revoke测试 --session2 sys@ORCL>revokeselectonzx.tfromzhaoxu; Revokesucceeded. sys@ORCL>select*fromdba_tab_privswheregrantee='ZHAOXU'; norowsselected --session1 zhaoxu@ORCL>selectcount(*)fromzx.t; selectcount(*)fromzx.t * ERRORatline1: ORA-00942:tableorviewdoesnotexist 对对象权限的grant和revoke操作与系统权限的一致,所有的命令都是立即生效,包括对已经连接的会话。 三、测试角色的grant和revoke 现在的zhaoxu用户仍然只有connect角色,并且已经打开一个会话 --session2 sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU'; GRANTEE GRANTED_ROLE ADMIN_OPTDEFAULT_R ------------------------------------------------------------------------------ ZHAOXU CONNECT NO YES --session1 zhaoxu@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'; GRANTEE GRANTED_ROLE ADMIN_OPTDEFAULT_R ------------------------------------------------------------------------------ ZHAOXU DBA NO YES ZHAOXU CONNECT NO YES --session1再次查看会话中的角色,没有dba角色,也没有查看v$session的权限 zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ CONNECT zhaoxu@ORCL>selectcount(*)fromv$session; selectcount(*)fromv$session * ERRORatline1: ORA-00942:tableorviewdoesnotexist --session1执行setrole命令,可以看到DBA及相关的角色已经加载到session1中了,也可以查询v$session zhaoxu@ORCL>setroledba; Roleset. zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ DBA SELECT_CATALOG_ROLE HS_ADMIN_SELECT_ROLE ...... 19rowsselected. zhaoxu@ORCL>selectcount(*)fromv$session; COUNT(*) ---------- 29 --使用zhaoxu用户打开session3,可以看到新会话中默认会加载DBA及相关角色 [oracle@rhel6~]$sqlpluszhaoxu/zhaoxu SQL*Plus:Release11.2.0.4.0ProductiononSatJan2116:22:012017 Copyright(c)1982,2013,Oracle.Allrightsreserved. Connectedto: OracleDatabase11gEnterpriseEditionRelease11.2.0.4.0-64bitProduction WiththePartitioning,OLAP,DataMiningandRealApplicationTestingoptions zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ CONNECT DBA SELECT_CATALOG_ROLE ...... 20rowsselected. 测试revoke DBA角色 --session2回收DBA角色 sys@ORCL>revokedbafromzhaoxu; Revokesucceeded. sys@ORCL>select*fromdba_role_privswheregrantee='ZHAOXU'; GRANTEE GRANTED_ROLE ADMIN_OPTDEFAULT_R ------------------------------------------------------------------------------ ZHAOXU CONNECT NO YES --session3查看会话的角色,仍然有DBA及相关角色 zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ CONNECT DBA SELECT_CATALOG_ROLE ...... 20rowsselected. --使用zhaoxu用户打开session4,查看只有CONNECT角色 [oracle@rhel6~]$sqlpluszhaoxu/zhaoxu SQL*Plus:Release11.2.0.4.0ProductiononSatJan2116:30:192017 Copyright(c)1982,DataMiningandRealApplicationTestingoptions zhaoxu@ORCL>select*fromsession_roles; ROLE ------------------------------------------------------------------------------------------ CONNECT --session3执行setrole命令 zhaoxu@ORCL>setroledba; setroledba * ERRORatline1: ORA-01924:role'DBA'notgrantedordoesnotexist zhaoxu@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 (编辑:李大同) 【声明】本站内容均来自网络,其相关言论仅代表作者个人观点,不代表本站立场。若无意侵犯到您的权利,请及时与联系站长删除相关内容! |