기존에 Clone DB를 생성하여 무정지 복구를 Manual하게 수행하던 것을 RMAN이 자동으로 진행합니다.
1. 임시 경로로 필요한 파일 복원
2. 파일 경로 변경 후 삭제된 테이블 복구
3. 임시경로에서 복구된 테이블을 추출 (Exp 또는 Expdp 사용)
4. 추출된 데이터를 운영 서버로 입력 (Imp 또는 Impdp 사용)
5. 복구에 사용된 DB 종료 후 관련 파일 삭제
위의 과정을 자동으로 실행해주는 기능이 recover table입니다.
1. 특징
RMAN을 사용하면 하나 이상의 테이블 또는 테이블 파티션을 지정된 시점으로 복구할 수 있으며 나머지 데이터베이스 Object에는 영향을 미치지 않습니다. 이전에 생성된 RMAN백업을 사용하여 테이블 및 테이블 파티션을 지정된 특정 시점으로 복구할 수 있습니다.
- 적은 수의 테이블을 특정 시점으로 복구해야 할 경우
- 논리적으로 손상되었거나 삭제 및 제거된 테이블을 복구해야 할 경우
- 원하는 특정 시점이 사용 가능한 UNDO보다 오래되어 플래시백 테이블을 사용할 수 없는 경우
- DDL 조작 후 테이블 구조를 수정한 후 유실된 데이터를 복구하려고 하는 경우
2. 요구 사항
테이블 또는 테이블 파티션을 복구하려면 UNDO, SYSTEM, SYSAUX 및 테이블 또는 테이블 파티션이 포함된 테이블스페이스의 전체 백업이 필요합니다.
RMAN 백업에서 테이블 및 테이블 파티션을 복구하려면 다음 정보를 제공해야 합니다.
- 복구해야 하는 테이블 또는 테이블 파티션의 이름
- 테이블 또는 테이블 파티션을 복구해야 하는 시점
- 복구된 테이블 또는 테이블 파티션을 대상 데이터베이스로 가져올지 여부
RMAN은 이 정보를 사용하여 지정된 테이블 또는 테이블 파티션을 복구하는 프로세스를 자동화합니다. 복구프로세스의 일부로 RMAN은 테이블 또는 테이블 파티션을 지정된 시점으로 복구하는데 사용되는 Auxiliary 데이터베이스를 생성합니다. 복구된 테이블 또는 테이블 파티션의 이름을 바꾸거나 새 테이블스페이스로 매핑하거나 새 스키마에 매핑하는 경우에는 반드시 새 이름을 지정해야 합니다.
3. 제약 사항
- SYS 스키마에 속하는 테이블과 테이블 파티션은 복구할 수 없습니다.
- SYSTEM 및 SYSAUX테이블스페이스의 테이블 및 테이블 파티션을 복구할 수 없습니다.
- Stand by 데이터베이스의 테이블과 테이블 파티션을 복구할 수 없습니다.
- NOT NULL 제약조건이 있는 테이블은 REMAP 옵션으로 복구할 수 없습니다.
4. 시나리오
(1) 실습을 위한 테이블 생성
SQL> create table recovertest
2 (no number,
3 name varchar2(10));
Table created.
SQL> insert into recovertest
2 values (1,'kim');
1 row created.
SQL> insert into recovertest
values (2,'lee');
1 row created.
SQL> insert into recovertest
values (3,'park');
1 row created.
SQL> commit;
Commit complete.
SQL> select * from recovertest;
NO NAME
---------- ----------
1 kim
2 lee
3 park
(2) 백업본 생성 및 확인
RMAN> backup database format '/home/oracle/rman2/recover_%T_%U';
Starting backup at 19/12/06
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=40 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=/oradata/ORCL19C/system01.dbf
input datafile file number=00003 name=/oradata/ORCL19C/sysaux01.dbf
input datafile file number=00007 name=/oradata/ORCL19C/users01.dbf
input datafile file number=00004 name=/oradata/ORCL19C/undotbs01.dbf
input datafile file number=00005 name=/oradata/ORCL19C/test01.dbf
channel ORA_DISK_1: starting piece 1 at 19/12/06
channel ORA_DISK_1: finished piece 1 at 19/12/06
piece handle=/home/oracle/rman2/recover_20191206_20uiodps_1_1 tag=TAG20191206T133139 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:15
Finished backup at 19/12/06
Starting Control File and SPFILE Autobackup at 19/12/06
piece handle=/u01/app/oracle/product/19.5.0/db_1/dbs/c-1490444115-20191206-02 comment=NONE
Finished Control File and SPFILE Autobackup at 19/12/06
RMAN> list backup;
List of Backup Sets
===================
…생략
List of Datafiles in backup set 53
File LV Type Ckp SCN Ckp Time Abs Fuz SCN Sparse Name
---- -- ---- ---------- -------- ----------- ------ ----
1 Full 2875477 19/12/06 NO /oradata/ORCL19C/system01.dbf
3 Full 2875477 19/12/06 NO /oradata/ORCL19C/sysaux01.dbf
4 Full 2875477 19/12/06 NO /oradata/ORCL19C/undotbs01.dbf
5 Full 2875477 19/12/06 NO /oradata/ORCL19C/test01.dbf
7 Full 2875477 19/12/06 NO /oradata/ORCL19C/users01.dbf
Recovertest의 정보가 백업되어 있는 백업본을 확인할 수 있습니다.
(3) 장애 발생 - 잘못된 업데이트 후 commit 발생
SQL> select to_char(sysdate,'YYYY-MM-DD:HH24:MI:SS') FROM DUAL;
TO_CHAR(SYSDATE,'YY
-------------------
2019-12-06:13:51:00 <- 복구를 위한 시간 중요
SQL> select * from recovertest;
NO NAME
---------- ----------
1 kim
2 lee
3 park
SQL> update recovertest
2 set name='';
3 rows updated.
SQL> select * from recovertest;
NO NAME
---------- ----------
1
2
3
SQL> commit;
Commit complete.
(4) recover table 수행
RMAN> recover table TEST.RECOVERTEST until time "to_date('2019-12-06:13:51:00','yyyy/mm/dd hh24:mi:ss')" auxiliary destination '/home/oracle/temp' datapump destination '/home/oracle' dump file 'recovertest.dmp' notableimport;
Starting recover at 19/12/06
…생략
initialization parameters used for automatic instance:
db_name=ORCL19C
db_unique_name=jcuh_pitr_ORCL19C
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_system_trig_enabled=FALSE
sga_target=752M
processes=200
db_create_file_dest=/home/oracle/temp
log_archive_dest_1='location=/home/oracle/temp'
#No auxiliary parameter file used
starting up automatic instance ORCL19C
Oracle instance started
Total System Global Area 788525944 bytes
Fixed Size 8901496 bytes
Variable Size 213909504 bytes
Database Buffers 557842432 bytes
Redo Buffers 7872512 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-12-06:13:51: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 19/12/06
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=180 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 /u01/app/oracle/product/19.5.0/db_1/dbs/c-1490444115-20191206-02
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/product/19.5.0/db_1/dbs/c-1490444115-20191206-02 tag=TAG20191206T133255
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
output file name=/home/oracle/temp/ORCL19C/controlfile/o1_mf_gymsko13_.ctl
Finished restore at 19/12/06
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('2019-12-06:13:51: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 /home/oracle/temp/ORCL19C/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 19/12/06
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 /home/oracle/temp/ORCL19C/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /home/oracle/temp/ORCL19C/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /home/oracle/temp/ORCL19C/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/rman2/recover_20191206_20uiodps_1_1
channel ORA_AUX_DISK_1: piece handle=/home/oracle/rman2/recover_20191206_20uiodps_1_1 tag=TAG20191206T133139
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:35
Finished restore at 19/12/06
datafile 1 switched to datafile copy
input datafile copy RECID=17 STAMP=1026311150 file name=/home/oracle/temp/ORCL19C/datafile/o1_mf_system_gymskvnp_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=18 STAMP=1026311150 file name=/home/oracle/temp/ORCL19C/datafile/o1_mf_undotbs1_gymskvnz_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=19 STAMP=1026311150 file name=/home/oracle/temp/ORCL19C/datafile/o1_mf_sysaux_gymskvnv_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-12-06:13:51: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 19/12/06
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 1 is already on disk as file /u01/app/oracle/product/19.5.0/db_1/dbs/arch1_1_1026257931.dbf
archived log file name=/u01/app/oracle/product/19.5.0/db_1/dbs/arch1_1_1026257931.dbf thread=1 sequence=1
media recovery complete, elapsed time: 00:00:00
Finished recover at 19/12/06
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 =
''/home/oracle/temp/ORCL19C/controlfile/o1_mf_gymsko13_.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 788525944 bytes
Fixed Size 8901496 bytes
Variable Size 213909504 bytes
Database Buffers 557842432 bytes
Redo Buffers 7872512 bytes
sql statement: alter system set control_files = ''/home/oracle/temp/ORCL19C/controlfile/o1_mf_gymsko13_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 788525944 bytes
Fixed Size 8901496 bytes
Variable Size 213909504 bytes
Database Buffers 557842432 bytes
Redo Buffers 7872512 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-12-06:13:51:00','yyyy/mm/dd hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 7 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 7;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 19/12/06
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=180 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 00007 to /home/oracle/temp/JCUH_PITR_ORCL19C/datafile/o1_mf_users_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece /home/oracle/rman2/recover_20191206_20uiodps_1_1
channel ORA_AUX_DISK_1: piece handle=/home/oracle/rman2/recover_20191206_20uiodps_1_1 tag=TAG20191206T133139
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
Finished restore at 19/12/06
datafile 7 switched to datafile copy
input datafile copy RECID=21 STAMP=1026311237 file name=/home/oracle/temp/JCUH_PITR_ORCL19C/datafile/o1_mf_users_gymso6o3_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2019-12-06:13:51:00','yyyy/mm/dd hh24:mi:ss')";
# online the datafiles restored or switched
sql clone "alter database datafile 7 online";
# recover and open resetlogs
recover clone database tablespace "USERS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 7 online
Starting recover at 19/12/06
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 1 is already on disk as file /u01/app/oracle/product/19.5.0/db_1/dbs/arch1_1_1026257931.dbf
archived log file name=/u01/app/oracle/product/19.5.0/db_1/dbs/arch1_1_1026257931.dbf thread=1 sequence=1
media recovery complete, elapsed time: 00:00:00
Finished recover at 19/12/06
database opened
contents of Memory Script:
{
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/home/oracle''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/home/oracle''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle''
Performing export of tables... <- Clone DB에서 Tocsgtest정보 expdp
EXPDP> Starting "SYS"."TSPITR_EXP_jcuh_usap":
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> . . exported "TOCSGTEST"."RECOVERTEST" 5.515 KB 3 rows
EXPDP> Master table "SYS"."TSPITR_EXP_jcuh_usap" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_jcuh_usap is:
EXPDP> /home/oracle/recovertest.dmp
EXPDP> Job "SYS"."TSPITR_EXP_jcuh_usap" successfully completed at Fri Dec 6 14:28:15 2019 elapsed 0 00:00:30
Export completed
Not performing table import after point-in-time recovery
Removing automatic instance
shutting down automatic instance
Oracle instance shut down
Automatic instance removed <- Clone DB 삭제
auxiliary instance file /home/oracle/temp/ORCL19C/datafile/o1_mf_temp_gymsm0r5_.tmp deleted
auxiliary instance file /home/oracle/temp/JCUH_PITR_ORCL19C/onlinelog/o1_mf_3_gymsoq5p_.log deleted
auxiliary instance file /home/oracle/temp/JCUH_PITR_ORCL19C/onlinelog/o1_mf_2_gymsoq59_.log deleted
auxiliary instance file /home/oracle/temp/JCUH_PITR_ORCL19C/onlinelog/o1_mf_1_gymsoq4j_.log deleted
auxiliary instance file /home/oracle/temp/JCUH_PITR_ORCL19C/datafile/o1_mf_users_gymso6o3_.dbf deleted
auxiliary instance file /home/oracle/temp/ORCL19C/datafile/o1_mf_sysaux_gymskvnv_.dbf deleted
auxiliary instance file /home/oracle/temp/ORCL19C/datafile/o1_mf_undotbs1_gymskvnz_.dbf deleted
auxiliary instance file /home/oracle/temp/ORCL19C/datafile/o1_mf_system_gymskvnp_.dbf deleted
auxiliary instance file /home/oracle/temp/ORCL19C/controlfile/o1_mf_gymsko13_.ctl deleted
Finished recover at 19/12/06
(5) impdp를 위한 directory 생성
SQL> create directory dump_dir as '/home/oracle';
Directory created.
SQL> grant read,write on directory dump_dir to system;
Grant succeeded.
(6) impdp실행 및 Table rename으로 복구
$ impdp system/oracle dumpfile=dump_dir:recovertest.dmp remap_schema=test:test2;
<- test에는 recovertest 테이블이 있으므로 remap_schema로 test2스키마에 생성한다
Import: Release 19.0.0.0.0 - Production on Fri Dec 6 14:33:10 2019
Version 19.5.0.0.0
Copyright (c) 1982, 2019, Oracle and/or its affiliates. All rights reserved.
Connected to: Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Master table "SYSTEM"."SYS_IMPORT_FULL_01" successfully loaded/unloaded
Starting "SYSTEM"."SYS_IMPORT_FULL_01": system/******** dumpfile=dump_dir:recovertest.dmp remap_schema=test:test2
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "TOCSG"."RECOVERTEST" 5.515 KB 3 rows
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
Job "SYSTEM"."SYS_IMPORT_FULL_01" successfully completed at Fri Dec 6 14:33:48 2019 elapsed 0 00:00:30
SQL> create table test.recovertest2
2 as select * from test2.recovertest;
Table created.
SQL> conn test/test
Connected.
SQL> drop table recovertest purge;
Table dropped.
SQL> alter table recovertest2 rename to recovertest;
Table altered.
SQL> select * from recovertest;
NO NAME
---------- ----------
1 kim
2 lee
3 park
'Oracle > RMAN' 카테고리의 다른 글
[RMAN] recover table 테스트 시나리오 (0) | 2022.07.01 |
---|---|
RMAN을 사용하여 Clone DB 생성 (0) | 2019.12.23 |
[RMAN]Database 사전 예방 점검 기능 (0) | 2019.12.21 |
[RMAN] Data Recovery Adivisor (0) | 2019.12.20 |
[RMAN] 전체 DATABASE(DATAFILE,CONTROLFILE,REDOLOG등)이 삭제 되었을때 복구 (0) | 2019.12.19 |
댓글