Sunday, May 16, 2010

I. RENAME OR MOVE DATAFILE(S) WITH THE DATABASE OPEN

I. RENAME OR MOVE DATAFILE(S) WITH THE DATABASE OPEN
----------------------------------------------------

Datafiles can be renamed or moved while the database is open. However, the
tablespace must be made READ-ONLY. This will allow users to select from the
tablespace, but prevents them from doing inserts, updates, and deletes. The
amount of time the tablespace is required to be read only will depend on how
large the datafile(s) are and how long it takes to copy the datafile(s) to the
new location.

Making the tablespace read only freezes the file header, preventing updates
from being made to the file header. Since this datafile is then at a read
only state, it is possible to copy the file while the database is open.

To do this you must follow these steps:

1. Determine how many datafiles are associated with the tablespace.

> SELECT FILE_NAME, STATUS FROM DBA_DATA_FILES
WHERE TABLESPACE_NAME = '';

TESTING1 >select file_name,status from dba_data_files where tablespace_name='TEST';

FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS
---------
/data/oracle/TESTING1/u01/test.dbf
AVAILABLE


2. Make sure that all datafiles returned have the status AVAILABLE.


3. Make the tablespace is read only.

 ALTER TABLESPACE READ ONLY;

TESTING1 >alter tablespace test read only;

Tablespace altered.


4. Make sure that the tablespace is defined as read only in the data
dictionary.

> SELECT TABLESPACE_NAME, STATUS FROM DBA_TABLESPACES
WHERE TABLESPACE_NAME = '';

TABLESPACE_NAME STATUS
------------------------------ ---------
READ ONLY

TESTING1 >select tablespace_name,status from dba_tablespaces where tablespace_name='TEST';

TABLESPACE_NAME STATUS
------------------------------ ---------
TEST READ ONLY



5. Copy the datafile(s) to the new location using the operating system copy
command. Once the datafile(s) have been copied to the new location compare
the sizes of the datafiles. Make sure that the sizes match.

cp test.dbf /data/oracle/TESTING1/test/



6. Once the datafiles have been copied to the new location alter the
tablespace offline.

> ALTER TABLESPACE OFFLINE;
TESTING1 >alter tablespace test offline;

Tablespace altered.

* At this point the tablespace is not accessible to users.

7. Once the tablespace is offline you will need to rename the datafile(s) to
the new location. This updates the entry for the datafile(s) in the
controlfile.

> ALTER DATABASE RENAME FILE
'/FULL_PATH_OF_OLD_LOCATION/AND_DATAFILE_NAME.DBF'
TO
'/FULL_PATH_OF_NEW_LOCATION/AND_DATAFILE_NAME.DBF';

* You will need to do this for all datafiles associated with
this tablespace. You can use the ALTER TABLESPACE ... RENAME DATAFILE
syntax as well.

TESTING1 >alter database rename file '/data/oracle/TESTING1/u01/test.dbf' to '/data/oracle/TESTING1/test/test.dbf';

Database altered.

8. Once the alter database statement has been processed for the datafile(s)
you can bring the tablespace online.

 ALTER TABLESPACE YOUR_TABLESPACE_NAME ONLINE;

TESTING1 >alter tablespace test online;

Tablespace altered.

9. After you bring the tablespace back online you can make the tablespace
read/write again.

 ALTER TABLESPACE YOUR_TABLESPACE_NAME READ WRITE;

TESTING1 >alter tablespace test read write;

Tablespace altered.

10. You can check the status of the tablespace to make sure it is read/write.
You can also verify that the controlfile has been updated by doing the
following:

 ALTER DATABASE BACKUP CONTROLFILE TO TRACE;


This will produce a readable copy of the contents of your controlfile
which will be placed in your user_dump_dest directory.

Optionally, you can query V$DATAFILE, which gets information from the
controlfile as well.

11. Remove the datafile(s) from the old location at the O/S level.


II. RENAME AND OR MOVE DATAFILE(S) WITH THE DATABASE SHUT DOWN
--------------------------------------------------------------

1. If the database is up, shut it down.

2. Copy the datafile to the new name/location at operating system level.

cp test.dbf /data/oracle/TESTING1/test/

3. Mount the database.

> STARTUP MOUNT

This command will read the control file but will not mount the datafiles.

4. Rename the file inside Oracle.


> ALTER DATABASE RENAME FILE
'/FULL_PATH_OF_OLD_LOCATION/AND_DATAFILE_NAME.DBF'
TO
'/FULL_PATH_OF_NEW_LOCATION/AND_DATAFILE_NAME.DBF';

TESTING1 >alter database rename file '/data/oracle/TESTING1/test/test.dbf' to '/data/oracle/TESTING1/u01/test.dbf';

Database altered.


Do this for all the datafiles that were renamed or moved at the operating
system level.

5. Open the database.

> ALTER DATABASE OPEN;

TESTING1 >alter database open;
alter database open
*
ERROR at line 1:
ORA-01113: file 4 needs media recovery
ORA-01110: data file 4: '/data/oracle/TESTING1/u01/test.dbf'


TESTING1 >recover datafile 4;
Media recovery complete.
TESTING1 >alter database open;


6. Query v$dbfile to confirm that the changes made were correct.

> SELECT * FROM V$DBFILE;

TESTING1 >select * from v$dbfile;

FILE#
----------
NAME
----------------------------------------------------------------------------------------------------
3
/data/oracle/TESTING1/u01/sysaux.dbf

2
/data/oracle/TESTING1/u01/undotbs01.dbf

1
/data/oracle/TESTING1/u01/system.dbf

4
/data/oracle/TESTING1/u01/test.dbf

7. Remove the datafile(s) from the old location at the operating system level.



NOTE: To rename or relocate datafiles in the SYSTEM tablespace you must use
option II, 'Renaming or Moving a Datafile with the Database Shut Down',
because you cannot take the SYSTEM tablespace offline.

No comments: