DBMS_PROFILER v13
The DBMS_PROFILER
package collects and stores performance information about the PL/pgSQL and SPL statements that are executed during a performance profiling session; use the functions and procedures listed below to control the profiling tool.
Function/Procedure | Return Type | Description |
---|---|---|
FLUSH_DATA | Status Code or Exception | Flushes performance data collected in the current session without terminating the session (profiling continues). |
GET_VERSION(major OUT, minor OUT) | n/a | Returns the version number of this package. |
INTERNAL_VERSION_CHECK | Status Code | Confirms that the current version of the profiler will work with the current database. |
PAUSE_PROFILER | Status Code or Exception | Pause data collection. |
RESUME_PROFILER | Status Code or Exception | Resume data collection. |
START_PROFILER(run_comment, run_comment1 [, run_number OUT ]) | Status Code or Exception | Start data collection. |
STOP_PROFILER | Status Code or Exception | Stop data collection and flush performance data to the PLSQL_PROFILER_RAWDATA table. |
The functions within the DBMS_PROFILER
package return a status code to indicate success or failure; the DBMS_PROFILER
procedures raise an exception only if they encounter a failure. The status codes and messages returned by the functions, and the exceptions raised by the procedures are listed in the table below.
Status Code | Message | Exception | Description |
---|---|---|---|
-1 | error version | version_mismatch | The profiler version and the database are incompatible. |
0 | success | n/a | The operation completed successfully. |
1 | error_param | profiler_error | The operation received an incorrect parameter. |
2 | error_io | profiler_error | The data flush operation has failed. |
FLUSH_DATA
The FLUSH_DATA
function/procedure flushes the data collected in the current session without terminating the profiler session. The data is flushed to the tables described in the Advanced Server Performance Features Guide. The function and procedure signatures are:
Parameters
status
Status code returned by the operation.
GET_VERSION
The GET_VERSION
procedure returns the version of DBMS_PROFILER
. The procedure signature is:
Parameters
major
The major version number of DBMS_PROFILER
.
minor
The minor version number of DBMS_PROFILER
.
INTERNAL_VERSION_CHECK
The INTERNAL_VERSION_CHECK
function confirms that the current version of DBMS_PROFILER
will work with the current database. The function signature is:
Parameters
status
Status code returned by the operation.
PAUSE_PROFILER
The PAUSE_PROFILER
function/procedure pauses a profiling session. The function and procedure signatures are:
Parameters
status
Status code returned by the operation.
RESUME_PROFILER
The RESUME_PROFILER
function/procedure pauses a profiling session. The function and procedure signatures are:
Parameters
status
Status code returned by the operation.
START_PROFILER
The START_PROFILER
function/procedure starts a data collection session. The function and procedure signatures are:
Parameters
run_comment
A user-defined comment for the profiler session. The default value is SYSDATE
.
run_comment1
An additional user-defined comment for the profiler session. The default value is ''.
run_number
The session number of the profiler session.
status
Status code returned by the operation.
STOP_PROFILER
The STOP_PROFILER
function/procedure stops a profiling session and flushes the performance information to the DBMS_PROFILER
tables and view. The function and procedure signatures are:
Parameters
status
Status code returned by the operation.
Using DBMS_PROFILER
The DBMS_PROFILER
package collects and stores performance information about the PL/pgSQL and SPL statements that are executed during a profiling session; you can review the performance information in the tables and views provided by the profiler.
DBMS_PROFILER
works by recording a set of performance-related counters and timers for each line of PL/pgSQL or SPL statement that executes within a profiling session. The counters and timers are stored in a table named SYS.PLSQL_PROFILER_DATA
. When you complete a profiling session, DBMS_PROFILER
will write a row to the performance statistics table for each line of PL/pgSQL or SPL code that executed within the session. For example, if you execute the following function:
DBMS_PROFILER
adds one PLSQL_PROFILER_DATA
entry for each line of code within the getBalance()
function (including blank lines and comments). The entry corresponding to the SELECT
statement executed exactly one time; and required a very small amount of time to execute. On the other hand, the entry corresponding to the RAISE INFO
statement executed once or not at all (depending on the value for the balance
column).
Some of the lines in this function contain no executable code so the performance statistics for those lines will always contain zero values.
To start a profiling session, invoke the DBMS_PROFILER.START_PROFILER
function (or procedure). Once you've invoked START_PROFILER
, Advanced Server will profile every PL/pgSQL or SPL function, procedure, trigger, or anonymous block that your session executes until you either stop or pause the profiler (by calling STOP_PROFILER
or PAUSE_PROFILER
).
It is important to note that when you start (or resume) the profiler, the profiler will only gather performance statistics for functions/procedures/triggers that start after the call to START_PROFILER
(or RESUME_PROFILER
).
While the profiler is active, Advanced Server records a large set of timers and counters in memory; when you invoke the STOP_PROFILER
(or FLUSH_DATA
) function/procedure, DBMS_PROFILER
writes those timers and counters to a set of three tables:
SYS.PLSQL_PROFILER_RAWDATA
Contains the performance counters and timers for each statement executed within the session.
SYS.PLSQL_PROFILER_RUNS
Contains a summary of each run (aggregating the information found in
PLSQL_PROFILER_RAWDATA
).SYS.PLSQL_PROFILER_UNITS
Contains a summary of each code unit (function, procedure, trigger, or anonymous block) executed within a session.
In addition, DBMS_PROFILER
defines a view, SYS.PLSQL_PROFILER_DATA
, which contains a subset of the PLSQL_PROFILER_RAWDATA
table.
Please note that a non-superuser may gather profiling information, but may not view that profiling information unless a superuser grants specific privileges on the profiling tables (stored in the SYS
schema). This permits a non-privileged user to gather performance statistics without exposing information that the administrator may want to keep secret.
Querying the DBMS_PROFILER Tables and View
The following step-by-step example uses DBMS_PROFILER
to retrieve performance information for procedures, functions, and triggers included in the sample data distributed with Advanced Server.
- Open the EDB-PSQL command line, and establish a connection to the Advanced Server database. Use an
EXEC
statement to start the profiling session:
Note
(The call to start_profiler()
includes a comment that DBMS_PROFILER
associates with the profiler session).
- Then call the
list_emp
function:
- Stop the profiling session with a call to
dbms_profiler.stop_profiler:
- Start a new session with the
dbms_profiler.start_profiler
function (followed by a new comment):