8i | 9i | 10g | 11g | 12c | 13c | 18c | 19c | 21c | 23c | Misc | PL/SQL | SQL | RAC | WebLogic | Linux

Home » Articles » 10g » Here

Oracle Data Pump (expdp, impdp) in Oracle Database 10g, 11g, 12c, 18c, 19c, 21c

Oracle Data Pump is a newer, faster and more flexible alternative to the "exp" and "imp" utilities used in previous Oracle versions. In addition to basic import and export functionality data pump provides a PL/SQL API and support for external tables.

This article was originally written against Oracle 10g, but the information is still relevant up to and including the latest versions of Oracle. New features are broken out into separate articles, but the help section at the bottom is up to date with the latest versions.

Related articles.

Getting Started

For the examples to work we must first unlock the SCOTT account and create a directory object it can access. The directory object is only a pointer to a physical directory, creating it does not actually create the physical directory on the file system of the database server.

CONN / AS SYSDBA
ALTER USER scott IDENTIFIED BY tiger ACCOUNT UNLOCK;

CREATE OR REPLACE DIRECTORY test_dir AS '/u01/app/oracle/oradata/';
GRANT READ, WRITE ON DIRECTORY test_dir TO scott;

Existing directories can be queried using the ALL_DIRECTORIES view.

Data Pump is a server-based technology, so it typically deals with directory objects pointing to physical directories on the database server. It does not write to the local file system on your client PC.

Table Exports/Imports

The TABLES parameter is used to specify the tables that are to be exported. The following is an example of the table export and import syntax.

expdp scott/tiger@db10g tables=EMP,DEPT directory=TEST_DIR dumpfile=EMP_DEPT.dmp logfile=expdpEMP_DEPT.log

impdp scott/tiger@db10g tables=EMP,DEPT directory=TEST_DIR dumpfile=EMP_DEPT.dmp logfile=impdpEMP_DEPT.log

For example output files see expdpEMP_DEPT.log and impdpEMP_DEPT.log.

The TABLE_EXISTS_ACTION=APPEND parameter allows data to be imported into existing tables.

Schema Exports/Imports

The OWNER parameter of exp has been replaced by the SCHEMAS parameter which is used to specify the schemas to be exported. The following is an example of the schema export and import syntax.

expdp scott/tiger@db10g schemas=SCOTT directory=TEST_DIR dumpfile=SCOTT.dmp logfile=expdpSCOTT.log

impdp scott/tiger@db10g schemas=SCOTT directory=TEST_DIR dumpfile=SCOTT.dmp logfile=impdpSCOTT.log

For example output files see expdpSCOTT.log and impdpSCOTT.log.

Database Exports/Imports

The FULL parameter indicates that a complete database export is required. The following is an example of the full database export and import syntax.

expdp system/password@db10g full=Y directory=TEST_DIR dumpfile=DB10G.dmp logfile=expdpDB10G.log

impdp system/password@db10g full=Y directory=TEST_DIR dumpfile=DB10G.dmp logfile=impdpDB10G.log

For an example output file see expdpDB10G.log.

That database user performing the export will need DATAPUMP_EXP_FULL_DATABASE role, and the user performing the import will need the DATAPUMP_IMP_FULL_DATABASE role.

INCLUDE and EXCLUDE

The INCLUDE and EXCLUDE parameters can be used to limit the export/import to specific objects. When the INCLUDE parameter is used, only those objects specified by it will be included in the export/import. When the EXCLUDE parameter is used, all objects except those specified by it will be included in the export/import. The two parameters are mutually exclusive, so use the parameter that requires the least entries to give you the result you require. The basic syntax for both parameters is the same.

INCLUDE=object_type[:name_clause] [, ...]
EXCLUDE=object_type[:name_clause] [, ...]

The following code shows how they can be used as command line parameters.

expdp scott/tiger@db10g schemas=SCOTT include=TABLE:"IN ('EMP', 'DEPT')" directory=TEST_DIR dumpfile=SCOTT.dmp logfile=expdpSCOTT.log

expdp scott/tiger@db10g schemas=SCOTT exclude=TABLE:"= 'BONUS'" directory=TEST_DIR dumpfile=SCOTT.dmp logfile=expdpSCOTT.log

If the parameter is used from the command line, depending on your OS, the special characters in the clause may need to be escaped, as follows. Because of this, it is easier to use a parameter file.

include=TABLE:\"IN (\'EMP\', \'DEPT\')\"

A single import/export can include multiple references to the parameters, so to export tables, views and some packages we could use either of the following approaches.

INCLUDE=TABLE,VIEW,PACKAGE:"LIKE '%API'"

or

INCLUDE=TABLE
INCLUDE=VIEW
INCLUDE=PACKAGE:"LIKE '%API'"

Multiple objects can be targeted in once statement using the LIKE and IN operators.

EXCLUDE=SCHEMA:"LIKE 'SYS%'"

EXCLUDE=SCHEMA:"IN ('OUTLN','SYSTEM','SYSMAN','FLOWS_FILES','APEX_030200','APEX_PUBLIC_USER','ANONYMOUS')"

The valid object type paths that can be included or excluded can be displayed using the DATABASE_EXPORT_OBJECTS, SCHEMA_EXPORT_OBJECTS, and TABLE_EXPORT_OBJECTS views.

CONTENT and QUERY

The CONTENT parameter allows you to alter the contents of the export. The following command uses the METADATA_ONLY parameter value to export the contents of the schema without the data.

expdp system/password@db10g schemas=SCOTT directory=TEST_DIR dumpfile=scott_meta.dmp logfile=expdp.log content=METADATA_ONLY

To capture the data without the metadata use the DATA_ONLY parameter value.

expdp system/password@db10g schemas=SCOTT directory=TEST_DIR dumpfile=scott_data.dmp logfile=expdp.log content=DATA_ONLY

The QUERY parameter allows you to alter the rows exported from one or more tables. The following example does a full database export, but doesn't include the data for the EMP and DEPT tables.

expdp system/password@db10g full=Y directory=TEST_DIR dumpfile=full.dmp logfile=expdp_full.log query='SCOTT.EMP:"WHERE deptno=0",SCOTT.DEPT:"WHERE deptno=0"'

The way you handle quotes on the command line will vary depending on what you are trying to achieve. Here are some examples that work for single tables and multiple tables directly from the command line.

# Single Table. Multiple quoting methods possible.
expdp scott/tiger@pdb1 schemas=scott directory=TEST_DIR dumpfile=scott1.dmp logfile=scott1.log query=SCOTT.EMP:'"WHERE deptno=10"'
expdp scott/tiger@pdb1 schemas=scott directory=TEST_DIR dumpfile=scott2.dmp logfile=scott2.log query=SCOTT.EMP:\"WHERE deptno=10\"
expdp scott/tiger@pdb1 schemas=scott directory=TEST_DIR dumpfile=scott3.dmp logfile=scott3.log query='SCOTT.EMP:"WHERE deptno=10"'

# Multiple WHERE clause on each table.
expdp scott/tiger@pdb1 schemas=scott directory=TEST_DIR dumpfile=scott4.dmp logfile=scott4.log query='SCOTT.EMP:"WHERE deptno=10",SCOTT.DEPT:"WHERE deptno=20"'

Network Exports/Imports (NETWORK_LINK)

The NETWORK_LINK parameter identifies a database link to be used as the source for a network export/import. The following database link will be used to demonstrate its use.

CONN / AS SYSDBA
GRANT CREATE DATABASE LINK TO test;

CONN test/test
CREATE DATABASE LINK remote_scott CONNECT TO scott IDENTIFIED BY tiger USING 'DEV';

In the case of exports, the NETWORK_LINK parameter identifies the database link pointing to the source server. The objects are exported from the source server in the normal manner, but written to a directory object on the local server, rather than one on the source server. Both the local and remote users require the EXP_FULL_DATABASE role granted to them.

expdp test/test@db10g tables=SCOTT.EMP network_link=REMOTE_SCOTT directory=TEST_DIR dumpfile=EMP.dmp logfile=expdpEMP.log

For imports, the NETWORK_LINK parameter also identifies the database link pointing to the source server. The difference here is the objects are imported directly from the source into the local server without being written to a dump file. Although there is no need for a DUMPFILE parameter, a directory object is still required for the logs associated with the operation. Both the local and remote users require the IMP_FULL_DATABASE role granted to them.

impdp test/test@db10g tables=SCOTT.EMP network_link=REMOTE_SCOTT directory=TEST_DIR logfile=impdpSCOTT.log remap_schema=SCOTT:TEST

Flashback Exports

The exp utility used the CONSISTENT=Y parameter to indicate the export should be consistent to a point in time. By default the expdp utility exports are only consistent on a per table basis. If you want all tables in the export to be consistent to the same point in time, you need to use the FLASHBACK_SCN or FLASHBACK_TIME parameter.

The FLASHBACK_TIME parameter value is converted to the approximate SCN for the specified time.

expdp ..... flashback_time=systimestamp

# In parameter file.
flashback_time="to_timestamp('09-05-2011 09:00:00', 'DD-MM-YYYY HH24:MI:SS')"

# Escaped on command line.
expdp ..... flashback_time=\"to_timestamp\(\'09-05-2011 09:00:00\', \'DD-MM-YYYY HH24:MI:SS\'\)\"

Not surprisingly, you can make exports consistent to an earlier point in time by specifying an earlier time or SCN, provided you have enough UNDO space to keep a read consistent view of the data during the export operation.

If you prefer to use the SCN, you can retrieve the current SCN using one of the following queries.

SELECT current_scn FROM v$database;
SELECT DBMS_FLASHBACK.get_system_change_number FROM dual;
SELECT TIMESTAMP_TO_SCN(SYSTIMESTAMP) FROM dual;

That SCN is then used with the FLASHBACK_SCN parameter.

expdp ..... flashback_scn=5474280

The following queries may prove useful for converting between timestamps and SCNs.

SELECT TIMESTAMP_TO_SCN(SYSTIMESTAMP) FROM dual;
SELECT SCN_TO_TIMESTAMP(5474751) FROM dual;

In 11.2, the introduction of legacy mode means that you can use the CONSISTENT=Y parameter with the expdp utility if you wish.

Miscellaneous Information

Unlike the original exp and imp utilities all data pump ".dmp" and ".log" files are created on the Oracle server, not the client machine.

Data pump performance can be improved by using the PARALLEL parameter. This should be used in conjunction with the "%U" wildcard in the DUMPFILE parameter to allow multiple dumpfiles to be created or read. The same wildcard can be used during the import to allow you to reference multiple files.

expdp scott/tiger@db10g schemas=SCOTT directory=TEST_DIR parallel=4 dumpfile=SCOTT_%U.dmp logfile=expdpSCOTT.log

impdp scott/tiger@db10g schemas=SCOTT directory=TEST_DIR parallel=4 dumpfile=SCOTT_%U.dmp logfile=impdpSCOTT.log

The DBA_DATAPUMP_JOBS view can be used to monitor the current jobs.

system@db10g> select * from dba_datapump_jobs;

OWNER_NAME                     JOB_NAME                       OPERATION
------------------------------ ------------------------------ ------------------------------
JOB_MODE                       STATE                              DEGREE ATTACHED_SESSIONS
------------------------------ ------------------------------ ---------- -----------------
SYSTEM                         SYS_EXPORT_FULL_01             EXPORT
FULL                           EXECUTING                               1                 1

Data Pump API

You can see more examples of this here.

Along with the data pump utilities Oracle provide an PL/SQL API. The following is an example of how this API can be used to perform a schema export.

DECLARE
  l_dp_handle       NUMBER;
BEGIN
  -- Open an schema export job.
  l_dp_handle := DBMS_DATAPUMP.open(
    operation   => 'EXPORT',
    job_mode    => 'SCHEMA',
    remote_link => NULL,
    job_name    => 'SCOTT_EXPORT',
    version     => 'LATEST');

  -- Specify the dump file name and directory object name.
  DBMS_DATAPUMP.add_file(
    handle    => l_dp_handle,
    filename  => 'SCOTT.dmp',
    directory => 'TEST_DIR');

  -- Specify the log file name and directory object name.
  DBMS_DATAPUMP.add_file(
    handle    => l_dp_handle,
    filename  => 'expdpSCOTT.log',
    directory => 'TEST_DIR',
    filetype  => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE);

  -- Specify the schema to be exported.
  DBMS_DATAPUMP.metadata_filter(
    handle => l_dp_handle,
    name   => 'SCHEMA_EXPR',
    value  => '= ''SCOTT''');

  DBMS_DATAPUMP.start_job(l_dp_handle);

  DBMS_DATAPUMP.detach(l_dp_handle);
END;
/

Once the job has started the status can be checked using.

system@db10g> select * from dba_datapump_jobs;

The following is an example of how this API can be used to perform a schema import with a schema remap operation.

DECLARE
  l_dp_handle       NUMBER;
BEGIN
  -- Open an schema import job.
  l_dp_handle := DBMS_DATAPUMP.open(
    operation   => 'IMPORT',
    job_mode    => 'SCHEMA',
    remote_link => NULL,
    job_name    => 'SCOTT_IMPORT',
    version     => 'LATEST');

  -- Specify the dump file name and directory object name.
  DBMS_DATAPUMP.add_file(
    handle    => l_dp_handle,
    filename  => 'SCOTT.dmp',
    directory => 'TEST_DIR');

  -- Specify the log file name and directory object name.
  DBMS_DATAPUMP.add_file(
    handle    => l_dp_handle,
    filename  => 'impdpSCOTT.log',
    directory => 'TEST_DIR',
    filetype  => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE);

  -- Perform a REMAP_SCHEMA from SCOTT to SCOTT2.
  DBMS_DATAPUMP.metadata_remap(
    handle     => l_dp_handle,
    name       => 'REMAP_SCHEMA',
    old_value  => 'SCOTT',
    value      => 'SCOTT2');

  DBMS_DATAPUMP.start_job(l_dp_handle);

  DBMS_DATAPUMP.detach(l_dp_handle);
END;
/

External Tables (Unloading/Loading Data Using External Tables)

Oracle have incorporated support for data pump technology into external tables. The ORACLE_DATAPUMP access driver can be used to unload data to data pump export files and subsequently reload it. The unload of data occurs when the external table is created using the "AS" clause.

CREATE TABLE emp_xt
  ORGANIZATION EXTERNAL
   (
     TYPE ORACLE_DATAPUMP
     DEFAULT DIRECTORY test_dir
     LOCATION ('emp_xt.dmp')
   )
   AS SELECT * FROM emp;

The data can then be queried using the following.

SELECT * FROM emp_xt;

The syntax to create the external table pointing to an existing file is similar, but without the "AS" clause. In this case we will do it the same schema, but this could be in a different schema in the same instance, or in an entirely different instance.

DROP TABLE emp_xt;

CREATE TABLE emp_xt (
  EMPNO     NUMBER(4),
  ENAME     VARCHAR2(10),
  JOB       VARCHAR2(9),
  MGR       NUMBER(4),
  HIREDATE  DATE,
  SAL       NUMBER(7,2),
  COMM      NUMBER(7,2),
  DEPTNO    NUMBER(2))
  ORGANIZATION EXTERNAL (
     TYPE ORACLE_DATAPUMP
     DEFAULT DIRECTORY test_dir
     LOCATION ('emp_xt.dmp')
  );

SELECT * FROM emp_xt;

Creating an external table using the ORACLE_DATAPUMP access driver is restricted to dump files created by the external table unload.

Secure External Password Store

You can also use the secure external password store to provide credentials for data pump.

$ expdp /@db10g_test tables=EMP,DEPT directory=TEST_DIR dumpfile=EMP_DEPT.dmp logfile=expdpEMP_DEPT.log

Roles

That database user performing the export and import operations will need the appropriate level of privilege to complete the actions. For example, if the user can't create a table in the schema, it will not be able to import a table into a schema.

Some of operations, including those at database level will need the DATAPUMP_EXP_FULL_DATABASE and/or DATAPUMP_IMP_FULL_DATABASE roles. These are very powerful, so don't grant them without careful consideration.

Interactive Command Mode

All data pump actions are performed by multiple jobs (DBMS_SCHEDULER not DBMS_JOB jobs). These jobs are controlled by a master control process which uses Advanced Queuing. At runtime an advanced queue table, named after the job name, is created and used by the master control process. The table is dropped on completion of the data pump job. The job and the advanced queue can be named using the JOB_NAME parameter. Cancelling the client process does not stop the associated data pump job. Issuing "CTRL+C" on the client during a job stops the client output and puts you into interactive command mode. You can read more about this in more detail here. Typing "status" at this prompt allows you to monitor the current job.

Export> status

Job: SYS_EXPORT_FULL_01
  Operation: EXPORT
  Mode: FULL
  State: EXECUTING
  Bytes Processed: 0
  Current Parallelism: 1
  Job Error Count: 0
  Dump File: D:\TEMP\DB10G.DMP
    bytes written: 4,096

Worker 1 Status:
  State: EXECUTING
  Object Schema: SYSMAN
  Object Name: MGMT_CONTAINER_CRED_ARRAY
  Object Type: DATABASE_EXPORT/SCHEMA/TYPE/TYPE_SPEC
  Completed Objects: 261
  Total Objects: 261

To switch back to the regular client, using the command "continue_client".

Help

The HELP=Y option displays the available parameters. The following output comes from 18c, but is edited to include the database version when the parameter was introduced.

expdp

$ expdp help=y

Export: Release 18.0.0.0.0 - Production on Mon Jan 28 08:31:55 2019
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates.  All rights reserved.


The Data Pump export utility provides a mechanism for transferring data objects
between Oracle databases. The utility is invoked with the following command:

   Example: expdp scott/tiger DIRECTORY=dmpdir DUMPFILE=scott.dmp

You can control how Export runs by entering the 'expdp' command followed
by various parameters. To specify parameters, you use keywords:

   Format:  expdp KEYWORD=value or KEYWORD=(value1,value2,...,valueN)
   Example: expdp scott/tiger DUMPFILE=scott.dmp DIRECTORY=dmpdir SCHEMAS=scott
               or TABLES=(T1:P1,T1:P2), if T1 is partitioned table

USERID must be the first parameter on the command line.

------------------------------------------------------------------------------

The available keywords and their descriptions follow. Default values are listed within square brackets.

ABORT_STEP (12.1)
Stop the job after it is initialized or at the indicated object.
Valid values are -1 or N where N is zero or greater.
N corresponds to the object's process order number in the master table.

ACCESS_METHOD (12.1)
Instructs Export to use a particular method to unload data.
Valid keyword values are: [AUTOMATIC], DIRECT_PATH and EXTERNAL_TABLE.

ATTACH (10.1)
Attach to an existing job.
For example, ATTACH=job_name.

CLUSTER (11.2)
Utilize cluster resources and distribute workers across the Oracle RAC [YES].

COMPRESSION (10.2)
Reduce the size of a dump file.
Valid keyword values are: ALL, DATA_ONLY, [METADATA_ONLY] and NONE.

COMPRESSION_ALGORITHM (12.1)
Specify the compression algorithm that should be used.
Valid keyword values are: [BASIC], LOW, MEDIUM and HIGH.

CONTENT (10.1)
Specifies data to unload.
Valid keyword values are: [ALL], DATA_ONLY and METADATA_ONLY.

DATA_OPTIONS (11.1)
Data layer option flags.
Valid keyword values are: GROUP_PARTITION_TABLE_DATA, VERIFY_STREAM_FORMAT and XML_CLOBS.

DIRECTORY (12.2)
Directory object to be used for dump and log files.

DUMPFILE (10.1)
Specify list of destination dump file names [expdat.dmp].
For example, DUMPFILE=scott1.dmp, scott2.dmp, dmpdir:scott3.dmp.

ENCRYPTION (11.1)
Encrypt part or all of a dump file.
Valid keyword values are: ALL, DATA_ONLY, ENCRYPTED_COLUMNS_ONLY, METADATA_ONLY and NONE.

ENCRYPTION_ALGORITHM (11.1)
Specify how encryption should be done.
Valid keyword values are: [AES128], AES192 and AES256.

ENCRYPTION_MODE (11.1)
Method of generating encryption key.
Valid keyword values are: DUAL, PASSWORD and [TRANSPARENT].

ENCRYPTION_PASSWORD (10.2)
Password key for creating encrypted data within a dump file.

ENCRYPTION_PWD_PROMPT (12.1)
Specifies whether to prompt for the encryption password [NO].
Terminal echo will be suppressed while standard input is read.

ESTIMATE (10.1)
Calculate job estimates.
Valid keyword values are: [BLOCKS] and STATISTICS.

ESTIMATE_ONLY (10.1)
Calculate job estimates without performing the export [NO].

EXCLUDE (10.1)
Exclude specific object types.
For example, EXCLUDE=SCHEMA:"='HR'".

FILESIZE (10.1)
Specify the size of each dump file in units of bytes.

FLASHBACK_SCN (10.1)
SCN used to reset session snapshot.

FLASHBACK_TIME (10.1)
Time used to find the closest corresponding SCN value.

FULL (10.1)
Export entire database [NO].

HELP (10.1)
Display Help messages [NO].

INCLUDE (10.1)
Include specific object types.
For example, INCLUDE=TABLE_DATA.

JOB_NAME (10.1)
Name of export job to create.

KEEP_MASTER (12.1)
Retain the master table after an export job that completes successfully [NO].

LOGFILE (10.1)
Specify log file name [export.log].

LOGTIME (12.1)
Specifies that messages displayed during export operations be timestamped.
Valid keyword values are: ALL, [NONE], LOGFILE and STATUS.

METRICS (12.1)
Report additional job information to the export log file [NO].

NETWORK_LINK (10.1)
Name of remote database link to the source system.

NOLOGFILE (10.1)
Do not write log file [NO].

PARALLEL (10.1)
Change the number of active workers for current job.

PARFILE (10.1)
Specify parameter file name.

QUERY (10.1)
Predicate clause used to export a subset of a table.
For example, QUERY=employees:"WHERE department_id > 10".

REMAP_DATA (11.1)
Specify a data conversion function.
For example, REMAP_DATA=EMP.EMPNO:REMAPPKG.EMPNO.

REUSE_DUMPFILES (11.1)
Overwrite destination dump file if it exists [NO].

SAMPLE (10.2)
Percentage of data to be exported.

SCHEMAS (10.1)
List of schemas to export [login schema].

SERVICE_NAME (11.2)
Name of an active Service and associated resource group to constrain Oracle RAC resources.

SOURCE_EDITION (11.2)
Edition to be used for extracting metadata.

STATUS (10.1)
Frequency (secs) job status is to be monitored where
the default [0] will show new status when available.

TABLES (10.1)
Identifies a list of tables to export.
For example, TABLES=HR.EMPLOYEES,SH.SALES:SALES_1995.

TABLESPACES (10.1)
Identifies a list of tablespaces to export.

TRANSPORTABLE (12.1)
Specify whether transportable method can be used.
Valid keyword values are: ALWAYS and [NEVER].

TRANSPORT_FULL_CHECK (10.1)
Verify storage segments of all tables [NO].

TRANSPORT_TABLESPACES (10.1)
List of tablespaces from which metadata will be unloaded.

VERSION (10.1)
Version of objects to export.
Valid keyword values are: [COMPATIBLE], LATEST or any valid database version.

VIEWS_AS_TABLES (12.1)
Identifies one or more views to be exported as tables.
For example, VIEWS_AS_TABLES=HR.EMP_DETAILS_VIEW.

------------------------------------------------------------------------------

The following commands are valid while in interactive mode.
Note: abbreviations are allowed.

ADD_FILE
Add dumpfile to dumpfile set.

CONTINUE_CLIENT
Return to logging mode. Job will be restarted if idle.

EXIT_CLIENT
Quit client session and leave job running.

FILESIZE
Default filesize (bytes) for subsequent ADD_FILE commands.

HELP
Summarize interactive commands.

KILL_JOB
Detach and delete job.

PARALLEL
Change the number of active workers for current job.

REUSE_DUMPFILES
Overwrite destination dump file if it exists [NO].

START_JOB
Start or resume current job.
Valid keyword values are: SKIP_CURRENT.

STATUS
Frequency (secs) job status is to be monitored where
the default [0] will show new status when available.

STOP_JOB
Orderly shutdown of job execution and exits the client.
Valid keyword values are: IMMEDIATE.

STOP_WORKER
Stops a hung or stuck worker.

TRACE
Set trace/debug flags for the current job.

$

impdp

$ impdp help=y

Import: Release 18.0.0.0.0 - Production on Mon Jan 28 08:44:08 2019
Version 18.3.0.0.0

Copyright (c) 1982, 2018, Oracle and/or its affiliates.  All rights reserved.


The Data Pump Import utility provides a mechanism for transferring data objects
between Oracle databases. The utility is invoked with the following command:

     Example: impdp scott/tiger DIRECTORY=dmpdir DUMPFILE=scott.dmp

You can control how Import runs by entering the 'impdp' command followed
by various parameters. To specify parameters, you use keywords:

     Format:  impdp KEYWORD=value or KEYWORD=(value1,value2,...,valueN)
     Example: impdp scott/tiger DIRECTORY=dmpdir DUMPFILE=scott.dmp

USERID must be the first parameter on the command line.

------------------------------------------------------------------------------

The available keywords and their descriptions follow. Default values are listed within square brackets.

ABORT_STEP (12.1)
Stop the job after it is initialized or at the indicated object.
Valid values are -1 or N where N is zero or greater.
N corresponds to the object's process order number in the master table.

ACCESS_METHOD (12.1)
Instructs Import to use a particular method to load data.
Valid keyword values are: [AUTOMATIC], CONVENTIONAL, DIRECT_PATH,
EXTERNAL_TABLE, and INSERT_AS_SELECT.

ATTACH (10.1)
Attach to an existing job.
For example, ATTACH=job_name.

CLUSTER (11.2)
Utilize cluster resources and distribute workers across the Oracle RAC [YES].

CONTENT (10.1)
Specifies data to load.
Valid keywords are: [ALL], DATA_ONLY and METADATA_ONLY.

DATA_OPTIONS (11.1)
Data layer option flags.
Valid keywords are: DISABLE_APPEND_HINT, ENABLE_NETWORK_COMPRESSION,
REJECT_ROWS_WITH_REPL_CHAR, SKIP_CONSTRAINT_ERRORS, CONTINUE_LOAD_ON_FORMAT_ERROR,
TRUST_EXISTING_TABLE_PARTITIONS and VALIDATE_TABLE_DATA.

DIRECTORY (10.1)
Directory object to be used for dump, log and SQL files.

DUMPFILE (10.1)
List of dump files to import from [expdat.dmp].
For example, DUMPFILE=scott1.dmp, scott2.dmp, dmpdir:scott3.dmp.

ENCRYPTION_PASSWORD (10.2)
Password key for accessing encrypted data within a dump file.
Not valid for network import jobs.

ENCRYPTION_PWD_PROMPT (12.1)
Specifies whether to prompt for the encryption password [NO].
Terminal echo is suppressed while standard input is read.

ESTIMATE (10.1)
Calculate network job estimates.
Valid keywords are: [BLOCKS] and STATISTICS.

EXCLUDE (10.1)
Exclude specific object types.
For example, EXCLUDE=SCHEMA:"='HR'".

FLASHBACK_SCN (10.1)
SCN used to reset session snapshot.

FLASHBACK_TIME (10.1)
Time used to find the closest corresponding SCN value.

FULL (10.1)
Import everything from source [YES].

HELP (10.1)
Display help messages [NO].

INCLUDE (10.1)
Include specific object types.
For example, INCLUDE=TABLE_DATA.

JOB_NAME (10.1)
Name of import job to create.

KEEP_MASTER (12.1)
Retain the master table after an import job that completes successfully [NO].

LOGFILE (10.1)
Log file name [import.log].

LOGTIME (12.1)
Specifies that messages displayed during import operations be timestamped.
Valid keyword values are: ALL, [NONE], LOGFILE and STATUS.

MASTER_ONLY (12.1)
Import just the master table and then stop the job [NO].

METRICS (12.1)
Report additional job information to the import log file [NO].

NETWORK_LINK (10.1)
Name of remote database link to the source system.

NOLOGFILE (10.1)
Do not write log file [NO].

PARALLEL (10.1)
Change the number of active workers for current job.

PARFILE (10.1)
Specify parameter file.

PARTITION_OPTIONS (11.1)
Specify how partitions should be transformed.
Valid keywords are: DEPARTITION, MERGE and [NONE].

QUERY (10.1)
Predicate clause used to import a subset of a table.
For example, QUERY=employees:"WHERE department_id > 10".

REMAP_DATA (11.1)
Specify a data conversion function.
For example, REMAP_DATA=EMP.EMPNO:REMAPPKG.EMPNO.

REMAP_DATAFILE (10.1)
Redefine data file references in all DDL statements.

REMAP_SCHEMA (10.1)
Objects from one schema are loaded into another schema.

REMAP_TABLE (11.1)
Table names are remapped to another table.
For example, REMAP_TABLE=HR.EMPLOYEES:EMPS.

REMAP_TABLESPACE (10.1)
Tablespace objects are remapped to another tablespace.

REUSE_DATAFILES (10.1)
Tablespace will be initialized if it already exists [NO].

SCHEMAS (10.1)
List of schemas to import.

SERVICE_NAME (11.2)
Name of an active service and associated resource group to constrain Oracle RAC resources.

SKIP_UNUSABLE_INDEXES (10.1)
Skip indexes that were set to the Index Unusable state.

SOURCE_EDITION (11.2)
Edition to be used for extracting metadata.

SQLFILE (10.1)
Write all the SQL DDL to a specified file.

STATUS (10.1)
Frequency (secs) job status is to be monitored where
the default [0] will show new status when available.

STREAMS_CONFIGURATION (10.1)
Enable the loading of Streams metadata [YES].

TABLE_EXISTS_ACTION (10.1)
Action to take if imported object already exists.
Valid keywords are: APPEND, REPLACE, [SKIP] and TRUNCATE.

TABLES (10.1)
Identifies a list of tables to import.
For example, TABLES=HR.EMPLOYEES,SH.SALES:SALES_1995.

TABLESPACES (10.1)
Identifies a list of tablespaces to import.

TARGET_EDITION (11.2)
Edition to be used for loading metadata.

TRANSFORM (10.1)
Metadata transform to apply to applicable objects.
Valid keywords are: DISABLE_ARCHIVE_LOGGING, INMEMORY, INMEMORY_CLAUSE,
LOB_STORAGE, OID, PCTSPACE, SEGMENT_ATTRIBUTES, SEGMENT_CREATION,
STORAGE, and TABLE_COMPRESSION_CLAUSE.

TRANSPORTABLE (12.1)
Options for choosing transportable data movement.
Valid keywords are: ALWAYS and [NEVER].
Only valid in NETWORK_LINK mode import operations.

TRANSPORT_DATAFILES (10.1)
List of data files to be imported by transportable mode.

TRANSPORT_FULL_CHECK (10.1)
Verify storage segments of all tables [NO].
Only valid in NETWORK_LINK mode import operations.

TRANSPORT_TABLESPACES (10.1)
List of tablespaces from which metadata is loaded.
Only valid in NETWORK_LINK mode import operations.

VERSION (10.1)
Version of objects to import.
Valid keywords are: [COMPATIBLE], LATEST, or any valid database version.
Only valid for NETWORK_LINK and SQLFILE.

VIEWS_AS_TABLES (12.1)
Identifies one or more views to be imported as tables.
For example, VIEWS_AS_TABLES=HR.EMP_DETAILS_VIEW.
Note that in network import mode, a table name is appended
to the view name.

------------------------------------------------------------------------------

The following commands are valid while in interactive mode.
Note: abbreviations are allowed.

CONTINUE_CLIENT
Return to logging mode. Job will be restarted if idle.

EXIT_CLIENT
Quit client session and leave job running.

HELP
Summarize interactive commands.

KILL_JOB
Detach and delete job.

PARALLEL
Change the number of active workers for current job.

START_JOB
Start or resume current job.
Valid keywords are: SKIP_CURRENT.

STATUS
Frequency (secs) job status is to be monitored where
the default [0] will show new status when available.

STOP_JOB
Orderly shutdown of job execution and exits the client.
Valid keywords are: IMMEDIATE.

STOP_WORKER
Stops a hung or stuck worker.

TRACE
Set trace/debug flags for the current job.

$

Time Zone File Version

When you are transferring data between databases there are two basic things that can cause problems.

Transferring data from a higher database version to a lower version is possible by using the VERSION parameter on the export. For example, if I am exporting from a 19c database and I want to import into a 18c database I would do the following.

expdp my_user/my_password@db19c version=18 schemas=SCOTT directory=TEST_DIR dumpfile=SCOTT.dmp logfile=expdpSCOTT.log

impdp my_user/my_password@db18c schemas=SCOTT directory=TEST_DIR dumpfile=SCOTT.dmp logfile=impdpSCOTT.log

The second thing to consider is the time zone file version. It isn't possible to transfer data between databases if they don't have the same time zone file version. Later versions of the database seem more sensitive to this issue. The import will give the following error.

ORA-39002: invalid operation

If you have this problem, you need to make sure the two databases have the same time zone file version. The process for upgrading the time zone file version is described here.

For more information see:

Hope this helps. Regards Tim...

Back to the Top.