IT博客汇
  • 首页
  • 精华
  • 技术
  • 设计
  • 资讯
  • 扯淡
  • 权利声明
  • 登录 注册

    Oracle23ai新特性—SCHEMA级授权( grant select any table on schema)

    惜分飞发表于 2024-07-29 14:26:15
    love 0

    联系:手机/微信(+86 17813235971) QQ(107644445)QQ咨询惜分飞

    标题:Oracle23ai新特性—SCHEMA级授权( grant select any table on schema)

    作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]

    创建测试用户a并在a中创建t1,t2两个测试表,另外创建用户b(只授权登录权限)

    [oracle@xifenfei ~]$ ss
    
    SQL*Plus: Release 23.0.0.0.0 - for Oracle Cloud and Engineered Systems on Mon Jul 29 22:14:11 2024
    Version 23.5.0.24.07
    
    Copyright (c) 1982, 2024, Oracle.  All rights reserved.
    
    
    Connected to:
    Oracle Database 23ai Enterprise Edition Release 23.0.0.0.0 - for Oracle Cloud and Engineered Systems
    Version 23.5.0.24.07
    
    SQL> show pdbs;
    
        CON_ID CON_NAME                       OPEN MODE  RESTRICTED
    ---------- ------------------------------ ---------- ----------
             3 XIFENFEI                       READ WRITE NO
    
    SQL> create user b identified by oracle;
    
    User created.
    
    SQL> grant create session  to b;
    
    Grant succeeded.
    
    SQL> grant unlimited tablespace to a;
    
    Grant succeeded.
    
    SQL> create table a.t1 as select * from dba_objects;
    
    Table created.
    
    SQL> c/t1/t2;
      1* create table a.t2 as select * from dba_objects
    SQL> /
    
    Table created.
    
    SQL> select count(1) from a.t1;
    
      COUNT(1)
    ----------
         70638
    
    SQL> select count(1) from a.t2;
    
      COUNT(1)
    ----------
         70639
    
    SQL> create user b identified by oracle;
    
    User created.
    
    SQL> grant create session  to b;
    
    Grant succeeded.
    

    直接使用b用户登录并尝试查询a用户数据,结果是无法查询数据报ora-00942(意料之中因为b现在无权限访问a.t1表)

    SQL> conn b/oracle@127.0.0.1/xifenfei
    Connected.
    SQL> select count(1) from a.t1;
    select count(1) from a.t1
                           *
    ERROR at line 1:
    ORA-00942: table or view "A"."T1" does not exist
    Help: https://docs.oracle.com/error-help/db/ora-00942/
    

    直接schema级别授权a用户下面的表给b用户查询权限

    [oracle@xifenfei ~]$ ss
    
    SQL*Plus: Release 23.0.0.0.0 - for Oracle Cloud and Engineered Systems on Mon Jul 29 22:07:14 2024
    Version 23.5.0.24.07
    
    Copyright (c) 1982, 2024, Oracle.  All rights reserved.
    
    
    Connected to:
    Oracle Database 23ai Enterprise Edition Release 23.0.0.0.0 - for Oracle Cloud and Engineered Systems
    Version 23.5.0.24.07
    
    SQL>  grant select any table on schema a to b;
    
    Grant succeeded.
    
    SQL>  conn b/oracle@127.0.0.1/xifenfei
    Connected.
    SQL> select count(1) from a.t1;
    
      COUNT(1)
    ----------
         70638
    
    SQL> select count(1) from a.t2;
    
      COUNT(1)
    ----------
         70639
    
    

    在a用户中新增加表,在b用户中可以直接查询(无需再次授权)

    SQL> conn a/oracle@127.0.0.1/xifenfei
    Connected.
    SQL>  create table t3 as select * from tab;
    
    Table created.
    
    SQL> select count(1) from t3;
    
      COUNT(1)
    ----------
             3
    
    SQL> conn b/oracle@127.0.0.1/xifenfei
    Connected.
    SQL> select count(1) from a.t3;
    
      COUNT(1)
    ----------
             3
    

    Oracle 23ai中,Oracle引入了架构级(SCHEMA级别)授权。这允许你以更简单、更直观的方式对整个Schema进行授权。以前的版本中如果需要类似授权操作,需要对schema下面所有表进行grant select on user.table to user2形式授权工作量比较大而且user1中如果新增加表还需要额外授权

    • 授权用户访问数据字典三种方式
    • update user$报ORA-01031错误
    • TTS实现跨版本迁移数据
    • 创建视图提示ORA-01031
    • oracle 23ai(23.5.0.24.07)完整功能版安装体验
    • Oracle常用用户权限视图
    • Oracle 10g绕过密码登陆数据库
    • 通过with实现对表非法dml操作—解决方案_with_subquery=materialize或者psu(2014.07以后)
    • 模拟19c数据库root pdb undo异常恢复
    • ORA-01031: insufficient privileges
    • 18c新特性:alter system cancel sql
    • PASSWORD_ROLLOVER_TIME—实现新老密码短期共存


沪ICP备19023445号-2号
友情链接