Actually, this topic "How to Move Oracle Database" follows my previous post: How to Move ORACLE HOME. But I think it can be used in any moving operations. Generally speaking, this post will include the following subtle topics:
- How to move spfile
- How to move control files
- How to move data files
- How to move redo logs
- How to move temp files
Our goal is to move the whole database to another place. That is, we abandon the old ORACLE HOME and start to use new home. To move a database, we take the following steps:
- Modify /etc/oratab
- Move Instance Files
- Configure Parameter File
- Restore SPFILE
- Create Necessary Directories
- Move Control Files
- Startup NOMOUNT
- Mount Control Files
- Compose OS Commands
- Move Database Files
- Compose Rename Statements
- Rename Database Files
- Open Database
All moving operations in this post are just copying files so as to keep original source intact in case of any incidents.
As you can see, we move the whole database offline. For moving some data files online, you may check the post: How to Change Data Files Location in Oracle.
Move Oracle Database
Suppose new ORACLE BASE and ORACLE HOME have been created and installed. From now on, we start to handle database moving to the new home.
Modify /etc/oratab
The very first step of moving a database is to update /etc/oratab where is the place to register database instances in this machine.
[oracle@primary dbs]$ vi /etc/oratab
...
#ORCL:/u01/app/oracle/product/11.2.0/dbhome_1:Y
ORCL:/oracle/ora11ghome:Y
Move Instance Files
Instance files include SPFILE, password file and snapshot of control file, etc. Actually, we copied all instance files under $OLD_ORACLE_HOME/dbs to the new home.
[oracle@primary admin]$ cp -pi $OLD_ORACLE_HOME/dbs/*$ORACLE_SID* $ORACLE_HOME/dbs/
[oracle@primary admin]$ cd $ORACLE_HOME/dbs
[oracle@primary dbs]$ ll
total 9540
-rw-rw----. 1 oracle dba 1544 Jan 21 19:06 hc_ORCL.dat
-rw-r--r--. 1 oracle oinstall 2851 May 15 2009 init.ora
-rw-r-----. 1 oracle dba 24 Feb 13 2018 lkORCL
-rw-r-----. 1 oracle dba 1536 Feb 13 2018 orapwORCL
-rw-r-----. 1 oracle dba 9748480 Feb 13 2018 snapcf_ORCL.f
-rw-r-----. 1 oracle dba 2560 Jan 21 19:06 spfileORCL.ora
Configure Parameter File
We need to point all path-related parameters to the new location. First of all, we create an easily modifiable PFILE from SPFILE.
[oracle@primary dbs]$ sqlplus / as sysdba
...
Connected to an idle instance.
SQL> create pfile from spfile;
File created.
SQL> exit
Disconnected
Then we modify some parameters which are mainly related to path changing.
[oracle@primary dbs]$ cp -p initORCL.ora initORCL.ora.20190121
[oracle@primary dbs]$ vi initORCL.ora
...
*.audit_file_dest='/oracle/admin/ORCL/adump'
*.control_files='/oracle/oradata/ORCL/control01.ctl','/oracle/fast_recovery_area/ORCL/control02.ctl'
*.db_recovery_file_dest='/oracle/fast_recovery_area'
*.diagnostic_dest='/oracle'
Restore SPFILE
We restore SPFILE from the modified PFILE. Then we are ready to startup NOMOUNT.
[oracle@primary dbs]$ cp -p spfileORCL.ora spfileORCL.ora.20190121
[oracle@primary dbs]$ sqlplus / as sysdba
...
Connected to an idle instance.
SQL> create spfile from pfile;
File created.
SQL> exit
Disconnected
Create Necessary Directories
According to our modified PFILE, some directories may need to be created before startup NOMOUNT.
[oracle@primary dbs]$ mkdir -p /oracle/admin/ORCL/adump
[oracle@primary dbs]$ mkdir -p /oracle/oradata/ORCL
[oracle@primary dbs]$ mkdir -p /oracle/fast_recovery_area/ORCL
Move Control Files
We copied both control files to the new ORACLE BASE.
[oracle@primary dbs]$ cp -pi $OLD_ORACLE_BASE/oradata/ORCL/control01.ctl $ORACLE_BASE/oradata/ORCL/
[oracle@primary dbs]$ cp -pi $OLD_ORACLE_BASE/fast_recovery_area/ORCL/control02.ctl $ORACLE_BASE/fast_recovery_area/ORCL/
[oracle@primary dbs]$ ll $ORACLE_BASE/*/ORCL/control*.ctl
-rw-r-----. 1 oracle dba 9781248 Jan 21 19:51 /oracle/fast_recovery_area/ORCL/control02.ctl
-rw-r-----. 1 oracle dba 9781248 Jan 21 19:51 /oracle/oradata/ORCL/control01.ctl
Please note that, we can choose to copy control files before or after startup NOMOUNT. Either way would be no problem, because NOMOUNT is irrelevant to the presence of control files.
Startup NOMOUNT
To verify the new SPFILE, we have to know how database reacts to it.
[oracle@primary dbs]$ sqlplus / as sysdba
...
Connected to an idle instance.
SQL> startup nomount;
ORACLE instance started.
Total System Global Area 1553305600 bytes
Fixed Size 2253544 bytes
Variable Size 956304664 bytes
Database Buffers 587202560 bytes
Redo Buffers 7544832 bytes
Let's see all directories are set correctly.
SQL> set pagesize 1000;
SQL> select value from v$parameter where value like '%/%';
VALUE
--------------------------------------------------------------------------------
/oracle/ora11ghome/dbs/spfileORCL.ora
/oracle/oradata/ORCL/control01.ctl, /oracle/fast_recovery_area/ORCL/control02.ct
l
?/dbs/arch
/oracle/fast_recovery_area
/oracle/diag/rdbms/orcl/ORCL/trace
/oracle/diag/rdbms/orcl/ORCL/trace
/oracle/diag/rdbms/orcl/ORCL/cdump
/oracle/admin/ORCL/adump
/oracle/ora11ghome/dbs/dr1ORCL.dat
/oracle/ora11ghome/dbs/dr2ORCL.dat
/oracle
11 rows selected.
SQL> show parameter;
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
O7_DICTIONARY_ACCESSIBILITY boolean FALSE
active_instance_count integer
aq_tm_processes integer 1
archive_lag_target integer 0
asm_diskgroups string
asm_diskstring string
asm_power_limit integer 1
asm_preferred_read_failure_groups string
audit_file_dest string /oracle/admin/ORCL/adump
audit_sys_operations boolean FALSE
audit_syslog_level string
audit_trail string NONE
awr_snapshot_time_offset integer 0
background_core_dump string partial
background_dump_dest string /oracle/diag/rdbms/orcl/ORCL/t
race
backup_tape_io_slaves boolean FALSE
bitmap_merge_area_size integer 1048576
blank_trimming boolean FALSE
buffer_pool_keep string
buffer_pool_recycle string
cell_offload_compaction string ADAPTIVE
cell_offload_decryption boolean TRUE
cell_offload_parameters string
cell_offload_plan_display string AUTO
cell_offload_processing boolean TRUE
cell_offloadgroup_name string
circuits integer
client_result_cache_lag big integer 3000
client_result_cache_size big integer 0
clonedb boolean FALSE
cluster_database boolean FALSE
cluster_database_instances integer 1
cluster_interconnects string
commit_logging string
commit_point_strength integer 1
commit_wait string
commit_write string
compatible string 11.2.0.4.0
control_file_record_keep_time integer 7
control_files string /oracle/oradata/ORCL/control01
.ctl, /oracle/fast_recovery_ar
ea/ORCL/control02.ctl
control_management_pack_access string DIAGNOSTIC+TUNING
core_dump_dest string /oracle/diag/rdbms/orcl/ORCL/c
dump
cpu_count integer 2
create_bitmap_area_size integer 8388608
create_stored_outlines string
cursor_bind_capture_destination string memory+disk
cursor_sharing string EXACT
cursor_space_for_time boolean FALSE
db_16k_cache_size big integer 0
db_2k_cache_size big integer 0
db_32k_cache_size big integer 0
db_4k_cache_size big integer 0
db_8k_cache_size big integer 0
db_block_buffers integer 0
db_block_checking string FALSE
db_block_checksum string TYPICAL
db_block_size integer 8192
db_cache_advice string ON
db_cache_size big integer 0
db_create_file_dest string
db_create_online_log_dest_1 string
db_create_online_log_dest_2 string
db_create_online_log_dest_3 string
db_create_online_log_dest_4 string
db_create_online_log_dest_5 string
db_domain string
db_file_multiblock_read_count integer 128
db_file_name_convert string
db_files integer 200
db_flash_cache_file string
db_flash_cache_size big integer 0
db_flashback_retention_target integer 1440
db_keep_cache_size big integer 0
db_lost_write_protect string NONE
db_name string ORCL
db_recovery_file_dest string /oracle/fast_recovery_area
db_recovery_file_dest_size big integer 4182M
db_recycle_cache_size big integer 0
db_securefile string PERMITTED
db_ultra_safe string OFF
db_unique_name string ORCL
db_unrecoverable_scn_tracking boolean TRUE
db_writer_processes integer 1
dbwr_io_slaves integer 0
ddl_lock_timeout integer 0
deferred_segment_creation boolean TRUE
dg_broker_config_file1 string /oracle/ora11ghome/dbs/dr1ORCL
.dat
dg_broker_config_file2 string /oracle/ora11ghome/dbs/dr2ORCL
.dat
dg_broker_start boolean FALSE
diagnostic_dest string /oracle
disk_asynch_io boolean TRUE
dispatchers string (PROTOCOL=TCP) (SERVICE=ORCLXD
B)
distributed_lock_timeout integer 60
dml_locks integer 1088
dnfs_batch_size integer 4096
dst_upgrade_insert_conv boolean TRUE
enable_ddl_logging boolean FALSE
enable_goldengate_replication boolean FALSE
event string
fal_client string
fal_server string
fast_start_io_target integer 0
fast_start_mttr_target integer 0
fast_start_parallel_rollback string LOW
file_mapping boolean FALSE
fileio_network_adapters string
filesystemio_options string none
fixed_date string
gcs_server_processes integer 0
global_context_pool_size string
global_names boolean FALSE
global_txn_processes integer 1
hash_area_size integer 131072
hi_shared_memory_address integer 0
hs_autoregister boolean TRUE
ifile file
instance_groups string
instance_name string ORCL
instance_number integer 0
instance_type string RDBMS
instant_restore boolean FALSE
java_jit_enabled boolean TRUE
java_max_sessionspace_size integer 0
java_pool_size big integer 0
java_restrict string none
java_soft_sessionspace_limit integer 0
job_queue_processes integer 1000
large_pool_size big integer 0
ldap_directory_access string NONE
ldap_directory_sysauth string no
license_max_sessions integer 0
license_max_users integer 0
license_sessions_warning integer 0
listener_networks string
local_listener string
lock_name_space string
lock_sga boolean FALSE
log_archive_config string
log_archive_dest string
log_archive_dest_1 string
log_archive_dest_10 string
log_archive_dest_11 string
log_archive_dest_12 string
log_archive_dest_13 string
log_archive_dest_14 string
log_archive_dest_15 string
log_archive_dest_16 string
log_archive_dest_17 string
log_archive_dest_18 string
log_archive_dest_19 string
log_archive_dest_2 string
log_archive_dest_20 string
log_archive_dest_21 string
log_archive_dest_22 string
log_archive_dest_23 string
log_archive_dest_24 string
log_archive_dest_25 string
log_archive_dest_26 string
log_archive_dest_27 string
log_archive_dest_28 string
log_archive_dest_29 string
log_archive_dest_3 string
log_archive_dest_30 string
log_archive_dest_31 string
log_archive_dest_4 string
log_archive_dest_5 string
log_archive_dest_6 string
log_archive_dest_7 string
log_archive_dest_8 string
log_archive_dest_9 string
log_archive_dest_state_1 string enable
log_archive_dest_state_10 string enable
log_archive_dest_state_11 string enable
log_archive_dest_state_12 string enable
log_archive_dest_state_13 string enable
log_archive_dest_state_14 string enable
log_archive_dest_state_15 string enable
log_archive_dest_state_16 string enable
log_archive_dest_state_17 string enable
log_archive_dest_state_18 string enable
log_archive_dest_state_19 string enable
log_archive_dest_state_2 string enable
log_archive_dest_state_20 string enable
log_archive_dest_state_21 string enable
log_archive_dest_state_22 string enable
log_archive_dest_state_23 string enable
log_archive_dest_state_24 string enable
log_archive_dest_state_25 string enable
log_archive_dest_state_26 string enable
log_archive_dest_state_27 string enable
log_archive_dest_state_28 string enable
log_archive_dest_state_29 string enable
log_archive_dest_state_3 string enable
log_archive_dest_state_30 string enable
log_archive_dest_state_31 string enable
log_archive_dest_state_4 string enable
log_archive_dest_state_5 string enable
log_archive_dest_state_6 string enable
log_archive_dest_state_7 string enable
log_archive_dest_state_8 string enable
log_archive_dest_state_9 string enable
log_archive_duplex_dest string
log_archive_format string %t_%s_%r.dbf
log_archive_local_first boolean TRUE
log_archive_max_processes integer 4
log_archive_min_succeed_dest integer 1
log_archive_start boolean FALSE
log_archive_trace integer 0
log_buffer integer 7208960
log_checkpoint_interval integer 0
log_checkpoint_timeout integer 1800
log_checkpoints_to_alert boolean FALSE
log_file_name_convert string
max_dispatchers integer
max_dump_file_size string unlimited
max_enabled_roles integer 150
max_shared_servers integer
memory_max_target big integer 1488M
memory_target big integer 1488M
nls_calendar string
nls_comp string BINARY
nls_currency string
nls_date_format string
nls_date_language string
nls_dual_currency string
nls_iso_currency string
nls_language string AMERICAN
nls_length_semantics string BYTE
nls_nchar_conv_excp string FALSE
nls_numeric_characters string
nls_sort string
nls_territory string AMERICA
nls_time_format string
nls_time_tz_format string
nls_timestamp_format string
nls_timestamp_tz_format string
object_cache_max_size_percent integer 10
object_cache_optimal_size integer 102400
olap_page_pool_size big integer 0
open_cursors integer 300
open_links integer 4
open_links_per_instance integer 4
optimizer_capture_sql_plan_baselines boolean FALSE
optimizer_dynamic_sampling integer 2
optimizer_features_enable string 11.2.0.4
optimizer_index_caching integer 0
optimizer_index_cost_adj integer 100
optimizer_mode string ALL_ROWS
optimizer_secure_view_merging boolean TRUE
optimizer_use_invisible_indexes boolean FALSE
optimizer_use_pending_statistics boolean FALSE
optimizer_use_sql_plan_baselines boolean TRUE
os_authent_prefix string ops$
os_roles boolean FALSE
parallel_adaptive_multi_user boolean TRUE
parallel_automatic_tuning boolean FALSE
parallel_degree_limit string CPU
parallel_degree_policy string MANUAL
parallel_execution_message_size integer 16384
parallel_force_local boolean FALSE
parallel_instance_group string
parallel_io_cap_enabled boolean FALSE
parallel_max_servers integer 80
parallel_min_percent integer 0
parallel_min_servers integer 0
parallel_min_time_threshold string AUTO
parallel_server boolean FALSE
parallel_server_instances integer 1
parallel_servers_target integer 32
parallel_threads_per_cpu integer 2
permit_92_wrap_format boolean TRUE
pga_aggregate_target big integer 0
plscope_settings string IDENTIFIERS:NONE
plsql_ccflags string
plsql_code_type string INTERPRETED
plsql_debug boolean FALSE
plsql_optimize_level integer 2
plsql_v2_compatibility boolean FALSE
plsql_warnings string DISABLE:ALL
pre_page_sga boolean FALSE
processes integer 150
processor_group_name string
query_rewrite_enabled string TRUE
query_rewrite_integrity string enforced
rdbms_server_dn string
read_only_open_delayed boolean FALSE
recovery_parallelism integer 0
recyclebin string on
redo_transport_user string
remote_dependencies_mode string TIMESTAMP
remote_listener string
remote_login_passwordfile string EXCLUSIVE
remote_os_authent boolean FALSE
remote_os_roles boolean FALSE
replication_dependency_tracking boolean TRUE
resource_limit boolean FALSE
resource_manager_cpu_allocation integer 2
resource_manager_plan string
result_cache_max_result integer 5
result_cache_max_size big integer 3840K
result_cache_mode string MANUAL
result_cache_remote_expiration integer 0
resumable_timeout integer 0
rollback_segments string
sec_case_sensitive_logon boolean TRUE
sec_max_failed_login_attempts integer 10
sec_protocol_error_further_action string CONTINUE
sec_protocol_error_trace_action string TRACE
sec_return_server_release_banner boolean FALSE
serial_reuse string disable
service_names string ORCL
session_cached_cursors integer 50
session_max_open_files integer 10
sessions integer 248
sga_max_size big integer 1488M
sga_target big integer 0
shadow_core_dump string partial
shared_memory_address integer 0
shared_pool_reserved_size big integer 10905190
shared_pool_size big integer 0
shared_server_sessions integer
shared_servers integer 1
skip_unusable_indexes boolean TRUE
smtp_out_server string
sort_area_retained_size integer 0
sort_area_size integer 65536
spfile string /oracle/ora11ghome/dbs/spfileO
RCL.ora
sql92_security boolean FALSE
sql_trace boolean FALSE
sqltune_category string DEFAULT
standby_archive_dest string ?/dbs/arch
standby_file_management string MANUAL
star_transformation_enabled string FALSE
statistics_level string TYPICAL
streams_pool_size big integer 0
tape_asynch_io boolean TRUE
thread integer 0
timed_os_statistics integer 0
timed_statistics boolean TRUE
trace_enabled boolean TRUE
tracefile_identifier string
transactions integer 272
transactions_per_rollback_segment integer 5
undo_management string AUTO
undo_retention integer 900
undo_tablespace string UNDOTBS1
use_indirect_data_buffers boolean FALSE
use_large_pages string TRUE
user_dump_dest string /oracle/diag/rdbms/orcl/ORCL/t
race
utl_file_dir string
workarea_size_policy string AUTO
xml_db_events string enable
It looks like everything is ready except all data related files.
Mount Control Files
We have to mount control files in order to know what files we should move.
SQL> alter database mount;
Database altered.
SQL> select count(*) num_of_files from (select name from v$datafile union select member as name from v$logfile union select name from v$tempfile);
NUM_OF_FILES
------------
12
Compose OS Commands
Here I leverage REGEXP_SUBSTR function to compose OS commands that we need to copy from the source destination to the target one.
SQL> set linesize 120;
SQL> select 'cp -pi ' || name || ' /oracle/oradata/ORCL' || regexp_substr(name, '*(/[a-zA-Z0-9]+.(dbf|log))$') || '; echo $?' commands from (select name from v$datafile union select member as name from v$logfile union select name from v$tempfile);
COMMANDS
------------------------------------------------------------------------------------------------------------------------
cp -pi /u01/app/oracle/oradata/ORCL/example01.dbf /oracle/oradata/ORCL/example01.dbf; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo01.log /oracle/oradata/ORCL/redo01.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo02.log /oracle/oradata/ORCL/redo02.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo03.log /oracle/oradata/ORCL/redo03.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo04.log /oracle/oradata/ORCL/redo04.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo05.log /oracle/oradata/ORCL/redo05.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/redo06.log /oracle/oradata/ORCL/redo06.log; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/sysaux01.dbf /oracle/oradata/ORCL/sysaux01.dbf; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/system01.dbf /oracle/oradata/ORCL/system01.dbf; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/temp01.dbf /oracle/oradata/ORCL/temp01.dbf; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/undotbs01.dbf /oracle/oradata/ORCL/undotbs01.dbf; echo $?
cp -pi /u01/app/oracle/oradata/ORCL/users01.dbf /oracle/oradata/ORCL/users01.dbf; echo $?
12 rows selected.
Move Database Files
You can issue the commands composed by the above statement to make our work easier. Please initiate another session to do it.
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/example01.dbf /oracle/oradata/ORCL/example01.dbf; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo01.log /oracle/oradata/ORCL/redo01.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo02.log /oracle/oradata/ORCL/redo02.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo03.log /oracle/oradata/ORCL/redo03.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo04.log /oracle/oradata/ORCL/redo04.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo05.log /oracle/oradata/ORCL/redo05.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/redo06.log /oracle/oradata/ORCL/redo06.log; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/sysaux01.dbf /oracle/oradata/ORCL/sysaux01.dbf; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/system01.dbf /oracle/oradata/ORCL/system01.dbf; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/temp01.dbf /oracle/oradata/ORCL/temp01.dbf; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/undotbs01.dbf /oracle/oradata/ORCL/undotbs01.dbf; echo $?
0
[oracle@primary ~]$ cp -pi /u01/app/oracle/oradata/ORCL/users01.dbf /oracle/oradata/ORCL/users01.dbf; echo $?
0
[oracle@primary ~]$ ll $ORACLE_BASE/oradata/$ORACLE_SID
total 8127172
-rw-r-----. 1 oracle oinstall 9781248 Jan 21 19:51 control01.ctl
-rw-r-----. 1 oracle oinstall 363077632 Jan 21 19:51 example01.dbf
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:51 redo01.log
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:50 redo02.log
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:50 redo03.log
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:50 redo04.log
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:50 redo05.log
-rw-r-----. 1 oracle oinstall 1073742336 Jan 21 19:50 redo06.log
-rw-r-----. 1 oracle oinstall 587210752 Jan 21 19:51 sysaux01.dbf
-rw-r-----. 1 oracle oinstall 807411712 Jan 21 19:51 system01.dbf
-rw-r-----. 1 oracle oinstall 30416896 Jan 21 19:50 temp01.dbf
-rw-r--r--. 1 oracle oinstall 0 Oct 31 19:20 temp.txt
-rw-r-----. 1 oracle oinstall 104865792 Jan 21 19:51 undotbs01.dbf
-rw-r-----. 1 oracle oinstall 5251072 Jan 21 19:51 users01.dbf
Compose Rename Statements
SQL> select 'ALTER DATABASE RENAME FILE ''' || name || ''' to ''/oracle/oradata/ORCL' || regexp_substr(name, '*(/[a-zA-Z0-9]+.(dbf|log))$') || ''';' statements from (select name from v$datafile union select member as name from v$logfile union select name from v$tempfile);
STATEMENTS
------------------------------------------------------------------------------------------------------------------------
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/example01.dbf' to '/oracle/oradata/ORCL/example01.dbf';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo01.log' to '/oracle/oradata/ORCL/redo01.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo02.log' to '/oracle/oradata/ORCL/redo02.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo03.log' to '/oracle/oradata/ORCL/redo03.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo04.log' to '/oracle/oradata/ORCL/redo04.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo05.log' to '/oracle/oradata/ORCL/redo05.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo06.log' to '/oracle/oradata/ORCL/redo06.log';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/sysaux01.dbf' to '/oracle/oradata/ORCL/sysaux01.dbf';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/system01.dbf' to '/oracle/oradata/ORCL/system01.dbf';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/temp01.dbf' to '/oracle/oradata/ORCL/temp01.dbf';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/undotbs01.dbf' to '/oracle/oradata/ORCL/undotbs01.dbf';
ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/users01.dbf' to '/oracle/oradata/ORCL/users01.dbf';
12 rows selected.
Rename Database Files
Use the composed statements to rename all database files.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/example01.dbf' to '/oracle/oradata/ORCL/example01.dbf';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo01.log' to '/oracle/oradata/ORCL/redo01.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo02.log' to '/oracle/oradata/ORCL/redo02.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo03.log' to '/oracle/oradata/ORCL/redo03.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo04.log' to '/oracle/oradata/ORCL/redo04.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo05.log' to '/oracle/oradata/ORCL/redo05.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/redo06.log' to '/oracle/oradata/ORCL/redo06.log';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/sysaux01.dbf' to '/oracle/oradata/ORCL/sysaux01.dbf';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/system01.dbf' to '/oracle/oradata/ORCL/system01.dbf';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/temp01.dbf' to '/oracle/oradata/ORCL/temp01.dbf';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/undotbs01.dbf' to '/oracle/oradata/ORCL/undotbs01.dbf';
Database altered.
SQL> ALTER DATABASE RENAME FILE '/u01/app/oracle/oradata/ORCL/users01.dbf' to '/oracle/oradata/ORCL/users01.dbf';
Database altered.
Check the result.
SQL> select 'ls -l ' || name file_listing from (select name from v$datafile union select member as name from v$logfile union select name from v$tempfile);
FILE_LISTING
------------------------------------------------------------------------------------------------------------------------
ls -l /oracle/oradata/ORCL/example01.dbf
ls -l /oracle/oradata/ORCL/redo01.log
ls -l /oracle/oradata/ORCL/redo02.log
ls -l /oracle/oradata/ORCL/redo03.log
ls -l /oracle/oradata/ORCL/redo04.log
ls -l /oracle/oradata/ORCL/redo05.log
ls -l /oracle/oradata/ORCL/redo06.log
ls -l /oracle/oradata/ORCL/sysaux01.dbf
ls -l /oracle/oradata/ORCL/system01.dbf
ls -l /oracle/oradata/ORCL/temp01.dbf
ls -l /oracle/oradata/ORCL/undotbs01.dbf
ls -l /oracle/oradata/ORCL/users01.dbf
12 rows selected.
Open Database
Now we can open the database.
SQL> alter database open;
Database altered.
SQL> select name, open_mode from v$database;
NAME OPEN_MODE
--------- --------------------
ORCL READ WRITE
Furthermore, we should trace any incident for a while.
[oracle@primary ~]$ tail -f /oracle/diag/rdbms/orcl/ORCL/trace/alert_ORCL.log
...
Now we have moved the database to another place. If you plans to move a database to a higher version for upgrade, you may refer to the post: How to Move 11.2.0.2 Database to 11.2.0.4 Environment and Upgrade.