Database Migration

Database Migration From Windows to Linux Using RMAN

This post describes the procedure required to migrate a database from Windows to Linux using the RMAN Convert Database command.
Both Windows and Linux platforms have the same endian format, which makes possible to transfer the whole database, making the migration process very straight forward and simple.
To migrate between platforms that have a different endian format, Cross Platform Transportable Table-spaces (XTTS) needs to be used instead.


The Windows Database

This exercise was done using a small default 10.2.0.4 database
 
SQL> select bytes,file_name from dba_data_files;
BYTES FILE_NAME
---------- ------------------------------------------------------------
440401920 G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSTEM_44QYBFPF_.DBF
246415360 G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_UNDOTBS1_44QYCFQW_.DBF
136314880 G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSAUX_44QYCZ3D_.DBF
5242880 G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_USERS_44QYDHY7_.DBF
 
SQL> select name from v$controlfile;
NAME
----------------------------------------------------------------------------------
G:\TECHNOLOGY\ORCLW\CONTROLFILE\O1_MF_44QY9SXR_.CTL
C:\ORACLE\PRODUCT\10.2.0\FLASH_RECOVERY_AREA\ORCLW\CONTROLFILE\O1_MF_44QY9TPX_.CTL
 
SQL> select member from v$logfile;
MEMBER
----------------------------------------------------------------------------------
G:\TECHNOLOGY\ORCLW\ONLINELOG\O1_MF_1_44QY9VJL_.LOG
C:\ORACLE\PRODUCT\10.2.0\FLASH_RECOVERY_AREA\ORCLW\ONLINELOG\O1_MF_1_44QY9ZZ7_.LOG
G:\TECHNOLOGY\ORCLW\ONLINELOG\O1_MF_2_44QYB14V_.LOG
C:\ORACLE\PRODUCT\10.2.0\FLASH_RECOVERY_AREA\ORCLW\ONLINELOG\O1_MF_2_44QYB5L1_.LOG
G:\TECHNOLOGY\ORCLW\ONLINELOG\O1_MF_3_44QYB6OY_.LOG
C:\ORACLE\PRODUCT\10.2.0\FLASH_RECOVERY_AREA\ORCLW\ONLINELOG\O1_MF_3_44QYBC2F_.LOG

List of Steps Needed to Complete the Migration
The migration process is simple, but as it has several steps it is convenient to be familiar with them before running it.
1. Check platform compatibility between source and target OS
2. Start the database in read only mode
3. Check database readiness for transport from Windows to Linux using DBMS_TDB.CHECK_DB
4. Check if there are any external objects
5. Execute the Rman Convert database command
6. Copy converted datafiles, generated Transport Script and Parameter File to Linux
7. Edit the init.ora for the new database
8. Edit the Transport Script and Parameter File changing the windows paths to Linux Paths
9. Execute the Transport Script
10.Change the Database ID
11.Check database integrity.

1. Check platform compatibility between source and target OS
You need to check the platforms to be sure they have the same endian format, also you need to save the
platform_name string to use it later as part of the convert database syntax in RMAN.

SQL> select * from V$DB_TRANSPORTABLE_PLATFORM where PLATFORM_NAME='Microsoft Windows IA (32-bit)'  or PLATFORM_NAME like 'Linux%' /

PLATFORM_ID PLATFORM_NAME        ENDIAN_FORMAT
----------- --------------------------------------------- --------------
7 Microsoft Windows IA (32-bit)                           Little
10 Linux IA (32-bit)                                               Little
11 Linux IA (64-bit)                                               Little
13 Linux x86 64-bit                                                Little

2. Start the database in read only mode
In order to execute dbms_tdb.check_db the database must be opened on read only mode.

SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup mount;
ORACLE instance started.
Total System Global Area 167772160 bytes
Fixed Size 1295608 bytes
Variable Size 71305992 bytes
Database Buffers 88080384 bytes
Redo Buffers 7090176 bytes
Database mounted.

SQL> alter database open read only;
Database altered.

3. Check database readiness for transport from Windows to Linux
If the execution of dbms_tdb.check_db does not return any exceptions, that means the database is ready for
transport to the target platform.

SQL> set serveroutput on

SQL> declare db_ready boolean;
begin
db_ready := dbms_tdb.check_db('Linux IA (32-bit)');
end;
 /
PL/SQL procedure successfully completed.

4. Check if there are any external objects
If there is any external objects take note of them, they will need to be taken care
manually
SQL> set serveroutput on
SQL> declare
external boolean;
begin
 /* value of external is ignored, but with SERVEROUTPUT set to ON
 * dbms_tdb.check_external displays report of external objects
* on console */
external := dbms_tdb.check_external;
end;
/

The following directories exist in the database:
SYS.DATA_PUMP_DIR, SYS.ORACLE_OCM_CONFIG_DIR, SYS.ADMIN_DIR, SYS.WORK_DIR
PL/SQL procedure successfully completed.

5. Using the RMAN CONVERT DATABASE Command
Having executed successfully the checkup steps, the database is open in read only mode, then the convert
database command can be executed with Rman.
In this example, I’m not using the db_file_name_convert '<source-path> '<target-path>' option because the
database is using oracle managed files (omf); when using omf Rman does generate and display the new file
names on the output of the convert database command.
At the end of the convert process Rman does display information about how to complete the conversion on the target platform.
C:\Documents and Settings\avargas>Rman target sys/oracle@orclw nocatalog
Recovery Manager: Release 10.2.0.4.0 - Production on Mon Jun 9 17:26:22 2008
Copyright (c) 1982, 2007, Oracle. All rights reserved.
connected to target database: ORCLW (DBID=1718464921)
using target database control file instead of recovery catalog

RMAN> CONVERT DATABASE NEW DATABASE 'orcllnx'
2> transport script 'G:\TECHNOLOGY\ORCLLNX\transportscript'
3> to platform 'Linux IA (32-bit)';
Starting convert at 09-JUN-08
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=154 devtype=DISK
Directory SYS.DATA_PUMP_DIR found in the database
Directory SYS.ORACLE_OCM_CONFIG_DIR found in the database

Directory SYS.ADMIN_DIR found in the database
Directory SYS.WORK_DIR found in the database
User SYS with SYSDBA and SYSOPER privilege found in password file
channel ORA_DISK_1: starting datafile conversion
input datafile fno=00001 name=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSTEM_44QYBFPF_.DBF
converted datafile=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSTEM_44TM3OPF_.DBF
channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:55
channel ORA_DISK_1: starting datafile conversion
input datafile fno=00002 name=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_UNDOTBS1_44QYCFQW_.DBF
converted datafile=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_UNDOTBS1_44TM5F98_.DBF
channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile conversion
input datafile fno=00003 name=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSAUX_44QYCZ3D_.DBF
converted datafile=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSAUX_44TM6JTB_.DBF
channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile conversion
input datafile fno=00004 name=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_USERS_44QYDHY7_.DBF
converted datafile=G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_USERS_44TM7BD5_.DBF
channel ORA_DISK_1: datafile conversion complete, elapsed time: 00:00:01
Run SQL script G:\TECHNOLOGY\ORCLLNX\TRANSPORTSCRIPT on the target platform to create
database
Edit init.ora file C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\INIT_00JIGSKL_1_0.ORA. This
PFILE will be used to create the database on the target platform
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 backup at 09-JUN-08

6. Copy Converted Datafiles, Generated Transport Script and Parameter File to the Linux
We need to copy over the generated files to the Linux server, they include all converted datafiles, the transport script and the generated pfile.
If needed create at this point the directories you will need on the Linux server, for dump destination and flash
recovery area i.e.:
mkdir –p /oradisk/oracle/app/admin/ORCLLNX/adump
mkdir –p /oradisk/oracle/app/admin/ORCLLNX/bdump
mkdir –p /oradisk/oracle/app/admin/ORCLLNX/cdump
mkdir –p /oradisk/oracle/app/admin/ORCLLNX/udump
mkdir –p /oradisk/database/ORCLLNX/FRA

You can use ftp to copy the required files to the Linux server.
In my test I will mount on the Linux server the directory for the new database, so I just move over the converted files to a predefined directory.
All converted files have the string 44TM as part of their names, i.e.: O1_MF_SYSTEM_44TM3OPF_.DBF, then,
while being at the datafiles location I do execute the move command to the new destination:
G:\TECHNOLOGY\ORCLW\DATAFILE>move *44TM* ..\..\ORCLLNX
G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSTEM_44TM3OPF_.DBF
G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_UNDOTBS1_44TM5F98_.DBF
G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_SYSAUX_44TM6JTB_.DBF
G:\TECHNOLOGY\ORCLW\DATAFILE\O1_MF_USERS_44TM7BD5_.DBF

Then I need to move the generated pfile also: 

G:\TECHNOLOGY\ORCLW\DATAFILE>move
C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\INIT_00JIGSKL_1_0.ORA
..\..\ORCLLNX\initORCLLNX.ora
Check that all required files are located on the ORCLLNX directory
G:\TECHNOLOGY\ORCLW\DATAFILE>dir ..\..\ORCLLNX
Volume in drive G is TECHNOLOGY
Volume Serial Number is 1877-B4EA
Directory of G:\TECHNOLOGY\ORCLLNX
06/09/2008 05:27 PM <DIR> .
06/09/2008 05:27 PM <DIR> ..
06/09/2008 05:31 PM 2,616 TRANSPORTSCRIPT
06/09/2008 05:30 PM 440,410,112 O1_MF_SYSTEM_44TM3OPF_.DBF
06/09/2008 05:31 PM 246,423,552 O1_MF_UNDOTBS1_44TM5F98_.DBF
06/09/2008 05:31 PM 146,808,832 O1_MF_SYSAUX_44TM6JTB_.DBF
06/09/2008 05:31 PM 5,251,072 O1_MF_USERS_44TM7BD5_.DBF
06/09/2008 05:31 PM 1,556 initORCLLNX.ora
6 File(s) 838,897,740 bytes
2 Dir(s) 18,968,444,928 bytes free

7. Edit init.ora for new databaseThe Rman convert command executed on Windows generated a parameter file that needs to be edited to be used on the target Linux Server.
The pfile generated by Rman:
# Please change the values of the following parameters:
control_files = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\CF_DORCLLNX_
ID-1718464921_00JIGSKL"
db_create_file_dest = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\TECHNOLOGY"
db_recovery_file_dest =
"C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\flash_recovery_area"
db_recovery_file_dest_size= 2147483648
audit_file_dest = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\ADUMP"
background_dump_dest = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\BDUMP"
user_dump_dest = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\UDUMP"
core_dump_dest = "C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\CDUMP"
db_name = "ORCLLNX"
# Please review the values of the following parameters:
__shared_pool_size = 62914560
__large_pool_size = 4194304
__java_pool_size = 4194304
__streams_pool_size = 0
__db_cache_size = 88080384
remote_login_passwordfile= "EXCLUSIVE"
db_domain = ""
dispatchers = "(PROTOCOL=TCP) (SERVICE=orclwXDB)"
# The values of the following parameters are from source database:
processes = 150

sga_target = 167772160
db_block_size = 8192
compatible = "10.2.0.3.0"
db_file_multiblock_read_count= 16
undo_management = "AUTO"
undo_tablespace = "UNDOTBS1"
job_queue_processes = 10
open_cursors = 300
pga_aggregate_target = 16777216
The pfile edited to be used on Linux
# Please change the values of the following parameters:
control_files = '/oradisk/database/ORCLLNX/orcllnx_control1.ctl' ,
'/oradisk/database/ORCLLNX/orcllnx_control2.ctl'
db_create_file_dest = '/oradisk/database/ORCLLNX'
db_recovery_file_dest = '/oradisk/database/ORCLLNX/FRA'
db_recovery_file_dest_size= 2147483648
audit_file_dest = '/oradisk/oracle/app/admin/ORCLLNX/adump'
background_dump_dest = '/oradisk/oracle/app/admin/ORCLLNX/bdump'
user_dump_dest = '/oradisk/oracle/app/admin/ORCLLNX/udump'
core_dump_dest = '/oradisk/oracle/app/admin/ORCLLNX/cdump'
db_name = 'ORCLLNX'
# Please review the values of the following parameters:
__shared_pool_size = 62914560
__large_pool_size = 4194304
__java_pool_size = 4194304

__streams_pool_size = 0
__db_cache_size = 88080384
remote_login_passwordfile= 'EXCLUSIVE'
db_domain = ''
dispatchers = '(PROTOCOL=TCP) (SERVICE=orcllnxXDB)'
# The values of the following parameters are from source database:
processes = 150
sga_target = 167772160
db_block_size = 8192
compatible = '10.2.0.3.0'
db_file_multiblock_read_count= 16
undo_management = 'AUTO'
undo_tablespace = 'UNDOTBS1'
job_queue_processes = 10
open_cursors = 300
pga_aggregate_target = 16777216

8. Edit The Transport Script
Before running the transport script on the target Linux server we need to edit it to set the correct paths for datafiles,controlfiles and dump directories, also we may want to change the value for tuning parameters.
The script generated by Rman:
-- The following commands will create a new control file and use it
-- to open the database.
-- Data used by Recovery Manager will be lost.
-- The contents of online logs will be lost and all backups will
-- be invalidated. Use this only if online logs are damaged.
-- After mounting the created controlfile, the following SQL
-- statement will place the database in the appropriate
-- protection mode:
-- ALTER DATABASE SET STANDBY DATABASE TO MAXIMIZE PERFORMANCE
STARTUP NOMOUNT
PFILE='C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\INIT_00JIGSKL_1_0.ORA'
CREATE CONTROLFILE REUSE SET DATABASE "ORCLLNX" RESETLOGS NOARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 SIZE 50M,
GROUP 2 SIZE 50M,

GROUP 3 SIZE 50M
DATAFILE
'C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\DATA_D-ORCLW_I-1718464921_TSSYSTEM_
FNO-1_07JIGSKL',
'C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\DATA_D-ORCLW_I-1718464921_TSUNDOTBS1_
FNO-2_08JIGSMD',
'C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\DATA_D-ORCLW_I-1718464921_TSSYSAUX_
FNO-3_09JIGSNG',
'C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\DATA_D-ORCLW_I-1718464921_TSUSERS_
FNO-4_0AJIGSOA'
CHARACTER SET AL32UTF8
;
-- 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 33554431M;
-- 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
PFILE='C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\INIT_00JIGSKL_1_0.ORA'
@@ ?/rdbms/admin/utlirp.sql
SHUTDOWN IMMEDIATE
STARTUP PFILE='C:\ORACLE\PRODUCT\10.2.0\DB_1\DATABASE\INIT_00JIGSKL_1_0.ORA'
-- The following step will recompile all PL/SQL modules.
-- It may take serveral hours to complete.
@@ ?/rdbms/admin/utlrp.sql
set feedback 6;
The script edited to be run on Linux:
STARTUP NOMOUNT
PFILE='/oradisk/oracle/app/oracle/product/10.2.0/db_1/dbs/initORCLLNX.ORA'
CREATE CONTROLFILE REUSE SET DATABASE "ORCLLNX" RESETLOGS NOARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 SIZE 50M,
GROUP 2 SIZE 50M,
GROUP 3 SIZE 50M
DATAFILE
'/oradisk/database/ORCLLNX/O1_MF_SYSTEM_44TM3OPF_.DBF',

'/oradisk/database/ORCLLNX/O1_MF_UNDOTBS1_44TM5F98_.DBF',
'/oradisk/database/ORCLLNX/O1_MF_SYSAUX_44TM6JTB_.DBF',
'/oradisk/database/ORCLLNX/O1_MF_USERS_44TM7BD5_.DBF'
CHARACTER SET AL32UTF8
;
-- 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 33554431M;
-- 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
PFILE='/oradisk/oracle/app/oracle/product/10.2.0/db_1/dbs/initORCLLNX.ORA'
@@ ?/rdbms/admin/utlirp.sql
SHUTDOWN IMMEDIATE
STARTUP
PFILE='/oradisk/oracle/app/oracle/product/10.2.0/db_1/dbs/initORCLLNX.ORA';
-- The following step will recompile all PL/SQL modules.
-- It may take several hours to complete.
@@ ?/rdbms/admin/utlrp.sql
set feedback 6;

9. Execute the Transport Script
This is the log of the transport script execution:
avargas-pc:/oradisk/database/ORCLLNX> sqlplus / as sysdba
SQL*Plus: Release 10.2.0.4.0 - Production on Wed Jun 11 10:11:54 2008
Copyright (c) 1982, 2007, Oracle. All Rights Reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> @transport

SQL> STARTUP NOMOUNT
PFILE='/oradisk/oracle/app/oracle/product/10.2.0/db_1/dbs/initORCLLNX.ora';
ORACLE instance started.
Total System Global Area 167772160 bytes
Fixed Size 1266368 bytes
Variable Size 71306560 bytes
Database Buffers 88080384 bytes
Redo Buffers 7118848 bytes

SQL> CREATE CONTROLFILE REUSE SET DATABASE "ORCLLNX" RESETLOGS NOARCHIVELOG
2 MAXLOGFILES 16
3 MAXLOGMEMBERS 3
4 MAXDATAFILES 100
5 MAXINSTANCES 8
6 MAXLOGHISTORY 292

7 LOGFILE
8 GROUP 1 SIZE 50M,
9 GROUP 2 SIZE 50M,
10 GROUP 3 SIZE 50M
11 DATAFILE
12 '/oradisk/database/ORCLLNX/O1_MF_SYSTEM_44TM3OPF_.DBF',
13 '/oradisk/database/ORCLLNX/O1_MF_UNDOTBS1_44TM5F98_.DBF',
14 '/oradisk/database/ORCLLNX/O1_MF_SYSAUX_44TM6JTB_.DBF',
15 '/oradisk/database/ORCLLNX/O1_MF_USERS_44TM7BD5_.DBF'
16 CHARACTER SET AL32UTF8
17 ;
Control file created.
SQL>
SQL> -- Database can now be opened zeroing the online logs.
SQL> ALTER DATABASE OPEN RESETLOGS;
Database altered.
SQL>
SQL> -- Commands to add tempfiles to temporary tablespaces.
SQL> -- Online tempfiles have complete space information.
SQL> -- Other tempfiles may require adjustment.
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE
2 SIZE 20971520 AUTOEXTEND ON NEXT 655360 MAXSIZE 33554431M;
Tablespace altered.
SQL> -- End of tempfile additions.

SQL> --
SQL>
SQL> set echo off
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
* 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 167772160 bytes
Fixed Size 1266368 bytes
Variable Size 71306560 bytes
Database Buffers 88080384 bytes
Redo Buffers 7118848 bytes
Database mounted.
Database opened.
>>>>>>>>>>>>>> UTLIRP and UTLRP execution started here <<<<<<<<<<<<<<<<<<
SQL>
SQL> WHENEVER SQLERROR EXIT;
SQL>
SQL> DOC
DOC>#######################################################################
DOC>#######################################################################
DOC> The following statement will cause an "ORA-01722: invalid number"
DOC> error if there the database was not opened in UPGRADE mode
DOC>
DOC> If you encounter this error, execute "SHUTDOWN", "STARTUP UPGRADE" and
DOC> re-execute utlirp.sql
DOC>#######################################################################
DOC>#######################################################################
DOC>#
SQL> SELECT TO_NUMBER('MUST_BE_OPEN_UPGRADE') FROM v$instance
2 WHERE status != 'OPEN MIGRATE';
no rows selected
SQL> Rem Store object numbers of all valid PL/SQL-based functional indexes
SQL> DROP TABLE utlirp_enabled_func_indexes;
Table dropped.
SQL> CREATE TABLE utlirp_enabled_func_indexes AS
2 SELECT obj# FROM ind$
3 WHERE bitand(property, 2048) != 0 AND bitand(flags, 1024) = 0;
Table created.
>>>>>>>>>>>>>> many output lines followed <<<<<<<<<<<<<<<<<<

These are the final lines of the logfile:
PL/SQL procedure successfully completed.
SQL>
SQL> DOC
DOC> The following query reports the number of objects that have compiled
DOC> with errors (objects that compile with errors have status set to 3 in
DOC> obj$). If the number is higher than expected, please examine the error
DOC> messages reported with each object (using SHOW ERRORS) to see if they
DOC> point to system misconfiguration or resource constraints that must be
DOC> fixed before attempting to recompile these objects.
DOC>#
SQL> select COUNT(*) "OBJECTS WITH ERRORS" from obj$ where status = 3;
OBJECTS WITH ERRORS
-------------------
0
SQL>
SQL>
SQL> DOC
DOC> The following query reports the number of errors caught during
DOC> recompilation. If this number is non-zero, please query the error
DOC> messages in the table UTL_RECOMP_ERRORS to see if any of these errors
DOC> are due to misconfiguration or resource constraints that must be
DOC> fixed before objects can compile successfully.
DOC>#
SQL> select COUNT(*) "ERRORS DURING RECOMPILATION" from utl_recomp_errors;

ERRORS DURING RECOMPILATION
---------------------------
0
SQL>
SQL>
SQL> Rem =====================================================================
SQL> Rem Run component validation procedure
SQL> Rem =====================================================================
SQL>
SQL> SET serveroutput on
SQL> EXECUTE dbms_registry_sys.validate_components;
PL/SQL procedure successfully completed.
SQL> SET serveroutput off
SQL>
SQL>
SQL> Rem
===========================================================================
SQL> Rem END utlrp.sql
SQL> Rem
===========================================================================
SQL> set feedback 6;

10. Change database identifier
To change the database identifier you need to use the NEWDBID utility “nid”. It is run from within Sqlplus having
the database mounted:
sqlplus "/ as sysdba"
startup mount
exit
To change the DBID
cd $ORACLE_HOME/bin
./nid target=/
To verify the DBID and database name
SELECT dbid, name FROM v$_database;
DBID Change, Execution Log:
avargas-pc:~/app/oracle/product/10.2.0/db_1/bin> sqlplus / as sysdba
SQL*Plus: Release 10.2.0.4.0 - Production on Wed Jun 11 10:25:09 2008
Copyright (c) 1982, 2007, Oracle. All Rights Reserved.
Connected to an idle instance.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 167772160 bytes
Fixed Size 1266368 bytes
Variable Size 71306560 bytes
Database Buffers 88080384 bytes
Redo Buffers 7118848 bytes
Database mounted.
SQL> exit
Disconnected from Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 -
Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
avargas-pc:~/app/oracle/product/10.2.0/db_1/bin> ./nid target=/
DBNEWID: Release 10.2.0.4.0 - Production on Wed Jun 11 10:25:50 2008
Copyright (c) 1982, 2007, Oracle. All rights reserved.
Connected to database ORCLLNX (DBID=1718464921)
Connected to server version 10.2.0
Control Files in database:
/oradisk/database/ORCLLNX/orcllnx_control1.ctl
/oradisk/database/ORCLLNX/orcllnx_control2.ctl
Change database ID of database ORCLLNX? (Y/[N]) => Y
Proceeding with operation
Changing database ID from 1718464921 to 1179074095

Control File /oradisk/database/ORCLLNX/orcllnx_control1.ctl - modified
Control File /oradisk/database/ORCLLNX/orcllnx_control2.ctl - modified
Datafile /oradisk/database/ORCLLNX/O1_MF_SYSTEM_44TM3OPF_.DBF - dbid changed
Datafile /oradisk/database/ORCLLNX/O1_MF_UNDOTBS1_44TM5F98_.DBF - dbid
changed
Datafile /oradisk/database/ORCLLNX/O1_MF_SYSAUX_44TM6JTB_.DBF - dbid changed
Datafile /oradisk/database/ORCLLNX/O1_MF_USERS_44TM7BD5_.DBF - dbid changed
Datafile /oradisk/database/ORCLLNX/ORCLLNX/datafile/o1_mf_temp_44yxofkr_.tmp
- dbid changed
Control File /oradisk/database/ORCLLNX/orcllnx_control1.ctl - dbid changed
Control File /oradisk/database/ORCLLNX/orcllnx_control2.ctl - dbid changed
Instance shut down
Database ID for database ORCLLNX changed to 1179074095.
All previous backups and archived redo logs for this database are unusable.
Database is not aware of previous backups and archived logs in Recovery Area.
Database has been shutdown, open database with RESETLOGS option.
Successfully changed database ID.
DBNEWID - Completed succesfully.
avargas-pc:~/app/oracle/product/10.2.0/db_1/bin> sqlplus / as sysdba
SQL*Plus: Release 10.2.0.4.0 - Production on Wed Jun 11 10:28:22 2008
Copyright (c) 1982, 2007, Oracle. All Rights Reserved.
Connected to an idle instance.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 167772160 bytes
Fixed Size 1266368 bytes
Variable Size 71306560 bytes
Database Buffers 88080384 bytes
Redo Buffers 7118848 bytes
Database mounted.

SQL> alter database open resetlogs;
Database altered.

11. Check database integrity

SQL> select tablespace_name from dba_tablespaces;
TABLESPACE_NAME
------------------------------
SYSTEM
UNDOTBS1
SYSAUX
TEMP
USERS

SQL> select file_name from dba_data_files;
FILE_NAME
-------------------------------------------------------------------------------
/oradisk/database/ORCLLNX/O1_MF_USERS_44TM7BD5_.DBF
/oradisk/database/ORCLLNX/O1_MF_SYSAUX_44TM6JTB_.DBF
/oradisk/database/ORCLLNX/O1_MF_UNDOTBS1_44TM5F98_.DBF
/oradisk/database/ORCLLNX/O1_MF_SYSTEM_44TM3OPF_.DBF
Checking component status after transport:

SQL> SELECT COMP_NAME,STATUS FROM DBA_REGISTRY;
COMP_NAME STATUS
-------------------------------------- ------
Oracle XML Database VALID
Oracle Expression Filter VALID

Oracle Rules Manager VALID
Oracle Workspace Manager VALID
Oracle interMedia VALID
Oracle Database Catalog Views VALID
Oracle Database Packages and Types VALID
JServer JAVA Virtual Machine VALID
Oracle XDK VALID
Oracle Database Java Packages VALID

End of Report

***********************************END******************************************




 

No comments:

SHRD0014: GLLEZL - process exiting with failure

  SYMPTOMS Journal Import completes with the following error: Error ------ ORA-01653 : unable to extend table GL.GL_IMPORT_REFERENCES ORA-01...