Pular para o conteúdo

TSPITR – Tablespace Point in Time Recovery

TSPITR – Tablespace Point in Time Recovery

Este é um dos Labs executados pelos alunos da Nerv no Treinamento Oracle Backup & Recovery.

No Oracle, é possível voltar apenas uma Tablespace em um determinado ponto no tempo.

No 11gR2 esta operação está totalmente automatizada. Este fantástico recurso é, na verdade, uma complexa utilização de outros recursos do Oracle. Por baixo dos panos, o TSPITR cria uma nova Instance (no diretório indicado no comando de RECOVER), recupera nelas apenas a SYSTEM, SYSAUX, mais a Tablespace de UNDO e só então, a Tablespace desejada, a partir de um Backup já existente. Em seguida, esta Tablespace da nova Instance tem seus metadados exportados, e então importados na Instance original. Ou seja, dava para fazer tudo manualmente, mas daria muito mais trabalho.

Repare que ao término da operação, a Tablespace é deixada em OFFLINE. Talvez isso seja intencional, pois provavelmente o DBA irá conferir os dados antes de liberar para a utilização pelos clientes.

[oracle@OBR ~]$ sqlplus SCOTT/TIGER
 SQL*Plus: Release 11.2.0.2.0 Production on Sun Jan 16 16:31:23 2011
 Copyright (c) 1982, 2010, Oracle.  All rights reserved.
 Connected to:
 Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production
 With the Partitioning, Oracle Label Security, OLAP, Data Mining,
 Oracle Database Vault and Real Application Testing options
 SQL> DROP TABLE T;
 Table dropped.
 SQL> EXIT
 Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production
 With the Partitioning, Oracle Label Security, OLAP, Data Mining,
 Oracle Database Vault and Real Application Testing options
 [oracle@OBR ~]$ mkdir /home/oracle/auxiliary
 [oracle@OBR ~]$ rman CATALOG=USER_CATALOGO/USER_CATALOGO@CATALOGO TARGET /
 Recovery Manager: Release 11.2.0.2.0 - Production on Sun Jan 16 16:32:14 2011
 Copyright (c) 1982, 2009, Oracle and/or its affiliates.  All rights reserved.
 connected to target database: ORCL (DBID=1267239156)
 connected to recovery catalog database
 RMAN> RECOVER TABLESPACE USUARIOS UNTIL SEQUENCE 83 AUXILIARY DESTINATION '/home/oracle/auxiliary/';
 Starting recover at 16-JAN-11
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=37 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=1 device type=DISK
 Creating automatic instance, with SID='lssm'
 initialization parameters used for automatic instance:
 db_name=ORCL
 db_unique_name=lssm_tspitr_ORCL
 compatible=11.2.0.0.0
 db_block_size=8192
 db_files=200
 sga_target=280M
 processes=50
 db_create_file_dest=/home/oracle/auxiliary/
 log_archive_dest_1='location=/home/oracle/auxiliary/'
 #No auxiliary parameter file used
 starting up automatic instance ORCL
 Oracle instance started
 Total System Global Area     292933632 bytes
 Fixed Size                     1343748 bytes
 Variable Size                100667132 bytes
 Database Buffers             184549376 bytes
 Redo Buffers                   6373376 bytes
 Automatic instance created
 Running TRANSPORT_SET_CHECK on recovery set tablespaces
 TRANSPORT_SET_CHECK completed successfully
 contents of Memory Script:
 {
 # set requested point in time
 set until  logseq 83 thread 1;
 # restore the controlfile
 restore clone controlfile;
 # mount the controlfile
 sql clone 'alter database mount clone database';
 # archive current online log
 sql 'alter system archive log current';
 # avoid unnecessary autobackups for structural changes during TSPITR
 sql 'begin dbms_backup_restore.AutoBackupFlag(FALSE); end;';
 # resync catalog
 resync catalog;
 }
 executing Memory Script
 executing command: SET until clause
 Starting restore at 16-JAN-11
 allocated channel: ORA_AUX_DISK_1
 channel ORA_AUX_DISK_1: SID=21 device type=DISK
 allocated channel: ORA_AUX_DISK_2
 channel ORA_AUX_DISK_2: SID=18 device type=DISK
 channel ORA_AUX_DISK_1: starting datafile backup set restore
 channel ORA_AUX_DISK_1: restoring control file
 channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/c-1267239156-20110116-01
 channel ORA_AUX_DISK_1: piece handle=/home/oracle/c-1267239156-20110116-01 tag=TAG20110116T112118
 channel ORA_AUX_DISK_1: restored backup piece 1
 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
 output file name=/home/oracle/auxiliary/ORCL/controlfile/o1_mf_6m6gkby9_.ctl
 Finished restore at 16-JAN-11
 sql statement: alter database mount clone database
 sql statement: alter system archive log current
 sql statement: begin dbms_backup_restore.AutoBackupFlag(FALSE); end;
 starting full resync of recovery catalog
 full resync complete
 contents of Memory Script:
 {
 # set requested point in time
 set until  logseq 83 thread 1;
 plsql <<<-- tspitr_2 declare   sqlstatement       varchar2(512);   offline_not_needed exception;   pragma exception_init(offline_not_needed, -01539); begin   sqlstatement := 'alter tablespace '||  'USUARIOS' ||' offline immediate';   krmicd.writeMsg(6162, sqlstatement);   krmicd.execSql(sqlstatement); exception   when offline_not_needed then     null; end; >>>;
 # set destinations for recovery set and auxiliary set datafiles
 set newname for clone datafile  1 to new;
 set newname for clone datafile  3 to new;
 set newname for clone datafile  2 to new;
 set newname for clone tempfile  1 to new;
 set newname for datafile  10 to
 "/u01/app/oracle/oradata/ORCL/usuarios01.dbf";
 # switch all tempfiles
 switch clone tempfile all;
 # restore the tablespaces in the recovery set and the auxiliary set
 restore clone datafile  1, 3, 2, 10;
 switch clone datafile all;
 }
 executing Memory Script
 executing command: SET until clause
 sql statement: alter tablespace USUARIOS offline immediate
 executing command: SET NEWNAME
 executing command: SET NEWNAME
 executing command: SET NEWNAME
 executing command: SET NEWNAME
 executing command: SET NEWNAME
 renamed tempfile 1 to /home/oracle/auxiliary/ORCL/datafile/o1_mf_temp_%u_.tmp in control file
 Starting restore at 16-JAN-11
 using channel ORA_AUX_DISK_1
 using channel ORA_AUX_DISK_2
 channel ORA_AUX_DISK_1: starting datafile backup set restore
 channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
 channel ORA_AUX_DISK_1: restoring datafile 00001 to /home/oracle/auxiliary/ORCL/datafile/o1_mf_system_%u_.dbf
 channel ORA_AUX_DISK_1: restoring datafile 00003 to /home/oracle/auxiliary/ORCL/datafile/o1_mf_undotbs1_%u_.dbf
 channel ORA_AUX_DISK_1: restoring datafile 00010 to /u01/app/oracle/oradata/ORCL/usuarios01.dbf
 channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/ORCL_20110116_182_1.bkp
 channel ORA_AUX_DISK_2: starting datafile backup set restore
 channel ORA_AUX_DISK_2: specifying datafile(s) to restore from backup set
 channel ORA_AUX_DISK_2: restoring datafile 00002 to /home/oracle/auxiliary/ORCL/datafile/o1_mf_sysaux_%u_.dbf
 channel ORA_AUX_DISK_2: reading from backup piece /home/oracle/ORCL_20110116_181_1.bkp
 channel ORA_AUX_DISK_2: piece handle=/home/oracle/ORCL_20110116_181_1.bkp tag=TAG20110116T105556
 channel ORA_AUX_DISK_2: restored backup piece 1
 channel ORA_AUX_DISK_2: restore complete, elapsed time: 00:03:41
 channel ORA_AUX_DISK_1: piece handle=/home/oracle/ORCL_20110116_182_1.bkp tag=TAG20110116T105556
 channel ORA_AUX_DISK_1: restored backup piece 1
 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:03:51
 Finished restore at 16-JAN-11
 datafile 1 switched to datafile copy
 input datafile copy RECID=27 STAMP=740594308 file name=/home/oracle/auxiliary/ORCL/datafile/o1_mf_system_6m6gkyj2_.dbf
 datafile 3 switched to datafile copy
 input datafile copy RECID=28 STAMP=740594308 file name=/home/oracle/auxiliary/ORCL/datafile/o1_mf_undotbs1_6m6gkz5j_.dbf
 datafile 2 switched to datafile copy
 input datafile copy RECID=29 STAMP=740594308 file name=/home/oracle/auxiliary/ORCL/datafile/o1_mf_sysaux_6m6gky8n_.dbf
 contents of Memory Script:
 {
 # set requested point in time
 set until  logseq 83 thread 1;
 # online the datafiles restored or switched
 sql clone "alter database datafile  1 online";
 sql clone "alter database datafile  3 online";
 sql clone "alter database datafile  2 online";
 sql clone "alter database datafile  10 online";
 # recover and open resetlogs
 recover clone database tablespace  "USUARIOS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
 alter clone database open resetlogs;
 }
 executing Memory Script
 executing command: SET until clause
 sql statement: alter database datafile  1 online
 sql statement: alter database datafile  3 online
 sql statement: alter database datafile  2 online
 sql statement: alter database datafile  10 online
 Starting recover at 16-JAN-11
 using channel ORA_AUX_DISK_1
 using channel ORA_AUX_DISK_2
 starting media recovery
 archived log for thread 1 with sequence 80 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_80_6m5wdfmw_.arc
 archived log for thread 1 with sequence 81 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_81_6m5wfgpb_.arc
 archived log for thread 1 with sequence 82 is already on disk as file /u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_82_6m5wfoqc_.arc
 channel ORA_AUX_DISK_1: starting archived log restore to default destination
 channel ORA_AUX_DISK_1: restoring archived log
 archived log thread=1 sequence=79
 channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/ORCL_20110116_185_1.bkp
 channel ORA_AUX_DISK_1: piece handle=/home/oracle/ORCL_20110116_185_1.bkp tag=TAG20110116T112106
 channel ORA_AUX_DISK_1: restored backup piece 1
 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
 archived log file name=/home/oracle/auxiliary/1_79_739458432.dbf thread=1 sequence=79
 channel clone_default: deleting archived log(s)
 archived log file name=/home/oracle/auxiliary/1_79_739458432.dbf RECID=102 STAMP=740594316
 archived log file name=/u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_80_6m5wdfmw_.arc thread=1 sequence=80
 archived log file name=/u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_81_6m5wfgpb_.arc thread=1 sequence=81
 archived log file name=/u01/app/oracle/fast_recovery_area/ORCL/archivelog/2011_01_16/o1_mf_1_82_6m5wfoqc_.arc thread=1 sequence=82
 media recovery complete, elapsed time: 00:00:01
 Finished recover at 16-JAN-11
 database opened
 contents of Memory Script:
 {
 # make read only the tablespace that will be exported
 sql clone 'alter tablespace  USUARIOS read only';
 # create directory for datapump import
 sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
 /home/oracle/auxiliary/''";
 # create directory for datapump export
 sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
 /home/oracle/auxiliary/''";
 }
 executing Memory Script
 sql statement: alter tablespace  USUARIOS read only
 sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/auxiliary/''
 sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/auxiliary/''
 Performing export of metadata...
 EXPDP> Starting "SYS"."TSPITR_EXP_lssm":
 EXPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
 EXPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE
 EXPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
 EXPDP> Master table "SYS"."TSPITR_EXP_lssm" successfully loaded/unloaded
 EXPDP> ******************************************************************************
 EXPDP> Dump file set for SYS.TSPITR_EXP_lssm is:
 EXPDP>   /home/oracle/auxiliary/tspitr_lssm_42593.dmp
 EXPDP> ******************************************************************************
 EXPDP> Datafiles required for transportable tablespace USUARIOS:
 EXPDP>   /u01/app/oracle/oradata/ORCL/usuarios01.dbf
 EXPDP> Job "SYS"."TSPITR_EXP_lssm" successfully completed at 16:44:14
 Export completed
 contents of Memory Script:
 {
 # shutdown clone before import
 shutdown clone immediate
 # drop target tablespaces before importing them back
 sql 'drop tablespace  USUARIOS including contents keep datafiles';
 }
 executing Memory Script
 database closed
 database dismounted
 Oracle instance shut down
 sql statement: drop tablespace  USUARIOS including contents keep datafiles
 Performing import of metadata...
 IMPDP> Master table "SYS"."TSPITR_IMP_lssm" successfully loaded/unloaded
 IMPDP> Starting "SYS"."TSPITR_IMP_lssm":
 IMPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
 IMPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE
 IMPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
 IMPDP> Job "SYS"."TSPITR_IMP_lssm" successfully completed at 16:45:31
 Import completed
 contents of Memory Script:
 {
 # make read write and offline the imported tablespaces
 sql 'alter tablespace  USUARIOS read write';
 sql 'alter tablespace  USUARIOS offline';
 # enable autobackups after TSPITR is finished
 sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;';
 # resync catalog
 resync catalog;
 }
 executing Memory Script
 sql statement: alter tablespace  USUARIOS read write
 sql statement: alter tablespace  USUARIOS offline
 sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end;
 starting full resync of recovery catalog
 full resync complete
 Removing automatic instance
 Automatic instance removed
 auxiliary instance file /home/oracle/auxiliary/ORCL/datafile/o1_mf_temp_6m6gsrvx_.tmp deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/onlinelog/o1_mf_3_6m6gsmq5_.log deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/onlinelog/o1_mf_2_6m6gskmr_.log deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/onlinelog/o1_mf_1_6m6gshdw_.log deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/datafile/o1_mf_sysaux_6m6gky8n_.dbf deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/datafile/o1_mf_undotbs1_6m6gkz5j_.dbf deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/datafile/o1_mf_system_6m6gkyj2_.dbf deleted
 auxiliary instance file /home/oracle/auxiliary/ORCL/controlfile/o1_mf_6m6gkby9_.ctl deleted
 Finished recover at 16-JAN-11
 RMAN> EXIT
 Recovery Manager complete.
 [oracle@OBR ~]$ sqlplus SCOTT/TIGER
 SQL*Plus: Release 11.2.0.2.0 Production on Sun Jan 16 16:46:26 2011
 Copyright (c) 1982, 2010, Oracle.  All rights reserved.
 Connected to:
 Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production
 With the Partitioning, Oracle Label Security, OLAP, Data Mining,
 Oracle Database Vault and Real Application Testing options
 SQL> DESC T;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 OBJECT_NAME                                        VARCHAR2(128)
 SUBOBJECT_NAME                                     VARCHAR2(30)
 OBJECT_ID                                          NUMBER
 DATA_OBJECT_ID                                     NUMBER
 OBJECT_TYPE                                        VARCHAR2(19)
 CREATED                                            DATE
 LAST_DDL_TIME                                      DATE
 TIMESTAMP                                          VARCHAR2(19)
 STATUS                                             VARCHAR2(7)
 TEMPORARY                                          VARCHAR2(1)
 GENERATED                                          VARCHAR2(1)
 SECONDARY                                          VARCHAR2(1)
 NAMESPACE                                          NUMBER
 EDITION_NAME                                       VARCHAR2(30)
 SQL> SELECT COUNT(*) FROM T;
 SELECT COUNT(*) FROM T
 *
 ERROR at line 1:
 ORA-00376: file 10 cannot be read at this time
 ORA-01110: data file 10: '/u01/app/oracle/oradata/ORCL/usuarios01.dbf'
 SQL> CONN / AS SYSDBA
 Connected.
 SQL> ALTER TABLESPACE USUARIOS ONLINE;
 Tablespace altered.
 SQL> CONN SCOTT/TIGER
 Connected.
 SQL> SELECT COUNT(*) FROM T;
 COUNT(*)
 ----------
 7
 SQL>

Quão útil foi este post ?

Clique em uma estrela para classificar o post

nota média 4.9 / 5. Contagem de votos: 33

Sem votos ! Seja o primeiro a classificar !

Deixe um comentário

O seu endereço de e-mail não será publicado. Campos obrigatórios são marcados com *

plugins premium WordPress