RMAN Transportable Tablespace with Data Pump

You can use this method only if the on-premises platform is little endian, and the database character sets of your on-premises database and the Databaseservice database are compatible.

You can use this method to eliminate placing the tablespaces in READ ONLY mode, as required by the Data Pump Transportable Tablespace method.

To migrate an on-premises source database to a database deployment on the Database service using the RMAN Transportable Tablespace with Data Pump method, you perform these tasks:

  1. On the on-premises database host, invoke RMAN and create the transportable tablespace set.

  2. Use a secure copy utility to transfer the Data Pump Export dump file and the tablespace datafiles to the Database service compute node.

  3. On the Database service compute node, prepare the database for the tablespace import.

  4. On the Database service compute node, invoke Data Pump Import and connect to the database. Import the data into the database using the TRANSPORT_DATAFILES option.

  5. After verifying that the data has been imported successfully, you can delete the dump file.

RMAN Transportable Tablespace with Data Pump: Example

This example provides a step-by-step demonstration of the tasks required to migrate tablespaces in an on-premises Oracle database to a Database service database.

This example performs a migration of the FSDATA and FSINDEX tablespaces.

In this example, the on-premises database is on a Linux host.

  1. On the on-premises database host, invoke RMAN and create the transportable tablespace set.

    1. On the on-premises database host, create an operating system directory for the datafiles.

      mkdir /u01/app/oracle/admin/orcl/rman_transdest
    2. On the on-premises data host, create an operating system directory for the RMAN auxiliary instance files.

      mkdir /u01/app/oracle/admin/orcl/rman_auxdest
    3. Invoke RMAN and log in as the SYSTEM user. Enter the password for the SYSTEM user when prompted.

      rman target system
    4. Execute the TRANSPORT TABLESPACE command.

      RMAN> TRANSPORT TABLESPACE fsdata, fsindex
      2> TABLESPACE DESTINATION '/u01/app/oracle/admin/orcl/rman_transdest'
      3> AUXILIARY DESTINATION '/u01/app/oracle/admin/orcl/rman_auxdest';
    5. Log out of RMAN.

    6. Optionally, navigate to the directory you specified for the TABLESPACE DESTINATION and view the files that were created by the TRANSPORT TABLESPACE operation.

      cd /u01/app/oracle/admin/orcl/rman_transdest
      $ ls
      dmpfile.dmp  fsdata01.dbf  fsindex01.dbf  impscrpt.sql
  2. Use a secure copy utility to transfer the Data Pump Export dump file and the tablespace datafiles to the Database service compute node.

    In this example the dump file is copied to the /u01 directory. Choose the appropriate location based on the size of the file that will be transferred.

    1. On the Database service compute node, create a directory for the dump file.

      mkdir /u01/app/oracle/admin/ORCL/dpdump/from_onprem
    2. Before using the scp command to copy files, make sure the SSH private key that provides access to the Database service compute node is available on your on-premises host.

    3. On the on-premises database host, use the SCP utility to transfer the dump file and all datafiles of the transportable set to the Database service compute node.

      scp -i private_key_file \
      /u01/app/oracle/admin/orcl/rman_transdest/dmpfile.dmp \
      oracle@IP_address_DBaaS_VM:/u01/app/oracle/admin/ORCL/dpdump/from_onprem
      
      $ scp -i private_key_file \
      /u01/app/oracle/admin/orcl/rman_transdest/fsdata01.dbf \
      oracle@IP_address_DBaaS_VM:/u02/app/oracle/oradata/ORCL
      
      $ scp -i private_key_file \
      /u01/app/oracle/admin/orcl/rman_transdest/fsindex01.dbf \
      oracle@IP_address_DBaaS_VM:/u02/app/oracle/oradata/ORCL
  3. On the Database service compute node, prepare the database for the tablespace import.

    1. On the Database service compute node, invoke SQL*Plus and log in to the database as the SYSTEM user.

    2. Create a directory object in the Database service database.

      SQL> CREATE DIRECTORY dp_from_onprem AS '/u01/app/oracle/admin/ORCL/dpdump/from_onprem';
    3. If the owners of the objects that will be imported do not exist in the database, create them before performing the import. The transportable tablespace mode of import does not create the users.

      SQL> CREATE USER fsowner
        2  PROFILE default
        3  IDENTIFIED BY fspass
        4  TEMPORARY TABLESPACE temp
        5  ACCOUNT UNLOCK;
  4. On the Database service compute node, invoke Data Pump Import and connect to the database.

    Import the data into the database using the TRANSPORT_DATAFILES option.

    impdp system DIRECTORY=dp_from_onprem DUMPFILE='dmpfile.dmp' \
    TRANSPORT_DATAFILES='/u02/app/oracle/oradata/ORCL/fsdata01.dbf', \
    '/u02/app/oracle/oradata/ORCL/fsindex01.dbf'
  5. After verifying that the data has been imported successfully, you can delete the dmpfile.dmp dump file.