내맘대로긍정이 알려주는
Oracle 23ai 신기능
무료 세미나 발표자료
OS환경 : Oracle Linux 6.8 (64bit)
DB 환경 : Oracle Database 11.2.0.4 ASM RAC to FS SINGLE
방법 : rac db(asm)에서 특정시점의 데이터를 single db(filesystem) 로 dbname 변경 후 복구 테스트
개요
rac db(asm)에서 특정시점의 데이터를 single db(filesystem)로 복구하는 내용
dbname을 변경하면서 복구하는 내용
rac를 single db로 변경하는 내용
asm을 filesystem으로 변경하는 내용
rman을 이용해 데이터를 복구하는 내용이 포함됨
source db : RAC(asm)
target db(clone) : SINGLE(filesystem)
다음 https://positivemh.tistory.com/518 글과 다른점
다음 글 : pfile에 dbname을 처음에는 racdb(기존이름)으로 설정한 뒤 컨트롤파일 restore 후 datafile 을 restore 후
pfile에 dbname을 CLONE(변경이름) 로 설정한 뒤 컨트롤파일 재생성 후 recover
현재 글 : pfile에 dbname을 처음부터 CLONE(변경이름) 로 설정한 뒤 컨트롤파일 restore 후 datafile 을 restore하지 못해
racdb(기존이름)으로 mount 상태로 만든뒤 restore한 datafile을 CLONE 폴더로 복사 후 컨트롤파일 재생성 후 recover
시나리오
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' |
init 파일 명 initCLONE.ora 로 변경
dbname과 다른 디렉토리 명은 CLONE로 변경함
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 | $ cat $ORACLE_HOME/dbs/initCLONE.ora *.audit_file_dest='/app/oracle/admin/CLONE/adump' *.audit_trail='db' #*.cluster_database=true *.compatible='11.2.0.4.0' *.control_files='/app/oracle/oradata/CLONE/control01.ctl' *.db_block_size=8192 #*.db_create_file_dest='+ORADATA' *.db_domain='' *.db_name='CLONE' #*.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='%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/CLONE/adump $ mkdir -p /app/oracle/oradata/CLONE $ 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=CLONE $ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Tue Feb 25 08:33:35 2020 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to an idle instance. 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 |
spfile 생성
1 2 3 | SQL> create spfile from pfile='$ORACLE_HOME/dbs/initCLONE.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/spfileCLONE.ora |
프로세스 확인
1 2 3 | $ ps -ef | grep pmon oracle 6965 1 0 02:51 ? 00:00:00 ora_pmon_CLONE 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 Tue Feb 25 08:35:22 2020 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: CLONE (not mounted) RMAN> restore controlfile from '/home/oracle/rman/db_control_c-968242930-20200222-00'; Starting restore at 25-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/CLONE/control01.ctl Finished restore at 25-FEB-20 |
db mount 상태로 변경
1 2 3 4 5 6 7 8 9 | RMAN> sql 'alter database mount'; sql statement: alter database mount RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03009: failure of sql command on default channel at 02/25/2020 08:36:47 RMAN-11003: failure during parse/execution of SQL statement: alter database mount ORA-01103: database name 'RACDB' in control file is not 'CLONE' |
기존 컨트롤파일에 기록된 db name은 RACDB인데
파라미터 파일에는 CLONE라는 db name을 작성해서 mount가 되지 않음
컨트롤파일을 재생성 하려 해도 datafile 이 restore되어 있지 않기 때문에 재생성불가함
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 recon3.sql STARTUP NOMOUNT CREATE CONTROLFILE SET DATABASE "CLONE" RESETLOGS ARCHIVELOG MAXLOGFILES 192 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 32 MAXLOGHISTORY 292 LOGFILE GROUP 1 ( '/app/oracle/oradata/CLONE/redo01.log' ) SIZE 50M BLOCKSIZE 512, GROUP 2 ( '/app/oracle/oradata/CLONE/redo02.log' ) SIZE 50M BLOCKSIZE 512, GROUP 3 ( '/app/oracle/oradata/CLONE/redo03.log' ) SIZE 50M BLOCKSIZE 512 DATAFILE '/app/oracle/oradata/CLONE/system01.dbf', '/app/oracle/oradata/CLONE/sysaux01.dbf', '/app/oracle/oradata/CLONE/undotbs01.dbf', '/app/oracle/oradata/CLONE/undotbs02.dbf', '/app/oracle/oradata/CLONE/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/CLONE/temp01.dbf' REUSE; |
db종료 후 기존 컨트롤파일 삭제 후 recon3.sql 실행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 | SQL> shutdown immediate ORA-01507: database not mounted ORACLE instance shut down. SQL> !rm -rf /app/oracle/oradata/CLONE/control01.ctl SQL> @recon3 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 CREATE CONTROLFILE SET DATABASE "CLONE" RESETLOGS ARCHIVELOG * ERROR at line 1: ORA-01503: CREATE CONTROLFILE failed ORA-01565: error in identifying file '/app/oracle/oradata/CLONE/system01.dbf' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 |
datafile 이 restore되어 있지 않기 때문에 재생성불가함
clone db 생성시에는 datafile 을 모두 가져 온뒤에 control file을 생성해서 그다음단계로 진행을 했지만
현재는 datafile 을 restore할 수 없어서 문제
datafile을 resotre 하려면 db를 mount 상태로 만들어야 하는데 datafile이 없어서 controlfile을 재생성 할수 없고
controlfile을 그냥 쓰자니 dbname이 달라서 mount 상태로 올릴수가 없음
임의로 datafile 과 같은 이름으로 파일 생성
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | $ cd /app/oracle/oradata/CLONE $ ls control01.ctl $ touch system01.dbf $ touch sysaux01.dbf $ touch undotbs01.dbf $ touch undotbs02.dbf $ touch bokgu01.dbf $ ls -al total 18072 drwxr-xr-x. 2 oracle oinstall 4096 Feb 25 09:29 . drwxr-x---. 5 oracle oinstall 4096 Feb 25 08:32 .. -rw-r--r--. 1 oracle oinstall 0 Feb 25 09:29 bokgu01.dbf -rw-r-----. 1 oracle oinstall 18497536 Feb 25 08:36 control01.ctl -rw-r--r--. 1 oracle oinstall 0 Feb 25 09:29 sysaux01.dbf -rw-r--r--. 1 oracle oinstall 0 Feb 25 09:29 system01.dbf -rw-r--r--. 1 oracle oinstall 0 Feb 25 09:29 undotbs01.dbf -rw-r--r--. 1 oracle oinstall 0 Feb 25 09:29 undotbs02.dbf |
똑같은 에러 발생 => 실제로 사용하는 datafile이 있어야함
다른 방법
기존 dbname으로 mount까지 올린다음 restore를 통해 datafile을 가져오고
다시 CLONE라는 dbname으로 컨트롤파일 재생성 후 복구 하는 방안이 있지만 특수한 경우가 아니라면
굳이 이렇게 작업할 이유는 없음(이미 기존 dbname으로 올렸으면 그대로 복구해서 사용하면됨)
racdb(기존 dbname)으로 mount 상태로 만든뒤 restore한 datafile을 CLONE 폴더로 복사
1 2 3 4 5 6 | $ cp -av /app/oracle/oradata/newdev/*.dbf /app/oracle/oradata/CLONE/ `/app/oracle/oradata/newdev/bokgu01.dbf' -> `/app/oracle/oradata/CLONE/bokgu01.dbf' `/app/oracle/oradata/newdev/sysaux01.dbf' -> `/app/oracle/oradata/CLONE/sysaux01.dbf' `/app/oracle/oradata/newdev/system01.dbf' -> `/app/oracle/oradata/CLONE/system01.dbf' `/app/oracle/oradata/newdev/undotbs01.dbf' -> `/app/oracle/oradata/CLONE/undotbs01.dbf' `/app/oracle/oradata/newdev/undotbs02.dbf' -> `/app/oracle/oradata/CLONE/undotbs02.dbf' |
sqlplus 에서 recon3.sql 실행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | SQL> shutdown immediate ORA-01507: database not mounted ORACLE instance shut down. SQL> @recon3 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. |
정상적으로 재생성됨
인스턴스 이름 및 상태 확인
1 2 3 4 5 | SQL> select instance_name, status from v$instance; INSTANCE_NAME STATUS ---------------- ------------ CLONE MOUNTED |
복구 작업 진행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | 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/115970626162.arc ORA-00280: change 241661 for thread 1 is in sequence #15 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto ORA-00308: cannot open archived log '/home/oracle/arch/115970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 ORA-00308: cannot open archived log '/home/oracle/arch/115970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 |
아카이브 파일을 찾을수 없다고 나옴
=> 기존에는 아카이브 파일 형식이 log_archive_format='rac11g_%t%s%r.arc' 이었는데 CLONE DB는
log_archive_format='%t%s%r.arc' 이어서 발생한 문제
방법 1.
아래처럼 파라미터 수정 후 재기동해서 아카이브 로그를 적용시킬수도 있고
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | SQL> alter system set log_archive_format='rac11g_%t%s%r.arc' scope=spfile; System altered. SQL> shutdown immediate ORA-01109: database not open Database dismounted. ORACLE instance shut down. SQL> startup mount 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 Database mounted. |
방법2.
recover 명령 후 Specify log에서 아카이브 파일 명을 직접 입력해주는 방법이 있음
아카이브 파일목록 확인
1 2 3 4 5 6 7 8 9 10 11 12 | $ cd /home/oracle/arch/ $ ls -al total 19200 drwxr-xr-x. 2 oracle oinstall 4096 Feb 23 07:26 . drwx------. 7 oracle oinstall 4096 Feb 25 10:02 .. -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 -rw-r-----. 1 oracle oinstall 10763776 Feb 23 04:13 rac11g_21970626162.arc -rw-r-----. 1 oracle oinstall 55808 Feb 23 04:13 rac11g_22970626162.arc |
recover 명령 수행
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | 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/115970626162.arc ORA-00280: change 241661 for thread 1 is in sequence #15 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} /home/oracle/arch/rac11g_115970626162.arc <-- 경로까지 지정해서 아카이브 파일명 입력 ORA-00279: change 241661 generated at needed for thread 2 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} /home/oracle/arch/rac11g_21970626162.arc <-- 경로까지 지정해서 thread 2번에 대한 아카이브 파일명 입력 ORA-00279: change 244906 generated at 02/22/2020 02:09:10 needed for thread 1 ORA-00289: suggestion : /home/oracle/arch/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 .. 원하는 아카이브 파일까지 수동으로 반복 |
이렇게 수동으로 원하는 아카이브 파일까지 입력해줘야함
만약 처음과 두번째 파일을 경로를 모두 입력해서 적용한뒤 그다음에는 auto를 입력한다면
1 2 3 4 5 6 7 8 9 10 11 12 | Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto ORA-00308: cannot open archived log '/home/oracle/arch/116970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 ORA-00308: cannot open archived log '/home/oracle/arch/116970626162.arc' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 3 |
이렇게 처음처럼 아카이브 파일을 찾지 못해서 에러가 발생함
아카이브 파일이 많지않다면 수동으로 입력할 수 있겠지만 많다고 하면
파라미터 파일에서 log_archive_format을 source db와 동일하게 맞춰서 복구 작업을 한 뒤에
추후에 log_archive_format을 변경하는것을 권장함
방법 1을 사용한 뒤 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 | SQL> recover database until time '2020-02-22:02:10:00' using backup controlfile; 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 Specify log: {<RET>=suggested | filename | AUTO | CANCEL} auto <-- auto 입력 ORA-00279: change 244906 generated at 03/13/2018 02:30:36 needed for thread 2 ORA-00289: suggestion : /home/oracle/arch/rac11g_21970626162.arc ORA-00280: change 244906 for thread 2 is in sequence #1 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 |
정상적으로 원하는 시점까지 복구됨
참조
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
https://gyh214.tistory.com/130
https://positivemh.tistory.com/268
https://positivemh.tistory.com/515
https://positivemh.tistory.com/510
https://positivemh.tistory.com/518
'ORACLE > Backup&Recover' 카테고리의 다른 글
rman 백업 정리 및 스크립트 (4) | 2020.05.10 |
---|---|
rac db(asm)에서 특정시점의 데이터를 single db(filesystem) 로 dbname 변경 후 복구 테스트2 (0) | 2020.02.28 |
오라클 rman에서 show all 정보와 list backup 정보는 어디있을까? (0) | 2020.02.24 |
rac db(asm)에서 특정시점의 데이터를 single db(filesystem) 복구 테스트 (0) | 2020.02.23 |
Oracle partition tablespace, table rman 복구 테스트 (0) | 2019.02.19 |