深蓝的天空下,有你有我...
共享酸、甜、苦、辣
posts - 23,comments - 19,trackbacks - 0

实战:在linux as4的oracle9i (9.2.0.6.0)利用logminer恢复误删数据
author: LiuYX
date:2007-06-23
Blog: http://www.blogjava.net/liuyxit

   今天在客户现场开发,突然计划排产员跑了上来,说发现一件很奇怪的事,刚打印的生产计划单,再也找不到了,另有一张未审的单也同时不见了。
打开应用系统的日志,发现他只删了一张单,经确认这张是的确要删的单据,并不是上面两张单的其中之一。
   唯一解析是有人误删了这两张单,没有办法之下只有查看Oracle的操作日志了,于是logminer就摆了上台,之前大部分在测试环境下操作,这次来了个实战,心底未免有些紧张。
下面记录恢复过程以备后用!

1.打开SecureCRT用root用户登陆数据服务器

2.转到oracle用户
su - oracle

3.运行sqlplus,用管理员权限连接
sqlplus /nolog
SQL> conn /as sysdba

4.先查一下系统参数UTL_FILE_DIR的当前值
SQL> show parameter UTL_FILE_DIR

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
utl_file_dir                         string     

当前还没有设值,好!那就设吧
alter system set UTL_FILE_DIR ='/home/oracle/logdict' scope=both;

发现出错
ERROR at line 1:
ORA-02095: specified initialization parameter cannot be modified

才发现原来一些参数不能即时生效的,必须修改到spfile,重启数据库才可以。只好:
alter system set UTL_FILE_DIR ='/home/oracle/logdict' scope=spfile;

5.关闭实例,并重新开闭
shutdown immediate;
startup;

6.安装logminer工具需要运行下面两个sql(环境变量$ORACLE_HOME用实际的路径代替)
SQL> @$ORACLE_HOME/rdbms/admin/dbmslm.sql
SQL> @$ORACLE_HOME/rdbms/admin/dbmslmd.sql
注: 这两个脚本必须均以SYS用户身份运行。其中第一个脚本用来创建DBMS_LOGMNR包,该包用来分析日志文件。第二个脚本用来创建DBMS_LOGMNR_D包,该包用来创建数据字典文件。


7.创建数据字典文件
EXECUTE dbms_logmnr_d.build( 'dictionary.ora', '/home/oracle/logdict');

注:第二个参数的路径应该先建好,如
cd /home/oracle
mkdir logdict

8.加入需要分析的在线重作日志文件
EXECUTE dbms_logmnr.add_logfile('/opt/oracle/oradata/means/redo01.log', dbms_logmnr.new);
EXECUTE dbms_logmnr.add_logfile('/opt/oracle/oradata/means/redo02.log', dbms_logmnr.addfile);
EXECUTE dbms_logmnr.add_logfile('/opt/oracle/oradata/means/redo03.log', dbms_logmnr.addfile);

注:
如果需要从分析列表里去掉一个文件用
EXECUTE dbms_logmnr.add_logfile('d:\ORACLE\ORADATA\ORA\REDO03_1.LOG',dbms_logmnr.removefile);

查询在线日志文件用
select * from v$log; --根据显示结果可知当前日志的组号为2

GROUP#    THREAD#  SEQUENCE#      BYTES    MEMBERS ARC STATUS
---------- ---------- ---------- ---------- ---------- --- ----------------
FIRST_CHANGE# FIRST_TIM
------------- ---------
         1          1        169  104857600          1 NO  INACTIVE
     14162736 23-JUN-07

         2          1        170  104857600          1 NO  CURRENT
     14181604 23-JUN-07

         3          1        171  104857600          1 NO  INACTIVE
     14230307 23-JUN-07


select * from v$logfile; --/根据组号可以找到对应的日志文件为redo02.log
 GROUP# STATUS  TYPE
---------- ------- -------
MEMBER
--------------------------------------------------------------------------------
         1         ONLINE
/opt/oracle/oradata/means/redo01.log

         2         ONLINE
/opt/oracle/oradata/means/redo02.log

         3         ONLINE
/opt/oracle/oradata/means/redo03.log

如果确认操作是在当前日志中,可以只分析redo02.log。

9.执行日志分析(全部分析出来)
EXECUTE dbms_logmnr.start_logmnr( DictFileName=>'/home/oracle/logdict/dictionary.ora');

不知为什么,我按网上的资料定了日期段,就是不通过,执行结果如下:
EXECUTE dbms_logmnr.start_logmnr( DictFileName => '/home/oracle/logdict/dictionary.ora',StartTime => to_date('2007-6-23 00:00:00','YYYY-MM-DD HH24:MI:SS'),EndTime => to_date('2007-6-23 11:00:00','YYYY-MM-DD HH24:MI:SS'));
ERROR at line 1:
ORA-01291: missing logfile
ORA-06512: at "SYS.DBMS_LOGMNR", line 53
ORA-06512: at line 1

10.这时可就可根据V$logmnr_contents视图的内容来查阅数据的历史操作了

11.导出执行过的sql
set   heading   off
spool /home/oracle/logdict/log.txt 
SELECT sql_redo FROM V$logmnr_contents WHERE sql_redo like 'delete from "MEANS"."AL_MAIN_PLAN" where "L_ORDER_ID" = ''6073''%';
spool off

12.后来发现有更方便的方法
create table means.log_contents as select * from V$logmnr_contents

13.然后用toad来查就更方便了!


如有错漏请高手指教,TKS!

附v$logmnr_contents的结构和常用字段说明

 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 SCN                                                NUMBER --System Change Number 可用select dbms_flashback.get_system_change_number from dual;获得当前改变号
 CSCN                                               NUMBER
 TIMESTAMP                                          DATE --执行操作的时间
 COMMIT_TIMESTAMP                                   DATE
 THREAD#                                            NUMBER
 LOG_ID                                             NUMBER
 XIDUSN                                             NUMBER
 XIDSLT                                             NUMBER
 XIDSQN                                             NUMBER
 PXIDUSN                                            NUMBER
 PXIDSLT                                            NUMBER
 PXIDSQN                                            NUMBER
 RBASQN                                             NUMBER
 RBABLK                                             NUMBER
 RBABYTE                                            NUMBER
 UBAFIL                                             NUMBER
 UBABLK                                             NUMBER
 UBAREC                                             NUMBER
 UBASQN                                             NUMBER
 ABS_FILE#                                          NUMBER
 REL_FILE#                                          NUMBER
 DATA_BLK#                                          NUMBER
 DATA_OBJ#                                          NUMBER
 DATA_OBJD#                                         NUMBER
 SEG_OWNER                                          VARCHAR2(32)
 SEG_NAME                                           VARCHAR2(256)
 SEG_TYPE                                           NUMBER
 SEG_TYPE_NAME                                      VARCHAR2(32)
 TABLE_SPACE                                        VARCHAR2(32)
 ROW_ID                                             VARCHAR2(19)
 SESSION#                                           NUMBER
 SERIAL#                                            NUMBER
 USERNAME                                           VARCHAR2(30)
 SESSION_INFO                                       VARCHAR2(4000)
 TX_NAME                                            VARCHAR2(256)
 ROLLBACK                                           NUMBER
 OPERATION                                          VARCHAR2(32)
 OPERATION_CODE                                     NUMBER
 SQL_REDO                                           VARCHAR2(4000)
 SQL_UNDO                                           VARCHAR2(4000)
 RS_ID                                              VARCHAR2(32)
 SEQUENCE#                                          NUMBER
 SSN                                                NUMBER
 CSF                                                NUMBER
 INFO                                               VARCHAR2(32)
 STATUS                                             NUMBER
 REDO_VALUE                                         RAW(4)
 UNDO_VALUE                                         RAW(4)
 SQL_COLUMN_TYPE                                    VARCHAR2(32)
 SQL_COLUMN_NAME                                    VARCHAR2(32)
 REDO_LENGTH                                        NUMBER
 REDO_OFFSET                                        NUMBER
 UNDO_LENGTH                                        NUMBER
 UNDO_OFFSET                                        NUMBER

posted on 2007-07-10 23:39 三刀流の逆风 阅读(2240) 评论(3)  编辑  收藏 所属分类: Oracle

FeedBack:
# re: 实战:在linux as4的oracle9i (9.2.0.6.0)利用logminer恢复误删数据
2007-07-12 13:04 | 祎恬凡
恩,看了看,收藏以阿,希望以后用不到。用到了找你!  回复  更多评论
  
# re: 实战:在linux as4的oracle9i (9.2.0.6.0)利用logminer恢复误删数据[未登录]
2008-05-22 10:25 | BOBO
我也碰到过和楼住一样的问题,我最后分析出来的日志居然是我自己的机器操作的,汗~~~,我一点影象都没有,误操作!分析日志的时候也是不能用日期,后来我就用起始SCN来分析的,后来查了很多资料也没查到原因  回复  更多评论
  
# re: 实战:在linux as4的oracle9i (9.2.0.6.0)利用logminer恢复误删数据
2011-06-30 17:26 | charlee
高手。问题处理得如此轻松  回复  更多评论
  

只有注册用户登录后才能发表评论。


网站导航: