标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 kfed MySQL恢复 ORA-00312 ORA-00607 ORA-00704 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)
- 操作系统 (102)
- 数据库 (1,683)
- DB2 (22)
- MySQL (73)
- Oracle (1,545)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (7)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (53)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (565)
- Oracle安装升级 (92)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (79)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (27)
- SQL Server恢复 (8)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- ORA-15411: Failure groups in disk group DATA have different number of disks.
- 断电引起的ORA-08102: 未找到索引关键字, 对象号 39故障处理
- ORA-00227: corrupt block detected in control file
- 手工删除19c rac
- 解决oracle数据文件路径有回车故障
- .wstop扩展名勒索数据库恢复
- Oracle Recovery Tools工具一键解决ORA-00376 ORA-01110故障(文件offline)
- OGG-02771 Input trail file format RELEASE 19.1 is different from previous trail file form at RELEASE 11.2.
- OGG-02246 Source redo compatibility level 19.0.0 requires trail FORMAT 12.2 or higher
- GoldenGate 19安装和打patch
- dd破坏asm磁盘头恢复
- 删除asmlib磁盘导致磁盘组故障恢复
- Kylin Linux 安装19c
- ORA-600 krse_arc_complete.4
- Oracle 19c 202410补丁(RUs+OJVM)
- ntfs MFT损坏(ntfs文件系统故障)导致oracle异常恢复
- .mkp扩展名oracle数据文件加密恢复
- 清空redo,导致ORA-27048: skgfifi: file header information is invalid
- A_H_README_TO_RECOVER勒索恢复
- 通过alert日志分析客户自行对一个数据库恢复的来龙去脉和点评
标签归档:ORA-12154
手动提交分布式事务一例
一.alert文件中出现了很多类此记录
Fri Feb 10 05:25:01 2012 Errors in file /tmp/recover/ahcx216_reco_7956.trc: ORA-12154: TNS:could not resolve service name Fri Feb 10 05:25:01 2012 Errors in file /tmp/recover/ahcx216_reco_7956.trc: ORA-12154: TNS:could not resolve service name
这里可以看出来两个信息:
1.出错的进程是rec0进程,而该进程的作用是解决分布式事务失败后遗留问题(事务提交或者回滚)
2.错误信息是tns不能被解析
二.查看trace文件
/tmp/recover/ahcx216_reco_7956.trc Oracle9i Enterprise Edition Release 9.2.0.8.0 - Production With the Partitioning, OLAP and Oracle Data Mining options JServer Release 9.2.0.8.0 - Production ORACLE_HOME = /opt/oracle/product/9.2.0/db_1 System name: Linux Node name: localhost.localdomain Release: 2.6.9-89.0.0.0.1.ELhugemem Version: #1 SMP Tue May 19 04:38:38 EDT 2009 Machine: i686 Instance name: ahcx216 Redo thread mounted by this instance: 1 Oracle process number: 7 Unix process pid: 7956, image: oracle@localhost.localdomain (RECO) *** SESSION ID:(6.1) 2012-02-10 04:58:24.886 *** 2012-02-10 04:58:24.886 ERROR, tran=6.1.712757, session#=1, ose=0: ORA-12154: TNS:could not resolve service name ……………… *** 2012-02-10 05:25:01.580 ERROR, tran=6.1.712757, session#=1, ose=0: ORA-12154: TNS:could not resolve service name *** 2012-02-10 05:25:01.627 ERROR, tran=12.19.99059, session#=1, ose=0: ORA-12154: TNS:could not resolve service name
通过这里我们可以看出事务id分别为12.19.99059和6.1.712757有问题
三.查看dba_2pc_pending视图
SQL> select local_tran_id,state,fail_time,retry_time from dba_2pc_pending; LOCAL_TRAN_ID STATE FAIL_TIME RETRY_TIME -------------- ---------------- -------------- -------------- 6.1.712757 collecting 2010/12/1 13:39:03 2012/2/10 5:38:52 12.19.99059 collecting 2010/12/1 15:56:26 2012/2/10 5:38:52
可以看出,果然有两个分布式事务在2010年12月1日出了问题(本库是一个问题库,在把库拉起来后发现该问题)
因为是异机恢复,而且间隔时间较长,很多tns的信息都已经不存在,所以需要手工提交分布式事务
四.手动提交事务
SQL> BEGIN 2 DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('6.1.712757'); 3 DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('12.19.99059'); 4 END; 5 / BEGIN * 第 1 行出现错误: ORA-30019: Illegal rollback Segment operation in Automatic Undo mode ORA-06512: at "SYS.DBMS_TRANSACTION", line 65 ORA-06512: at "SYS.DBMS_TRANSACTION", line 85 ORA-06512: at line 2 SQL> alter session set "_smu_debug_mode"=4; Session altered. ------------------------------------------------------------- --设置UNDO_SUPPRESS_ERRORS=true也可以解决此问题 alter system set UNDO_SUPPRESS_ERRORS = TRUE; EXECUTE DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('<事务ID>'); commit; alter system set UNDO_SUPPRESS_ERRORS = false; -------------------------------------------------------------- SQL> commit; SQL> exec DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('6.1.712757'); PL/SQL procedure successfully completed. SQL> exec DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('12.19.99059'); BEGIN DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('12.19.99059'); END; * ERROR at line 1: ORA-01453: SET TRANSACTION must be first statement of transaction ORA-06512: at "SYS.DBMS_TRANSACTION", line 65 ORA-06512: at "SYS.DBMS_TRANSACTION", line 85 ORA-06512: at line 1 --第一个分布式事务处理后,未提交导致 SQL> commit; Commit complete. SQL> exec DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('12.19.99059'); PL/SQL procedure successfully completed. SQL> commit; Commit complete.
五.补充说明
开始在另一个会话中,执行失败原因
SQL> alter session set "_smu_debug_mode"=4; 会话已更改。 SQL> commit; 提交完成。 SQL> BEGIN 2 DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('6.1.712757'); 3 DBMS_TRANSACTION.PURGE_LOST_DB_ENTRY('12.19.99059'); 4 END; 5 / BEGIN * 第 1 行出现错误: ORA-01453: SET TRANSACTION must be first statement of transaction ORA-06512: at "SYS.DBMS_TRANSACTION", line 65 ORA-06512: at "SYS.DBMS_TRANSACTION", line 85 ORA-06512: at line 3
因为这里的begin end中包含了两个事务的清理,在清理完第一个事务之后,需要提交才能够清理第二个,这里因为没有提交,导致ORA-01453错误。