天天看點

tspitr(tablespace point in time recovery)實驗

===========環境模拟=================

-----------模拟資料----------------

[email protected]>create tablespace test

  2  datafile '/u01/app/oracle/oradata/ORCL/test.dbf' size 5m;

Tablespace created.

[email protected]>

[email protected]>

[email protected]>create table test(x int)tablespace test;

Table created.

[email protected]>insert into test values(1);

1 row created.

[email protected]>;

  1* insert into test values(1)

[email protected]>insert into test values(2);

1 row created.

[email protected]>commit;

Commit complete.

[email protected]>alter system switch logfile;

System altered.

[email protected]>/

System altered.

[email protected]>/

System altered.

[email protected]>/

System altered.

[email protected]>insert into test values(3);

1 row created.

[email protected]>alter system switch logfile; 

System altered.

[email protected]>insert into test values(4);

1 row created.

[email protected]>commit;

Commit complete.

[email protected]>alter system switch logfile;

System altered.

[email protected]>insert into test values(5);

1 row created.

[email protected]>commit;

Commit complete.

[email protected]>alter system switch logfile;

System altered.

[email protected]>/

System altered.

[email protected]>/

System altered.

[email protected]>shutdown immediate;

-----------删除資料檔案------------

[[email protected] ORCL]$ ls

control01.ctl  example01.dbf  redo03.log    temp01.dbf     users01.dbf

control02.ctl  redo01.log     sysaux01.dbf  test.dbf

control03.ctl  redo02.log     system01.dbf  undotbs01.dbf

[[email protected] ORCL]$ mv test.dbf test.dbf.bak

-----------制造歸檔斷點-----------------

[[email protected] 2016_01_13]# mv o1_mf_1_10_c9cj7grz_.arc o1_mf_1_10_c9cj7grz_.arc.bak

[[email protected] 2016_01_13]# ls

o1_mf_1_10_c9cj7grz_.arc.bak  o1_mf_1_14_c9cj9zsv_.arc  o1_mf_1_6_c9cj5xdt_.arc

o1_mf_1_11_c9cj8lgw_.arc      o1_mf_1_3_c9cj24qn_.arc   o1_mf_1_7_c9cj5yj9_.arc

o1_mf_1_12_c9cj9msn_.arc      o1_mf_1_4_c9cj382m_.arc   o1_mf_1_8_c9cj63xy_.arc

o1_mf_1_13_c9cj9ssq_.arc      o1_mf_1_5_c9cj4xpn_.arc   o1_mf_1_9_c9cj676b_.arc

[[email protected] 2016_01_13]# ll

total 500

-rw-r----- 1 oracle oinstall   5120 Jan 13 11:13 o1_mf_1_10_c9cj7grz_.arc.bak

-rw-r----- 1 oracle oinstall   2048 Jan 13 11:14 o1_mf_1_11_c9cj8lgw_.arc

-rw-r----- 1 oracle oinstall  38400 Jan 13 11:14 o1_mf_1_12_c9cj9msn_.arc

-rw-r----- 1 oracle oinstall   1536 Jan 13 11:15 o1_mf_1_13_c9cj9ssq_.arc

-rw-r----- 1 oracle oinstall   6144 Jan 13 11:15 o1_mf_1_14_c9cj9zsv_.arc

-rw-r----- 1 oracle oinstall 406016 Jan 13 11:11 o1_mf_1_3_c9cj24qn_.arc

-rw-r----- 1 oracle oinstall   2560 Jan 13 11:11 o1_mf_1_4_c9cj382m_.arc

-rw-r----- 1 oracle oinstall   5120 Jan 13 11:12 o1_mf_1_5_c9cj4xpn_.arc

-rw-r----- 1 oracle oinstall   4608 Jan 13 11:13 o1_mf_1_6_c9cj5xdt_.arc

-rw-r----- 1 oracle oinstall   1024 Jan 13 11:13 o1_mf_1_7_c9cj5yj9_.arc

-rw-r----- 1 oracle oinstall   1536 Jan 13 11:13 o1_mf_1_8_c9cj63xy_.arc

-rw-r----- 1 oracle oinstall   1024 Jan 13 11:13 o1_mf_1_9_c9cj676b_.arc

[[email protected] 2016_01_13]# 

============恢複過程=====================

-----------打開資料庫-------------------

[email protected]>startup        

ORACLE instance started.

Total System Global Area  285212672 bytes

Fixed Size                  1218992 bytes

Variable Size              92276304 bytes

Database Buffers          188743680 bytes

Redo Buffers                2973696 bytes

Database mounted.

ORA-01157: cannot identify/lock data file 6 - see DBWR trace file

ORA-01110: data file 6: '/u01/app/oracle/oradata/ORCL/test.dbf'

[email protected]>alter database datafile 6 offline drop;

Database altered.

[email protected]>alter database open;

Database altered.

---------查詢需要恢複的表空間--------------

RMAN> report schema;

using target database control file instead of recovery catalog

Report of database schema

List of Permanent Datafiles

===========================

File Size(MB) Tablespace           RB segs Datafile Name

---- -------- -------------------- ------- ------------------------

1    480      SYSTEM               ***     /u01/app/oracle/oradata/ORCL/system01.dbf

2    30       UNDOTBS1             ***     /u01/app/oracle/oradata/ORCL/undotbs01.dbf

3    240      SYSAUX               ***     /u01/app/oracle/oradata/ORCL/sysaux01.dbf

4    5        USERS                ***     /u01/app/oracle/oradata/ORCL/users01.dbf

5    100      EXAMPLE              ***     /u01/app/oracle/oradata/ORCL/example01.dbf

6    0        TEST                 ***     /u01/app/oracle/oradata/ORCL/test.dbf

List of Temporary Files

=======================

File Size(MB) Tablespace           Maxsize(MB) Tempfile Name

---- -------- -------------------- ----------- --------------------

1    20       TEMP                 32767       /u01/app/oracle/oradata/ORCL/temp01.dbf

--------準備輔助資料庫路徑---------------

[[email protected] oracle]$ mkdir aux

[[email protected] oracle]$ cd aux/

[[email protected] aux]$ pwd

/u01/app/oracle/aux

--------恢複資料檔案至斷點--------------

RMAN> recover tablespace 'TEST' until logseq 9 auxiliary destination '/u01/app/oracle/aux';

Starting recover at 13-JAN-16

allocated channel: ORA_DISK_1

channel ORA_DISK_1: sid=148 devtype=DISK

RMAN-05026: WARNING: presuming following set of tablespaces applies to specified point in time

List of tablespaces expected to have UNDO segments

tablespace SYSTEM

tablespace UNDOTBS1

Creating automatic instance, with SID='brdd'

initialization parameters used for automatic instance:

db_name=ORCL

compatible=10.2.0.1.0

db_block_size=8192

db_files=200

db_unique_name=tspitr_ORCL_brdd

large_pool_size=1M

shared_pool_size=110M

#No auxiliary parameter file used

db_create_file_dest=/u01/app/oracle/aux

control_files=/u01/app/oracle/aux/cntrl_tspitr_ORCL_brdd.f

starting up automatic instance ORCL

Oracle instance started

Total System Global Area     201326592 bytes

Fixed Size                     1218508 bytes

Variable Size                146802740 bytes

Database Buffers              50331648 bytes

Redo Buffers                   2973696 bytes

Automatic instance created

contents of Memory Script:

{

# set the until clause

set until  logseq 9 thread 1;

# restore the controlfile

restore clone controlfile;

# mount the controlfile

sql clone 'alter database mount clone database';

# archive current online log for tspitr to a resent until time

sql 'alter system archive log current';

# avoid unnecessary autobackups for structural changes during TSPITR

sql 'begin dbms_backup_restore.AutoBackupFlag(FALSE); end;';

}

executing Memory Script

executing command: SET until clause

Starting restore at 13-JAN-16

allocated channel: ORA_AUX_DISK_1

channel ORA_AUX_DISK_1: sid=37 devtype=DISK

channel ORA_AUX_DISK_1: starting datafile backupset restore

channel ORA_AUX_DISK_1: restoring control file

channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/flash_recovery_area/ORCL/backupset/2016_01_13/o1_mf_ncsnf_TAG20160113T111138_c9cj4tcp_.bkp

channel ORA_AUX_DISK_1: restored backup piece 1

piece handle=/u01/app/oracle/flash_recovery_area/ORCL/backupset/2016_01_13/o1_mf_ncsnf_TAG20160113T111138_c9cj4tcp_.bkp tag=TAG20160113T111138

channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:02

output filename=/u01/app/oracle/aux/cntrl_tspitr_ORCL_brdd.f

Finished restore at 13-JAN-16

sql statement: alter database mount clone database

sql statement: alter system archive log current

sql statement: begin dbms_backup_restore.AutoBackupFlag(FALSE); end;

released channel: ORA_DISK_1

released channel: ORA_AUX_DISK_1

contents of Memory Script:

{

# generated tablespace point-in-time recovery script

# set the until clause

set until  logseq 9 thread 1;

plsql <<<-- tspitr_2

declare

  sqlstatement       varchar2(512);

  offline_not_needed exception;

  pragma exception_init(offline_not_needed, -01539);

begin

  sqlstatement := 'alter tablespace '||  'TEST' ||' offline for recover';

  krmicd.writeMsg(6162, sqlstatement);

  krmicd.execSql(sqlstatement);

exception

  when offline_not_needed then

    null;

end; >>>;

# set an omf destination filename for restore

set newname for clone datafile  1 to new;

# set an omf destination filename for restore

set newname for clone datafile  2 to new;

# set an omf destination tempfile

set newname for clone tempfile  1 to new;

# set a destination filename for restore

set newname for datafile  6 to 

 "/u01/app/oracle/oradata/ORCL/test.dbf";

# rename all tempfiles

switch clone tempfile all;

# restore the tablespaces in the recovery set plus the auxilliary tablespaces

restore clone datafile  1, 2, 6;

switch clone datafile all;

#online the datafiles restored or flipped

sql clone "alter database datafile  1 online";

#online the datafiles restored or flipped

sql clone "alter database datafile  2 online";

#online the datafiles restored or flipped

sql clone "alter database datafile  6 online";

# make the controlfile point at the restored datafiles, then recover them

recover clone database tablespace  "TEST", "SYSTEM", "UNDOTBS1" delete archivelog;

alter clone database open resetlogs;

# PLUG HERE the creation of a temporary tablespace if export fails due to lack

# of temporary space.

# For example in Unix these two lines would do that:

#sql clone "create tablespace aux_tspitr_tmp

#           datafile ''/tmp/aux_tspitr_tmp.dbf'' size 500K";

}

executing Memory Script

executing command: SET until clause

sql statement: alter tablespace TEST offline for recover

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

executing command: SET NEWNAME

renamed temporary file 1 to /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_temp_%u_.tmp in control file

Starting restore at 13-JAN-16

allocated channel: ORA_AUX_DISK_1

channel ORA_AUX_DISK_1: sid=39 devtype=DISK

channel ORA_AUX_DISK_1: starting datafile backupset restore

channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set

restoring datafile 00001 to /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_system_%u_.dbf

restoring datafile 00002 to /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_undotbs1_%u_.dbf

restoring datafile 00006 to /u01/app/oracle/oradata/ORCL/test.dbf

channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/flash_recovery_area/ORCL/backupset/2016_01_13/o1_mf_nnndf_TAG20160113T111138_c9cj3btp_.bkp

channel ORA_AUX_DISK_1: restored backup piece 1

piece handle=/u01/app/oracle/flash_recovery_area/ORCL/backupset/2016_01_13/o1_mf_nnndf_TAG20160113T111138_c9cj3btp_.bkp tag=TAG20160113T111138

channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:26

Finished restore at 13-JAN-16

datafile 1 switched to datafile copy

input datafile copy recid=5 stamp=901020119 filename=/u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_system_c9cjowoq_.dbf

datafile 2 switched to datafile copy

input datafile copy recid=6 stamp=901020119 filename=/u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_undotbs1_c9cjowqp_.dbf

sql statement: alter database datafile  1 online

sql statement: alter database datafile  2 online

sql statement: alter database datafile  6 online

Starting recover at 13-JAN-16

using channel ORA_AUX_DISK_1

starting media recovery

archive log thread 1 sequence 5 is already on disk as file /u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_5_c9cj4xpn_.arc

archive log thread 1 sequence 6 is already on disk as file /u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_6_c9cj5xdt_.arc

archive log thread 1 sequence 7 is already on disk as file /u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_7_c9cj5yj9_.arc

archive log thread 1 sequence 8 is already on disk as file /u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_8_c9cj63xy_.arc

archive log filename=/u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_5_c9cj4xpn_.arc thread=1 sequence=5

archive log filename=/u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_6_c9cj5xdt_.arc thread=1 sequence=6

archive log filename=/u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_7_c9cj5yj9_.arc thread=1 sequence=7

archive log filename=/u01/app/oracle/flash_recovery_area/ORCL/archivelog/2016_01_13/o1_mf_1_8_c9cj63xy_.arc thread=1 sequence=8

media recovery complete, elapsed time: 00:00:02

Finished recover at 13-JAN-16

database opened

contents of Memory Script:

{

# export the tablespaces in the recovery set

host 'exp userid =\"/@\(DESCRIPTION=\(ADDRESS=\(PROTOCOL=beq\)\(PROGRAM=/u01/app/oracle/product/10.2.0/bin/oracle\)\(ARGV0=oraclebrdd\)\(ARGS=^'\(DESCRIPTION=\(LOCAL=YES\)\(ADDRESS=\(PROTOCOL=beq\)\)\)^'\)\(ENVS=^'ORACLE_SID=brdd^'\)\)\(CONNECT_DATA=\(SID=brdd\)\)\) as sysdba\" point_in_time_recover=y tablespaces=

 TEST file=

tspitr_a.dmp';

# shutdown clone before import

shutdown clone immediate

# import the tablespaces in the recovery set

host 'imp userid =\"/@ as sysdba\" point_in_time_recover=y file=

tspitr_a.dmp';

# online/offline the tablespace imported

sql "alter tablespace  TEST online";

sql "alter tablespace  TEST offline";

# enable autobackups in case user does open resetlogs from RMAN after TSPITR

sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;';

}

executing Memory Script

Export: Release 10.2.0.1.0 - Production on Wed Jan 13 11:22:15 2016

Copyright (c) 1982, 2005, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production

With the Partitioning, OLAP and Data Mining options

Export done in US7ASCII character set and AL16UTF16 NCHAR character set

server uses UTF8 character set (possible charset conversion)

Note: table data (rows) will not be exported

About to export Tablespace Point-in-time Recovery objects...

For tablespace TEST ...

. exporting cluster definitions

. exporting table definitions

. . exporting table                           TEST

. exporting referential integrity constraints

. exporting triggers

. end point-in-time recovery

Export terminated successfully without warnings.

host command complete

database closed

database dismounted

Oracle instance shut down

Import: Release 10.2.0.1.0 - Production on Wed Jan 13 11:22:30 2016

Copyright (c) 1982, 2005, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production

With the Partitioning, OLAP and Data Mining options

Export file created by EXPORT:V10.02.01 via conventional path

About to import Tablespace Point-in-time Recovery objects...

import done in US7ASCII character set and AL16UTF16 NCHAR character set

import server uses UTF8 character set (possible charset conversion)

. importing SYS's objects into SYS

. . importing table                         "TEST"

Import terminated successfully without warnings.

host command complete

sql statement: alter tablespace  TEST online

sql statement: alter tablespace  TEST offline

sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end;

Removing automatic instance

Automatic instance removed

auxiliary instance file /u01/app/oracle/aux/cntrl_tspitr_ORCL_brdd.f deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_system_c9cjowoq_.dbf deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_undotbs1_c9cjowqp_.dbf deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/datafile/o1_mf_temp_c9cjq24h_.tmp deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/onlinelog/o1_mf_1_c9cjptyy_.log deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/onlinelog/o1_mf_2_c9cjpwoo_.log deleted

auxiliary instance file /u01/app/oracle/aux/TSPITR_ORCL_BRDD/onlinelog/o1_mf_3_c9cjpzph_.log deleted

Finished recover at 13-JAN-16

RMAN> 

------------表空間上線----------

[email protected]>alter database datafile 6 online;

Database altered.

[email protected]>desc dba_tablespaces;

 Name                                      Null?    Type

 ----------------------------------------- -------- ----------------------------

 TABLESPACE_NAME                           NOT NULL VARCHAR2(30)

 BLOCK_SIZE                                NOT NULL NUMBER

 INITIAL_EXTENT                                     NUMBER

 NEXT_EXTENT                                        NUMBER

 MIN_EXTENTS                               NOT NULL NUMBER

 MAX_EXTENTS                                        NUMBER

 PCT_INCREASE                                       NUMBER

 MIN_EXTLEN                                         NUMBER

 STATUS                                             VARCHAR2(9)

 CONTENTS                                           VARCHAR2(9)

 LOGGING                                            VARCHAR2(9)

 FORCE_LOGGING                                      VARCHAR2(3)

 EXTENT_MANAGEMENT                                  VARCHAR2(10)

 ALLOCATION_TYPE                                    VARCHAR2(9)

 PLUGGED_IN                                         VARCHAR2(3)

 SEGMENT_SPACE_MANAGEMENT                           VARCHAR2(6)

 DEF_TAB_COMPRESSION                                VARCHAR2(8)

 RETENTION                                          VARCHAR2(11)

 BIGFILE                                            VARCHAR2(3)

[email protected]>select TABLESPACE_NAME,STATUS from dba_tablespaces;

TABLESPACE_NAME                STATUS

------------------------------ ---------

SYSTEM                         ONLINE

UNDOTBS1                       ONLINE

SYSAUX                         ONLINE

TEMP                           ONLINE

USERS                          ONLINE

EXAMPLE                        ONLINE

TEST                           OFFLINE

7 rows selected.

[email protected]>alter tablespace test online;

Tablespace altered.

[email protected]>select * from test;

         X

----------

         1

         2