Transport an entire database to a Different platform
Here I’m go to demonstrate How do we transport entire database to a different platform.
We can use “convert database” command to move an entire database to different operating system But we need to check out both Operating system having same endian format.
Here I’m go to Transport Database From Linux 32 bit machine to Windows 7 64 bit machine.
Source Database :
Database Name –> dbasm
OS –>Linux 32 Bit,
Endian Format :
SQL> col platform_name for a40 SQL> set linesize 100 SQL> select a.platform_id,a.platform_name,b.endian_format 2 from v$database a,v$transportable_platform b where b.platform_id(+) = a.platform_id; PLATFORM_ID PLATFORM_NAME ENDIAN_FORMAT ----------- ---------------------------------------- -------------- 10 Linux IA (32-bit) Little
Target Database :
OS --> Windows 7 64 Bit Endian Format (I checked currently running on another database of this OS). SQL> set linesize 100 SQL> col platform_name for a40 SQL> select a.platform_id,a.platform_name,b.endian_format 2 from v$database a,v$transportable_platform b where b.platform_id(+) = a.platform_id; PLATFORM_ID PLATFORM_NAME ENDIAN_FORMAT ----------- ---------------------------------------- -------------- 12 Microsoft Windows x86 64-bit Little
Step 1 : Create One Tablespace and add a table and some data
SQL> select name from v$database; NAME---------DBASM SQL> create tablespace testtbs datafile '+DATA' size 50m; Tablespace created. SQL> create user testme identified by testme default tablespace testtbs; User created. SQL> grant connect,resource to testme; Grant succeeded. SQL> conn testme/testmeConnected.SQL> create table employee(name varchar2(20)); Table created. SQL> insert into employee values('azar'); 1 row created. SQL> insert into employee values('kareem'); 1 row created. SQL> insert into employee values('jabar'); 1 row created. SQL> insert into employee values('ajmal'); 1 row created. SQL> commit; Commit complete.
Step 2: Check Datafile
NAME -------------------------------------------------------------------------------- +DATA/dbasm/datafile/system.256.753010703 +DATA/dbasm/datafile/sysaux.257.753010705 +DATA/dbasm/datafile/undotbs1.258.753010705 +DATA/dbasm/datafile/users.259.753010705 +DATA/dbasm/datafile/testtbs.275.753248961
Step 3:
Take RMAN BACKUP
Step 4:
The source database is eligible for transporting to the destination operatingsystem platform by executing the dbms_tdb.check_db procedure.
SQL> shutdown immediate Database closed. Database dismounted. ORACLE instance shut down. SQL> startup mount ORACLE instance started. Total System Global Area 636100608 bytes Fixed Size 1338392 bytes Variable Size 222299112 bytes Database Buffers 406847488 bytes Redo Buffers 5615616 bytes Database mounted. SQL> alter database open read only; Database altered. SQL> set serveroutput on SQL> declare 2 db_ready boolean; 3 begin 4 db_ready := dbms_tdb.check_db('Microsoft Windows x86 64-bit',dbms_tdb.skip_readonly); 5 end; 6 / PL/SQL procedure successfully completed. For External Table. SQL> declare 2 external boolean; 3 begin 4 external := dbms_tdb.check_external; 5 end; 6 / The following directories exist in the database: SYS.ORACLE_OCM_CONFIG_DIR, SYS.DATA_PUMP_DIR, SYS.XMLDIR PL/SQL procedure successfully completed.
Step 5: Convert Database . Database should be in Read Only mode.
[oracle@mazar ~]$ rlwrap rman target / Recovery Manager: Release 11.2.0.1.0 - Production on Wed Jun 8 05:28:46 2011 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. connected to target database: DBASM (DBID=2095353796) RMAN> convert database new database 'dbasm' 2> transport script '/u01/temp/dbasm_script' 3> to platform 'Microsoft Windows x86 64-bit' 4> db_file_name_convert '+DATA/dbasm/datafile/' '/u01/temp/'; Starting conversion at source at 08-JUN-11 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=33 device type=DISK Directory SYS.ORACLE_OCM_CONFIG_DIR found in the database Directory SYS.DATA_PUMP_DIR found in the database Directory SYS.XMLDIR found in the database User SYS with SYSDBA and SYSOPER privilege found in password file channel ORA_DISK_1: starting datafile conversion input datafile file number=00001 name=+DATA/dbasm/datafile/system.256.753010703 converted datafile=/u01/temp/system.256.753010703 channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:59 channel ORA_DISK_1: starting datafile conversion input datafile file number=00002 name=+DATA/dbasm/datafile/sysaux.257.753010705 converted datafile=/u01/temp/sysaux.257.753010705 channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:55 channel ORA_DISK_1: starting datafile conversion input datafile file number=00003 name=+DATA/dbasm/datafile/undotbs1.258.753010705 converted datafile=/u01/temp/undotbs1.258.753010705 channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:07 channel ORA_DISK_1: starting datafile conversion input datafile file number=00005 name=+DATA/dbasm/datafile/testtbs.275.753248961 converted datafile=/u01/temp/testtbs.275.753248961 channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:07 channel ORA_DISK_1: starting datafile conversion input datafile file number=00004 name=+DATA/dbasm/datafile/users.259.753010705 converted datafile=/u01/temp/users.259.753010705 channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:03 Edit init.ora file /u01/app/oracle/product/11.2.0/dbhome_1/dbs/init_00mebgha_1_0.ora. This PFILE will be used to create the database on the target platform Run SQL script /u01/temp/dbasm_script on the target platform to create database To recompile all PL/SQL modules, run utlirp.sql and utlrp.sql on the target platform To change the internal database identifier, use DBNEWID Utility Finished conversion at source at 08-JUN-11 RMAN>
Step 6:
Now Move the “dbasm_script”,pfile –“init_00mebgha_1_0.ora”, and all db file from “/u01/temp/”
to Windows platform using External Hard Disk.
Now you need to edit the “Init” file and “dbasm_script” appropriate your windows directory struture where you want restore
all datafiles.
i just Edited My init Ora file like Below
Step 7: copied init_00mebgha_1_0.ora and renamed it initDBASM.ora –>
C:\app\Azar\product\11.2.0\dbhome_1\dbs\initDBASM.ora
Edit initDBASM.ora
# Please change the values of the following parameters: db_create_file_dest = "C:\app\Azar\product\11.2.0\dbhome_1\dbs\dbasm" db_recovery_file_dest = "C:\app\Azar\product\11.2.0\dbhome_1\dbs\dbasm" db_recovery_file_dest_size= 8078229504 audit_file_dest = "C:\app\Azar\admin\dbasm\adump" db_name = "DBASM" # Please review the values of the following parameters: # __oracle_base = "C:\app\Azar" __shared_pool_size = 209715200 __large_pool_size = 4194304 __java_pool_size = 4194304 __streams_pool_size = 4194304 __sga_target = 637534208 __db_cache_size = 406847488 __shared_io_pool_size = 0 remote_login_passwordfile= "EXCLUSIVE" db_domain = "" dispatchers = "(PROTOCOL=TCP) (SERVICE=dbasmXDB)" __pga_aggregate_target = 213909504 # The values of the following parameters are from source database: processes = 150 sga_target = 637534208 db_block_size = 8192 compatible = "11.2.0.0.0" log_archive_format = "%t_%s_%r.dbf" undo_tablespace = "UNDOTBS1" audit_trail = "OS" open_cursors = 300 pga_aggregate_target = 211812352 # diagnostic_dest = "C:\app\Azar"
Step 8: Copied dbasm_script.sql file –> C:\app\dbasm_script.sql
Edited below like
STARTUP NOMOUNT PFILE='C:\app\Azar\product\11.2.0\dbhome_1\dbs\initDBASM.ora' -- Create SPFILE CREATE SPFILE FROM PFILE = 'C:\app\Azar\product\11.2.0\dbhome_1\dbs\initDBASM.ora'; STARTUP FORCE NOMOUNT CREATE CONTROLFILE REUSE SET DATABASE "DBASM" RESETLOGS ARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 100 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 SIZE 50M BLOCKSIZE 512, GROUP 2 SIZE 50M BLOCKSIZE 512, GROUP 3 SIZE 50M BLOCKSIZE 512 DATAFILE 'C:\app\Azar\oradata\dbasm\system.256.753010703', 'C:\app\Azar\oradata\dbasm\sysaux.257.753010705', 'C:\app\Azar\oradata\dbasm\undotbs1.258.753010705', 'C:\app\Azar\oradata\dbasm\users.259.753010705', 'C:\app\Azar\oradata\dbasm\testtbs.275.753248961' CHARACTER SET WE8MSWIN1252 ; -- 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 SIZE 20971520 AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M; -- End of tempfile additions. -- set echo off prompt ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ prompt * Your database has been created successfully! prompt * There are many things to think about for the new database. Here prompt * is a checklist to help you stay on track: prompt * 1. You may want to redefine the location of the directory objects. prompt * 2. You may want to change the internal database identifier (DBID) prompt * or the global database name for this database. Use the prompt * NEWDBID Utility (nid). prompt ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ SHUTDOWN IMMEDIATE STARTUP UPGRADE @@ ?/rdbms/admin/utlirp.sql SHUTDOWN IMMEDIATE STARTUP -- The following step will recompile all PL/SQL modules. -- It may take serveral hours to complete. @@ ?/rdbms/admin/utlrp.sql set feedback 6;
Step 9:
Copied DBF files to “C:\app\Azar\oradata\dbasm\”
Step 10: Create new instance and password file
C:\Windows\system32>oradim -new -sid dbasm Instance created. C:\Windows\system32>orapwd file=c:\app\Azar\product\11.2.0\dbhome_1\database\PWDdbasm.ora password=Test123
Step 11: Run the script file
C:\Windows\system32>set ORACLE_SID=dbasm C:\Windows\system32>sqlplus SQL*Plus: Release 11.2.0.1.0 Production on Wed Jun 8 14:31:52 2011 Copyright (c) 1982, 2010, Oracle. All rights reserved. Enter user-name: sys/Test123 as sysdba Connected to an idle instance. SQL> @c:\app\dbasm_script.sql ORACLE instance started. Total System Global Area 634679296 bytes Fixed Size 2178416 bytes Variable Size 184550032 bytes Database Buffers 440401920 bytes Redo Buffers 7548928 bytes File created. ORACLE instance started. Total System Global Area 634679296 bytes Fixed Size 2178416 bytes Variable Size 184550032 bytes Database Buffers 440401920 bytes Redo Buffers 7548928 bytes Control file created. Database altered. ALTER TABLESPACE TEMP ADD TEMPFILE * ERROR at line 1: ORA-00604: error occurred at recursive SQL level 1 ORA-06553: PLS-801: internal error [56327] ORA-00604: error occurred at recursive SQL level 1 ORA-06553: PLS-801: internal error [56327] ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ * Your database has been created successfully! * There are many things to think about for the new database. Here * is a checklist to help you stay on track: * 1. You may want to redefine the location of the directory objects. * 2. You may want to change the internal database identifier (DBID) * or the global database name for this database. Use the * NEWDBID Utility (nid). ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ Database closed. Database dismounted. ORACLE instance shut down. ORACLE instance started. Total System Global Area 634679296 bytes Fixed Size 2178416 bytes Variable Size 184550032 bytes Database Buffers 440401920 bytes Redo Buffers 7548928 bytes Database mounted Database opened. DOC> utlirp.sql completed successfully. All PL/SQL objects in the DOC> database have been invalidated. DOC> DOC> Shut down and restart the database in normal mode and run utlrp.sql to DOC> recompile invalid objects. DOC>####################################################################### DOC>####################################################################### DOC># SQL> SHUTDOWN IMMEDIATE Database closed. Database dismounted. ORACLE instance shut down. SQL> STARTUP ORACLE instance started. Total System Global Area 634679296 bytes Fixed Size 2178416 bytes Variable Size 184550032 bytes Database Buffers 440401920 bytes Redo Buffers 7548928 bytes Database mounted. Database opened. SQL> -- The following step will recompile all PL/SQL modules. SQL> -- It may take serveral hours to complete. SQL> @@ ?/rdbms/admin/utlrp.sql SQL> Rem SQL> Rem $Header: utlrp.sql 24-jul-2003.10:06:51 gviswana Exp $ SQL> Rem SQL> Rem utlrp.sql SQL> Rem SQL> Rem Copyright (c) 1998, 2003, Oracle Corporation. All rights reserved. SQL> Rem SQL> Rem NAME SQL> Rem utlrp.sql - Recompile invalid objects SQL> Rem Warning: XDB now invalid, could not find xdbconfig ORDIM INVALID OBJECTS: CODE_SEQUENCE110_T - 6 - 13 ORDIM INVALID OBJECTS: CODE_SEQUENCE112_COLL - 6 - 13 ORDIM INVALID OBJECTS: CODE_SQ111_T - 6 - 13 ORDIM INVALID OBJECTS: ORD_DICOM_HEADER114_T - 6 - 13 ORDIM INVALID OBJECTS: MEDIA_STORAGE_SOP_CLASS116_T - 6 - 13 ORDIM INVALID OBJECTS: MEDIA_STORAGE_SOP_INSTA117_T - 6 - 13 ORDIM INVALID OBJECTS: TRANSFER_SYNTAX_UID118_T - 6 - 13 ORDIM INVALID OBJECTS: IMPLEMENTATION_CLASS_UI119_T - 6 - 13 ORDIM INVALID OBJECTS: IMPLEMENTATION_VERSION_120_T - 6 - 13 ORDIM INVALID OBJECTS: SOURCE_APPLICATION_ENTI121_T - 6 - 13 ORDIM INVALID OBJECTS: FILE_META_HEADER115_T - 6 - 13 ORDIM INVALID OBJECTS: NAME124_T - 6 - 13 ORDIM INVALID OBJECTS: ID125_T - 6 - 13 ORDIM INVALID OBJECTS: BIRTH_DATE126_T - 6 - 13 ORDIM INVALID OBJECTS: SEX127_T - 6 - 13 ORDIM INVALID OBJECTS: PATIENT123_T - 6 - 13 ORDIM INVALID OBJECTS: INSTANCE_UID129_T - 6 - 13 ORDIM INVALID OBJECTS: DATE130_T - 6 - 13 ORDIM INVALID OBJECTS: TIME132_T - 6 - 13 ORA-25153: Temporary Tablespace is Empty ORA-01403: no data found FAILED CHECK FOR PACKAGE BODY WWV_FLOW_API PL/SQL procedure successfully completed. Now Database successfully created.
Step 12: Check the new database
SQL> select status from v$instance; STATUS ------------ OPEN SQL> select name from v$database; NAME --------- DBASM SQL> select name from v$datafile; NAME -------------------------------------------------------------------------------- C:\APP\AZAR\ORADATA\DBASM\SYSTEM.256.753010703 C:\APP\AZAR\ORADATA\DBASM\SYSAUX.257.753010705 C:\APP\AZAR\ORADATA\DBASM\UNDOTBS1.258.753010705 C:\APP\AZAR\ORADATA\DBASM\USERS.259.753010705 C:\APP\AZAR\ORADATA\DBASM\TESTTBS.275.753248961 SQL> select * from v$tempfile; no rows selected SQL> ALTER TABLESPACE TEMP ADD TEMPFILE SIZE 20971520 AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M; Tablespace altered. SQL> select name from v$tempfile; NAME -------------------------------------------------------------------------------- C:\APP\AZAR\PRODUCT\11.2.0\DBHOME_1\DBS\DBASM\DBASM\DATAFILE\O1_MF_TEMP_6YYR9B7D _.TMP SQL> conn testme/testme Connected. SQL> select * from tab; TNAME TABTYPE CLUSTERID ------------------------------ ------- ---------- EMPLOYEE TABLE SQL> select * from employee; NAME -------------------- azar kareem jabar ajmal SQL>
Ref :
http://download.oracle.com/docs/cd/E11882_01/backup.112/e10642/rcmxplat.htm#BRADV89986
Trackbacks & Pingbacks