Oracle Data Pump - Part III

James Koopmann's picture
articles: 

On our quest to learn about Oracle's Data Pump utility it has often been compared to the old export and import (exp & imp) utilities that we have all grown to love (or hate). This article is where where Data Pump takes a detour from these old utilities and begins to shine. This article will explore some of the export modes available and give examples on how to export selected object types and dependencies those objects have.

In order to use Data Pump, we learned in Part II of this series that a datapump directory was required to export and import from and to databases. Here are the three setup and authorization commands needed to get started.

SQL> CREATE DIRECTORY datapump AS 'C:\oradata\datapump';
SQL> GRANT EXP_FULL_DATABASE  to scott;
SQL> GRANT READ, WRITE ON DIRECTORY datapump to scott;

In the last article various FULL exports were performed. These are termed 'FULL mode' exports for the obvious reason and had the following format.

C:\>expdp scott/tiger FULL=y DIRECTORY=datapump DUMPFILE=full.dmp LOGFILE=full.log

A slight change to this example, changing the FULL keyword to SCHEMA, allows us to perform a SCHEMA mode export where a particular schema will be exported. Anyone familiar with the old export / import (exp / imp) utilities should feel right at home here. To export multiple schema's you need only separate each schema with commas.

C:\>expdp scott/tiger 
   SCHEMAS=SCOTT DIRECTORY=datapump DUMPFILE=scott.dmp LOGFILE=scott.log

Likewise we could change the SCHEMS option and export all objects in a particular tablespace by switching to the TABLESPACES export mode.
C:\>expdp scott/tiger TABLESPACES=USERS DIRECTORY=datapump DUMPFILE=TSusers.dmp LOGFILE=TSusers.log

If you wanted to export a single table, you need only switch to TABLE mode and use the following export command.

C:\>expdp scott/tiger 
   TABLES=SCOTT.DEPT DIRECTORY=datapump DUMPFILE=dept.dmp LOGFILE=dept.log

The interesting point to notice when issuing these commands is to take a close look at the export logs for each of these export modes. When taking a full schema export you will notice that the export pulls out various additional object types such as grants, roles, sequences, and views. To just name a few. Here is the log from the SCHEMA export performed above.

Starting "SCOTT"."SYS_EXPORT_SCHEMA_01":  scott/******** 
   SCHEMAS=SCOTT DIRECTORY=datapump DUMPFILE=scott.dmp LOGFILE=scott.log
Estimate in progress using BLOCKS method...
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 1024 KB
Processing object type SCHEMA_EXPORT/USER
Processing object type SCHEMA_EXPORT/SYSTEM_GRANT
Processing object type SCHEMA_EXPORT/ROLE_GRANT
Processing object type SCHEMA_EXPORT/DEFAULT_ROLE
Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA
Processing object type SCHEMA_EXPORT/SEQUENCE/SEQUENCE
Processing object type SCHEMA_EXPORT/TABLE/TABLE
Processing object type SCHEMA_EXPORT/TABLE/INDEX/INDEX
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
Processing object type SCHEMA_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type SCHEMA_EXPORT/TABLE/COMMENT
Processing object type SCHEMA_EXPORT/FUNCTION/FUNCTION
Processing object type SCHEMA_EXPORT/PROCEDURE/PROCEDURE
Processing object type SCHEMA_EXPORT/PROCEDURE/GRANT/OWNER_GRANT/OBJECT_GRANT
Processing object type SCHEMA_EXPORT/FUNCTION/ALTER_FUNCTION
Processing object type SCHEMA_EXPORT/PROCEDURE/ALTER_PROCEDURE
Processing object type SCHEMA_EXPORT/VIEW/VIEW
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT
Processing object type SCHEMA_EXPORT/TABLE/TRIGGER
Processing object type SCHEMA_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. . exported "SCOTT"."DEMO_IMAGES"                       56.57 KB      11 rows
. . exported "SCOTT"."DEMO_CUSTOMERS"                    8.976 KB       7 rows
. . exported "SCOTT"."DEMO_ORDERS"                       6.421 KB      10 rows
. . exported "SCOTT"."DEMO_ORDER_ITEMS"                  6.578 KB      16 rows
. . exported "SCOTT"."DEMO_PAGE_HIERARCHY"               5.984 KB      18 rows
. . exported "SCOTT"."DEMO_PRODUCT_INFO"                 7.656 KB      10 rows
. . exported "SCOTT"."DEMO_STATES"                       6.046 KB      51 rows
. . exported "SCOTT"."DEMO_USERS"                        7.179 KB       2 rows
. . exported "SCOTT"."DEPT"                              5.648 KB       4 rows
. . exported "SCOTT"."EMP"                               7.804 KB      14 rows
. . exported "SCOTT"."HT_ISSUES"                         14.28 KB      29 rows
. . exported "SCOTT"."HT_PEOPLE"                         7.203 KB      18 rows
. . exported "SCOTT"."HT_PROJECTS"                       6.406 KB       5 rows
. . exported "SCOTT"."SALGRADE"                          5.570 KB       5 rows
. . exported "SCOTT"."BONUS"                                 0 KB       0 rows
Master table "SCOTT"."SYS_EXPORT_SCHEMA_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_SCHEMA_01 is:
  C:\ORADATA\DATAPUMP\SCOTT.DMP
Job "SCOTT"."SYS_EXPORT_SCHEMA_01" successfully completed at 18:49:55

If we then take a look at the export for a tables you will quickly notice that not all the object types that were exported for the SCHEMA mode have been exported for the TABLE mode. Some of this is because, in our example, the DEPT table does not have certain dependent objects and because other object types are not at all exported even though they would seem to have a dependency. For instance indexes, triggers, and statistics will be exported under TABLE mode but a view on the DEPT table will not. So as a caution, be careful and examine your export logs. You may not be getting everything you think is a dependent object.

Starting "SCOTT"."SYS_EXPORT_TABLE_01":  scott/******** 
   TABLES=SCOTT.DEPT DIRECTORY=datapump DUMPFILE=dept.dmp LOGFILE=dept.log
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX
Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. . exported "SCOTT"."DEPT"                              5.648 KB       4 rows
Master table "SCOTT"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_TABLE_01 is:
  C:\ORADATA\DATAPUMP\DEPT.DMP
Job "SCOTT"."SYS_EXPORT_TABLE_01" successfully completed at 18:46:56

One way to determine the objects that will or can be exported for the different modes is to look at the three DBA views DATABASE_EXPORT_OBJECTS, SCHEMA_EXPORT_OBJECTS, and TABLE_EXPORT_OBJECTS. Each of these views, if queried, will give you a list and short description on the specific paths to object types that you can expect INCLUDE or EXCLUDE to be dependent on the object you are exporting or importing. For instance if you were to query the TABLE_EXPORT_OBJECTS view with the following SQL you would get a list of all objects that are dependent on exporting a table. As you can see there is no entry for exporting views based on a table export. In actuality there are 86 INCLUCE/EXCLUDE types just in the TABLE_EXPORT_OBJECTS view and many more the other two export views. I would encourage you to select the object paths for each of the views and get acquainted with what you can export.

SQL> SELECT object_path, comments FROM table_export_objects where object_path like 'TABLE%';
OBJECT_PATH                                             COMMENTS
------------------------------------------------------- --------------------------------------------------
TABLE/AUDIT_OBJ                                         Object audits on the selected tables
TABLE/COMMENT                                           Table and column comments on the selected tables
TABLE/CONSTRAINT                                        Constraints (including referential constraints)
TABLE/CONSTRAINT/REF_CONSTRAINT                         Referential constraints
TABLE/FGA_POLICY                                        Fine-grained auditing policies
TABLE/GRANT                                             Object grants on the selected tables
TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT                    Object grants on the selected tables
TABLE/INDEX                                             Indexes
TABLE/INDEX/STATISTICS                                  Precomputed statistics
TABLE/INSTANCE_CALLOUT                                  Instance callouts
TABLE/POST_INSTANCE/GRANT/PROCDEPOBJ_GRANT              Grants on instance procedural objects
TABLE/POST_INSTANCE/PROCDEPOBJ                          Instance procedural objects
TABLE/POST_INSTANCE/PROCDEPOBJ_AUDIT                    Audits on instance procedural objects
TABLE/POST_TABLE_ACTION                                 Post-table actions
TABLE/PRE_TABLE_ACTION                                  Pre-table actions
TABLE/PROCACT_INSTANCE                                  Instance procedural actions
TABLE/RLS_CONTEXT                                       Fine-grained access control contexts
TABLE/RLS_GROUP                                         Fine-grained access control policy groups
TABLE/RLS_POLICY                                        Fine-grained access control policies
TABLE/TRIGGER                                           Triggers on the selected tables
TABLE_EXPORT/TABLE/AUDIT_OBJ                            Object audits on the selected tables
TABLE_EXPORT/TABLE/COMMENT                              Table and column comments on the selected tables
TABLE_EXPORT/TABLE/CONSTRAINT                           Constraints (including referential constraints)
TABLE_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT            Referential constraints
TABLE_EXPORT/TABLE/FGA_POLICY                           Fine-grained auditing policies
TABLE_EXPORT/TABLE/GRANT                                Object grants on the selected tables
TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT       Object grants on the selected tables
TABLE_EXPORT/TABLE/INDEX                                Indexes
TABLE_EXPORT/TABLE/INDEX/STATISTICS                     Precomputed statistics
TABLE_EXPORT/TABLE/INSTANCE_CALLOUT                     Instance callouts
TABLE_EXPORT/TABLE/POST_INSTANCE/GRANT/PROCDEPOBJ_GRANT Grants on instance procedural objects
TABLE_EXPORT/TABLE/POST_INSTANCE/PROCDEPOBJ             Instance procedural objects
TABLE_EXPORT/TABLE/POST_INSTANCE/PROCDEPOBJ_AUDIT       Audits on instance procedural objects
TABLE_EXPORT/TABLE/POST_TABLE_ACTION                    Post-table actions
TABLE_EXPORT/TABLE/PRE_TABLE_ACTION                     Pre-table actions
TABLE_EXPORT/TABLE/PROCACT_INSTANCE                     Instance procedural actions
TABLE_EXPORT/TABLE/RLS_CONTEXT                          Fine-grained access control contexts
TABLE_EXPORT/TABLE/RLS_GROUP                            Fine-grained access control policy groups
TABLE_EXPORT/TABLE/RLS_POLICY                           Fine-grained access control policies
TABLE_EXPORT/TABLE/TRIGGER                              Triggers on the selected tables

Through the INCLUDE/EXCLUDE options you can fine tune your exports to pull exactly what you want from your databases. So, to take advantage of these INCLUDE/EXCLUDE object types we can perform an export on a table and not include statistics with the following export command.

C:\>expdp scott/tiger 
   TABLES=SCOTT.DEPT EXCLUDE=STATISTICS DIRECTORY=datapump DUMPFILE=dept.dmp LOGFILE=dept.log
Export: Release 10.2.0.1.0 - Production on Tuesday, 23 August, 2005 19:40:25

Copyright (c) 2003, 2005, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
Starting "SCOTT"."SYS_EXPORT_TABLE_01":  scott/******** 
   TABLES=SCOTT.DEPT EXCLUDE=STATISTICS DIRECTORY=datapump DUMPFILE=5dept.dmp L
OGFILE=dept.log
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX
Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
. . exported "SCOTT"."DEPT"                              5.648 KB       4 rows
Master table "SCOTT"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_TABLE_01 is:
  C:\ORADATA\DATAPUMP\DEPT.DMP
Job "SCOTT"."SYS_EXPORT_TABLE_01" successfully completed at 19:40:40

When playing around with Data Pump export and using the INCLUDE / EXCLUDE feature, I soon found out that it was much easier to use a parameter file (parfile) when specifying the different INCLUDE / EXCLUDE options. This is the same concept as the old export and import (exp & imp) utilities. This is easier because in the course of trying to put all of the potential options on one command line and with the fact that there are “special” characters required when specifying INCLUCE / EXCLUDE options, you will soon find it easier to add to and subtract from the export command. I tried a number of times putting these options on a single command line but had numerous issues. So I would suggest just getting use to the parfile from the start.
For an example in using the parfile I decided to export the DEPT table from the SCOTT schema and include views. Remember, as noted earlier in this article that views are not available to export under a table. So if you were to look at the DBA views, also noted above, you need to at least go up to a schema export to include views. So I created the following parfile. This will actually export all views in the SCOTT schema. If you knew the view names associated with the DEPT table you could also create in IN list much like the INCLUDE statement for the DEPT table.

Parfile dept.par

SCHEMAS=SCOTT 
INCLUDE=TABLE:"IN ('DEPT')" 
INCLUDE=VIEW
DIRECTORY=datapump 
DUMPFILE=dept.dmp 
LOGFILE=dept.log

Here is the command line that would be issued. Looks very similar to the old export utility exp.

C:\>expdp scott/tiger parfile=dept.par

Export: Release 10.2.0.1.0 - Production on Tuesday, 23 August, 2005 19:54:46

Copyright (c) 2003, 2005, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
Starting "SCOTT"."SYS_EXPORT_SCHEMA_01":  scott/******** parfile=dept.par
Estimate in progress using BLOCKS method...
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type SCHEMA_EXPORT/TABLE/TABLE
Processing object type SCHEMA_EXPORT/TABLE/INDEX/INDEX
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
Processing object type SCHEMA_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type SCHEMA_EXPORT/VIEW/VIEW
Processing object type SCHEMA_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
. . exported "SCOTT"."DEPT"                              5.648 KB       4 rows
Master table "SCOTT"."SYS_EXPORT_SCHEMA_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_SCHEMA_01 is:
  C:\ORADATA\DATAPUMP\DEPT.DMP
Job "SCOTT"."SYS_EXPORT_SCHEMA_01" successfully completed at 19:55:04

Data Pump's import command is much the same as the export command. I actually just replaced the expdp with the impdp command in these examples and had no problems importing back into my database. Many times though we want to import into a different schema and this is accomplished by the REMAP_SCHEMA option. Here is an example where I imported the DEPT table into a different schema.

C:\>impdp system/tiger REMAP_SCHEMA=SCOTT:JKOOPMANN DIRECTORY=datapump DUMPFILE=dept.dmp LOGFILE=dept.log

Oracle's Data Pump utility has many options that allow you to fine tune what you can export from a database. Just remember to query the DBA views (DATABASE_EXPORT_OBJECTS, SCHEMA_EXPORT_OBJECTS, and TABLE_EXPORT_OBJECTS) that dictate the dependent objects that will be exported under certain scenarios. Also keep in mind you can just as easily exclude these object types to pull out exactly what you want.