Până la versiunea 12c atunci când era nevoie să se recupereze o tabelă dintr-un backup rman trebuia restaurată toată baza de date după care se exporta cu data pump tabela dorită iar în cele din urma tabela era importată în baza de date inițială. Întreg procesul fiind costisitor ca și timp iar efortul logistic nu este de neglijat, în general desfășurându-se pe un host separat. In ultima versiune a bazei de date mecanismul a fost destul de mult simplificat astfel încât nu este nevoie decât sa ne asigurăm că backup-ul este disponibil și putină răbdare după care Oracle va face totul în locul nostru…să vedem cum…
SQL> select count(*) from oe.INVENTORIES; COUNT(*) ---------- 1112 SQL> drop table oe.INVENTORIES purge; Table dropped.
Acum am creat un scenariu cu ajutorul căruia putem verifica dacă putem restaura tabela pierdută.
RMAN> list backup of database summary; List of Backups =============== Key TY LV S Device Type Completion Time #Pieces #Copies Compressed Tag ------- -- -- - ----------- --------------- ------- ------- ---------- --- 2 B F A DISK 17-SEP-16 1 1 NO TAG20160917T154202
[oracle@localhost oradata]$ mkdir test [oracle@localhost oradata]$ du -skh * 3.1G orcl 0 test [oracle@localhost oradata]$ df -h . Filesystem Size Used Avail Use% Mounted on /dev/mapper/ol-root 23G 17G 5.6G 76% /
M-am asigurat că am backup și suficient spațiu disponibil pentru a restaura backup-ul bazei de date în /opt/oracle/oradata/test
Să începem:
RMAN> recover table oe.INVENTORIES until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')" auxiliary destination '/opt/oracle/oradata/test'; Starting recover at 2016-09-17:16:23:26 using target database control file instead of recovery catalog current log archived allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=46 device type=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='bjEa' initialization parameters used for automatic instance: db_name=ORCL db_unique_name=bjEa_pitr_ORCL compatible=12.1.0.2.0 db_block_size=8192 db_files=200 diagnostic_dest=/opt/oracle _system_trig_enabled=FALSE sga_target=800M processes=200 db_create_file_dest=/opt/oracle/oradata/test log_archive_dest_1='location=/opt/oracle/oradata/test' #No auxiliary parameter file used starting up automatic instance ORCL Oracle instance started Total System Global Area 838860800 bytes Fixed Size 2929936 bytes Variable Size 230689520 bytes Database Buffers 599785472 bytes Redo Buffers 5455872 bytes Automatic instance created contents of Memory Script: { # set requested point in time set until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')"; # 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'; } executing Memory Script executing command: SET until clause Starting restore at 2016-09-17:16:23:35 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=21 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 /opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_ncsnf_TAG20160917T154202_cxtgkbfq_.b kp channel ORA_AUX_DISK_1: piece handle=/opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_ncsnf_TAG20160917T154202_cxtgkbfq_.bkp tag=TAG201 60917T154202 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01 output file name=/opt/oracle/oradata/test/ORCL/controlfile/o1_mf_cxtjyql9_.ctl Finished restore at 2016-09-17:16:23:36 sql statement: alter database mount clone database sql statement: alter system archive log current contents of Memory Script: { # set requested point in time set until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')"; # set destinations for recovery set and auxiliary set datafiles set newname for clone datafile 1 to new; set newname for clone datafile 4 to new; set newname for clone datafile 3 to new; set newname for clone tempfile 1 to new; # switch all tempfiles switch clone tempfile all; # restore the tablespaces in the recovery set and the auxiliary set restore clone datafile 1, 4, 3; switch clone datafile all; } executing Memory Script executing command: SET until clause executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME renamed tempfile 1 to /opt/oracle/oradata/test/ORCL/datafile/o1_mf_temp_%u_.tmp in control file Starting restore at 2016-09-17:16:23:41 using channel ORA_AUX_DISK_1 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 /opt/oracle/oradata/test/ORCL/datafile/o1_mf_system_%u_.dbf channel ORA_AUX_DISK_1: restoring datafile 00004 to /opt/oracle/oradata/test/ORCL/datafile/o1_mf_undotbs1_%u_.dbf channel ORA_AUX_DISK_1: restoring datafile 00003 to /opt/oracle/oradata/test/ORCL/datafile/o1_mf_sysaux_%u_.dbf channel ORA_AUX_DISK_1: reading from backup piece /opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_nnndf_TAG20160917T154202_cxtgjt9g_.b kp channel ORA_AUX_DISK_1: piece handle=/opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_nnndf_TAG20160917T154202_cxtgjt9g_.bkp tag=TAG201 60917T154202 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15 Finished restore at 2016-09-17:16:23:56 datafile 1 switched to datafile copy input datafile copy RECID=4 STAMP=922811036 file name=/opt/oracle/oradata/test/ORCL/datafile/o1_mf_system_cxtjyx46_.dbf datafile 4 switched to datafile copy input datafile copy RECID=5 STAMP=922811036 file name=/opt/oracle/oradata/test/ORCL/datafile/o1_mf_undotbs1_cxtjyx4q_.dbf datafile 3 switched to datafile copy input datafile copy RECID=6 STAMP=922811036 file name=/opt/oracle/oradata/test/ORCL/datafile/o1_mf_sysaux_cxtjyx4n_.dbf contents of Memory Script: { # set requested point in time set until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')"; # online the datafiles restored or switched sql clone "alter database datafile 1 online"; sql clone "alter database datafile 4 online"; sql clone "alter database datafile 3 online"; # recover and open database read only recover clone database tablespace "SYSTEM", "UNDOTBS1", "SYSAUX"; sql clone 'alter database open read only'; } executing Memory Script executing command: SET until clause sql statement: alter database datafile 1 online sql statement: alter database datafile 4 online sql statement: alter database datafile 3 online Starting recover at 2016-09-17:16:23:56 using channel ORA_AUX_DISK_1 starting media recovery archived log for thread 1 with sequence 15 is already on disk as file /opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_15_cxtgkckn_. arc archived log for thread 1 with sequence 16 is already on disk as file /opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_16_cxtjyg7f_. arc archived log file name=/opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_15_cxtgkckn_.arc thread=1 sequence=15 archived log file name=/opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_16_cxtjyg7f_.arc thread=1 sequence=16 media recovery complete, elapsed time: 00:00:01 Finished recover at 2016-09-17:16:23:57 sql statement: alter database open read only contents of Memory Script: { sql clone "create spfile from memory"; shutdown clone immediate; startup clone nomount; sql clone "alter system set control_files = ''/opt/oracle/oradata/test/ORCL/controlfile/o1_mf_cxtjyql9_.ctl'' comment= ''RMAN set'' scope=spfile"; shutdown clone immediate; startup clone nomount; # mount database sql clone 'alter database mount clone database'; } executing Memory Script sql statement: create spfile from memory database closed database dismounted Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 838860800 bytes Fixed Size 2929936 bytes Variable Size 230689520 bytes Database Buffers 599785472 bytes Redo Buffers 5455872 bytes sql statement: alter system set control_files = ''/opt/oracle/oradata/test/ORCL/controlfile/o1_mf_cxtjyql9_.ctl'' comment= ''RMAN set'' scope=spfile Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 838860800 bytes Fixed Size 2929936 bytes Variable Size 230689520 bytes Database Buffers 599785472 bytes Redo Buffers 5455872 bytes sql statement: alter database mount clone database contents of Memory Script: { # set requested point in time set until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')"; # set destinations for recovery set and auxiliary set datafiles set newname for datafile 5 to new; # restore the tablespaces in the recovery set and the auxiliary set restore clone datafile 5; switch clone datafile all; } executing Memory Script executing command: SET until clause executing command: SET NEWNAME Starting restore at 2016-09-17:16:24:39 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=21 device type=DISK 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 00005 to /opt/oracle/oradata/test/BJEA_PITR_ORCL/datafile/o1_mf_example_%u_.dbf channel ORA_AUX_DISK_1: reading from backup piece /opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_nnndf_TAG20160917T154202_cxtgjt9g_.bkp channel ORA_AUX_DISK_1: piece handle=/opt/oracle/fast_recovery_area/ORCL/backupset/2016_09_17/o1_mf_nnndf_TAG20160917T154202_cxtgjt9g_.bkp tag=TAG20160917T154202 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15 Finished restore at 2016-09-17:16:24:54 datafile 5 switched to datafile copy input datafile copy RECID=8 STAMP=922811094 file name=/opt/oracle/oradata/test/BJEA_PITR_ORCL/datafile/o1_mf_example_cxtk0qcg_.dbf contents of Memory Script: { # set requested point in time set until time "to_date('2016-09-17 16:03:00','yyyy-mm-dd hh24:mi:ss')"; # online the datafiles restored or switched sql clone "alter database datafile 5 online"; # recover and open resetlogs recover clone database tablespace "EXAMPLE", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog; alter clone database open resetlogs; } executing Memory Script executing command: SET until clause sql statement: alter database datafile 5 online Starting recover at 2016-09-17:16:24:54 using channel ORA_AUX_DISK_1 starting media recovery archived log for thread 1 with sequence 15 is already on disk as file /opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_15_cxtgkckn_.arc archived log for thread 1 with sequence 16 is already on disk as file /opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_16_cxtjyg7f_.arc archived log file name=/opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_15_cxtgkckn_.arc thread=1 sequence=15 archived log file name=/opt/oracle/fast_recovery_area/ORCL/archivelog/2016_09_17/o1_mf_1_16_cxtjyg7f_.arc thread=1 sequence=16 media recovery complete, elapsed time: 00:00:00 Finished recover at 2016-09-17:16:24:54 database opened contents of Memory Script: { # create directory for datapump import sql "create or replace directory TSPITR_DIROBJ_DPDIR as '' /opt/oracle/oradata/test''"; # create directory for datapump export sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as '' /opt/oracle/oradata/test''"; } executing Memory Script sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/opt/oracle/oradata/test'' sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/opt/oracle/oradata/test'' Performing export of tables... EXPDP> Starting "SYS"."TSPITR_EXP_bjEa_Fwds": EXPDP> Estimate in progress using BLOCKS method... EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA EXPDP> Total estimation using BLOCKS method: 64 KB EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE EXPDP> Processing object type TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT EXPDP> Processing object type TABLE_EXPORT/TABLE/COMMENT EXPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX EXPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT EXPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS EXPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER EXPDP> . . exported "OE"."INVENTORIES" 21.77 KB 1112 rows EXPDP> Master table "SYS"."TSPITR_EXP_bjEa_Fwds" successfully loaded/unloaded EXPDP> ****************************************************************************** EXPDP> Dump file set for SYS.TSPITR_EXP_bjEa_Fwds is: EXPDP> /opt/oracle/oradata/test/tspitr_bjEa_77335.dmp EXPDP> Job "SYS"."TSPITR_EXP_bjEa_Fwds" successfully completed at Sat Sep 17 16:25:34 2016 elapsed 0 00:00:18 Export completed contents of Memory Script: { # shutdown clone before import shutdown clone abort } executing Memory Script Oracle instance shut down Performing import of tables... IMPDP> Master table "SYS"."TSPITR_IMP_bjEa_kEax" successfully loaded/unloaded IMPDP> Starting "SYS"."TSPITR_IMP_bjEa_kEax": IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA IMPDP> . . imported "OE"."INVENTORIES" 21.77 KB 1112 rows IMPDP> Processing object type TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT IMPDP> Processing object type TABLE_EXPORT/TABLE/COMMENT IMPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX IMPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT IMPDP> Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS IMPDP> Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER IMPDP> Job "SYS"."TSPITR_IMP_bjEa_kEax" successfully completed at Sat Sep 17 16:25:53 2016 elapsed 0 00:00:14 Import completed Removing automatic instance Automatic instance removed auxiliary instance file /opt/oracle/oradata/test/ORCL/datafile/o1_mf_temp_cxtjzfg8_.tmp deleted auxiliary instance file /opt/oracle/oradata/test/BJEA_PITR_ORCL/onlinelog/o1_mf_3_cxtk175y_.log deleted auxiliary instance file /opt/oracle/oradata/test/BJEA_PITR_ORCL/onlinelog/o1_mf_2_cxtk171b_.log deleted auxiliary instance file /opt/oracle/oradata/test/BJEA_PITR_ORCL/onlinelog/o1_mf_1_cxtk16s8_.log deleted auxiliary instance file /opt/oracle/oradata/test/BJEA_PITR_ORCL/datafile/o1_mf_example_cxtk0qcg_.dbf deleted auxiliary instance file /opt/oracle/oradata/test/ORCL/datafile/o1_mf_sysaux_cxtjyx4n_.dbf deleted auxiliary instance file /opt/oracle/oradata/test/ORCL/datafile/o1_mf_undotbs1_cxtjyx4q_.dbf deleted auxiliary instance file /opt/oracle/oradata/test/ORCL/datafile/o1_mf_system_cxtjyx46_.dbf deleted auxiliary instance file /opt/oracle/oradata/test/ORCL/controlfile/o1_mf_cxtjyql9_.ctl deleted auxiliary instance file tspitr_bjEa_77335.dmp deleted Finished recover at 2016-09-17:16:25:54
SQL> select count(*) from oe.INVENTORIES; COUNT(*) ---------- 1112
Din output-ul restaurarii se vede destul de clar că rman-ul urmează exact aceeași procedura despre care vorbeam la începutul articolului cu mențiunea ca totul se întâmplă cu ajutorul unei singure comenzi
„recover tables oe.INVENTORIES until time „to_date(‘2016-09-17 16:03:00′,’yyyy-mm-dd hh24:mi:ss’)”
auxiliary destination ‘/opt/oracle/oradata/test’;”.
In funcție de situația în care vă aflați există posibilitatea de a restaura tabela cu altă denumire, de exemplu:
„recover tables oe.INVENTORIES until time „to_date(‘2016-09-17 16:03:00′,’yyyy-mm-dd hh24:mi:ss’)”
auxiliary destination ‘/opt/oracle/oradata/test’
remap table ‘OE’.’INVENTORIES’:’INVENTORIES_RECOVER’;”