The profiler allows users to measure performance cost of SQL and PSQL code.
It's implemented with a system package in the engine passing data to a profiler plugin.
This documentation treats the engine and plugin parts as a single thing, in the way the default profiler is going to be used.
The `RDB$PROFILER` package allows to profile execution of PSQL code collecting statistics of how many times each line was executed along with its minimum, maximum and accumulated execution times (with nanoseconds precision), as well open and fetch statistics of implicit and explicit SQL cursors.
To collect profile data, an user must first start a profile session with `RDB$PROFILER.START_SESSION`. This function returns an profile session ID which is later stored in the profiler snapshot tables to be queried and analyzed by the user.
After a session is started, PSQL and SQL statements statistics starts to be collected in memory. Note that a profile session collects data only of statements executed in the same attachment where the session was started.
Data is aggregated and stored per requests (i.e. a statement execution). When querying snapshot tables, user may do extra aggregation per statements or use the auxiliary views that do that automatically.
A session may be paused to temporary disable statistics collecting. It may be resumed later to return statistics collection in the same session.
A new session may be started when a session is already active. In this case it has the same semantics of finishing the current session with `RDB$PROFILER.FINISH_SESSION(FALSE)` so snapshots tables are not updated in the same moment.
To analyze the collected data, the user must flush the data to the snapshot tables, which may be done finishing or pausing a session (with `FLUSH` parameter set to `TRUE`) or calling `RDB$PROFILER.FLUSH`.
Following is a sample profile session and queries for data analysis.
```
-- Preparation - create table and routines that will be analyzed
create table tab (
id integer not null,
val integer not null
);
set term !;
create or alter function mult(p1 integer, p2 integer) returns integer
as
begin
return p1 * p2;
end!
create or alter procedure ins
as
declare n integer = 1;
begin
while (n <= 1000)
do
begin
if (mod(n, 2) = 1) then
insert into tab values (:n, mult(:n, 2));
n = n + 1;
end
end!
set term ;!
-- Start profiling
select rdb$profiler.start_session('Default_Profiler', 'Profile Session 1') from rdb$database;
`RDB$PROFILER.START_SESSION` starts a new profiler session, turns it the current session and return its identifier.
Input parameters:
-`PLUGIN_NAME` type `VARCHAR(255) CHARACTER SET UTF8`
-`DESCRIPTION` type `VARCHAR(255) CHARACTER SET UTF8`
Return type: `BIGINT NOT NULL`.
## Procedure `PAUSE_SESSION`
`RDB$PROFILER.PAUSE_SESSION` pauses the current profiler session so the next executed statements statistics are not collected.
If `FLUSH` is `TRUE` the snapshot tables are updated with data up to the current moment. Otherwise data remains only in memory for later update.
Calling `RDB$PROFILER.PAUSE_SESSION(TRUE)` has the same semantics of calling `RDB$PROFILER.PAUSE_SESSION(FALSE)` followed by `RDB$PROFILER.FLUSH`.
Input parameters:
-`FLUSH` type `BOOLEAN NOT NULL`
## Procedure `RESUME_SESSION`
`RDB$PROFILER.RESUME_SESSION` resumes the current profiler session if it was paused so the next executed statements statistics are collected again.
## Procedure `FINISH_SESSION`
`RDB$PROFILER.FINISH_SESSION` finishes the current profiler session.
If `FLUSH` is `TRUE` the snapshot tables are updated with data of the finished session (and old finished sessions not yet present in the snapshot). Otherwise data remains only in memory for later update.
Calling `RDB$PROFILER.FINISH_SESSION(TRUE)` has the same semantics of calling `RDB$PROFILER.FINISH_SESSION(FALSE)` followed by `RDB$PROFILER.FLUSH`.
After update data is stored in tables `PLG$PROF_SESSIONS`, `PLG$PROF_STATEMENTS`, `PLG$PROF_RECORD_SOURCES`, `PLG$PROF_REQUESTS`, `PLG$PROF_PSQL_STATS` and `PLG$PROF_RECORD_SOURCE_STATS` and may be read and analyzed by the user.
Snapshot tables (as well views and sequence) are automatically created in the first usage of the profiler. They are owned by the current user with read/write permissions for `PUBLIC`.
When a session is deleted the related data in others profiler snapshot tables are automatically deleted too through foregin keys with `DELETE CASCADE` option.
Below is the list of tables that stores profile data.
These views help profile data extraction aggregated at statement level.
They should be the preferred way to analyze the collected data. They can also be used together with the tables to get additional data not present on the views.
After hot spots are found, one can drill down in the data at the request level through the tables.