联系:手机/微信(+86 17813235971) QQ(107644445)
作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]
一.模拟数据文件删除
[oracle@node1 ~]$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.3.0 Production on Sat Dec 31 22:00:52 2011 Copyright (c) 1982, 2011, Oracle. All rights reserved. --数据库版本 Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production With the Partitioning, Oracle Label Security, OLAP, Data Mining, Oracle Database Vault and Real Application Testing options --所有数据文件 SQL> select name from v$datafile; NAME -------------------------------------------------------------------------------- /opt/oracle/oradata/ora11g/system01.dbf /opt/oracle/oradata/ora11g/sysaux01.dbf /opt/oracle/oradata/ora11g/undotbs01.dbf /opt/oracle/oradata/ora11g/users01.dbf /opt/oracle/oradata/ora11g/example01.dbf --删除example01.dbf数据文件 SQL> !rm /opt/oracle/oradata/ora11g/example01.dbf SQL> !ls -l /opt/oracle/oradata/ora11g/example01.dbf ls: /opt/oracle/oradata/ora11g/example01.dbf: 没有那个文件或目录 --因为数据文件被删除,创建表失败 SQL> create table t_xifenfei tablespace example 2 as select * from dba_tables; as select * from dba_tables * ERROR at line 2: ORA-01116: error in opening database file 5 ORA-01110: data file 5: '/opt/oracle/oradata/ora11g/example01.dbf' ORA-27041: unable to open file Linux-x86_64 Error: 2: No such file or directory Additional information: 3
二.找回数据文件
--查找dbw进程spid [oracle@node1 ~]$ ps -ef|grep dbw|grep -v grep oracle 18387 1 0 Dec22 ? 00:00:12 ora_dbw0_ora11g --查看该进程所有文件句柄 [oracle@node1 ~]$ ll /proc/18387/fd 总计 0 lr-x------ 1 oracle oinstall 64 12-31 22:03 0 -> /dev/null l-wx------ 1 oracle oinstall 64 12-31 22:03 1 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 10 -> /dev/zero lr-x------ 1 oracle oinstall 64 12-31 22:03 11 -> /dev/zero lr-x------ 1 oracle oinstall 64 12-31 22:03 12 -> /opt/oracle/product/11.2.0/db_1/rdbms/mesg/orazhs.msb lrwx------ 1 oracle oinstall 64 12-31 22:03 13 -> /opt/oracle/product/11.2.0/db_1/dbs/hc_ora11g.dat lr-x------ 1 oracle oinstall 64 12-31 22:03 14 -> /proc/18387/fd lr-x------ 1 oracle oinstall 64 12-31 22:03 15 -> /dev/zero lr-x------ 1 oracle oinstall 64 12-31 22:03 16 -> /opt/oracle/product/11.2.0/db_1/rdbms/mesg/oraus.msb lrwx------ 1 oracle oinstall 64 12-31 22:03 17 -> /opt/oracle/product/11.2.0/db_1/dbs/hc_ora11g.dat lrwx------ 1 oracle oinstall 64 12-31 22:03 18 -> /opt/oracle/product/11.2.0/db_1/dbs/lkORA11G lr-x------ 1 oracle oinstall 64 12-31 22:03 19 -> /opt/oracle/product/11.2.0/db_1/rdbms/mesg/orazhs.msb l-wx------ 1 oracle oinstall 64 12-31 22:03 2 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 20 -> /opt/oracle/product/11.2.0/db_1/rdbms/mesg/oraus.msb lrwx------ 1 oracle oinstall 64 12-31 22:03 21 -> socket:[441562] lrwx------ 1 oracle oinstall 64 12-31 22:03 256 -> /opt/oracle/oradata/ora11g/control01.ctl lrwx------ 1 oracle oinstall 64 12-31 22:03 257 -> /opt/oracle/oradata/ora11g/system01.dbf lrwx------ 1 oracle oinstall 64 12-31 22:03 258 -> /opt/oracle/oradata/ora11g/sysaux01.dbf lrwx------ 1 oracle oinstall 64 12-31 22:03 259 -> /opt/oracle/oradata/ora11g/undotbs01.dbf lrwx------ 1 oracle oinstall 64 12-31 22:03 260 -> /opt/oracle/oradata/ora11g/users01.dbf lrwx------ 1 oracle oinstall 64 12-31 22:03 261 -> /opt/oracle/oradata/ora11g/example01.dbf (deleted) lrwx------ 1 oracle oinstall 64 12-31 22:03 262 -> /opt/oracle/oradata/ora11g/temp01.dbf lr-x------ 1 oracle oinstall 64 12-31 22:03 3 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 4 -> /dev/null lrwx------ 1 oracle oinstall 64 12-31 22:03 5 -> /opt/oracle/product/11.2.0/db_1/dbs/hc_ora11g.dat lr-x------ 1 oracle oinstall 64 12-31 22:03 6 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 7 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 8 -> /dev/null lr-x------ 1 oracle oinstall 64 12-31 22:03 9 -> /dev/null --通过句柄恢复数据文件[被删除数据文件会被标示(deleted)] [oracle@node1 ~]$ cp /proc/18387/fd/261 /opt/oracle/oradata/ora11g/example01.dbf --确认该数据文件已经恢复成功 [oracle@node1 ~]$ ll /opt/oracle/oradata/ora11g/example01.dbf -rw-r----- 1 oracle oinstall 362422272 12-31 22:05 /opt/oracle/oradata/ora11g/example01.dbf
三.数据文件online
SQL> alter database datafile 5 offline; Database altered. SQL> recover datafile 5; Media recovery complete. SQL> alter database datafile 5 online; Database altered. SQL> create table t_xifenfei tablespace example 2 as select * from dba_tables; Table created.
四.补充说明
在意外使用os命令删除掉数据文件时,千万不要慌张重启数据库或者操作系统,可以通过dbwn进程相关句柄找回数据文件
如果是unix系统,可能需要先通过lsof找到句柄,然后通过cp实现
建议不要用 some chinese插件 会屏蔽很多国外的评论
数据文件被删除后,请不要offline,不然在句柄中就会被删除掉
兄弟,我也没有办法。前段时间不知道得罪谁了,国外的留言,一天几百条,我邮箱都爆掉了
你这个案例是在什么系统下?
这个案例适合什么系统?
Jerry,
这个测试是linux系统
lsof安装