分类: Oracle
2010-04-12 22:16:23
导读:
一、先听段故事吧~
二,logminer的基本方法
三、实际中有可能用到的例子
一、先听段故事吧~
p109
oracle重做日志文件包含了对用户数据和数据库的数据字典所做的所有改变。
1,日志挖掘的意义:
·准确定位错误发生的时间点,然后采取相应的补救措施
·还原表,将表恢复到先前一个状态,然后用已存档的日志文件向前回滚
·性能协调和容量规划
·事后审核
2,注意事项:
·重做日志文件必须和运行logminer的数据库有相同的字符集
·logminer 必须运行在生成正在分析的重做日志文件的硬件平台上
·数据库必须运行在archvielog模式
·不能在共享服务器环境中做logminer操作
3,logminer的局限
不支持以下内容
·数据类型LONG和LOB
·简单的和嵌套的数据提取类型(ADTs)
·集合(嵌套表和varrays)
·对象Refs
·索引结构的表(IOTs)
4,如何安装DBMS_LOGMNR_D过程?
10G中创建DBMS_LOGMNR_D过程的sql
SQL> START /opt/oracle/product/10.2.0/db_1/rdbms/admin/dbmslmd.sql
二,logminer的基本方法
步骤1,获取数据字典的平面文件(意思就是把数据字典内容映射到一个文本文件里面!)
alter system set utl_file_dir=’/mc/oracle/logmnr’ scope=spfile <==设置utl_file_dir;这个需要重启oracle
shutdown immediate;
startup
sqlplus ‘/as sysdba’
execute dbms_logmnr_d.build('dictionary.ora','/mc/oracle/logmnr',options => dbms_logmnr_d.store_in_flat_file);
host
oracle@mmloyal [/mc/oracle/logmnr]# ll -h
total 27M
-rw-r--r-- 1 oracle dba 27M Apr 7 00:40 dictionary.ora <==这就是数据字典的平面文件!
步骤2,指定要分析的重做日志文件
sys@MC> execute dbms_logmnr.add_logfile( logfilename =>'/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07/o1_mf_1_523_5vrgkmnd_.arc',options => dbms_logmnr.new);
PL/SQL procedure successfully completed.
步骤3,查看将要分析那个日志
select * from v$logmnr_logs;
步骤4,移走不想挖掘的日志文件
sys@MC> execute dbms_logmnr.add_logfile( logfilename =>'/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07/o1_mf_1_522_5vrgf9dm_.arc',options => dbms_logmnr.removefile);
PL/SQL procedure successfully completed.
步骤5,启动logminer
这里要制定刚才创建的数据库字典文件,要不然分析重做日志后将以16进制显示数据对象,到时候你就傻眼了~
注意:若没有制定平面文件字典名称,那么指定dict_from_redo_logs或者dict_from_on
sys@MC> execute dbms_logmnr.add_logfile( logfilename =>'/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07/o1_mf_1_523_5vrgkmnd_.arc',options => dbms_logmnr.new);
PL/SQL procedure successfully completed.
sys@MC> exec dbms_logmnr.start_logmnr(dictfilename =>'/mc/oracle/logmnr/dictionary.ora'); <==这里要知道字典文件
PL/SQL procedure successfully completed.
Tips:只挖掘那些提交成功的sql(options选项)
exec dbms_logmnr.start_logmnr(dictfilename =>'/mc/oracle/logmnr/dictionary.ora',options => dbms_logmnr.committed_da
Tips:挖掘某时间范围内的数据
exec dbms_logmnr.start_logmnr(
dictfilename => ‘/mc/oracle/logmnr/dictionary.ora’,
starttime => to_date(’02-Apr-2010 09:30:00’,’DD-MON-YYYY HH:MI:SS’),
endtime => to_date(’02-Apr-2010 19:30:00’,’DD-MON-YYYY HH:MI:SS’));
Tips:挖掘某个SCN范围内的日志
exec dbms_logmnr.start_logmnr(
dictfilename => ‘/mc/oracle/logmnr/dictionary.ora’,
startscn => 19009,
endscn => 2220390);
步骤6,查看日志挖掘的结果
select * from v$logmnr_contents <==结果按scn号排列
Tips: 使用logminer执行对象级的恢复操作
column sql_redo format a4000
column sql_undo format a4000
select sql_redo,sql_undo from v$logmnr_contents where rownum<3
说明:
sql_redo 列记录的sql代表原来的操作
sql_undo列记录的sql代表要撤销上面操作的方法(这些sql都是logmnr构建的!)
步骤7,结束logminer会话
sys@MC> exec dbms_logmnr.end_logmnr;
PL/SQL procedure successfully completed.
三、实际中有可能用到的例子
在2010-4-7 3:00~5:00我创建了表a还插入数据还修改了数据。。现在呢就是想通过日志挖掘把我这些动作呈现一下啊哈哈!
查看归档日志(当然最好的办法是看v$archived_log 是这个视图吗??)
步骤1:
root@mmloyal [/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07]# ll -rt
total 3316
-rw-r----- 1 oracle dba 3369984 Apr 7 00:52 o1_mf_1_522_5vrgf9dm_.arc
-rw-r----- 1 oracle dba 12288 Apr 7 00:54 o1_mf_1_523_5vrgkmnd_.arc
-rw-r----- 1 oracle dba 5120 Apr 7 00:54 o1_mf_1_524_5vrglfbh_.arc
sys@MC> conn mctest3/*****
Connected.
步骤2:切换并归档日志
mctest3@MC> alter system archive log current;
步骤3:创建a表
mctest3@MC> create table a(id int,name varchar2(64))
Table created.
mctest3@MC> insert into a values('1','1')
mctest3@MC> update a set id='2',name='2' where id='1';
mctest3@MC> commit;
mctest3@MC> select * from a;
步骤4:再切换并归档日志
mctest3@MC> alter system archive log current;
root@mmloyal [/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07]# ll -rt
total 8316
-rw-r----- 1 oracle dba 3369984 Apr 7 00:52 o1_mf_1_522_5vrgf9dm_.arc
-rw-r----- 1 oracle dba 12288 Apr 7 00:54 o1_mf_1_523_5vrgkmnd_.arc
-rw-r----- 1 oracle dba 5120 Apr 7 00:54 o1_mf_1_524_5vrglfbh_.arc
-rw-r----- 1 oracle dba 5070848 Apr 7 03:29 o1_mf_1_525_5vrqo3vw_.arc
-rw-r----- 1 oracle dba 34304 Apr 7 03:33 o1_mf_1_526_5vrqwpz4_.arc
步骤5:创建字典文件
命令要写在一行,不能换行;再就是用绝对路径~
sys@MC> exec dbms_logmnr_d.build(dictionary_filename => 'mcdict.ora',dictionary_location => '/mc/oracle/logmnr');
LogMnr Dictionary Procedure started
LogMnr Dictionary File Opened
Procedure executed successfully - LogMnr Dictionary Created
PL/SQL procedure successfully completed.
步骤6:添加归档日志文件
sys@MC> exec dbms_logmnr.add_logfile(logfilename => '/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07/o1_mf_1_526_5vrqwpz4_.arc',options => dbms_logmnr.new);
PL/SQL procedure successfully completed.
步骤7:再加归档日志文件
sys@MC> exec dbms_logmnr.add_logfile(logfilename => '/opt/oracle/flash_recovery_area/MC/archivelog/2010_04_07/o1_mf_1_525_5vrqo3vw_.arc',options => dbms_logmnr.addfile);
PL/SQL procedure successfully completed.
步骤8:启动挖掘,并限定在某一时间范围内
sys@MC> exec dbms_logmnr.start_logmnr(dictfilename => '/mc/oracle/logmnr/mcdict.ora',starttime => to_date('07-Apr-2010 03:00:00', 'DD-MON-YYYY HH:MI:SS'),endtime => to_date('07-Apr-2010 03:55:00', 'DD-MON-YYYY HH:MI:SS'));
PL/SQL procedure successfully completed.
步骤9:查询该时间范围里面对表A做了哪些操作
注意了:查询v$logmnr_contents的内容只能在当前会话里面操作
sys@MC> select SCN,sql_redo,sql_undo from v$logmnr_contents where table_name = 'A';
SCN SQL_REDO SQL_UNDO
--------------- -------------------------------------------------- -----------------------------------
11699235 create table a(id int,name varchar2(64));
步骤10:统计上面时间范围内数据库对表的修改情况
sys@MC> COL SEG_OWNER FORMAT A10
sys@MC> COL SEG_NAME FORMAT A50
sys@MC> COL HITS FORMAT 999
sys@MC> SELECT SEG_OWNER,SEG_NAME,COUNT(*) AS HITS
FROM V$LOGMNR_CONTENTS WHERE SEG_NAME NOT LIKE '%$%'
GROUP BY SEG_OWNER,SEG_NAME;
SEG_OWNER SEG_NAME HITS
----------------- ----------------------------------------- ----
SYS SMON_SCN_TIME 58
MCTEST3 A 1
SYSMAN MGMT_STRING_METRIC_HISTORY 2
SYS LOGMNR_BUILDLOG 1
SYSMAN MGMT_METRICS_RAW,SYS_IOT_OVER_62005 262
SYSMAN MGMT_SYSTEM_PERFORMANCE_LOG 376
SYSMAN MGMT_CURRENT_METRICS,SYS_IOT_OVER_62008 7
步骤11:结束日志挖掘:
sys@MC> exec dbms_logmnr.end_logmnr;
PL/SQL procedure successfully completed.