• Skip to primary navigation
  • Skip to main content
  • Skip to primary sidebar
  • Skip to footer navigation

The Geek Diary

  • OS
    • Linux
    • CentOS/RHEL
    • Solaris
    • Oracle Linux
    • VCS
  • Interview Questions
  • Database
    • oracle
    • oracle 12c
    • ASM
    • mysql
    • MariaDB
  • DevOps
    • Docker
    • Shell Scripting
  • Big Data
    • Hadoop
    • Cloudera
    • Hortonworks HDP

Oracle Database 12c New Feature – Move a Datafile Online

by admin

In this release, a data file can now be moved online while it is open and being accessed, even for data files in system tablespace. Being able to move a data file online means that many maintenance operations, such as moving data to another storage device or moving databases into Oracle Automatic Storage Management (Oracle ASM), can be performed while users are accessing the system. This ensures that continuity of service and service-level agreements (SLA) on uptime can be met.

With Oracle 12C, you can now do the following operations while the datafile is online and being accessed:

  1. Renaming an Online Data File
  2. Relocating an Online Data File
  3. Copying an Online Data File
  4. Relocating an Online Data File and Overwriting an Existing File
  5. Relocating an Online Data File to Oracle ASM

The following is an example of how each operation is done.

Renaming an Online Data File

SQL> CREATE TABLESPACE test DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test.dbf' SIZE 50M
EXTENT MANAGEMENT LOCAL
SEGMENT SPACE MANAGEMENT AUTO;  2    3

Tablespace created.
SQL> select file_name, status, online_status from dba_data_files;

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/system01.dbf
AVAILABLE SYSTEM

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/sysaux01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/undotbs01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/users01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test.dbf
AVAILABLE ONLINE
SQL> ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test.dbf' 
TO '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';

Database altered.
SQL> select file_name, status, online_status from dba_data_files where file_name='/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf
AVAILABLE ONLINE

Relocating an Online Data File

SQL> ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf' TO '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf';
 
Database altered.
SQL> select file_name, status, online_status from dba_data_files where file_name='/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';

no rows selected
SQL> select file_name, status, online_status from dba_data_files;

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/system01.dbf
AVAILABLE SYSTEM

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/sysaux01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/undotbs01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/users01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf
AVAILABLE ONLINE

Copying an Online Data File

SQL> ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf' TO '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf' keep;

Database altered.
SQL> select file_name, status, online_status from dba_data_files where file_name='/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';

no rows selected
SQL> select file_name, status, online_status from dba_data_files;

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/system01.dbf
AVAILABLE SYSTEM

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/sysaux01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/undotbs01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/users01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf
AVAILABLE ONLINE

-- expect to see the entry:
-- /bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf
-- AVAILABLE ONLINE

-- However, when i try to move the datafile to the location /bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3 i get the following error
-- which verifies that the datafile was indeed copied and kept available in the old location:

SQL> ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf'
TO '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';   2
ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf'
*
ERROR at line 1:
ORA-01119: error in creating database file
'/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf'
ORA-27038: created file already exists
Additional information: 1

Example of relocating an Online Data File and Overwriting an Existing File

SQL> ALTER DATABASE MOVE DATAFILE '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/test_renamed.dbf' 
TO '/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf' REUSE;

Database altered.
SQL> select file_name, status, online_status from dba_data_files where file_name='/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf';

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf
AVAILABLE ONLINE
SQL> select file_name, status, online_status from dba_data_files;

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS    ONLINE_
--------- -------
/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/system01.dbf
AVAILABLE SYSTEM

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/sysaux01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/undotbs01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/users01.dbf
AVAILABLE ONLINE

/bugmnt17/em/celclnx14/SR3.5377673271/app/oracle/oradata/T12cB3/test_renamed.dbf
AVAILABLE ONLINE

Relocate an Online Data File to Oracle ASM

This example moves the data file user1.dbf from the /u01/oracle/rbdb1/ directory to an Oracle ASM location.

SQL> ALTER DATABASE MOVE DATAFILE '/u01/oracle/rbdb1/user1.dbf' 
  TO '+dgroup_01/data/orcl/datafile/user1.dbf';

This example moves the data file from one Oracle ASM location to another Oracle ASM location.

SQL> ALTER DATABASE MOVE DATAFILE '+dgroup_01/data/orcl/datafile/user1.dbf' 
  TO '+dgroup_02/data/orcl/datafile/user1.dbf';

Filed Under: oracle, oracle 12c

Some more articles you might also be interested in …

  1. PL/SQL Nested Blocks
  2. Oracle Software Group Accounts OSDBA, OSOPER, Oracle Inventory group
  3. Understanding Dynamic Oracle Net Server Tracing
  4. How to Find OCR Master Node
  5. How to pass a value from shell script to GoldenGate replicat for mapping to target table column
  6. ORA-12514: TNS:listener does not currently know of service requested in connect descriptor
  7. Oracle 12c: Migrate non-CDB and Convert to a PDB using 12c RMAN Active Database Duplication
  8. Unable to create spfile for Oracle ASM instance
  9. What are Oracle Database Valut Schemas
  10. How To Set the Permission of the Files Created Using UTL_FILE

You May Also Like

Primary Sidebar

Recent Posts

  • JavaFX ComboBox: Set a value to the combo box
  • Nginx load balancing
  • nginx 504 gateway time-out
  • Images preview with ngx_http_image_filter_module

© 2022 · The Geek Diary

  • Archives
  • Contact Us
  • Copyright