There may be times when a normal SQL trace of a PLSQL package is not sufficient. For example, when the SQL statements seem to be running fast, but the procedure takes a long time. It may be useful to understand which calls in the PLSQL package are taking the time. With this in mind, this document provides a step by step guide to tracing PLSQL using DBMS_HPROF.
If we are writing Procedure , its always advice able to add below in procedure to capture more details on error
DBMS_UTILITY.FORMAT_ERROR_BACKTRACE holds the line number of the error.
DBMS_UTILITY.FORMAT_ERROR_STACK still holds the last error message.
One of way to debug compilation issues is using PLSQL_DEBUG = true; before complication
EG
alter session set plsql_warnings='enable:all';
ALTER SESSION SET PLSQL_WARNINGS='ENABLE:ALL','DISABLE:06015';
ALTER SESSION SET PLSQL_DEBUG = true;
ALTER PACKAGE XXXX COMPILE DEBUG;
ALTER PACKAGE XXXX COMPILE DEBUG BODY;
Tracing Plsql using Event 10938
One of other way to trace plslq is using trace event 10938 .
Event 10928 - Trace PL/SQL Execution : This event traces PL/SQL execution
ALTER SESSION SET EVENTS '10928 trace name context forever, level 1';
Event 10938 - Dump PL/SQL Execution Statistics : This event dumps PL/SQL execution statistics.
ALTER SESSION SET EVENTS '10938 trace name context forever, level 1';
Level Description for event 10938
1 Trace all calls
2 Trace calls to enabled programs only
4 Trace all exceptions
8 Trace exceptions in enabled program units only
10 Tracing for levels 2 and 8
14 Tracing for levels 2, 4, and 8
There is also option for tracing plsql using dbms_trace.set_plsql_trace
dbms_trace.set_plsql_trace(dbms_trace.TRACE_ENABLED_CALLS+dbms_trace.TRACE_LIMIT);
DBMS_HPROF.
create directory PROF_DIR as '/home/oracle/pl';
grant all on directory plshprof_dir to pltest;
grant execute on dbms_hprof to pltest;
-- as user PLTEST
execute dbms_hprof.create_tables();
With the last call the tables DBMSHP_TRACE_DATA, DBMSHP_RUNS, DBMSHP_FUNCTION_INFO and DBMSHP_PARENT_CHILD_INFO are created. They store the information in the database schema and can be queried afterwards.
Create the DBMS_HRPOF objects if not present .
Log on to the PLTEST that owns the PLSQL package being profiled.
sqlplus <user>/<password>
SQL> @$ORACLE_HOME/rdbms/admin/dbmshptab.sql
Profiling Pl/sql
SET SERVEROUTPUT ON;
EXEC DBMS_HPROF.START_PROFILING('PROF_DIR','P1_PROFILE_DATA.trc');
/* Within the same session run the P1 procedure */
EXEC P1;
/* Stop the profiling */
EXEC DBMS_HPROF.STOP_PROFILING;
Analyzing Raw File Generated :
This raw profiler trace file can be analyzed in two ways:
1) Using the DBMS_HPROF.ANALYZE function.
2) Using the "plshprof" command line utility.
Eg :
plshprof -output <out_file_name> P1_PROFILE_DATA.trc
Reference :
How to Tune PL/SQL Applications and Identify Hot Spots using DBMS_HPROF (Doc ID 763944.1)
How to resolve error - PLS-00201: identifier 'DBMS_HPROF' must be declared? (Doc ID 2867790.1)
SRDC - Providing Supporting Information for PL/SQL Runtime Issues (Doc ID 2288591.1)
https://blogs.oracle.com/coretec/post/plsql-tuning-with-plsql-hierarchical-profiler
DBMS_PROFILER
What about customers who have only limited privileges to their Oracle environment and who may not have access to a logical directory. The solution is the usage of the package DBMS_PROFILER, which writes the data directly into database tables. The procedure works similar to the described procedure of DBMS_HPROF.
First the corresponding repository tables PLSQL_PROFILER_RUNS, PLSQL_PROFILER_DATA and PLSQL_PROFILER_UNITS are created in the application schema. To do this, use the proftab.sql utility from the $ORACLE_HOME/rdbms/admin directory.
Configuring the profiler is fairly easy; in the schema that owns the PL/SQL objects the proftab.sql script (located at $ORACLE_HOME/rdbms/admin)
must be run to create the tables that the profiler needs to store run data; those tables are:
PLSQL_PROFILER_UNITS
PLSQL_PROFILER_RUNS
PLSQL_PROFILER_DATA
An example of how to use the profiler once the setup has been successfully completed follows:
set linesize 1000 trimspool on
select dbms_profiler.start_profiler('DATES PACKAGE') from dual;
select dates_pkg.minutes_elapsed(sysdate-10, sysdate) from dual;
select dbms_profiler.stop_profiler from dual;
spool dates_package_profiler_run.rpt
@?/rdbms/admin/profsum
spool off
or
execute dbms_profiler.start_profiler;
execute testprof;
execute dbms_profiler.stop_profiler;
select runid, run_date, run_comment from plsql_profiler_runs;
Reference :
https://docs.oracle.com/cd/E11882_01/appdev.112/e41502/adfns_profiler.htm#ADFNS02301
Script to produce HTML report with top consumers out of PL/SQL Profiler DBMS_PROFILER data (Doc ID 243755.1)
https://oracle-base.com/articles/11g/plsql-hierarchical-profiler-11gr1
No comments:
Post a Comment