标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-00742 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 Oracle 恢复 ORACLE恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (103)
- 数据库 (1,716)
- DB2 (22)
- MySQL (74)
- Oracle (1,576)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (160)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (54)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (575)
- Oracle安装升级 (94)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (81)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (28)
- SQL Server恢复 (9)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- 不当使用_allow_resetlogs_corruption参数引起ORA-600 2662错误
- CSSD signal 11 in thread clssnmRcfgMgrThread故障处理
- 使用sid方式直接访问pdb(USE_SID_AS_SERVICE_LISTENER)
- ORA-00069: cannot acquire lock — table locks disabled for xxxx
- ORA-600 [4000] [a]相关bug
- sql server数据库“正在恢复”故障处理
- 如何判断数据文件是否处于begin backup状态
- CDM备份缺少归档打开数据库报ORA-600 kcbzib_kcrsds_1故障处理
- ORA-07445: exception encountered: core dump [expgod()+43] [IN_PAGE_ERROR]
- 2025年第一起ORA-600 16703故障恢复
- _gc_undo_affinity=FALSE触发ORA-01558
- public授权语句
- 中文环境显示AR8MSWIN1256(阿拉伯语字符集)
- 处理 Oracle 块损坏
- Oracle各种类型坏块说明和处理
- fio测试io,导致磁盘文件系统损坏故障恢复
- ORA-742 写丢失常见bug记录
- Oracle 19c 202501补丁(RUs+OJVM)-19.26
- 避免 19c 数据库性能问题需要考虑的事项 (Doc ID 3050476.1)
- Bug 21915719 Database hang or may fail to OPEN in 12c IBM AIX or HPUX Itanium – ORA-742, DEADLOCK or ORA-600 [kcrfrgv_nextlwn_scn] ORA-600 [krr_process_read_error_2]
标签归档:grant select any table on schema
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中如果新增加表还需要额外授权