Expdp - Trace
Export/Import DataPump Parameter TRACE - How to Diagnose Oracle Data Pump [ID 286496.1] |
Purpose
This document describes how to use the TRACE parameter with the Export Data Pump (expdp) and Import Data Pump (impdp) database utilities when diagnosing incorrect behavior and/or troubleshooting Data Pump errors.
Scope and Application
The article is intended for users of the database utilities Export Data Pump (expdp) and Import Data Pump (impdp), and who need to troubleshoot the execution of the jobs that are generated by these utilities. These database utilities were introduced with Oracle10g. The article gives detailed information how to use the undocumented parameter TRACE.
Export/Import DataPump Parameter TRACE - How to Diagnose Oracle Data Pump
1. Introduction.
In Oracle10g, we introduced the new database utilities Export Data Pump and Import Data Pump.
Data Pump jobs use a master table, a master process, and worker processes to perform the work and keep track of the progress. For every Data Pump Export job and Data Pump Import job, a master process is created. The master process controls the entire job, including communicating with the clients, creating and controlling a pool of worker processes, and performing logging operations.
Example output when a full database Export Data Pump is running with parallelism 2:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f%U.dmp \
LOGFILE=expdp_f.log FULL=y PARALLEL=2
% ps -ef | grep expdp
oracle 8874 8704 1 07:00 pts/2 00:00:03 expdp DIRECTORY=my_dir ...
% ps -ef | grep ORCL
oracle 8875 8874 4 07:00 ? 00:00:11 oracleORCL (DESCRIPTION=(LOCAL=YES) ...
oracle 8879 1 3 07:00 ? 00:00:08 ora_dm00_ORCL
oracle 8881 1 94 07:00 ? 00:04:17 ora_dw01_ORCL
oracle 8893 1 3 07:00 ? 00:00:09 ora_dw02_ORCL
...
-- Obtain Data Pump process info:
set lines 150 pages 100 numwidth 7
col program for a38
col username for a10
col spid for a7
select to_char(sysdate,'YYYY-MM-DD HH24:MI:SS') "DATE", s.program, s.sid,
s.status, s.username, d.job_name, p.spid, s.serial#, p.pid
from v$session s, v$process p, dba_datapump_sessions d
where p.addr=s.paddr and s.saddr=d.saddr;
DATE PROGRAM SID STATUS
------------------- -------------------------------------- ------- --------
USERNAME JOB_NAME SPID SERIAL# PID
---------- ------------------------------ ------- ------- -------
SYSTEM SYS_EXPORT_FULL_01 8875 8 18
SYSTEM SYS_EXPORT_FULL_01 8879 21 21
SYSTEM SYS_EXPORT_FULL_01 8881 7 22
SYSTEM SYS_EXPORT_FULL_01 8893 26 23
The Data Pump processes will disappear when the Data Pump job completes or is (temporary) stopped.
Improved tracing capabilities have been implemented with these utilities. The tracing can be controlled with the TRACE parameter.
Data Pump is server based and not client based. This means that most Data Pump specific defects will be fixed on the server side (changes in packages in source and target database) and not on the client side (Export or Import Data Pump client). If a Data Pump defect that occurs during an import job is fixed in a later patchset (e.g. 10.2.0.4.0) and the target database is still on the base release (10.2.0.1.0) then the defect will still occur when importing with a 10.2.0.4.0 Import Data Pump client into this 10.2.0.1.0 target database. The same applies to export jobs. It is therefore recommended that both the source database and the target database have the latest patchset installed. For details, see also:
Note:553337.1 "Export/Import DataPump Parameter VERSION - Compatibility of Data Pump Between Different Oracle Versions"
2. How to create a Data Pump trace file ? Parameter: TRACE
Tracing can be enabled by specifying an 7 digit hexadecimal mask in the TRACE parameter of Export DataPump (expdp) or Import DataPump (impdp). The first three digits enable tracing for a specific Data Pump component, while the last four digits are usually: 0300.
Any leading zero's can be omitted, and the value specified for the TRACE parameter is not case sensitive.
Example:
TRACE = 04A0300
-- or:
TRACE=4a0300
Some rules to remember when specifying a value for the TRACE parameter:
- do not specify more than 7 hexadecimal digits;
- do not specify the typical leading 0x hexadecimal specification characters;
- do not convert the hexadecimal value to a decimal value;
- omit any leading zero's (not required though);
- values are not case sensitive.
When using the TRACE parameter, an error may occur if the Data Pump job is run with a non-privileged user, e.g.:
% expdp scott/tiger DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log TABLES=emp TRACE=480300
Export: Release 10.2.0.3.0 - Production on Friday, 19 October, 2007 13:46:33
Copyright (c) 2003, 2005, Oracle. All rights reserved.
Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Production
With the Partitioning, Oracle Label Security, OLAP and Data Mining Scoring Engine options
ORA-31631: privileges are required
To resolve this problem: ensure that the user that connects to the database with the Export Data Pump or Import Data Pump utility, is a privileged user (i.e. a user who has the DBA role or the EXP_FULL_DATABASE resp. IMP_FULL_DATABASE role), e.g.:
-- run this Data Pump job with TRACE as a privileged user:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log TABLES=scott.emp TRACE=480300
-- or:
-- make user SCOTT a privileged user:
CONNECT / AS SYSDBA
GRANT exp_full_database TO scott;
% expdp scott/tiger DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log TABLES=emp TRACE=480300
For details, see also:
Note:351598.1 "Export/Import DataPump: The Minimum Requirements to Use Export DataPump and Import DataPump (System Privileges)"
Also ensure that the init.ora/spfile initialization parameter MAX_DUMP_FILE_SIZE is large enough to capture all the trace information (or set it to unlimited which is the default value), e.g.:
-- Ensure enough trace data can be written to the trace files:
CONNECT / as sysdba
SHOW PARAMETER max_dump
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_dump_file_size string 10M
ALTER SYSTEM SET max_dump_file_size = unlimited SCOPE = both;
SHOW PARAMETER max_dump
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_dump_file_size string UNLIMITED
The majority of errors that occur during a Data Pump job, can be diagnosed by creating a trace file for the Master Control Process (MCP) and the Worker Process(es) only, e.g.:
-- To run a Data Pump job with standard tracing:
-- This results in two trace files in BACKGROUND_DUMP_DEST:
-- Master Process trace file: <SID>_dm<number>_<process_id>.trc
-- Worker Process trace file: <SID>_dw<number>_<process_id>.trc
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log SCHEMAS=scott TRACE=480300
Each Data Pump component can be specified explicitly in order to obtain tracing details of that component:
-- Summary of Data Pump trace levels:
-- ==================================
Trace DM DW ORA Lines
level trc trc trc in
(hex) file file file trace Purpose
------- ---- ---- ---- ------ -----------------------------------------------
10300 x x x SHDW: To trace the Shadow process (API) (expdp/impdp)
20300 x x x KUPV: To trace Fixed table
40300 x x x 'div' To trace Process services
80300 x KUPM: To trace Master Control Process (MCP) (DM)
100300 x x KUPF: To trace File Manager
200300 x x x KUPC: To trace Queue services
400300 x KUPW: To trace Worker process(es) (DW)
800300 x KUPD: To trace Data Package
1000300 x META: To trace Metadata Package
--- +
1FF0300 x x x 'all' To trace all components (full tracing)
Combinations of tracing Data Pump components are possible, e.g.:
-- Example of combination (last 4 digits are usually 0300):
40300 to trace Process services
80300 to trace Master Control Process (MCP)
400300 to trace Worker process(es)
-- +
4C0300 to trace Process services and Master Control and Worker processes
In order to trace all Data Pump components, level 1FF0300 can be specified:
-- Run a Data Pump job with full tracing:
-- This results in two trace files in BACKGROUND_DUMP_DEST:
-- Master Process trace file: <SID>_dm<number>_<process_id>.trc
-- Worker Process trace file: <SID>_dw<number>_<process_id>.trc
-- And one trace file in USER_DUMP_DEST:
-- Shadow Process trace file: <SID>_ora_<process_id>.trc
% impdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=impdp_s.log FULL=y TRACE=1ff0300
Note: For initial Data Pump tracing, the value 480300 is sufficient. When value 480300 is specified, we will trace the Master Control process (MCP) and the Worker process(es). When creating a Data Pump trace file, we recommend to use the value 480300 unless a different trace level is requested by Oracle Support.
3. How to start tracing the Data Pump job ?
Depending on how the Export or Import Data Pump job was started, there are several ways to activate tracing of the Data Pump processes.
3.1. Use the TRACE parameter upon the start of the job.
Start tracing by specifying the TRACE parameter and a trace level when the Export Data Pump or Import Data Pump is started. This is the standard way to activate Data Pump tracing.
Example:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log TABLES=scott.emp TRACE=480300
3.2. Use the TRACE parameter when restarting a job.
If an Export or Import Data Pump job was started without the TRACE parameter, it can be temporary stopped, and restarted with the TRACE parameter.
Example:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f.dmp \
LOGFILE=expdp_f.log TABLES=scott.emp TRACE=480300
Export: Release 10.2.0.3.0 - Production on Thursday, 18 October, 2007 17:11:08
Copyright (c) 2003, 2005, Oracle. All rights reserved.
Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Production
With the Partitioning, Oracle Label Security, OLAP and Data Mining Scoring Engine options
FLASHBACK automatically enabled to preserve database integrity.
Starting "SYSTEM"."SYS_EXPORT_FULL_01": system/ DIRECTORY=my_dir
DUMPFILE=expdp_f.dmp LOGFILE=expdp_f.log FULL=y
Estimate in progress using BLOCKS method...
Processing object type DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA
-- press Control-C to go to the Interactive Command mode,
-- and temporarystop the job with the STOP_JOB command:
Export> stop
Are you sure you wish to stop this job ([yes]/no): yes
-- use the system generated job-name SYS_EXPORT_FULL_01 to re-attach to the job
-- and specify the TRACE parameter with a tracing level:
% expdp system/manager ATTACH=sys_export_full_01 TRACE=480300
Export: Release 10.2.0.3.0 - Production on Thursday, 18 October, 2007 17:23:48
Copyright (c) 2003, 2005, Oracle. All rights reserved.
Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Production
With the Partitioning, Oracle Label Security, OLAP and Data Mining Scoring Engine options
Job: SYS_EXPORT_FULL_01
Owner: SYSTEM
Operation: EXPORT
Creator Privs: FALSE
GUID: F4E6BF997DFA46378D543F998E82653E
Start Time: Thursday, 18 October, 2007 17:23:49
Mode: FULL
Instance: m10203wa
Max Parallelism: 1
EXPORT Job Parameters:
Parameter Name Parameter Value:
CLIENT_COMMAND system/ DIRECTORY=my_dir DUMPFILE=expdp_f.dmp
LOGFILE=expdp_f.log FULL=y
State: IDLING
Bytes Processed: 0
Current Parallelism: 1
Job Error Count: 0
Dump File: /usr/DataPump/expdp_f.dmp
bytes written: 4,096
Worker 1 Status:
State: UNDEFINED
-- restart the job and change back from Interactive Command mode to Logging mode
-- with CONTINUE_CLIENT (note that tracing with level 480300 is now active):
Export> cont
Restarting "SYSTEM"."SYS_EXPORT_FULL_01": system/ DIRECTORY=my_dir
DUMPFILE=expdp_f.dmp LOGFILE=expdp_s.log FULL=y
Processing object type DATABASE_EXPORT/TABLESPACE
Processing object type DATABASE_EXPORT/PROFILE
...
3.3. Use a database init.ora/spfile event to trace Data Pump.
Data Pump tracing can also be started with a line with EVENT 39089 in the initialization parameter file. This method should only be used to trace the Data Pump calls in an early state, e.g. if details are needed about the DBMS_DATAPUMP.OPEN API call. Trace level 0x300 will trace all Data Pump client processes. Note that this event cannot be enabled through an ALTER SYSTEM command, only a restart of the database will enable the event.
Example when using init.ora initialization parameter file:
- add the following line to init.ora parameter file:
EVENT="39089 trace name context forever,level 0x300"
- Restart the database.
- Start the Export Data Pump or Import Data Pump job.
Example when using spfile initialization parameter file:
-- when using spfile parameter file:
CONNECT / as sysdba
SHOW PARAMETER event
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
event string
ALTER SYSTEM SET EVENTS = '39089 trace name context forever, level 0x300'
SCOPE = spfile;
SHUTDOWN immediate
STARTUP
SHOW PARAMETER event
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
event string 39089 trace name context forev
er, level 0x300
- Start the Export Data Pump or Import Data Pump job.
-- to remove the event(s) again:
ALTER SYSTEM RESET EVENT SCOPE = spfile SID='*';
SHUTDOWN immediate
STARTUP
Note: Only set this event 39089 if tracing in an early state of job execution is needed. For normal standard tracing, use the TRACE parameter as described in the sections 3.1. and 3.2. above.
For details about setting events, see also:
@ For Support:
4. How are Data Pump trace files named, and where to find them ?
Data Pump trace files are written to the directories specified by the init.ora/spfile initialization parameters BACKGROUND_DUMP_DEST and USER_DUMP_DEST.
4.1 Data Pump Master Control Process (MCP).
Format : <SID>_dm<number>_<process_id>.trc
Example: ORCL_dm00_2896.trc or: ORCL_dm01_3422.trc (for second active Master Control Process)
Location: BACKGROUND_DUMP_DEST or <ADR_HOME>/trace
4.2. Data Pump Worker Process trace file.
Format : <SID>_dw<number>_<process_id>.trc
Example: ORCL_dw01_2936.trc or: ORCL_dw01_2844.trc and ORCL_dw02_2986.trc (if PARALLEL=2)
Location: BACKGROUND_DUMP_DEST or <ADR_HOME>/trace
4.3. Data Pump Shadow Process trace file.
Format : <SID>_ora_<process_id>.trc
Example: ORCL_ora_3020.trc
Location: USER_DUMP_DEST or <ADR_HOME>/trace
-- determine location of the trace files on disk (Oracle10g):
CONNECT system/manager
SHOW PARAMETER dump
NAME TYPE VALUE
------------------------------------ ----------- -----------------------------
background_dump_dest string /oracle/admin/ORCL/BDUMP
user_dump_dest string /oracle/admin/ORCL/UDUMP
...
-- determine location of the trace files on disk (Oracle11g):
CONNECT system/manager
SHOW PARAMETER diag
NAME TYPE VALUE
------------------------------------ ----------- -----------------------------
diagnostic_dest string /oracle
Note that in Oracle10g the default location for the trace files is: $ORACLE_HOME/rdbms/log
This location will be used if the initialization parameters BACKGROUND_DUMP_DEST and/or USER_DUMP_DEST are not set.
For Oracle11g, the trace files are written to the <ADR_HOME>/trace
where <ADR_HOME> is: <ADR_BASE>/diag/<product_type>/<prod_id>/<instance_id>
where <ADR_BASE> is specified by DIAGNOSTIC_DEST (defaults to: $ORACLE_HOME/log).
E.g.: /oracle/diag/rdbms/ORCL/ORCL/trace
For details, see also:
5. How to get a detailed status report of a Data Pump job ? Parameter: STATUS
If a Data Pump is started, a detailed status report of the job can be obtains with the STATUS parameter in Interactive Command mode.
Example:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f%U.dmp \
LOGFILE=expdp_f.log FILESIZE=2g FULL=y
Export: Release 10.2.0.3.0 - 64bit Production on Friday, 19 October, 2007 14:05:33
Copyright (c) 2003, 2005, Oracle. All rights reserved.
Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - 64bit Production
With the Partitioning, OLAP and Data Mining options
Starting "SYSTEM"."SYS_EXPORT_FULL_01": system/ DIRECTORY=my_dir
DUMPFILE=expdp_f%U.dmp LOGFILE=expdp_f.log FILESIZE=2g FULL=y
Estimate in progress using BLOCKS method...
Processing object type DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA
-- press Control-C to go to the Interactive Command mode,
-- and get a STATUS report of the 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: /bugmnt7/em/celclnx7/user/expdp/expdp_f01.dmp
bytes written: 4,096
Dump File: /bugmnt7/em/celclnx7/user/expdp/expdp_f%u.dmp
Worker 1 Status:
State: EXECUTING
Object Schema: SCOTT
Object Name: EMP
Object Type: DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA
Completed Objects: 959
Worker Parallelism: 1
-- To get a detailed STATUS report every minute while in Logging mode:
Export> stat=60
Export> cont
Total estimation using BLOCKS method: 8.437 GB
Processing object type DATABASE_EXPORT/TABLESPACE
...
Note that the status information is written only to your standard output device, not to the Data Pump log file.
6. How to get timing details on processed objects ? Parameter: METRICS
With the undocumented parameter METRICS additional information can be obtained about the number of objects that were processed and the time it took for processing them. Objects in this context are for example the exported system GRANT privileges, the imported tablespace quota GRANT statements, the exported CREATE TABLE statements. Note that the METRICS parameter does not create any additional trace files. Instead, the extra details are logged in the logfile of the Export Data Pump or Import Data Pump job.
Example output:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
LOGFILE=expdp_s.log SCHEMAS=scott METRICS=y
Export: Release 10.2.0.3.0 - Production on Thursday, 18 October, 2007 17:05:53
Copyright (c) 2003, 2005, Oracle. All rights reserved.
Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Production
With the Partitioning, Oracle Label Security, OLAP and Data Mining Scoring Engine options
FLASHBACK automatically enabled to preserve database integrity.
Starting "SYSTEM"."SYS_EXPORT_SCHEMA_01": system/ DIRECTORY=my_dir
DUMPFILE=expdp_s.dmp LOGFILE=expdp_s.log SCHEMAS=scott METRICS=y
Estimate in progress using BLOCKS method...
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 192 KB
Processing object type SCHEMA_EXPORT/USER
Completed 1 USER objects in 0 seconds
Processing object type SCHEMA_EXPORT/SYSTEM_GRANT
Completed 2 SYSTEM_GRANT objects in 0 seconds
Processing object type SCHEMA_EXPORT/ROLE_GRANT
Completed 2 ROLE_GRANT objects in 0 seconds
Processing object type SCHEMA_EXPORT/DEFAULT_ROLE
Completed 1 DEFAULT_ROLE objects in 0 seconds
Processing object type SCHEMA_EXPORT/TABLESPACE_QUOTA
Completed 1 TABLESPACE_QUOTA objects in 2 seconds
Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA
Completed 1 PROCACT_SCHEMA objects in 5 seconds
Processing object type SCHEMA_EXPORT/TABLE/TABLE
Completed 4 TABLE objects in 0 seconds
Processing object type SCHEMA_EXPORT/TABLE/INDEX/INDEX
Completed 2 INDEX objects in 1 seconds
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
Completed 2 CONSTRAINT objects in 1 seconds
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT
Completed 1 REF_CONSTRAINT objects in 1 seconds
. . exported "SCOTT"."DEPT" 5.656 KB 4 rows
. . exported "SCOTT"."EMP" 7.820 KB 14 rows
. . exported "SCOTT"."SALGRADE" 5.585 KB 5 rows
. . exported "SCOTT"."BONUS" 0 KB 0 rows
Master table "SYSTEM"."SYS_EXPORT_SCHEMA_01" successfully loaded/unloaded
Dump file set for SYSTEM.SYS_EXPORT_SCHEMA_01 is:
/usr/DataPump/expdp_s.dmp
Job "SYSTEM"."SYS_EXPORT_SCHEMA_01" successfully completed at 17:06:14
7. How to get SQL trace files of the Data Pump processes ?**
For troubleshooting specific situations, it may be required to create a SQL trace file for an Export Data Pump or Import Data Pump job. These SQL trace files can be created by setting Event 10046 for a specific process (usually the Worker process). Note that these SQL trace files can become very large, so ensure that there is enough free space in the directory that is specified by the init.ora/spfile initialization parameter BACKGROUND_DUMP_DEST.
event 10046, level 1 = enable standard SQL_TRACE functionality
event 10046, level 4 = as level 1, plus trace the BIND values
event 10046, level 8 = as level 1, plus trace the WAITs
event 10046, level 12 = as level 1, plus trace the BIND values and the WAITs
Remarks:
- level 1: lowest level tracing - not always sufficient to determine cause of errors;
- level 4: useful when an error in Data Pump's worker or master process occurs;
- level 12: useful when there is an issue with Data Pump performance.
When creating a level 8 or 12 SQL trace file, it is required that the init.ora/spfile initialization parameter TIMED_STATISTICS is set to TRUE before the event is set and before the Data Pump job is started. The performance impact of setting this parameter temporary to TRUE is minimal. The SQL trace files that were created with level 8 or 12 as especially useful for investigating performance problems.
Example:
-- For Event 10046, level 8 and 12: ensure we gather time related statistics:
CONNECT / as sysdba
SHOW PARAMETER timed_statistics
NAME TYPE VALUE
--------------------------------- ----------- ---------------------------
timed_statistics string FALSE
ALTER SYSTEM SET timed_statistics = TRUE SCOPE = memory;
-- Now set the event and start the Data Pump job
-- To set the value back to the default:
ALTER SYSTEM SET timed_statistics = FALSE SCOPE = memory;
7.1. Create a standard SQL_TRACE file (level 1).
If the output of standard SQL_TRACE functionality is sufficient (i.e.: neither bind values nore waits details are needed), then this SQL tracing can be activated with the Data Pump parameter trace. To activate standard SQL tracing, use the value 1.
Example:
-- Trace Worker process (400300) with standard SQL_TRACE functionality (1):
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f.dmp \
LOGFILE=expdp_f.log TABLES=scott.emp TRACE=400301
Note that this level of tracing is usually not sufficient for tracing Data Pump when an error occurs or when there is an issue with Data Pump performance. For tracing Data Pump when an error occurs use level 4, and when there is an issue with Data Pump performance use level 12 (see sections below).
7.2. Activate SQL_TRACE on specific Data Pump process with higher trace level.
If a specific Data Pump process needs to traced, and more SQL_TRACE details are required, and it is not required to trace the start of the job, then the Event 10046 with the desired level can also be set on the process that needs to be traced (usually the Worker process).
Example:
- Start the Data Pump job, e.g.:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f%U.dmp \
LOGFILE=expdp_f.log FILESIZE=2G FULL=y
-- In SQL*Plus, obtain Data Pump process info:
CONNECT / as sysdba
set lines 150 pages 100 numwidth 7
col program for a38
col username for a10
col spid for a7
select to_char(sysdate,'YYYY-MM-DD HH24:MI:SS') "DATE", s.program, s.sid,
s.status, s.username, d.job_name, p.spid, s.serial#, p.pid
from v$session s, v$process p, dba_datapump_sessions d
where p.addr=s.paddr and s.saddr=d.saddr;
DATE PROGRAM SID STATUS
------------------- -------------------------------------- ------- --------
USERNAME JOB_NAME SPID SERIAL# PID
---------- ------------------------------ ------- ------- -------
SYSTEM SYS_EXPORT_FULL_01 17288 29 18
SYSTEM SYS_EXPORT_FULL_01 17292 50 22
SYSTEM SYS_EXPORT_FULL_01 17294 17 23
In the example output above we see that the Data Pump Master process (DM00) has SID: 143 and serial#: 50 and the Data Pump Worker process (DW01) has SID: 150 and serial#: 17. These details can be used to activate SQL tracing in SQL*Plus with DBMS_SYSTEM.SET_EV, e.g.:
-- In SQL*Plus, activate SQL tracing with DBMS_SYSTEM and SID/SERIAL#
-- Syntax: DBMS_SYSTEM.SET_EV([SID],[SERIAL#],[EVENT],[LEVEL],'')
-- Example to SQL_TRACE Worker process with level 4 (Bind values):
execute sys.dbms_system.set_ev(150,17,10046,4,'');
-- and stop tracing:
execute sys.dbms_system.set_ev(150,17,10046,0,'');
-- Example to SQL_TRACE Master Control process with level 8 (Waits):
execute sys.dbms_system.set_ev(143,50,10046,8,'');
-- and stop tracing:
execute sys.dbms_system.set_ev(143,50,10046,0,'');
The example output of the query above also shows that the Data Pump Master process (DM00) has OS process Id: 17292 and the Data Pump Worker process (DW01) has OS process Id: 17294. With this information, it is also possible to use 'oradebug' in SQL*Plus to activate SQL tracing for those processes, e.g.:
-- In SQL*Plus, activate SQL tracing with ORADEBUG and the SPID:
-- Example to SQL_TRACE Worker process with level 4 (Bind values):
oradebug setospid 17294
oradebug unlimit
oradebug event 10046 trace name context forever, level 4
oradebug tracefile_name
-- Example to SQL_TRACE Master Control process with level 8 (Waits):
oradebug setospid 17292
oradebug unlimit
oradebug event 10046 trace name context forever, level 8
oradebug tracefile_name
-- To stop the tracing:
oradebug event 10046 trace name context off
Either DBMS_SYSTEM.SET_EV or 'oradebug' can be used to create a Data Pump trace file.
7.3. Place complete database in SQL_TRACE with specific level.
It is possible that there is not enough time to activate tracing on a specific Data Pump process because an error occurs at an early stage of the job, or that the the Data Pump process needs to be traced from the beginning. In those cases, the Event 10046 with the desired level has to be set in SQL*Plus at database level, and the Data Pump job has to be started afterwards. When the job completes, unset the event again.
Example:
-- Activate SQL tracing database wide,
-- Be careful: all processes will be traced !
CONNECT / as sysdba
ALTER SYSTEM SET EVENTS '10046 trace name context forever, level 4';
- Start the Export Data Pump or Import Data Pump job, e.g.:
% expdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_f.dmp \
LOGFILE=expdp_f.log TABLES=scott.emp
-- Unset event immediately after Data Pump job ends:
ALTER SYSTEM SET EVENTS '10046 trace name context off';
Be careful though: the steps above will result in SQL tracing on all processes, so only use this method if no other database activity takes place (or hardly any other activity), and when the Data Pump job ends relatively quickly.
7.4. Analyze the SQL trace files and create a TKPROF output file.
If the SQL trace files were created with level 1 or 4 then we are usually interested in the statements (and their bind variables). Example scenario: Data Pump aborts with a specific error. When investigating those kind of errors, it makes sense to compress the complete trace file and upload the compressed file.
If the SQL trace files were created with level 8 or 12 then we are usually interested in the timing of the statements (and their wait events). Example scenario: there is an presumptive performance issue during a Data Pump job. These SQL trace files can become very large and the tkprof output after analyzing the files are in most cases more meaningful. When investigating those kind of errors, it makes sense to upload the tkprof output files only.
Example:
-- create standard tkprof output files for Data Pump Master and Worker SQL traces:
% cd /oracle/admin/ORCL/BDUMP
% tkprof orcl_dm00_17292.trc tkprof_orcl_dm00_17292.out waits=y sort=exeela
% tkprof orcl_dw01_17294.trc tkprof_orcl_dw01_17294.out waits=y sort=exeela
For details about Event 10046 and tkprof, see also:
8. How to get header details of Export Data Pump dumpfiles ?
Every export Data Pump dumpfile starts with a header (usually 4 kb in size) which contains details about the dumpfile. Starting with Oracle10g Release 2 (10.2.0.1.0), this header information can be extracted from the dumpfile by calling the procedure DBMS_DATAPUMP.GET_DUMPFILE_INFO. Header information can be extracted from any export dumpfile, even from dumpfiles created with the classic export client. Example output of a procedure that extracts information from a dumpfile header:
----------------------------------------------------------------------------
...File Version....: 2.1 (Oracle11g Release 1: 11.1.0.x)
...Master Present..: 1 (Yes)
...GUID............: AE9D4A8A85C6444F813600C00199745A
...File Number.....: 1
...Characterset ID.: 46 (WE8ISO8859P15)
...Creation Date...: Wed Mar 19 16:06:45 2008
...Flags...........: 2
...Job Name........: "SYSTEM"."SYS_EXPORT_SCHEMA_01"
...Platform........: x86_64/Linux 2.4.xx
...Instance........: ORCL
...Language........: WE8ISO8859P15
...Block size......: 4096
...Metadata Compres: 1 (Yes)
...Data Compressed.: 0 (No)
...Metadata Encrypt: 0 (No)
...Data Encrypted..: 0 (No)
...Master Piece Cnt: 1
...Master Piece Num: 1
...Job Version.....: 11.01.00.00.00
...Max Items Code..: 20
----------------------------------------------------------------------------
For more details and an example code of procedure SHOW_DUMPFILE_INFO, see:
Besides the DBMS_DATAPUMP.GET_DUMPFILE_INFO procedure, it is also possible to start an Import Data Pump job with TRACE=100300 in order to create a trace file with the dumpfile header details. The dumpfile header details are written to the Data Pump Master trace file: [SID]dm[number]_[PID].trc which can be found in the directory specified by the init.ora/spfile parameter BACKGROUND_DUMP_DEST.
Example:
-- create a SQL file with TRACE parameter value 100300 (trace file layer);
-- although this impdp job will give an error (ORA-39166: Object ... was not found)
-- a trace file will be written with the file header details we are interested in:
-- On windows, place all expdp parameters on one single line:
D:\DataPump> impdp system/manager DIRECTORY=my_dir DUMPFILE=expdp_s.dmp
NOLOGFILE=y SQLFILE=impdp_s.sql TABLES=notexist TRACE=100300
Example output of trace file: orcl_dm00_1696.trc
...
KUPF: 17:14:23.345: newImpFile: EXAMINE_DUMP_FILE
KUPF: 17:14:23.355: ......DB Version = 10.02.00.03.00
KUPF: 17:14:23.355: File Version Str = 1.1
KUPF: 17:14:23.355: File Version Num = 257
KUPF: 17:14:23.355: Version CapBits1 = 32775
KUPF: 17:14:23.355: ......Has Master = 1
KUPF: 17:14:23.355: ........Job Guid = 76DC6D8BC4A6479EADECB81E71FAEF93
KUPF: 17:14:23.355: Master Table Pos = 19
KUPF: 17:14:23.355: Master Table Len = 138856
KUPF: 17:14:23.375: .....File Number = 1
KUPF: 17:14:23.385: ......Charset ID = 46
KUPF: 17:14:23.385: ...Creation date = Thu Oct 18 16:51:36 2007
KUPF: 17:14:23.385: ...........Flags = 0
KUPF: 17:14:23.385: ......Media Type = 0
KUPF: 17:14:23.385: ........Job Name = "SYSTEM"."SYS_EXPORT_SCHEMA_01"
KUPF: 17:14:23.395: ........Platform = IBMPC/WIN_NT-8.1.0
KUPF: 17:14:23.395: ........Language = WE8ISO8859P15
KUPF: 17:14:23.395: .......Blocksize = 4096
KUPF: 17:14:23.405: newImpFile: file; D:\DataPump\expdp_s.dmp, FID; 1
...
For more details and an example, see:
9. How to get Data Definition Language (DDL) statements ? Parameter: SQLFILE
With the Import Data Pump parameter SQLFILE you can specify the name of a file into which all of the SQL DDL is written that Import would have executed, based on other parameters. The SQL is not actually executed, and the target system remains unchanged. The file is written to the directory object specified in the DIRECTORY parameter, unless another directory_object is explicitly specified here. Any existing file that has a name matching the one specified with this parameter is overwritten.
Syntax: SQLFILE=[directory_object:]file_name
Example:
-- create a SQL file with DDL statements:
% impdp scott/tiger DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
NOLOGFILE=y SQLFILE=impdp_s.sql FULL=y
Example output of sqlfile: impdp_s.sql
-- CONNECT SYSTEM
-- new object type path is: SCHEMA_EXPORT/USER
CREATE USER "SCOTT" IDENTIFIED BY VALUES 'F894844C34402B67'
DEFAULT TABLESPACE "USERS"
TEMPORARY TABLESPACE "TEMP";
-- new object type path is: SCHEMA_EXPORT/SYSTEM_GRANT
GRANT CREATE TABLE TO "SCOTT";
GRANT CREATE SESSION TO "SCOTT";
-- new object type path is: SCHEMA_EXPORT/ROLE_GRANT
GRANT "EXP_FULL_DATABASE" TO "SCOTT";
GRANT "IMP_FULL_DATABASE" TO "SCOTT";
...
For more details, see:
10. How to get the DDL both as SQL statements and as XML data ?
With the classic export dumpfiles, the Data Definition Language (DDL) statements were stored inside the export dumpfile as normal (ready-to-use) SQL statements. With Data Pump however, the data to recreate the DDL statements is stored in XML format. This XML data can be obtained together with the actual DDL statements by running an import DataPump job with the SQLFILE and TRACE parameter.
-- create a SQL file with DDL statements and XML data:
% impdp scott/tiger DIRECTORY=my_dir DUMPFILE=expdp_s.dmp \
NOLOGFILE=y SQLFILE=impdp_s.sql FULL=y TRACE=2
Example output of sqlfile: impdp_s.sql
-- CONNECT SYSTEM
-- new object type path is: SCHEMA_EXPORT/USER
<?xml version="1.0"?><ROWSET><ROW>
<USER_T><VERS_MAJOR>1</VERS_MAJOR><VERS_MINOR>0</VERS_MINOR>
<USER_ID>79</USER_ID><NAME>SCOTT</NAME><TYPE_NUM>1</TYPE_NUM>
<PASSWORD>F894844C34402B67</PASSWORD><DATATS>USERS</DATATS>
<TEMPTS>TEMP</TEMPTS><CTIME>18-OCT-07</CTIME><PTIME>18-OCT-07</PTIME>
<PROFNUM>0</PROFNUM><PROFNAME>DEFAULT</PROFNAME><DEFROLE>1</DEFROLE>
<ASTATUS>0</ASTATUS><LCOUNT>0</LCOUNT>
<DEFSCHCLASS>DEFAULT_CONSUMER_GROUP</DEFSCHCLASS><SPARE1>0</SPARE1></USER_T>
</ROW></ROWSET>
CREATE USER "SCOTT" IDENTIFIED BY VALUES 'F894844C34402B67'
DEFAULT TABLESPACE "USERS"
TEMPORARY TABLESPACE "TEMP";
-- new object type path is: SCHEMA_EXPORT/SYSTEM_GRANT
...
Note: it is not recommended to perform an import Data Pump job with TRACE=2 unless explicitly requested by Oracle Support.
The list of trace level in data pump is shown below.
Trace DM DW ORA Lines level trc trc trc in (hex) file file file trace Purpose
------- ---- ---- ---- ------ -----------------------------------------------
10300 x x x SHDW: To trace the Shadow process (API) (expdp/impdp)
20300 x x x KUPV: To trace Fixed table 40300 x x x 'div' To trace Process services
80300 x KUPM: To trace Master Control Process (MCP) (DM)
100300 x x KUPF: To trace File Manager 200300 x x x KUPC: To trace Queue services
400300 x KUPW: To trace Worker process(es) (DW)
800300 x KUPD: To trace Data Package 1000300 x META: To trace Metadata Package --- +
1FF0300 x x x 'all' To trace all components (full tracing)
No comments:
Post a Comment