내맘대로긍정이 알려주는
Oracle 23ai 신기능
무료 세미나 발표자료
OS환경 : Oracle Linux 6.8 (64bit)
DB 환경 : Oracle Database 11.2.0.4 ASM RAC to FS SINGLE
방법 : RMAN을 이용한 RAC db(asm) to SINGLE db(filesystem) 복구 테스트
개요
rac db(asm)에서 특정시점의 데이터를 single db(filesystem)로 복구하는 내용
rac를 single db로 변경하는 내용
asm을 filesystem으로 변경하는 내용
rman을 이용해 데이터를 복구하는 내용이 포함됨
source db : RAC(asm)
target db(clone) : SINGLE(filesystem)
시나리오
source db rac 확인
1 2 3 4 5 6 7 8 | SQL> select instance_name , version, status from gv$instance; INSTANCE_NAME VERSION STATUS ---------------- ----------------- ------------ racdb1 11.2.0.4.0 OPEN racdb2 11.2.0.4.0 OPEN 2 rows selected. |
아카이브 모드 확인
1 2 3 4 5 6 7 | SQL> archive log list Database log mode Archive Mode Automatic archival Enabled Archive destination /home/oracle/arch Oldest online log sequence 14 Next log sequence to archive 15 Current log sequence 15 |
기존 테이블 스페이스 위치 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 | SQL> col file_name for a70 select tablespace_name, file_name from dba_data_files TABLESPACE_NAME FILE_NAME ------------------------------ ---------------------------------------------------------------------- SYSTEM +ORADATA/racdb/datafile/system.259.970626167 SYSAUX +ORADATA/racdb/datafile/sysaux.260.970626173 UNDOTBS1 +ORADATA/racdb/datafile/undotbs1.261.970626177 UNDOTBS2 +ORADATA/racdb/datafile/undotbs2.263.970626185 USERS +ORADATA/racdb/datafile/users.264.970626185 USERS +ORADATA/racdb/datafile/users.268.970884085 USERS +ORADATA/racdb/datafile/users.269.970884253 |
ASM 사용중
테이블 스페이스 생성 및 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | SQL> create tablespace bokgu datafile size 1g; Tablespace created. SQL> select tablespace_name, file_name from dba_data_files; TABLESPACE_NAME FILE_NAME ------------------------------ ---------------------------------------------------------------------- SYSTEM +ORADATA/racdb/datafile/system.259.970626167 SYSAUX +ORADATA/racdb/datafile/sysaux.260.970626173 UNDOTBS1 +ORADATA/racdb/datafile/undotbs1.261.970626177 UNDOTBS2 +ORADATA/racdb/datafile/undotbs2.263.970626185 USERS +ORADATA/racdb/datafile/users.264.970626185 USERS +ORADATA/racdb/datafile/users.268.970884085 USERS +ORADATA/racdb/datafile/users.269.970884253 BOKGU +ORADATA/racdb/datafile/bokgu.270.1033003033 |
유저 생성 및 권한부여
1 2 3 4 5 6 7 | SQL> create user bokgu_user identified by bokgu_user account unlock default tablespace bokgu quota unlimited on bokgu; User created. SQL> grant resource, connect to bokgu_user; User created. |
데이터 생성
1 2 3 4 5 6 7 8 9 10 11 12 13 | SQL> conn bokgu_user/bokgu_user; SQL> create table bokgu_table (c1 number, c2 number); SQL> begin for i in 1..10000 loop insert into bokgu_table values (i, i+i); end loop; end; / commit; |
데이터 건수 확인
1 2 3 4 5 | SQL> select count(*) from bokgu_table; COUNT(*) ---------- 10000 |
데이터가 해당 tablespace 에 잘 들어갔는지 확인
1 2 3 4 5 6 7 8 9 10 11 12 | SQL> conn / as sysdba col owner for a20 col segment_name for a20 col tablespace_name for a10 select owner, tablespace_name, segment_name, segment_type from dba_segments where owner ='BOKGU_USER'; OWNER TABLESPACE SEGMENT_NAME SEGMENT_TYPE -------------------- ---------- -------------------- ------------------ BOKGU_USER BOKGU BOKGU_TABLE TABLE |
현재 시간 확인
1 2 3 4 5 | SQL> select to_char(sysdate,'YYYY-MM-DD:HH24:MI:SS') dt from dual; DT ------------------- 2020-02-22:01:25:36 |
rman 사전 설정
백업 경로 지정
1 2 3 4 5 6 | $ mkdir -p /home/oracle/rman/ $ rman target / RMAN> configure channel device type disk format '/home/oracle/rman/db_%U_%T'; new RMAN configuration parameters: CONFIGURE CHANNEL DEVICE TYPE DISK FORMAT '/home/oracle/rman/db_%U_%T'; new RMAN configuration parameters are successfully stored |
컨트롤파일 자동 백업 옵션 및 경로 지정
1 2 3 4 5 6 7 8 9 | RMAN> CONFIGURE CONTROLFILE AUTOBACKUP ON; new RMAN configuration parameters: CONFIGURE CONTROLFILE AUTOBACKUP ON; new RMAN configuration parameters are successfully stored RMAN> CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '/home/oracle/rman/db_control_%F'; new RMAN configuration parameters: CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '/home/oracle/rman/db_control_%F'; new RMAN configuration parameters are successfully stored |
rman 설정 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | RMAN> show all; using target database control file instead of recovery catalog RMAN configuration parameters for database with db_unique_name RACDB are: CONFIGURE RETENTION POLICY TO REDUNDANCY 1; # default CONFIGURE BACKUP OPTIMIZATION OFF; # default CONFIGURE DEFAULT DEVICE TYPE TO DISK; # default CONFIGURE CONTROLFILE AUTOBACKUP ON; CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '/home/oracle/rman/db_control_%F'; CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET; # default CONFIGURE DATAFILE BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default CONFIGURE ARCHIVELOG BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default CONFIGURE CHANNEL DEVICE TYPE DISK FORMAT '/home/oracle/rman/db_%U_%T'; CONFIGURE MAXSETSIZE TO UNLIMITED; # default CONFIGURE ENCRYPTION FOR DATABASE OFF; # default CONFIGURE ENCRYPTION ALGORITHM 'AES128'; # default CONFIGURE COMPRESSION ALGORITHM 'BASIC' AS OF RELEASE 'DEFAULT' OPTIMIZE FOR LOAD TRUE ; # default CONFIGURE ARCHIVELOG DELETION POLICY TO NONE; # default CONFIGURE SNAPSHOT CONTROLFILE NAME TO '/app/oracle/product/11.2.0/db_1/dbs/snapcf_racdb.f'; # default |
백업 실행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | RMAN> backup database; Starting backup at 22-FEB-20 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=52 instance=racdb1 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=00008 name=+ORADATA/racdb/datafile/bokgu.270.1033003033 input datafile file number=00001 name=+ORADATA/racdb/datafile/system.259.970626167 input datafile file number=00002 name=+ORADATA/racdb/datafile/sysaux.260.970626173 input datafile file number=00003 name=+ORADATA/racdb/datafile/undotbs1.261.970626177 input datafile file number=00004 name=+ORADATA/racdb/datafile/undotbs2.263.970626185 input datafile file number=00006 name=+ORADATA/racdb/datafile/users.268.970884085 input datafile file number=00007 name=+ORADATA/racdb/datafile/users.269.970884253 input datafile file number=00005 name=+ORADATA/racdb/datafile/users.264.970626185 channel ORA_DISK_1: starting piece 1 at 22-FEB-20 channel ORA_DISK_1: finished piece 1 at 22-FEB-20 piece handle=/home/oracle/rman/db_01up4p9p_1_1_20200222 tag=TAG20200222T013905 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07 Finished backup at 22-FEB-20 Starting Control File and SPFILE Autobackup at 22-FEB-20 piece handle=/home/oracle/rman/db_control_c-968242930-20200222-00 comment=NONE Finished Control File and SPFILE Autobackup at 22-FEB-20 |
백업본 확인
1 2 3 4 5 6 | $ ls -al /home/oracle/rman/ total 296172 drwxr-xr-x 2 oracle dba 80 Feb 22 01:39 . drwxr-xr-x. 11 oracle dba 4096 Feb 22 01:28 .. -rw-r----- 1 oracle dba 284696576 Feb 22 01:39 db_01up4p9p_1_1_20200222 -rw-r----- 1 oracle dba 18579456 Feb 22 01:39 db_control_c-968242930-20200222-00 |
일부 데이터 삭제
1 2 3 4 5 6 7 8 | SQL> conn bokgu_user/bokgu_user; SQL> delete bokgu_table where rownum <= 5000; 5000 rows deleted. SQL> commit; Commit complete. |
데이터 건수 확인
1 2 3 4 5 | SQL> select count(*) from bokgu_table; COUNT(*) ---------- 5000 |
로그 스위치
1 2 3 4 5 6 7 | SQL> conn / as sysdba alter system switch logfile; / / / / |
현재 시간 확인
1 2 3 4 5 | SQL> select to_char(sysdate,'YYYY-MM-DD:HH24:MI:SS') dt from dual; DT ------------------- 2020-02-22:02:10:35 |
3분 기다림
데이터 추가 삽입
1 2 3 4 5 6 7 8 9 10 11 12 | SQL> conn bokgu_user/bokgu_user; SQL> begin for i in 1..2500 loop insert into bokgu_table values (i, i+i); end loop; end; / commit; |
데이터 건수 확인
1 2 3 4 5 | SQL> select count(*) from bokgu_table; COUNT(*) ---------- 7500 |
로그 스위치
1 2 3 4 5 6 7 | SQL> conn / as sysdba alter system switch logfile; / / / / |
현재 시간 확인
1 2 3 4 5 | SQL> select to_char(sysdate,'YYYY-MM-DD:HH24:MI:SS') dt from dual; DT ------------------- 2020-02-22:02:14:35 |
복구하려는 데이터 시점과 데이터 건수
시간 : 2020-02-22:02:10:35 데이터 : 5000건
pfile 백업
1 2 3 | SQL> create pfile='$ORACLE_HOME/dbs/initracdb.ora' from spfile; File created. |
pfile을 target db 서버로 전송
1 2 3 4 5 6 7 | $ scp ORACLE_HOME/dbs/initracdb.ora oracle@192.168.137.60:/app/oracle/product/11.2.0/db_1/dbs/initracdb.ora The authenticity of host '192.168.137.53 (192.168.137.60)' can't be established. ECDSA key fingerprint is SHA256:1OePOlbxKQPG5ybT9hZCOSmKh6OqLxkT5UBkLm6IP+s. ECDSA key fingerprint is MD5:f1:a2:b3:0d:2b:fd:b5:e1:bf:ad:48:35:3e:9a:04:e3. Are you sure you want to continue connecting (yes/no)? yes Warning: Permanently added '192.168.137.60' (ECDSA) to the list of known hosts. initracdb.ora 100% 1530 927.9KB/s 00:00 |
single target db 서버
백업된 pfile 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 | $ cat $ORACLE_HOME/dbs/initracdb.ora racdb2.__db_cache_size=1191182336 racdb1.__db_cache_size=1191182336 racdb2.__java_pool_size=16777216 racdb1.__java_pool_size=16777216 racdb2.__large_pool_size=16777216 racdb1.__large_pool_size=16777216 racdb2.__oracle_base='/app/oracle'#ORACLE_BASE set from environment racdb1.__oracle_base='/app/oracle'#ORACLE_BASE set from environment racdb2.__pga_aggregate_target=570425344 racdb1.__pga_aggregate_target=570425344 racdb2.__sga_target=1694498816 racdb1.__sga_target=1694498816 racdb2.__shared_io_pool_size=0 racdb1.__shared_io_pool_size=0 racdb2.__shared_pool_size=452984832 racdb1.__shared_pool_size=452984832 racdb2.__streams_pool_size=0 racdb1.__streams_pool_size=0 *.audit_file_dest='/app/oracle/admin/racdb/adump' *.audit_trail='db' *.cluster_database=true *.compatible='11.2.0.4.0' *.control_files='+ORADATA/racdb/controlfile/current.256.970626165','+ORAFRA/racdb/controlfile/current.271.970626165' *.db_block_size=8192 #*.db_create_file_dest='+ORADATA' *.db_domain='' *.db_name='racdb' *.db_recovery_file_dest='+ORAFRA' *.db_recovery_file_dest_size=4194304000 *.diagnostic_dest='/app/oracle' racdb2.instance_number=2 racdb1.instance_number=1 *.log_archive_dest='' *.log_archive_dest_1='location=/home/oracle/arch' *.log_archive_format='rac11g_%t%s%r.arc' *.open_cursors=300 *.pga_aggregate_target=558891008 *.processes=150 *.remote_listener='rac-scan:1521' *.remote_login_passwordfile='exclusive' *.sga_target=1678770176 racdb2.thread=2 racdb1.thread=1 racdb2.undo_tablespace='UNDOTBS2' racdb1.undo_tablespace='UNDOTBS1' |
dbname은 변경하지 않고 다른 디렉토리 명은 모두 newdev로 변경함
racdb1,2.__ 부분 모두 삭제
audit_file_dest 변경
파라미터 주석 : cluster_database,db_create_file_dest, db_recovery_file_dest, racdb2.instance_number=2
racdb1.instance_number=1, remote_listener, racdb2.thread=1, racdb2.thread=2
컨트롤 파일 위치 변경
sga_target 변경(선택)
undo_tablespace 변경
수정된 pfile
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 | $ vi $ORACLE_HOME/dbs/initracdb.ora *.audit_file_dest='/app/oracle/admin/newdev/adump' *.audit_trail='db' #*.cluster_database=true *.compatible='11.2.0.4.0' *.control_files='/app/oracle/oradata/newdev/control01.ctl','/app/oracle/oradata/newdev/control02.ctl' *.db_block_size=8192 #*.db_create_file_dest='+ORADATA' *.db_domain='' *.db_name='racdb' #*.db_recovery_file_dest='+ORAFRA' #*.db_recovery_file_dest_size=4194304000 *.diagnostic_dest='/app/oracle' #racdb2.instance_number=2 #racdb1.instance_number=1 *.log_archive_dest='' *.log_archive_dest_1='location=/home/oracle/arch' *.log_archive_format='rac11g_%t%s%r.arc' *.open_cursors=300 *.pga_aggregate_target=558891008 *.processes=150 #*.remote_listener='rac-scan:1521' *.remote_login_passwordfile='exclusive' *.sga_target=1678770176 #racdb2.thread=2 #racdb1.thread=1 *.undo_tablespace='UNDOTBS1' |
db 관련 폴더 생성
1 2 3 | $ mkdir -p /app/oracle/admin/newdev/adump $ mkdir -p /app/oracle/oradata/newdev $ mkdir -p /home/oracle/rman/ |
source db서버에서 target db 서버로 rman 백업 파일 전송
1 2 3 4 | $ scp /home/oracle/rman/* oracle@192.168.137.60:/home/oracle/rman/ oracle@192.168.137.60's password: db_01up4p9p_1_1_20200222 100% 272MB 28.1MB/s 00:09 db_control_c-968242930-20200222-00 100% |
source db서버에서 target db 서버로 아카이브 파일 전송
조회
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 | $ ls -al /home/oracle/arch total 9520 drwxr-xr-x 2 oracle dba 4096 Feb 22 02:14 . drwxr-xr-x. 11 oracle dba 4096 Feb 22 02:52 .. -rw-r----- 1 oracle dba 8814592 Feb 22 02:09 rac11g_115970626162.arc -rw-r----- 1 oracle dba 1536 Feb 22 02:09 rac11g_116970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:09 rac11g_117970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:09 rac11g_118970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:09 rac11g_119970626162.arc -rw-r----- 1 oracle dba 885760 Feb 22 02:14 rac11g_120970626162.arc -rw-r----- 1 oracle dba 2560 Feb 22 02:14 rac11g_121970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:14 rac11g_122970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:14 rac11g_123970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:14 rac11g_124970626162.arc -rw-r----- 1 oracle dba 1024 Feb 22 02:14 rac11g_125970626162.arc |
Feb 22 02:09 파일까지만 전송(119970626162.arc 까지)
1 2 3 4 5 6 7 8 | $ cd /home/oracle/arch $ scp rac11g_115970626162.arc rac11g_116970626162.arc rac11g_117970626162.arc rac11g_118970626162.arc rac11g_119970626162.arc oracle@192.168.137.60:/home/oracle/arch/ oracle@192.168.137.60's password: rac11g_115970626162.arc 100% 8608KB 31.2MB/s 00:00 rac11g_116970626162.arc 100% 1536 921.3KB/s 00:00 rac11g_117970626162.arc 100% 1024 1.1MB/s 00:00 rac11g_118970626162.arc 100% 1024 1.5MB/s 00:00 rac11g_119970626162.arc |
target db 서버에서 파일 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | $ ls -al /home/oracle/arch/ /home/oracle/rman/ /home/oracle/arch/: total 8632 drwxr-xr-x. 2 oracle oinstall 4096 Feb 23 02:42 . drwx------. 6 oracle oinstall 4096 Feb 23 02:36 .. -rw-r-----. 1 oracle oinstall 8814592 Feb 23 02:42 rac11g_115970626162.arc -rw-r-----. 1 oracle oinstall 1536 Feb 23 02:42 rac11g_116970626162.arc -rw-r-----. 1 oracle oinstall 1024 Feb 23 02:42 rac11g_117970626162.arc -rw-r-----. 1 oracle oinstall 1024 Feb 23 02:42 rac11g_118970626162.arc -rw-r-----. 1 oracle oinstall 1024 Feb 23 02:42 rac11g_119970626162.arc /home/oracle/rman/: total 296176 drwxr-xr-x. 2 oracle oinstall 4096 Feb 23 02:43 . drwx------. 6 oracle oinstall 4096 Feb 23 02:36 .. -rw-r-----. 1 oracle oinstall 284696576 Feb 23 02:39 db_01up4p9p_1_1_20200222 -rw-r-----. 1 oracle oinstall 18579456 Feb 23 02:39 db_control_c-968242930-20200222-00 |
db nomount로 기동
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | $ export ORACLE_SID=racdb $ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Sun Feb 23 02:44:31 2020 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to an idle instance. SQL> startup nomount ORACLE instance started. Total System Global Area 1653518336 bytes Fixed Size 2253784 bytes Variable Size 1006636072 bytes Database Buffers 637534208 bytes Redo Buffers 7094272 bytes |
spfile 생성
1 2 3 | SQL> create spfile from pfile='$ORACLE_HOME/dbs/initracdb.ora'; File created. |
재기동 및 파라미터 파일 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | SQL> shutdown immediate ORA-01507: database not mounted ORACLE instance shut down. SQL> startup nomount ORACLE instance started. Total System Global Area 1686925312 bytes Fixed Size 2253864 bytes Variable Size 419433432 bytes Database Buffers 1258291200 bytes Redo Buffers 6946816 bytes SQL> show parameter spfile NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ spfile string /app/oracle/product/11.2.0/db_1/dbs/spfileracdb.ora |
프로세스 확인
1 2 3 | $ ps -ef | grep pmon oracle 6965 1 0 02:51 ? 00:00:00 ora_pmon_racdb oracle 7004 6878 0 02:52 pts/0 00:00:00 grep pmon |
컨트롤 파일 restore
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | $ rman target / Recovery Manager: Release 11.2.0.4.0 - Production on Sun Feb 23 03:04:57 2020 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: RACDB (not mounted) RMAN> restore controlfile from '/home/oracle/rman/db_control_c-968242930-20200222-00'; Starting restore at 23-FEB-20 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=19 device type=DISK channel ORA_DISK_1: restoring control file channel ORA_DISK_1: restore complete, elapsed time: 00:00:01 output file name=/app/oracle/oradata/newdev/control01.ctl output file name=/app/oracle/oradata/newdev/control02.ctl Finished restore at 23-FEB-20 |
db mount 상태로 변경
1 2 3 4 | RMAN> sql 'alter database mount'; sql statement: alter database mount released channel: ORA_DISK_1 |
rman 설정 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | RMAN> show all; using target database control file instead of recovery catalog RMAN configuration parameters for database with db_unique_name RACDB are: CONFIGURE RETENTION POLICY TO REDUNDANCY 1; # default CONFIGURE BACKUP OPTIMIZATION OFF; # default CONFIGURE DEFAULT DEVICE TYPE TO DISK; # default CONFIGURE CONTROLFILE AUTOBACKUP ON; CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '/home/oracle/rman/db_control_%F'; CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET; # default CONFIGURE DATAFILE BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default CONFIGURE ARCHIVELOG BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default CONFIGURE CHANNEL DEVICE TYPE DISK FORMAT '/home/oracle/rman/db_%U_%T'; CONFIGURE MAXSETSIZE TO UNLIMITED; # default CONFIGURE ENCRYPTION FOR DATABASE OFF; # default CONFIGURE ENCRYPTION ALGORITHM 'AES128'; # default CONFIGURE COMPRESSION ALGORITHM 'BASIC' AS OF RELEASE 'DEFAULT' OPTIMIZE FOR LOAD TRUE ; # default CONFIGURE ARCHIVELOG DELETION POLICY TO NONE; # default CONFIGURE SNAPSHOT CONTROLFILE NAME TO '/app/oracle/product/11.2.0/db_1/dbs/snapcf_racdb.f'; # default |
db 상태 확인
1 2 3 4 5 | SQL> select instance_name, status from v$instance; INSTANCE_NAME STATUS ---------------- ------------ racdb MOUNTED |
rman 백업된 파일 다시 등록
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 | RMAN> catalog start with '/home/oracle/rman/'; searching for all files that match the pattern /home/oracle/rman/ List of Files Unknown to the Database ===================================== File Name: /home/oracle/rman/db_control_c-968242930-20200222-00 Do you really want to catalog the above files (enter YES or NO)? yes <-- yes 입력 cataloging files... cataloging done List of Cataloged Files ======================= File Name: /home/oracle/rman/db_control_c-968242930-20200222-00 |
백업된 리스트 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | RMAN> list backup; List of Backup Sets =================== BS Key Type LV Size Device Type Elapsed Time Completion Time ------- ---- -- ---------- ----------- ------------ --------------- 1 Full 271.50M DISK 00:00:04 22-FEB-20 BP Key: 1 Status: AVAILABLE Compressed: NO Tag: TAG20200222T013905 Piece Name: /home/oracle/rman/db_01up4p9p_1_1_20200222 List of Datafiles in backup set 1 File LV Type Ckp SCN Ckp Time Name ---- -- ---- ---------- --------- ---- 1 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/system.259.970626167 2 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/sysaux.260.970626173 3 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/undotbs1.261.970626177 4 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/undotbs2.263.970626185 5 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/users.264.970626185 6 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/users.268.970884085 7 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/users.269.970884253 8 Full 241661 22-FEB-20 +ORADATA/racdb/datafile/bokgu.270.1033003033 |
또는
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | RMAN> report schema; using target database control file instead of recovery catalog RMAN-06139: WARNING: control file is not current for REPORT SCHEMA Report of database schema for database with db_unique_name RACDB List of Permanent Datafiles =========================== File Size(MB) Tablespace RB segs Datafile Name ---- -------- -------------------- ------- ------------------------ 1 700 SYSTEM *** /app/oracle/oradata/newdev/system01.dbf 2 600 SYSAUX *** /app/oracle/oradata/newdev/sysaux01.dbf 3 200 UNDOTBS1 *** /app/oracle/oradata/newdev/undotbs01.dbf 4 200 UNDOTBS2 *** /app/oracle/oradata/newdev/undotbs02.dbf 5 0 USERS *** +ORADATA/racdb/datafile/users.264.970626185 6 0 USERS *** +ORADATA/racdb/datafile/users.268.970884085 7 0 USERS *** +ORADATA/racdb/datafile/users.269.970884253 8 1024 BOKGU *** /app/oracle/oradata/newdev/bokgu01.dbf List of Temporary Files ======================= File Size(MB) Tablespace Maxsize(MB) Tempfile Name ---- -------- -------------------- ----------- -------------------- 1 20 TEMP 32767 +ORADATA/racdb/tempfile/temp.262.970626177 |
RMAN용 스크립트 작성 및 실행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 | RMAN> run { allocate channel ch1 device type disk ; allocate channel ch2 device type disk ; set newname for tempfile 1 to '/app/oracle/oradata/newdev/temp01.dbf'; set newname for datafile 1 to '/app/oracle/oradata/newdev/system01.dbf' ; set newname for datafile 2 to '/app/oracle/oradata/newdev/sysaux01.dbf' ; set newname for datafile 3 to '/app/oracle/oradata/newdev/undotbs01.dbf' ; set newname for datafile 4 to '/app/oracle/oradata/newdev/undotbs02.dbf' ; set newname for datafile 8 to '/app/oracle/oradata/newdev/bokgu01.dbf' ; #restore database skip tablespace 'users'; restore datafile 1,2,3,4,8; switch datafile all; switch tempfile all; } <- 이까지 입력 후 엔터 allocated channel: ch1 channel ch1: SID=19 device type=DISK allocated channel: ch2 channel ch2: SID=20 device type=DISK executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME Starting restore at 23-FEB-20 channel ch1: starting datafile backup set restore channel ch1: specifying datafile(s) to restore from backup set channel ch1: restoring datafile 00001 to /app/oracle/oradata/newdev/system01.dbf channel ch1: restoring datafile 00002 to /app/oracle/oradata/newdev/sysaux01.dbf channel ch1: restoring datafile 00003 to /app/oracle/oradata/newdev/undotbs01.dbf channel ch1: restoring datafile 00004 to /app/oracle/oradata/newdev/undotbs02.dbf channel ch1: restoring datafile 00008 to /app/oracle/oradata/newdev/bokgu01.dbf channel ch1: reading from backup piece /home/oracle/rman/db_01up4p9p_1_1_20200222 channel ch1: piece handle=/home/oracle/rman/db_01up4p9p_1_1_20200222 tag=TAG20200222T013905 channel ch1: restored backup piece 1 channel ch1: restore complete, elapsed time: 00:00:26 Finished restore at 23-FEB-20 datafile 1 switched to datafile copy input datafile copy RECID=6 STAMP=1033105122 file name=/app/oracle/oradata/newdev/system01.dbf datafile 2 switched to datafile copy input datafile copy RECID=7 STAMP=1033105122 file name=/app/oracle/oradata/newdev/sysaux01.dbf datafile 3 switched to datafile copy input datafile copy RECID=8 STAMP=1033105122 file name=/app/oracle/oradata/newdev/undotbs01.dbf datafile 4 switched to datafile copy input datafile copy RECID=9 STAMP=1033105122 file name=/app/oracle/oradata/newdev/undotbs02.dbf datafile 8 switched to datafile copy input datafile copy RECID=10 STAMP=1033105122 file name=/app/oracle/oradata/newdev/bokgu01.dbf renamed tempfile 1 to /app/oracle/oradata/newdev/temp01.dbf in control file released channel: ch1 released channel: ch2 |
recover 명령 실행
1 2 3 4 5 | SQL> recover database until time '2020-02-22:02:10:00' using backup controlfile; ORA-00283: recovery session canceled due to errors ORA-01110: data file 5: '+ORADATA/racdb/datafile/users.264.970626185' ORA-01157: cannot identify/lock data file 5 - see DBWR trace file ORA-01110: data file 5: '+ORADATA/racdb/datafile/users.264.970626185' |
데이터 파일 5번(users ts)를 restore 하지 않았기 때문에 에러가 발생함
현재 rman을 이용해서 datafile, controlfile을 복원(restore)한 상태
지금처럼 특정 datafile을 restore하지 않는 경우는 두가지 이유가 있을수 있음
1. 만약 복구하고 싶은 테이블스페이스(datafile)가 복구를 하지 않아도 되는 테이블 스페이스보다 같거나 적은 경우
복구하고 싶은 테이블스페이스(system ts 제외하고 1개) >= 복구를 하지 않아도 되는 테이블 스페이스(1개)
복구 방법 => 컨트롤 파일 재생성 없이 datafile offline 처리
(offline 대상 datafile이 많이 않다면 손쉽게 offline 가능함)
=> 1번 방법을 사용해도 ASM에서 FileSystem으로 변경할 경우 컨트롤파일을 재생성해줘야함
2. 복구하고싶은 테이블스페이스(datafile) 보다 복구를 하지 않아도 되는 테이블 스페이스가 더 많은 경우
복구하고 싶은 테이블스페이스(system ts 제외하고 1개) < 복구를 하지 않아도 되는 테이블 스페이스(10개)
복구 방법 => 컨트롤 파일 재생성 시 복구하지 않을 데이터파일 제외
(수동으로 데이터파일을 offline 하기엔 손이 많이가기 때문에 이방법 사용)
1번 방법 테스트
datafile offline 처리
1 2 3 4 5 6 7 8 9 10 11 | SQL> alter database datafile 5 offline; Database altered. SQL> alter database datafile 6 offline; Database altered. SQL> alter database datafile 7 offline; Database altered. |
recover 명령 실행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 | SQL> recover database until time '2020-02-22:02:10:00' using backup controlfile; ORA-00279: change 241661 generated at 02/22/2020 01:39:05 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_115970626162.arc ORA-00280: change 241661 for thread 1 is in sequence #15 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto <- auto 입력 ORA-00279: change 241661 generated at 03/13/2018 02:30:36 needed for thread 2 ORA-00289: suggestion : /home/oracle/arch/rac11g_21970626162.arc ORA-00280: change 241661 for thread 2 is in sequence #1 ORA-00279: change 244906 generated at 02/22/2020 02:09:10 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_116970626162.arc ORA-00280: change 244906 for thread 1 is in sequence #16 ORA-00278: log file '/home/oracle/arch/rac11g_115970626162.arc' no longer needed for this recovery ORA-00279: change 244911 generated at 02/22/2020 02:09:14 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_117970626162.arc ORA-00280: change 244911 for thread 1 is in sequence #17 ORA-00278: log file '/home/oracle/arch/rac11g_116970626162.arc' no longer needed for this recovery ORA-00279: change 244914 generated at 02/22/2020 02:09:14 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_118970626162.arc ORA-00280: change 244914 for thread 1 is in sequence #18 ORA-00278: log file '/home/oracle/arch/rac11g_117970626162.arc' no longer needed for this recovery ORA-00279: change 244918 generated at 02/22/2020 02:09:15 needed for thread 2 ORA-00289: suggestion : /home/oracle/arch/rac11g_22970626162.arc ORA-00280: change 244918 for thread 2 is in sequence #2 ORA-00278: log file '/home/oracle/arch/rac11g_21970626162.arc' no longer needed for this recovery ORA-00279: change 244921 generated at 02/22/2020 02:09:15 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_119970626162.arc ORA-00280: change 244921 for thread 1 is in sequence #19 ORA-00278: log file '/home/oracle/arch/rac11g_118970626162.arc' no longer needed for this recovery ORA-00279: change 244932 generated at 02/22/2020 02:09:40 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_120970626162.arc ORA-00280: change 244932 for thread 1 is in sequence #20 ORA-00278: log file '/home/oracle/arch/rac11g_119970626162.arc' no longer needed for this recovery ORA-00308: cannot open archived log '/home/oracle/arch/rac11g_120970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 |
rac11g_119970626162.arc 까지 복구가 완료됨
rac11g_120970626162.arc는 2020-02-22:02:10:00 이후의 로그이기 때문에 target db 서버에는 존재하지 않아서 에러가 발생함
db 기동
1 2 3 4 | SQL> alter database open resetlogs; * ERROR at line 1: ORA-00349: failure obtaining block size for '+oradat |
datafile, controlfile 는 모두 다시 만들어졌지만 online redo log 파일이 없기때문에 에러가 발생함
https://positivemh.tistory.com/508 참조
해결방법
컨트롤파일 백업
1 | SQL> alter database backup controlfile to trace as '/home/oracle/recon.sql'; |
컨트롤파일 생성파일 확인(기존)
REUSE RESETLOGS가 적힌 부분만 남기고 다른 REUSE NORESETLOGS 부분은 삭제한 상태
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 | $ cat recon.sql STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "RACDB" RESETLOGS ARCHIVELOG MAXLOGFILES 192 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 32 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512, GROUP 2 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 DATAFILE '/app/oracle/oradata/newdev/system01.dbf', '/app/oracle/oradata/newdev/sysaux01.dbf', '/app/oracle/oradata/newdev/undotbs01.dbf', '/app/oracle/oradata/newdev/undotbs02.dbf', '+ORADATA/racdb/datafile/users.264.970626185', '+ORADATA/racdb/datafile/users.268.970884085', '+ORADATA/racdb/datafile/users.269.970884253', '/app/oracle/oradata/newdev/bokgu01.dbf' CHARACTER SET KO16MSWIN949 ; -- Configure RMAN configuration record 1 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON'); -- Configure RMAN configuration record 2 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CHANNEL','DEVICE TYPE DISK FORMAT ''/home/oracle/rman/db_%U_%T'''); -- Configure RMAN configuration record 3 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''/home/oracle/rman/db_control_%F'''); -- Commands to re-create incarnation table -- Below log names MUST be changed to existing filenames on -- disk. Any one log file from each branch can be used to -- re-create incarnation records. -- ALTER DATABASE REGISTER LOGFILE '/home/oracle/arch/rac11g_11970626162.arc'; -- Recovery is required if any of the datafiles are restored backups, -- or if the last shutdown was not normal or immediate. RECOVER DATABASE USING BACKUP CONTROLFILE -- Create log files for threads other than thread one. ALTER DATABASE ADD LOGFILE THREAD 2 GROUP 3 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 REUSE, GROUP 4 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 REUSE; -- Database can now be opened zeroing the online logs. ALTER DATABASE OPEN RESETLOGS; -- Commands to add tempfiles to temporary tablespaces. -- Online tempfiles have complete space information. -- Other tempfiles may require adjustment. ALTER TABLESPACE TEMP ADD TEMPFILE '/app/oracle/oradata/newdev/temp01.dbf' REUSE; -- End of tempfile additions. -- |
변경 사항 :
redo log 위치 ASM 에서 filesystem으로 변경
사용하지 않는 데이터파일 구문 삭제
RECOVER DATABASE, ALTER DATABASE OPEN RESETLOGS 구문 삭제
rac2번 노드(threads) redo log 생성 구문 삭제
-- 등 주석 구문 삭제
컨트롤파일 생성파일 변경 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 | $ cat recon.sql STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "RACDB" RESETLOGS ARCHIVELOG MAXLOGFILES 192 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 32 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '/app/oracle/oradata/newdev/redo01.log' ) SIZE 50M BLOCKSIZE 512, GROUP 2 ( '/app/oracle/oradata/newdev/redo02.log' ) SIZE 50M BLOCKSIZE 512, GROUP 3 ( '/app/oracle/oradata/newdev/redo03.log' ) SIZE 50M BLOCKSIZE 512 DATAFILE '/app/oracle/oradata/newdev/system01.dbf', '/app/oracle/oradata/newdev/sysaux01.dbf', '/app/oracle/oradata/newdev/undotbs01.dbf', '/app/oracle/oradata/newdev/undotbs02.dbf', '/app/oracle/oradata/newdev/bokgu01.dbf' CHARACTER SET KO16MSWIN949 ; VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON'); VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CHANNEL','DEVICE TYPE DISK FORMAT ''/home/oracle/rman/db_%U_%T'''); VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''/home/oracle/rman/db_control_%F'''); --ALTER TABLESPACE TEMP ADD TEMPFILE '/app/oracle/oradata/newdev/temp01.dbf' REUSE; |
db 종료
1 2 3 4 5 6 | SQL> shutdown immediate ORA-01109: database not open Database dismounted. ORACLE instance shut down. |
컨트롤파일 재생성
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | SQL> @recon.sql ORACLE instance started. Total System Global Area 1686925312 bytes Fixed Size 2253864 bytes Variable Size 419433432 bytes Database Buffers 1258291200 bytes Redo Buffers 6946816 bytes Control file created. PL/SQL procedure successfully completed. PL/SQL procedure successfully completed. PL/SQL procedure successfully completed. |
복구는 아까 했기때문에 바로 open 시도
1 2 3 4 | SQL> alter database open resetlogs * ERROR at line 1: ORA-38856: cannot mark instance UNNAMED_INSTANCE_2 (redo thread 2) as enabled |
에러가 발생하지만 버그로 발생한 문제임
https://positivemh.tistory.com/507 참조
히든파라미터 적용
1 2 3 | SQL> alter system set "_no_recovery_through_resetlogs"=true; System altered. |
다시 open 시도
1 2 3 | SQL> alter database open resetlogs; Database altered. |
정상적으로 open됨
데이터 확인
1 2 3 4 5 6 7 | SQL> conn bokgu_user/bokgu_user Connected. SQL> select count(*) from bokgu_table; COUNT(*) ---------- 5000 |
정상적으로 원하는 시점까지 복구됨
2번 방법 테스트
작업전 데이터 모두 삭제
1 2 3 4 5 6 | SQL> shutdown immediate Database closed. Database dismounted. stareORACLE instance shut down. $ rm -rf /app/oracle/oradata/newdev/* |
[컨트롤 파일 restore] 부터 [RMAN용 스크립트 작성 및 실행]까지 다시 수행
컨트롤파일 백업(하지 않고 위에서 만든 recon.sql 이용해도 무관)
1 | SQL> alter database backup controlfile to trace as '/home/oracle/recon2.sql'; |
컨트롤파일 생성파일 확인(기존)
REUSE RESETLOGS가 적힌 부분만 남기고 다른부분은 REUSE NORESETLOGS 부분은 삭제한 상태
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 | $ cat recon2.sql STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "RACDB" RESETLOGS ARCHIVELOG MAXLOGFILES 192 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 32 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512, GROUP 2 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 DATAFILE '/app/oracle/oradata/newdev/system01.dbf', '/app/oracle/oradata/newdev/sysaux01.dbf', '/app/oracle/oradata/newdev/undotbs01.dbf', '/app/oracle/oradata/newdev/undotbs02.dbf', '+ORADATA/racdb/datafile/users.264.970626185', '+ORADATA/racdb/datafile/users.268.970884085', '+ORADATA/racdb/datafile/users.269.970884253', '/app/oracle/oradata/newdev/bokgu01.dbf' CHARACTER SET KO16MSWIN949 ; -- Configure RMAN configuration record 1 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON'); -- Configure RMAN configuration record 2 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CHANNEL','DEVICE TYPE DISK FORMAT ''/home/oracle/rman/db_%U_%T'''); -- Configure RMAN configuration record 3 VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''/home/oracle/rman/db_control_%F'''); -- Commands to re-create incarnation table -- Below log names MUST be changed to existing filenames on -- disk. Any one log file from each branch can be used to -- re-create incarnation records. -- ALTER DATABASE REGISTER LOGFILE '/home/oracle/arch/rac11g_11970626162.arc'; -- Recovery is required if any of the datafiles are restored backups, -- or if the last shutdown was not normal or immediate. RECOVER DATABASE USING BACKUP CONTROLFILE -- Create log files for threads other than thread one. ALTER DATABASE ADD LOGFILE THREAD 2 GROUP 3 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 REUSE, GROUP 4 ( '+oradata', '+orafra' ) SIZE 50M BLOCKSIZE 512 REUSE; -- Database can now be opened zeroing the online logs. ALTER DATABASE OPEN RESETLOGS; -- Commands to add tempfiles to temporary tablespaces. -- Online tempfiles have complete space information. -- Other tempfiles may require adjustment. ALTER TABLESPACE TEMP ADD TEMPFILE '/app/oracle/oradata/newdev/temp01.dbf' REUSE; -- End of tempfile additions. -- |
변경 사항 :
redo log 위치 ASM 에서 filesystem으로 변경
사용하지 않는 데이터파일 구문 삭제
RECOVER DATABASE, ALTER DATABASE OPEN RESETLOGS 구문 삭제
rac2번 노드(threads) redo log 생성 구문 삭제
-- 등 주석 구문 삭제
컨트롤파일 생성파일 변경 확인
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 | $ cat recon2.sql STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "RACDB" RESETLOGS ARCHIVELOG MAXLOGFILES 192 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 32 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '/app/oracle/oradata/newdev/redo01.log' ) SIZE 50M BLOCKSIZE 512, GROUP 2 ( '/app/oracle/oradata/newdev/redo02.log' ) SIZE 50M BLOCKSIZE 512, GROUP 3 ( '/app/oracle/oradata/newdev/redo03.log' ) SIZE 50M BLOCKSIZE 512 DATAFILE '/app/oracle/oradata/newdev/system01.dbf', '/app/oracle/oradata/newdev/sysaux01.dbf', '/app/oracle/oradata/newdev/undotbs01.dbf', '/app/oracle/oradata/newdev/undotbs02.dbf', '/app/oracle/oradata/newdev/bokgu01.dbf' CHARACTER SET KO16MSWIN949 ; VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON'); VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CHANNEL','DEVICE TYPE DISK FORMAT ''/home/oracle/rman/db_%U_%T'''); VARIABLE RECNO NUMBER; EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''/home/oracle/rman/db_control_%F'''); --ALTER TABLESPACE TEMP ADD TEMPFILE '/app/oracle/oradata/newdev/temp01.dbf' REUSE; |
db 종료
1 2 3 4 5 6 | SQL> shutdown immediate ORA-01109: database not open Database dismounted. ORACLE instance shut down. |
컨트롤파일 재생성
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | SQL> @recon.sql ORACLE instance started. Total System Global Area 1686925312 bytes Fixed Size 2253864 bytes Variable Size 419433432 bytes Database Buffers 1258291200 bytes Redo Buffers 6946816 bytes Control file created. PL/SQL procedure successfully completed. PL/SQL procedure successfully completed. PL/SQL procedure successfully completed. |
recover 명령 실행
1 2 3 4 5 6 7 8 9 10 11 12 | SQL> recover database until time '2020-02-22:02:10:00' using backup controlfile; ORA-00279: change 241661 generated at 02/22/2020 01:39:05 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_115970626162.arc ORA-00280: change 241661 for thread 1 is in sequence #15 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto <- auto 입력 ORA-00279: change 241661 generated at needed for thread 2 ORA-00266: name of archived log file needed |
auto 입력시 ORA-00266 에러가 발생함
https://positivemh.tistory.com/509 참조
해결방법
원본db(source rac db)에서 v$archived_log 뷰 조회
1 2 3 4 5 6 7 8 9 10 11 12 13 | SQL> col name for a50 select thread#, FIRST_CHANGE#, NEXT_CHANGE#, name from v$archived_log where 241661 between FIRST_CHANGE# and NEXT_CHANGE# / THREAD# FIRST_CHANGE# NEXT_CHANGE# NAME ---------- ------------- ------------ -------------------------------------------------- 1 231611 244906 /home/oracle/arch/rac11g_115970626162.arc 2 194681 244918 /home/oracle/arch/rac11g_21970626162.arc 2 rows selected. |
THREAD 1번 2번이 나오는데
나의 경우는 ORA-00279: change 241661 generated at needed for thread 2 로 표시되기 때문에
2번 아카이브파일 경로(/home/oracle/arch/rac11g_21970626162.arc)를 입력해주면됨
THREAD 2번 파일을 입력하면 no longer needed for this recovery(이 복구에 더 이상 필요하지 않음)이라고 표시됨
이후 auto 를 입력하면 자동으로 아카이브를 적용시킴
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 | SQL> recover database until time '2020-02-22:02:10:00' using backup controlfile; ORA-00279: change 241661 generated at 02/22/2020 01:39:05 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_115970626162.arc ORA-00280: change 241661 for thread 1 is in sequence #15 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} /home/oracle/arch/rac11g_21970626162.arc ORA-00279: change 244906 generated at 02/22/2020 02:09:10 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_116970626162.arc ORA-00280: change 244906 for thread 1 is in sequence #16 ORA-00278: log file '/home/oracle/arch/rac11g_115970626162.arc' no longer needed for this recovery Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto <- auto 입력 ORA-00279: change 244911 generated at 02/22/2020 02:09:14 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_117970626162.arc ORA-00280: change 244911 for thread 1 is in sequence #17 ORA-00278: log file '/home/oracle/arch/rac11g_116970626162.arc' no longer needed for this recovery ORA-00279: change 244914 generated at 02/22/2020 02:09:14 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_118970626162.arc ORA-00280: change 244914 for thread 1 is in sequence #18 ORA-00278: log file '/home/oracle/arch/rac11g_117970626162.arc' no longer needed for this recovery ORA-00279: change 244918 generated at 02/22/2020 02:09:15 needed for thread 2 ORA-00289: suggestion : /home/oracle/arch/rac11g_22970626162.arc ORA-00280: change 244918 for thread 2 is in sequence #2 ORA-00278: log file '/home/oracle/arch/rac11g_21970626162.arc' no longer needed for this recovery ORA-00279: change 244921 generated at 02/22/2020 02:09:15 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_119970626162.arc ORA-00280: change 244921 for thread 1 is in sequence #19 ORA-00278: log file '/home/oracle/arch/rac11g_118970626162.arc' no longer needed for this recovery ORA-00279: change 244932 generated at 02/22/2020 02:09:40 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/rac11g_120970626162.arc ORA-00280: change 244932 for thread 1 is in sequence #20 ORA-00278: log file '/home/oracle/arch/rac11g_119970626162.arc' no longer needed for this recovery ORA-00308: cannot open archived log '/home/oracle/arch/rac11g_120970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 |
rac11g_119970626162.arc 까지 복구가 완료됨
rac11g_120970626162.arc는 2020-02-22:02:10:00 이후의 로그이기 때문에 target db 서버에는 존재하지 않아서 에러가 발생함
db open
1 2 3 | SQL> alter database open resetlogs; Database altered. |
정상적으로 open됨
데이터 확인
1 2 3 4 5 6 7 | SQL> conn bokgu_user/bokgu_user Connected. SQL> select count(*) from bokgu_table; COUNT(*) ---------- 5000 |
정상적으로 원하는 시점까지 복구됨
+ 참조 명령어
리스토어 제외할 테이블스페이스지정
1 | RMAN> restore database skip tablespace'users','example'; |
참조
DOCS 342784.1
http://www.br8dba.com/rman-database-restore-from-asm-to-file-system/
https://gyh214.tistory.com/132
https://dinggur.tistory.com/151
https://docs.oracle.com/cd/E18283_01/backup.112/e10642/rcmdupad.htm
https://dinggur.tistory.com/186
https://community.oracle.com/thread/3875366
https://aboutdb.tistory.com/?page=83
https://positivemh.tistory.com/507
https://positivemh.tistory.com/508
https://positivemh.tistory.com/509
https://gyh214.tistory.com/162
https://m.blog.naver.com/hanccii/220985607102
https://dinggur.tistory.com/182
http://www.dba-oracle.com/t_rman_60_set_newname.htm
https://www.dba-village.com/village/dvp_forum.OpenThread?ThreadIdA=46880&DestinationA=RSS
'ORACLE > Backup&Recover' 카테고리의 다른 글
rac db(asm)에서 특정시점의 데이터를 single db(filesystem) 로 dbname 변경 후 복구 테스트 (0) | 2020.02.24 |
---|---|
오라클 rman에서 show all 정보와 list backup 정보는 어디있을까? (0) | 2020.02.24 |
Oracle partition tablespace, table rman 복구 테스트 (0) | 2019.02.19 |
datapump stop_job 후 재기동 후 start_job (0) | 2019.01.08 |
hot backup 복구 시나리오2 (0) | 2018.12.19 |