You can use the transportable tablespaces feature to move a subset of an Oracle Database and "plug" it in to another Oracle Database, essentially moving tablespaces between the databases. The tablespaces being transported can be either dictionary managed or locally managed. Starting with Oracle9i, the transported tablespaces are not required to be of the same block size as the target database standard block size.
Moving data using transportable tablespaces is much faster than performing either an export/import or unload/load of the same data. This is because the datafiles containing all of the actual data are simply copied to the destination location, and you use an import utility to transfer only the metadata of the tablespace objects to the new database.
Starting with Oracle Database 10g, you can transport tablespaces across platforms. This functionality can be used to Allow a database to be migrated from one platform to another. However not all platforms are supported. To see which platforms are supported give the following query.
SQL> COLUMN PLATFORM_NAME FORMAT A30
SQL> SELECT * FROM V$TRANSPORTABLE_PLATFORM;
If the source platform and the target platform are of different endianness, then an additional step must be done on either the source or target platform to convert the tablespace being transported to the target format. If they are of the same endianness, then no conversion is necessary and tablespaces can be transported as if they were on the same platform.
Important: Before a tablespace can be transported to a different platform, the datafile header must identify the platform to which it belongs. In an Oracle Database with compatibility set to 10.0.0 or higher, you can accomplish this by making the datafile read/write at least once.
SQL> alter tablespace ica read only;
Then,
SQL> alter tablespace ica read write;
To move or copy a set of tablespaces, perform the following steps.
If you are transporting the tablespace set to a platform different from the source platform, then determine if the source and target platforms are supported and their endianness. If both platforms have the same endianness, no conversion is necessary. Otherwise you must do a conversion of the tablespace set either at the source or target database.
Ignore this step if you are transporting your tablespace set to the same platform.
A transportable tablespace set consists of datafiles for the set of tablespaces being transported and an export file containing structural information for the set of tablespaces.
If you are transporting the tablespace set to a platform with different endianness from the source platform, you must convert the tablespace set to the endianness of the target platform. You can perform a source-side conversion at this step in the procedure, or you can perform a target-side conversion as part of step 4.
Copy the datafiles and the export file to the target database. You can do this using any facility for copying flat files (for example, an operating system copy utility, ftp, the DBMS_FILE_COPY package, or publishing on CDs).
If you have transported the tablespace set to a platform with different endianness from the source platform, and you have not performed a source-side conversion to the endianness of the target platform, you should perform a target-side conversion now.
Invoke the Export utility to plug the set of tablespaces into the target database.
These steps are illustrated more fully in the example that follows, where it is assumed the following datafiles and tablespaces exist:
Tablespace |
Datafile: |
ica_sales_1 |
/u01/oracle/oradata/ica_salesdb/ica_sales_101.dbf |
ica_sales_2 |
/u01/oracle/oradata/ica_salesdb/ica_sales_201.dbf |
This step is only necessary if you are transporting the tablespace set to a platform different from the source platform. If ica_sales_1 and ica_sales_2 were being transported to a different platform, you can execute the following query on both platforms to determine if the platforms are supported and their endian formats:
SELECT d.PLATFORM_NAME, ENDIAN_FORMAT FROM V$TRANSPORTABLE_PLATFORM tp, V$DATABASE d WHERE tp.PLATFORM_NAME = d.PLATFORM_NAME;
The following is the query result from the source platform:
PLATFORM_NAME ENDIAN_FORMAT ------------------------- --------------
Solaris[tm] OE (32-bit) Big
The following is the result from the target platform:
PLATFORM_NAME ENDIAN_FORMAT ------------------------- --------------
Microsoft Windows NT Little
You can see that the endian formats are different and thus a conversion is necessary for transporting the tablespace set.
There may be logical or physical dependencies between objects in the transportable set and those outside of the set. You can only transport a set of tablespaces that is self-contained. That is it should not have tables with foreign keys referring to primary key of tables which are in other tablespaces. It should not have tables with some partitions in other tablespaces. To find out whether the tablespace is self contained do the following
EXECUTE DBMS_TTS.TRANSPORT_SET_CHECK('ica_sales_1,ica_sales_2', TRUE);
After executing the above give the following query to see whether any violations are there.
SQL> SELECT * FROM TRANSPORT_SET_VIOLATIONS;
VIOLATIONS
---------------------------------------------------------------------------
Constraint DEPT_FK between table SAMI.EMP in tablespace
ICA_SALES_1 and table
SAMI.DEPT in tablespace OTHER
Partitioned table SAMI.SALES is partially contained in the
transportable set
These violations must be resolved before ica_sales_1 and ica_sales_2 are transportable
After ensuring you have a self-contained set of tablespaces that you want to transport, generate a transportable tablespace set by performing the following actions:
Make all tablespaces in the set you are copying read-only.
SQL> ALTER TABLESPACE ica_sales_1 READ ONLY;
Tablespace altered.
SQL> ALTER TABLESPACE ica_sales_2 READ ONLY;
Tablespace altered.
Invoke the Export utility on the host system and specify which tablespaces are in the transportable set.
SQL> HOST
$ exp system/password FILE=/u01/oracle/expdat.dmp
TRANSPORT_TABLESPACES = ica_sales_1,ica_sales_2
If ica_sales_1 and ica_sales_2 are being transported to a different platform, and the endianness of the platforms is different, and if you want to convert before transporting the tablespace set, then convert the datafiles composing the ica_sales_1 and ica_sales_2 tablespaces. You have to use RMAN utility to convert datafiles
$ RMAN TARGET /
Recovery Manager: Release 10.1.0.0.0
Copyright (c) 1995,
2003, Oracle Corporation. All rights reserved.
connected to target database: ica_salesdb (DBID=3295731590)
Convert the datafiles into a temporary location on the source platform. In this example, assume that the temporary location, directory /temp, has already been created. The converted datafiles are assigned names by the system.
RMAN> CONVERT TABLESPACE ica_sales_1,ica_sales_2
TO PLATFORM 'Microsoft Windows NT' FORMAT '/temp/%U';
Starting backup at 08-APR-03
using target database control
file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=11
devtype=DISK
channel ORA_DISK_1: starting datafile conversion
input
datafile fno=00005 name=/u01/oracle/oradata/ica_salesdb/ica_sales_101.dbf
converted datafile=/temp/data_D-10_I-3295731590_TS-ADMIN_TBS_FNO-5_05ek24v5
channel ORA_DISK_1: datafile conversion complete, elapsed
time: 00:00:15
channel ORA_DISK_1: starting datafile conversion
input
datafile fno=00004 name=/u01/oracle/oradata/ica_salesdb/ica_sales_101.dbf
converted datafile=/temp/data_D-10_I-3295731590_TS-EXAMPLE_FNO-4_06ek24vl
channel ORA_DISK_1: datafile conversion complete, elapsed
time: 00:00:45
Finished backup at 08-APR-07
Transport both the datafiles and the export file of the tablespaces to a place accessible to the target database. You can use any facility for copying flat files (for example, an operating system copy utility, ftp, the DBMS_FILE_TRANSFER package, or publishing on CDs).
Plug in the tablespaces and integrate the structural information using the Import utility, imp:
IMP system/password FILE=expdat.dmp
DATAFILES=/ica_salesdb/ica_sales_101.dbf,/ica_salesdb/ica_sales_201.dbf
REMAP_SCHEMA=(smith:sami)
REMAP_SCHEMA=(williams:john)
The REMAP_SCHEMA parameter changes the ownership of database objects. If you do not specify REMAP_SCHEMA, all database objects (such as tables and indexes) are created in the same user schema as in the source database, and those users must already exist in the target database. If they do not exist, then the import utility returns an error. In this example, objects in the tablespace set owned by smith in the source database will be owned by sami in the target database after the tablespace set is plugged in. Similarly, objects owned by williams in the source database will be owned by john in the target database. In this case, the target database is not required to have users smith and williams, but must have users sami and john.
After this statement executes successfully, all tablespaces in the set being copied remain in read-only mode. Check the import logs to ensure that no error has occurred.
Now, put the tablespaces into read/write mode as follows:
ALTER TABLESPACE ica_sales_1 READ WRITE;
ALTER TABLESPACE ica_sales_2 READ WRITE;
Interface Computers Academy © 2007-2017 All Rights Reserved