标签云
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-01595 ORA-08103 ORA-600 2131 ORA-600 2662 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,738)
- DB2 (22)
- MySQL (75)
- Oracle (1,588)
- 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备份恢复 (582)
- Oracle安装升级 (95)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (83)
- PostgreSQL (27)
- pdu工具 (5)
- PostgreSQL恢复 (9)
- SQL Server (29)
- SQL Server恢复 (10)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- ORA-39773: parse of metadata stream failed故障处理
- sql数据库备份失败—失败: 23(数据错误(循环冗余检查)
- vmdk文件被加密恢复(虚拟机文件加密)
- 差点被误操作的ORA-600 kcratr_nab_less_than_odr故障
- win平台19c 打patch遭遇2个小问题汇总
- pg单个数据库目录恢复-pdu恢复单个数据库目录数据
- pg删除数据恢复—pdu恢复pg delete数据
- .[OnlyBuy@cyberfear.com].REVRAC勒索mysql恢复
- 表dml操作权限授权给public,导致只读用户失效
- 21c数据库恢复遭遇ora-600 ktugct: corruption detected
- pg_control丢失/损坏处理
- 当前主流数据库版本服务支持周期-202503
- pg启动报invalid checkpoint record处理
- 删除redo导致ORA-00313 ORA-00312故障处理
- Navicat连接postgresql时出现column “datlastsysoid” does not exist错误解决
- aix磁盘损坏oracle数据库恢复
- pg误删除数据恢复(PostgreSQL delete数据恢复)
- PostgreSQL表文件损坏恢复—pdu恢复损坏的表文件
- linux rm -rf 删除数据文件恢复
- PostgreSQL恢复工具—pdu恢复单个表文件
标签归档:impdp sys授权
impdp导入数据丢失sys授权问题分析
在使用expdp/impdp迁移的过程中,偶尔会遇到用户中关于sys对象的授权丢失导致不少pl/sql程序无效,通过测试重现sys授权丢失现象
创建用户并进行sys对象授权给该用户
C:\Users\XFF>sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Sun Jan 19 12:04:22 2025 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> create user xff identified by oracle; User created. SQL> grant resource,connect to xff; Grant succeeded. SQL> grant select on sys.obj$ to xff; Grant succeeded. SQL> grant execute on sys.dbms_lock to xff; Grant succeeded. SQL> grant select on sys.v_$session to xff; Grant succeeded. SQL> exit Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options
使用exp导出数据
C:\Users\XFF>expdp "'/ as sysdba'" dumpfile=xff.dmp schemas=xff Export: Release 11.2.0.4.0 - Production on Sun Jan 19 12:05:35 2025 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options Starting "SYS"."SYS_EXPORT_SCHEMA_04": "/******** AS SYSDBA" dumpfile=xff.dmp schemas=xff Estimate in progress using BLOCKS method... Total estimation using BLOCKS method: 0 KB Processing object type SCHEMA_EXPORT/USER Processing object type SCHEMA_EXPORT/SYSTEM_GRANT Processing object type SCHEMA_EXPORT/ROLE_GRANT Processing object type SCHEMA_EXPORT/DEFAULT_ROLE Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA Master table "SYS"."SYS_EXPORT_SCHEMA_04" successfully loaded/unloaded ****************************************************************************** Dump file set for SYS.SYS_EXPORT_SCHEMA_04 is: C:\APP\XFF\ADMIN\ORCL\DPDUMP\XFF.DMP Job "SYS"."SYS_EXPORT_SCHEMA_04" successfully completed at Sun Jan 19 12:05:37 2025 elapsed 0 00:00:02
使用impdp导入数据
C:\Users\XFF>impdp "'/ as sysdba'" dumpfile=xff.dmp remap_schema=xff:nxff Import: Release 11.2.0.4.0 - Production on Sun Jan 19 12:06:22 2025 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options Master table "SYS"."SYS_IMPORT_FULL_01" successfully loaded/unloaded Starting "SYS"."SYS_IMPORT_FULL_01": "/******** AS SYSDBA" dumpfile=xff.dmp remap_schema=xff:nxff Processing object type SCHEMA_EXPORT/USER Processing object type SCHEMA_EXPORT/SYSTEM_GRANT Processing object type SCHEMA_EXPORT/ROLE_GRANT Processing object type SCHEMA_EXPORT/DEFAULT_ROLE Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA Job "SYS"."SYS_IMPORT_FULL_01" successfully completed at Sun Jan 19 12:06:23 2025 elapsed 0 00:00:00
验证用户的权限
C:\Users\XFF>sqlplus xff/oracle SQL*Plus: Release 11.2.0.4.0 Production on Sun Jan 19 12:09:21 2025 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> show user; USER is "XFF" SQL> select count(1) from v$session; COUNT(1) ---------- 26 SQL> select count(1) from sys.obj$; COUNT(1) ---------- 90656 SQL> desc sys.dbms_lock PROCEDURE ALLOCATE_UNIQUE Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- LOCKNAME VARCHAR2 IN LOCKHANDLE VARCHAR2 OUT EXPIRATION_SECS NUMBER(38) IN DEFAULT FUNCTION CONVERT RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- ID NUMBER(38) IN LOCKMODE NUMBER(38) IN TIMEOUT NUMBER IN DEFAULT FUNCTION CONVERT RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- LOCKHANDLE VARCHAR2 IN LOCKMODE NUMBER(38) IN TIMEOUT NUMBER IN DEFAULT FUNCTION RELEASE RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- ID NUMBER(38) IN FUNCTION RELEASE RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- LOCKHANDLE VARCHAR2 IN FUNCTION REQUEST RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- ID NUMBER(38) IN LOCKMODE NUMBER(38) IN DEFAULT TIMEOUT NUMBER(38) IN DEFAULT RELEASE_ON_COMMIT BOOLEAN IN DEFAULT FUNCTION REQUEST RETURNS NUMBER(38) Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- LOCKHANDLE VARCHAR2 IN LOCKMODE NUMBER(38) IN DEFAULT TIMEOUT NUMBER(38) IN DEFAULT RELEASE_ON_COMMIT BOOLEAN IN DEFAULT PROCEDURE SLEEP Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- SECONDS NUMBER IN SQL> conn nxff/oracle Connected. SQL> desc sys.dbms_lock ERROR: ORA-04043: object sys.dbms_lock does not exist SQL> select count(1) from sys.obj$; select count(1) from sys.obj$ * ERROR at line 1: ORA-00942: table or view does not exist SQL> select count(1) from v$session; select count(1) from v$session * ERROR at line 1: ORA-00942: table or view does not exist
确认通过impdp迁移过去的nxff用户没有之前xff用户里面sys授权的对象的访问权限.通过sqlfile查看expdp导出的dmp文件中ddl内容,确认确实没有sys部分的授权
出现这个问题的原因是由于expdp不会导出sys中对象,所以就丢失了这部分授权信息,可以通过获取语句获取权限,然后执行补全
SQL> select 'grant ' || privilege || ' on ' ||'"'||table_name ||'"'|| 2 ' to ' || grantee || ';' "GRANTS" 3 from dba_tab_privs 4 where owner = 'SYS' and privilege not in ('READ', 'WRITE') 5 and grantee in ('XFF') 6 order by 1; GRANTS -------------------------------------------------------------------------------- grant EXECUTE on "DBMS_LOCK" to XFF; grant SELECT on "OBJ$" to XFF; grant SELECT on "V_$SESSION" to XFF;