Clonación RMAN sin conexión a target
Una tarea frecuente para el DBA es crear una copia de una base de datos existente. Hay varias opciones que dependen de la versión de Oracle en uso,sin considerar el procedimiento clásico de copia manual de archivos por filesystem mientras la base está baja (sin usar utilitarios).
El utilitario RMAN en la versión 11.2 ofrece el comando DUPLICATE para realizar la clonación de una base, con las siguientes variantes:
- Tomar los datos de una instancia activa
- Usar un respaldo ya existente
Me interesa mostrar aquí un ejemplo completo de creación de una nueva base en el mismo servidor que la base origen, usando el método de clonación RMAN a partir de respaldos sin conexión a la base origen para una base single instance usando archivos en filesystem (no ASM).
¿Por qué esta opción? Este mecanismo es usado frecuentemente en servidores donde hay varias bases y donde periódicamente se actualizan varias a partir de una. Algo habitual en ambientes de test, capacitación o similares.
También es la forma más simple de crear o actualizar una copia de producción con una sintaxis que permite hacerlo con muy poco código (y en este caso, siempre que se disponga de un respaldo de la base original).
El hecho de que sea en el mismo servidor lo hace más complicado que si fuera en otro, ya que los directorios cambian. Simplificando este procedimiento se puede hacer la copia a otro servidor manteniendo la estructura de directorios, algo también muy frecuente.
No incluyo detalles de la clonación a partir de una instancia activa porque es algo menos frecuente de usar en un entorno de producción, ya que genera mucha actividad de lectura en la base de datos origen. Con las nuevas opciones agregadas en 12c esto se mejora (backup sets y section size) y los detalles amerita otro artículo.
En este ejemplo vamos a crear una base de datos de nombre TEST (SID) a partir de la base origen PROD, siguiendo la recomendación OFA para los directorios: datos en /u02/oradata, binarios en /u01/app/oracle (asumimos que ya existen y se comparten con la base origen), y usando Oracle 11gR2 (11.2.0.2) en Linux x86-64 (OpenSuse 12.3).
Primero vemos los pasos a seguir, luego un ejemplode ejecución completa, y finalmente algunos errores que pueden surgir.
Pasos para realizar la duplicación
1) Crear los directorios donde se va a ubicar la nueva base ($ORACLE_BASE/diag/rdbms/test no es necesario porque se crea de forma automática al crear la base).mkdir -p /u01/app/oracle/admin/TEST/adump mkdir /u02/oradata/TEST mkdir /u01/app/oracle/fast_recovery_area/TEST2) Crear archivo de parámetros (pfile).
En versiones anteriores era necesario copiar el archivo de parámetros de la base origen, y luego modificarlo cambiando el nombre de la base y directorios, y agregando los parámetros DB_FILE_NAME_CONVERT / LOG_FILE_NAME_CONVERT. A partir de 11g esto ya no es más obligatorio, pudiendo crear el spfile como copia de la base origen y hacer ajustes de parámetros en la misma sentencia de clonación. Más adelante los detalles. Aprovechando esto, lo único que se precisa en el archivo de parámetros es el nombre de la base:
echo "dbname=TEST" > $ORACLE_HOME/dbs/initTEST.ora3) Crear el password file de la nueva base. Esto se puede hacer manualmente o agregando el parámetro PASSWORD FILE al comando DUPLICATE.
orapwd file=$ORACLE_HOME/dbs/orapwTEST password=xxxxx entries=104) Levantar la nueva base en modo nomount.
set ORACLE_SID=TEST sqlplus / as sysdba startup nomount5) Ejecutar la duplicación.
Vamos a usar el último respaldo completo de la base original, ubicado en /u01/app/oracle/fast_recovery_area/PROD (destino por defecto de respaldos RMAN usando Fast Recovery Area). Notar que en este directorio puede haber muchos respaldos, y el comando DUPLICATE va a tomar el más reciente. Si quisiéramos usar otro respaldo, hay que indicar el path completo (incluyendo backupset/AAAA_MM_DD).
Al elegir no incluir parámetros que conviertan nombres en el archivo pfile, ahora necesitamos hacer más largo este comando:
- Antes del DUPLICATE usamos la nueva funcionalidad en 11.2 de renombrar varios archivos a la vez, con "SET NEWNAME FOR DATABASE" indicando el nuevo path y la regla para nombrar los nuevos archivos. El modificar “%b” deja el nombre original. Más detalles sobre los valores posibles aquí: http://docs.oracle.com/cd/E11882_01/backup.112/e10643/rcmsynta2014.htm
- Al comando DUPLICATE agregamos el parámetro SPFILE para que copie el original, y PARAMETER_VALUE_CONVERT para cambiar nombres de directorios que aparezcan en los parámetros copiados. Hay que tener cuidado en este punto de incluir todos los directorios que referencien a archivos de la base original, ya que si no se cambian se intentarán usar por la nueva base. Una forma simple de no olvidar ninguno es buscarlos en el original:
oracle@oraculo:>strings $ORACLE_HOME/dbs/spfilePROD.ora | grep -i PROD | grep '/' PROD.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment *.audit_file_dest='/u01/app/oracle/admin/PROD/adump' *.control_files='/u02/oradata/PROD/control01 .ctl','/u01/app/oracle/fast_recovery_area/PROD/control02.ctl'Ahora sí, el comando a ejecutar para duplicar es:
run { SET NEWNAME FOR DATABASE TO '/u02/oradata/TEST/%b'; DUPLICATE DATABASE TO "TEST" SPFILE PARAMETER_VALUE_CONVERT '/u02/oradata/PROD/','/u02/oradata/TEST/', '/u01/app/oracle/fast_recovery_area/PROD/','/u01/app/oracle/fast_recovery_area/TEST/', '/u01/app/oracle/admin/PROD/', '/u01/app/oracle/admin/TEST/' BACKUP LOCATION '/u01/app/oracle/fast_recovery_area/PROD/'; }
Ejemplo completo de duplicación
A continuación vemos un ejemplo completo de ejecutar los comandos mostrados antes.Primero, validamos si tenemos un respaldo completo de la base origen. Para hacer completo el ejemplo suponemos que no lo tenemos, así que tomamos uno.
Resaltamos en negrita lo ingresado en la terminal, y en rojo las validaciones importantes del resultado de los comandos.
oracle@oraculo:~>. oraenv ORACLE_SID = [ent11g] ? PROD The Oracle base remains unchanged with value /u01/app/oracle oracle@oraculo:~>sqlplus / as sysdba SQL*Plus: Release 11.2.0.2.0 Production on Tue Aug 20 08:36:46 2013 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Release 11.2.0.2.0 - 64bit Production 08:37:13 SYS@PROD>archive log list Database log mode Archive Mode Automatic archival Enabled Archive destination USE_DB_RECOVERY_FILE_DEST Oldest online log sequence 136 Next log sequence to archive 138 Current log sequence 138 08:37:19 SYS@PROD>exit Disconnected from Oracle Database 11g Release 11.2.0.2.0 - 64bit Production oracle@oraculo:~>rman target / Recovery Manager: Release 11.2.0.2.0 - Production on Wed Aug 21 09:01:46 2013 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. connected to target database: PROD (DBID=462231560) RMAN>show all; using target database control file instead of recovery catalog RMAN configuration parameters for database with db_unique_name PROD are: CONFIGURE RETENTION POLICY TO RECOVERY WINDOW OF 3 DAYS; CONFIGURE BACKUP OPTIMIZATION ON; CONFIGURE DEFAULT DEVICE TYPE TO DISK; # default CONFIGURE CONTROLFILE AUTOBACKUP ON; CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '%F'; # default CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO COMPRESSED BACKUPSET; CONFIGURE DATAFILE BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default CONFIGURE ARCHIVELOG BACKUP COPIES FOR DEVICE TYPE DISK TO 1; # default 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 '/u01/app/oracle/product/11.2.0/std/dbs/snapcf_PROD.f'; # default RMAN>list backup summary; using target database control file instead of recovery catalog List of Backups =============== Key TY LV S Device Type Completion Time #Pieces #Copies Compressed Tag ------- -- -- - ----------- -------------------- ------- ------- ---------- --- 14 B F A DISK 08/AUG/2012 21:07:42 1 1 NO TAG20120808T210739 16 B F A DISK 08/AUG/2012 21:13:15 1 1 NO TAG20120808T211308 18 B F A DISK 10/AUG/2012 21:18:23 1 1 NO TAG20120810T211818 20 B F A DISK 10/AUG/2012 21:31:41 1 1 NO TAG20120810T213136 22 B F A DISK 10/AUG/2012 21:32:13 1 1 NO TAG20120810T213209 23 B F A DISK 20/AUG/2013 00:08:54 1 1 YES TAG20130820T000000 24 B F A DISK 20/AUG/2013 00:09:01 1 1 NO TAG20130820T000857 25 B F A DISK 20/AUG/2013 08:38:40 1 1 YES TAG20130820T083839 26 B F A DISK 20/AUG/2013 08:38:43 1 1 NO TAG20130820T083841 RMAN>backup database plus archivelog; Starting backup at 21/AUG/2013 09:02:10 current log archived allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=143 device type=DISK channel ORA_DISK_1: starting compressed archived log backup set channel ORA_DISK_1: specifying archived log(s) in backup set input archived log thread=1 sequence=135 RECID=10 STAMP=790808277 input archived log thread=1 sequence=136 RECID=11 STAMP=790809179 input archived log thread=1 sequence=137 RECID=12 STAMP=790982292 input archived log thread=1 sequence=138 RECID=13 STAMP=823942366 input archived log thread=1 sequence=139 RECID=14 STAMP=824029333 channel ORA_DISK_1: starting piece 1 at 21/AUG/2013 09:02:14 channel ORA_DISK_1: finished piece 1 at 21/AUG/2013 09:02:29 piece handle=/u01/app/oracle/fast_recovery_area/PROD/backupset/ 2013_08_21/o1_mf_annnn_TAG20130821T090213_919c26ob_.bkp tag=TAG20130821T090213 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15 Finished backup at 21/AUG/2013 09:02:29 Starting backup at 21/AUG/2013 09:02:30 using channel ORA_DISK_1 channel ORA_DISK_1: starting compressed full datafile backup set channel ORA_DISK_1: specifying datafile(s) in backup set input datafile file number=00001 name=/u02/oradata/PROD/system01.dbf input datafile file number=00002 name=/u02/oradata/PROD/sysaux01.dbf input datafile file number=00003 name=/u02/oradata/PROD/undotbs01.dbf input datafile file number=00004 name=/u02/oradata/PROD/users01.dbf input datafile file number=00005 name=/u02/oradata/PROD/prueba.dbf channel ORA_DISK_1: starting piece 1 at 21/AUG/2013 09:02:30 channel ORA_DISK_1: finished piece 1 at 21/AUG/2013 09:04:35 piece handle=/u01/app/oracle/fast_recovery_area/PROD/backupset/ 2013_08_21/o1_mf_nnndf_TAG20130821T090230_919c2tnz_.bkp tag=TAG20130821T090230 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:02:05 Finished backup at 21/AUG/2013 09:04:35 Starting backup at 21/AUG/2013 09:04:36 current log archived using channel ORA_DISK_1 channel ORA_DISK_1: starting compressed archived log backup set channel ORA_DISK_1: specifying archived log(s) in backup set input archived log thread=1 sequence=140 RECID=15 STAMP=824029477 channel ORA_DISK_1: starting piece 1 at 21/AUG/2013 09:04:38 channel ORA_DISK_1: finished piece 1 at 21/AUG/2013 09:04:39 piece handle=/u01/app/oracle/fast_recovery_area/PROD/backupset/ 2013_08_21/o1_mf_annnn_TAG20130821T090438_919c6plp_.bkp tag=TAG20130821T090438 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01 Finished backup at 21/AUG/2013 09:04:39 Starting Control File and SPFILE Autobackup at 21/AUG/2013 09:04:40 piece handle=/u01/app/oracle/fast_recovery_area/PROD/autobackup/ 2013_08_21/o1_mf_s_824029480_919c6tsr_.bkp comment=NONE Finished Control File and SPFILE Autobackup at 21/AUG/2013 09:04:47 RMAN>exit Recovery Manager complete.Listado 1 – Toma de respaldo inicial
Ahora sí podemos ejecutar la duplicación:
oracle@oraculo:~>mkdir -p /u01/app/oracle/admin/TEST/adump oracle@oraculo:~>mkdir -p /u02/oradata/TEST oracle@oraculo:~>mkdir /u01/app/oracle/fast_recovery_area/TEST oracle@oraculo:~>orapwd file=/u01/app/oracle/product/11.2.0/std/dbs/ orapwTEST password=secreta entries=10 oracle@oraculo:~>export ORACLE_SID=TEST oracle@oraculo:~>sqlplus / as sysdba SQL*Plus: Release 11.2.0.2.0 Production on Wed Aug 21 09:03:16 2013 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to an idle instance. 09:03:42 SYS@TEST>startup nomount; ORACLE instance started. Total System Global Area 217157632 bytes Fixed Size 2225064 bytes Variable Size 159386712 bytes Database Buffers 50331648 bytes Redo Buffers 5214208 bytes 09:03:55 SYS@TEST>exit Disconnected from Oracle Database 11g Release 11.2.0.2.0 - 64bit Production oracle@oraculo:~>rman auxiliary sys Recovery Manager: Release 11.2.0.2.0 - Production on Wed Aug 21 09:04:12 2013 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. auxiliary database Password: connected to auxiliary database: TEST (not mounted) RMAN>run { SET NEWNAME FOR DATABASE TO '/u02/oradata/TEST/%b'; DUPLICATE DATABASE TO "TEST" SPFILE PARAMETER_VALUE_CONVERT '/u02/oradata/PROD/', '/u02/oradata/TEST/','/u01/app/oracle/fast_recovery_area/ PROD/','/u01/app/oracle/fast_recovery_area/TEST/' BACKUP LOCATION '/u01/app /oracle/fast_recovery_area/PROD/' ; } executing command: SET NEWNAME Starting Duplicate Db at 21/AUG/2013 09:05:14 contents of Memory Script: { restore clone spfile to '/u01/app/oracle/product/11.2.0/std/dbs/spfileTEST.ora' from '/u01/app/oracle/fast_recovery_area/PROD/autobackup/2013_08_21/o1_mf_s_824029480_919c6tsr_.bkp'; sql clone "alter system set spfile= ''/u01/app/oracle/product/11.2.0/std/dbs/spfileTEST.ora''"; } executing Memory Script Starting restore at 21/AUG/2013 09:05:15 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=96 device type=DISK channel ORA_AUX_DISK_1: restoring spfile from AUTOBACKUP /u01/app/oracle/fast_recovery_area/ PROD/autobackup/2013_08_21/o1_mf_s_824029480_919c6tsr_.bkp channel ORA_AUX_DISK_1: SPFILE restore from AUTOBACKUP complete Finished restore at 21/AUG/2013 09:05:16 sql statement: alter system set spfile= ''/u01/app/oracle/product/11.2.0/std/dbs/spfileTEST.ora'' contents of Memory Script: { sql clone "alter system set db_name = ''TEST'' comment= ''duplicate'' scope=spfile"; sql clone "alter system set control_files = ''/u02/oradata/TEST/control01.ctl'', ''/u01/app/oracle/fast_recovery_area/TEST/control02.ctl'' comment= '''' scope=spfile"; shutdown clone immediate; startup clone nomount; } executing Memory Script sql statement: alter system set db_name = ''TEST'' comment= ''duplicate'' scope=spfile sql statement: alter system set control_files = ''/u02/oradata/TEST/control01.ctl'', ''/u01/app/oracle/fast_recovery_area/TEST/control02.ctl'' comment= '''' scope=spfile Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 1043886080 bytes Fixed Size 2233088 bytes Variable Size 603983104 bytes Database Buffers 432013312 bytes Redo Buffers 5656576 bytes contents of Memory Script: { sql clone "alter system set db_name = ''PROD'' comment= ''Modified by RMAN duplicate'' scope=spfile"; sql clone "alter system set db_unique_name = ''TEST'' comment= ''Modified by RMAN duplicate'' scope=spfile"; shutdown clone immediate; startup clone force nomount restore clone primary controlfile from '/u01/app/oracle/fast_recovery_area/ PROD/autobackup/2013_08_21/o1_mf_s_824029480_919c6tsr_.bkp'; alter clone database mount; } executing Memory Script sql statement: alter system set db_name = ''PROD'' comment= ''Modified by RMAN duplicate'' scope=spfile sql statement: alter system set db_unique_name = ''TEST'' comment= ''Modified by RMAN duplicate'' scope=spfile Oracle instance shut down Oracle instance started Total System Global Area 1043886080 bytes Fixed Size 2233088 bytes Variable Size 603983104 bytes Database Buffers 432013312 bytes Redo Buffers 5656576 bytes Starting restore at 21/AUG/2013 09:05:35 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=134 device type=DISK channel ORA_AUX_DISK_1: restoring control file channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01 output file name=/u02/oradata/TEST/control01.ctl output file name=/u01/app/oracle/fast_recovery_area/TEST/control02.ctl Finished restore at 21/AUG/2013 09:05:36 database mounted released channel: ORA_AUX_DISK_1 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=134 device type=DISK contents of Memory Script: { set until scn 2718101; set newname for datafile 1 to "/u02/oradata/TEST/system01.dbf"; set newname for datafile 2 to "/u02/oradata/TEST/sysaux01.dbf"; set newname for datafile 3 to "/u02/oradata/TEST/undotbs01.dbf"; set newname for datafile 4 to "/u02/oradata/TEST/users01.dbf"; set newname for datafile 5 to "/u02/oradata/TEST/prueba.dbf"; restore clone database ; } executing Memory Script executing command: SET until clause executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME Starting restore at 21/AUG/2013 09:05:43 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 /u02/oradata/TEST/system01.dbf channel ORA_AUX_DISK_1: restoring datafile 00002 to /u02/oradata/TEST/sysaux01.dbf channel ORA_AUX_DISK_1: restoring datafile 00003 to /u02/oradata/TEST/undotbs01.dbf channel ORA_AUX_DISK_1: restoring datafile 00004 to /u02/oradata/TEST/users01.dbf channel ORA_AUX_DISK_1: restoring datafile 00005 to /u02/oradata/TEST/prueba.dbf channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/ PROD/backupset/2013_08_21/o1_mf_nnndf_TAG20130821T090230_919c2tnz_.bkp channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/PROD/backupset/ 2013_08_21/o1_mf_nnndf_TAG20130821T090230_919c2tnz_.bkp tag=TAG20130821T090230 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:25 Finished restore at 21/AUG/2013 09:07:09 contents of Memory Script: { switch clone datafile all; } executing Memory Script datafile 1 switched to datafile copy input datafile copy RECID=6 STAMP=824029629 file name=/u02/oradata/TEST/system01.dbf datafile 2 switched to datafile copy input datafile copy RECID=7 STAMP=824029629 file name=/u02/oradata/TEST/sysaux01.dbf datafile 3 switched to datafile copy input datafile copy RECID=8 STAMP=824029629 file name=/u02/oradata/TEST/undotbs01.dbf datafile 4 switched to datafile copy input datafile copy RECID=9 STAMP=824029629 file name=/u02/oradata/TEST/users01.dbf datafile 5 switched to datafile copy input datafile copy RECID=10 STAMP=824029630 file name=/u02/oradata/TEST/prueba.dbf contents of Memory Script: { set until scn 2718101; recover clone database delete archivelog ; } executing Memory Script executing command: SET until clause Starting recover at 21/AUG/2013 09:07:11 using channel ORA_AUX_DISK_1 starting media recovery archived log for thread 1 with sequence 139 is already on disk as file /u01/app/oracle/ fast_recovery_area/PROD/archivelog/2013_08_21/o1_mf_1_139_919c23sz_.arc archived log for thread 1 with sequence 140 is already on disk as file /u01/app/oracle/ fast_recovery_area/PROD/archivelog/2013_08_21/o1_mf_1_140_919c6okc_.arc archived log file name=/u01/app/oracle/fast_recovery_area/PROD/archivelog/2013_08_21/ o1_mf_1_139_919c23sz_.arc thread=1 sequence=139 archived log file name=/u01/app/oracle/fast_recovery_area/PROD/archivelog/2013_08_21/ o1_mf_1_140_919c6okc_.arc thread=1 sequence=140 media recovery complete, elapsed time: 00:00:02 Finished recover at 21/AUG/2013 09:07:14 Oracle instance started Total System Global Area 1043886080 bytes Fixed Size 2233088 bytes Variable Size 603983104 bytes Database Buffers 432013312 bytes Redo Buffers 5656576 bytes contents of Memory Script: { sql clone "alter system set db_name = ''TEST'' comment= ''Reset to original value by RMAN'' scope=spfile"; sql clone "alter system reset db_unique_name scope=spfile"; shutdown clone immediate; startup clone nomount; } executing Memory Script sql statement: alter system set db_name = ''TEST'' comment= ''Reset to original value by RMAN'' scope=spfile sql statement: alter system reset db_unique_name scope=spfile Oracle instance shut down connected to auxiliary database (not started) Oracle instance started Total System Global Area 1043886080 bytes Fixed Size 2233088 bytes Variable Size 603983104 bytes Database Buffers 432013312 bytes Redo Buffers 5656576 bytes sql statement: CREATE CONTROLFILE REUSE SET DATABASE "TEST" RESETLOGS ARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 100 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 SIZE 50 M , GROUP 2 SIZE 50 M , GROUP 3 SIZE 50 M DATAFILE '/u02/oradata/TEST/system01.dbf' CHARACTER SET WE8ISO8859P15 contents of Memory Script: { set newname for tempfile 1 to "/u02/oradata/TEST/temp01.dbf"; switch clone tempfile all; catalog clone datafilecopy "/u02/oradata/TEST/sysaux01.dbf", "/u02/oradata/TEST/undotbs01.dbf", "/u02/oradata/TEST/users01.dbf", "/u02/oradata/TEST/prueba.dbf"; switch clone datafile all; } executing Memory Script executing command: SET NEWNAME renamed tempfile 1 to /u02/oradata/TEST/temp01.dbf in control file cataloged datafile copy datafile copy file name=/u02/oradata/TEST/sysaux01.dbf RECID=1 STAMP=824029648 cataloged datafile copy datafile copy file name=/u02/oradata/TEST/undotbs01.dbf RECID=2 STAMP=824029648 cataloged datafile copy datafile copy file name=/u02/oradata/TEST/users01.dbf RECID=3 STAMP=824029648 cataloged datafile copy datafile copy file name=/u02/oradata/TEST/prueba.dbf RECID=4 STAMP=824029648 datafile 2 switched to datafile copy input datafile copy RECID=1 STAMP=824029648 file name=/u02/oradata/TEST/sysaux01.dbf datafile 3 switched to datafile copy input datafile copy RECID=2 STAMP=824029648 file name=/u02/oradata/TEST/undotbs01.dbf datafile 4 switched to datafile copy input datafile copy RECID=3 STAMP=824029648 file name=/u02/oradata/TEST/users01.dbf datafile 5 switched to datafile copy input datafile copy RECID=4 STAMP=824029648 file name=/u02/oradata/TEST/prueba.dbf contents of Memory Script: { Alter clone database open resetlogs; } executing Memory Script database opened Finished Duplicate Db at 21/AUG/2013 09:07:51 RMAN>exit Recovery Manager complete.Listado 2 – Ejecución de RMAN Duplicate
Vemos que finalizó OK. Validamos cómo quedó la nueva base:
oracle@oraculo:~>ls -lrt /u02/oradata/TEST total 1430580 -rw-r----- 1 oracle oinstall 744497152 Aug 21 09:07 system01.dbf -rw-r----- 1 oracle oinstall 99622912 Aug 21 09:07 undotbs01.dbf -rw-r----- 1 oracle oinstall 5251072 Aug 21 09:07 users01.dbf -rw-r----- 1 oracle oinstall 5251072 Aug 21 09:07 prueba.dbf -rw-r----- 1 oracle oinstall 303046656 Aug 21 09:07 temp01.dbf -rw-r----- 1 oracle oinstall 597696512 Aug 21 09:07 sysaux01.dbf -rw-r----- 1 oracle oinstall 10076160 Aug 21 09:08 control01.ctl oracle@oraculo:~>sqlplus / as sysdba SQL*Plus: Release 11.2.0.2.0 Production on Wed Aug 21 09:08:47 2013 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Release 11.2.0.2.0 - 64bit Production 09:08:48 SYS@TEST>select instance_name, status from v$instance; INSTANCE_NAME STATUS -------------------- ---------------------- TEST OPEN Elapsed: 00:00:00.11 09:08:51 SYS@TEST>exit Disconnected from Oracle Database 11g Release 11.2.0.2.0 - 64bit Production oracle@oraculo:~>strings $ORACLE_HOME/dbs/spfileTEST.ora PROD.__db_cache_size=268435456 TEST.__db_cache_size=432013312 PROD.__java_pool_size=4194304 TEST.__java_pool_size=4194304 PROD.__large_pool_size=4194304 TEST.__large_pool_size=4194304 PROD.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment TEST.__oracle_base='/u01/app/oracle'#ORACLE_BASE set from environment PROD.__pga_aggregate_target=364904448 TEST.__pga_aggregate_target=419430400 PROD.__sga_target=683671552 TEST.__sga_target=629145600 PROD.__shared_io_p ool_size=0 TEST.__shared_io_pool_size=0 PROD.__shared_pool_size=390070272 TEST.__shared_pool_size=176160768 PROD.__streams_pool_size=4194304 TEST.__streams_pool_size=0 *.audit_file_dest='/u01/app/oracle/admin/TEST/adump' *.audit_trail='db' *.compatible='11.2.0.0.0' *.control_files='/u02/oradata/TEST/control01.ctl','/u01/app/oracle/fast_recovery_area/ TEST/control02.ctl'#Restore Controlfile *.db_block_size=8192 *.db_domain='' *.db_name='TEST'#Reset to original value by RMAN *.db_ recovery_file_dest='/u01/app/oracle/fast_recovery_area' *.db_recovery_file_dest_size=10485760000 *.diagnostic_dest='/u01/app/oracle' *.dispatchers='(PROTOCOL=TCP) (SERVICE=PRODXDB)' *.memory_target=1048576000 *.open_cursors=300 *.processes=150 *.remote_login_passwordfile='EXCLUSIVE' *.undo_tablespace='UNDOTBS1'Listado 3 – Validaciones
Con esto la nueva base queda funcionando, y podemos ver todos los pasos que fueron realizados por el comando DUPLICATE, lo que sirve para investigar en caso que se genere algún error en el proceso de duplicación.
Errores posibles
Si algunos de los requisitos previos no se cumplen, o no se utilizan los parámetros correctos en el comando DUPLICATE, es posible encontrarse con errores. A continuación se repasan algunos errores que generé de forma intencional omitiendo alguna de las partes del procedimiento descripto antes, para ver las distintas situaciones que se pueden dar y cómo resolverlas.Si luego de un error vamos a reintentar la duplicación, hay que recordar borrar el nuevo spfile creado por el DUPLICATE (pudo quedar creado con valores incorrectos), y volver a reiniciar la nueva base en modo nomount:
oracle@oraculo:~>rm $ORACLE_HOME/dbs/spfileTEST.ora oracle@oraculo:~>sqlplus / as sysdba SQL*Plus: Release 11.2.0.2.0 Production on Wed Aug 21 08:46:09 2013 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Release 11.2.0.2.0 - 64bit Production 08:46:19 SYS@TEST>shutdown immediate; ORA-01507: database not mounted ORACLE instance shut down. 08:46:32 SYS@TEST>startup nomount ORACLE instance started. Total System Global Area 217157632 bytes Fixed Size 2225064 bytes Variable Size 159386712 bytes Database Buffers 50331648 bytes Redo Buffers 5214208 bytes 08:46:43 SYS@TEST>exitListado 4 – Previo a reintentar duplicaciones fallidas
Ahora sí, estos son algunos errores que pueden encontrarse y su explicación:
1) RMAN-05569: SPFILE backup not found
Starting Duplicate Db at 20/AUG/2013 08:35:51 RMAN-00571: ==================================================== RMAN-00569: ============= ERROR MESSAGE STACK FOLLOWS ========== RMAN-00571: ==================================================== RMAN-03002: failure of Duplicate Db command at 08/20/2013 08:35:51 RMAN-05501: aborting duplication of target database RMAN-05569: SPFILE backup not found in /u01/app/oracle/fast_recovery_area/PROD/backupset/2013_08_20/Este error se produjo porque el autobackup del controlfile/spfile no está en el directorio indicado en el parámetro LOCATION. Notar que este path no es el usado en el ejemplo exitoso anterior, sino que tiene un día en particular, 2013_08_20. Los autobackup se generan bajo el directorio FRA/PROD/autobackup/2013_08_20, por eso no lo encuentra ahí.La solución es copiar a este directorio el archivo de respaldo que incluye el spfile.
2) RMAN-05576: CONTROLFILE backup not found
Starting Duplicate Db at 20/AUG/2013 08:39:09 RMAN-00571: ==================================================== RMAN-00569: ============ ERROR MESSAGE STACK FOLLOWS =========== RMAN-00571: ==================================================== RMAN-03002: failure of Duplicate Db command at 08/20/2013 08:39:09 RMAN-05501: aborting duplication of target database RMAN-05576: CONTROLFILE backup not found for database PROD with DBID 462231560 in /u01/app/oracle/fast_recovery_area/PROD/backupset/2013_08_20/Este error es similar al anterior, pero esta vez se pudo encontrar el spfile (o no se copió si no incluyeron la clausula SPFILE en el comando DUPLICATE), pero no pudo encontrar un respaldo del controlfile. En este caso también se apunta a un directorio que no lo tiene, por lo que se resuelve de igual forma, copiando allí el archivo que incluye el respaldo del controfile.
3) ORA-00205: error in identifying control file
RMAN-00571: =================================================== RMAN-00569: =========== ERROR MESSAGE STACK FOLLOWS =========== RMAN-00571: =================================================== RMAN-03002: failure of Duplicate Db command at 08/20/2013 08:40:52 RMAN-05501: aborting duplication of target database RMAN-03015: error occurred in stored script Memory Script RMAN-06136: ORACLE error from auxiliary database: ORA-00205: error in identifying control file, check alert log for more infoEste error es delicado porque compromete los controfile de la base original, que pudieron ser sobrescritos al ejecutar el duplicate. Es consecuencia de omitir alguno de los path donde existen controlfiles en el parámetro PARAMETER_VALUE_CONVERT. Esto se puede ver fácilmente inspeccionando la salida previa al error, del mismo comando DUPLICATE, al comienzo cuando ejecuta "alter system set control_files". Para generar este error de ejemplo, omití el par '/u01/app/oracle/fast_recovery_area/PROD/','/u01/app/oracle/fast_recovery_area/TEST/' al final de PARAMETER_VALUE_CONVERT.
También se ve con claridad cuál es el controlfile que no se ubicó correctamente en el alert.log de la nueva base:
oracle@oraculo:~>tail $ORACLE_BASE/diag/rdbms/test/TEST/trace/alert_TEST.log alter database mount ORA-00210: cannot open the specified control file ORA-00202: control file: '/u01/app/oracle/fast_recovery_area/PROD/control02.ctl' ORA-27086: unable to lock file - already in use Linux-x86_64 Error: 11: Resource temporarily unavailable Additional information: 8 Additional information: 4089 Tue Aug 20 08:40:35 2013 Checker run found 1 new persistent data failures ORA-205 signalled during: alter database mount... Tue Aug 20 08:40:35 2013 License high water mark = 3 USER (ospid: 5952): terminating the instance Instance terminated by USER, pid = 5952Se resuelve agregando el path de este controlfile junto con el nuevo directorio al parámetro PARAMETER_VALUE_CONVERT. Se debe validar que no se dañó el controlfile de la base origen al ejecutar este comando.
4) ORA-19504: failed to create file
RMAN-00571: ==================================================== RMAN-00569: ============ ERROR MESSAGE STACK FOLLOWS =========== RMAN-00571: ==================================================== RMAN-03002: failure of Duplicate Db command at 08/20/2013 08:55:18 RMAN-05501: aborting duplication of target database RMAN-03015: error occurred in stored script Memory Script ORA-19504: failed to create file "/u01/app/oracle/fast_recovery_area/TEST/control02.ctl" ORA-27040: file create error, unable to create file Linux-x86_64 Error: 2: No such file or directory ORA-19600: input file is control file (/u02/oradata/TEST/control01.ctl) ORA-19601: output file is control file (/u01/app/oracle/fast_recovery_area/TEST/control02.ctl)Este error es claro, no existe el directorio /u01/app/oracle/fast_recovery_area/TEST/
5) RMAN-05001: auxiliary file name ... conflicts
Errors in memory script RMAN-03015: error occurred in stored script Memory Script RMAN-06136: ORACLE error from auxiliary database: ORA-01507: database not mounted ORA-06512: at "SYS.X$DBMS_RCVMAN", line 13371 ORA-06512: at line 1 RMAN-05501: aborting duplication of target database RMAN-05001: auxiliary file name /u02/oradata/PROD/prueba.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /u02/oradata/PROD/undotbs01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /u02/oradata/PROD/sysaux01.dbf conflicts with a file used by the target database RMAN-05001: auxiliary file name /u02/oradata/PROD/system01.dbf conflicts with a file used by the target database RMAN-00571: ==================================================== RMAN-00569: ============ ERROR MESSAGE STACK FOLLOWS =========== RMAN-00571: ==================================================== RMAN-03002: failure of Duplicate Db command at 08/20/2013 08:58:25 RMAN-00567: Recovery Manager could not print some error messagesEn este caso no incluí el primer paso de "SET NEWNAME..", y al no tener los parámetros DB_FILE_NAME_CONVERT y LOG_FILE_NAME_CONVERT en el pfile de la nueva base, el controlfile trata de usar los de la base origen sin renombrarlos
No hay comentarios:
Publicar un comentario