Dynamic runtime instrumentation tools architecture (DRITA) v15
The Dynamic Runtime Instrumentation Tools Architecture (DRITA) allows a DBA to query catalog views to determine the wait events that affect the performance of individual sessions or the whole system. DRITA records the number of times each event occurs as well as the time spent waiting. You can use this information to diagnose performance problems. DRITA consumes minimal system resources.
DRITA compares snapshots to evaluate the performance of a system. A snapshot is a saved set of system performance data at a given point in time. A unique ID number identifies each snapshot. You can use snapshot ID numbers with DRITA reporting functions to return system performance statistics.
Configuring and using DRITA
EDB Postgres Advanced Server's postgresql.conf
file includes a configuration parameter named timed_statistics
that controls collecting timing data. The valid parameter values are TRUE
or FALSE
. The default value is FALSE
.
timed_statistics
is a dynamic parameter that you can modify in the postgresql.conf
file or while a session is in progress. To enable DRITA, you must either:
Modify the
postgresql.conf
file, setting thetimed_statistics
parameter toTRUE
.Connect to the server with the EDB-PSQL client and invoke the command:
Connect to the server with the EDB-PSQL client, and invoke the command:
After modifying the timed_statistics
parameter, take a starting snapshot. A snapshot captures the current state of each timer and event counter. The server compares the starting snapshot to a later snapshot to gauge system performance.
Use the edbsnap()
function to take the beginning snapshot:
Then, run the workload that you want to evaluate. When the workload is complete or at a strategic point during the workload, take another snapshot:
You can capture multiple snapshots during a session. Then, use the DRITA functions and reports to manage and compare the snapshots to evaluate performance information.
DRITA functions
You can use DRITA functions to gather wait information and manage snapshots. DRITA functions are fully supported by EDB Postgres Advanced Server 14 whether your installation is made compatible with Oracle databases or is in PostgreSQL-compatible mode.
get_snaps()
The get_snaps()
function returns a list of the current snapshots. The signature is:
This example uses the get_snaps()
function to display a list of snapshots:
The first column in the result list displays the snapshot identifier. The second column displays the date and time that the snapshot was captured.
sys_rpt()
The sys_rpt()
function returns system wait information. The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
This example shows a call to the sys_rpt()
function:
The information displayed in the result set includes:
Column name | Description |
---|---|
WAIT NAME | The name of the wait |
COUNT | The number of times that the wait event occurred |
WAIT TIME | The time of the wait event in seconds |
% WAIT | The percentage of the total wait time used by this wait for this session |
sess_rpt()
The sess_rpt()
function returns session wait information. The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
This example shows a call to the sess_rpt()
function:
The information displayed in the result set includes:
Column name | Description |
---|---|
ID | The processID of the session |
USER | The name of the user incurring the wait |
WAIT NAME | The name of the wait event |
COUNT | The number of times that the wait event occurred |
TIME | The length of the wait event in seconds |
% WAIT SES | The percentage of the total wait time used by this wait for this session |
% WAIT ALL | The percentage of the total wait time used by this wait for all sessions |
sessid_rpt()
The sessid_rpt()
function returns session ID information for a specified backend. The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
backend_id
An integer value that represents the backend identifier.
This example shows a call to sessid_rpt()
:
The information displayed in the result set includes:
Column name | Description |
---|---|
ID | The process ID of the wait |
USER | The name of the user that owns the session |
WAIT NAME | The name of the wait event |
COUNT | The number of times that the wait event occurred |
TIME | The length of the wait in seconds |
% WAIT SES | The percentage of the total wait time used by this wait for this session |
% WAIT ALL | The percentage of the total wait time used by this wait for all sessions |
sesshist_rpt()
The sesshist_rpt()
function returns session wait information for a specified backend. The signature is:
Parameters
snapshot_id
An integer value that identifies the snapshot.
session_id
An integer value that represents the session.
This example shows a call to the sesshist_rpt()
function:
Note
The example was shortened. Over 1300 rows are actually generated.
The information displayed in the result set includes:
Column name | Description |
---|---|
ID | The system-assigned identifier of the wait |
USER | The name of the user that incurred the wait |
SEQ | The sequence number of the wait event |
WAIT NAME | The name of the wait event |
ELAPSED | The length of the wait event in microseconds |
File | The relfilenode number of the file |
Name | If available, the name of the file name related to the wait event |
# of Blk | The block number read or written for a specific instance of the event |
Sum of Blks | The number of blocks read |
purgesnap()
The purgesnap()
function purges a range of snapshots from the snapshot tables. The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
purgesnap()
removes all snapshots between beginning_id
and ending_id
, inclusive:
A call to the get_snaps()
function after executing the example shows that snapshots 6
through 9
were purged from the snapshot tables:
truncsnap()
Use the truncsnap() function to delete all records from the snapshot table. The signature is:
For example:
A call to the get_snaps()
function after calling the truncsnap()
function shows that all records were removed from the snapshot tables:
Simulating Statspack AWR reports
These functions return information comparable to the information contained in an Oracle Statspack/Automatic Workload Repository (AWR) report. When taking a snapshot, performance data from system catalog tables is saved into history tables. These reporting functions report on the differences between two given snapshots:
stat_db_rpt()
stat_tables_rpt()
statio_tables_rpt()
stat_indexes_rpt()
statio_indexes_rpt()
You can execute the reporting functions individually or you can execute all five functions by calling the edbreport()
function.
edbreport()
The edbreport()
function includes data from the other reporting functions, plus system information. The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
The call to the edbreport()
function returns a composite report that contains system information and the reports returned by the other statspack functions:
'
The information displayed in the report introduction includes the database name and version, the current date, the beginning and ending snapshot date and times, database and tablespace details, and schema information.
The information displayed in the Top 10 Relations by pages
section includes:
Column name | Description |
---|---|
TABLE | The name of the table |
RELPAGES | The number of pages in the table |
The information displayed in the Top 10 Indexes by pages
section includes:
Column name | Description |
---|---|
INDEX | The name of the index |
RELPAGES | The number of pages in the index |
The information displayed in the Top 10 Relations by DML
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
UPDATES | The number of UPDATES performed on the table |
DELETES | The number of DELETES performed on the table |
INSERTS | The number of INSERTS performed on the table |
The information displayed in the DATA from pg_stat_database
section of the report includes:
Column name | Description |
---|---|
DATABASE | The name of the database. |
NUMBACKENDS | Number of backends currently connected to this database. This is the only column in this view that returns a value reflecting current state. All other columns return the accumulated values since the last reset. |
XACT COMMIT | Number of transactions in this database that were committed. |
XACT ROLLBACK | Number of transactions in this database that were rolled back. |
BLKS READ | Number of disk blocks read in this database. |
BLKS HIT | Number of times disk blocks were found already in the buffer cache when a read wasn't necessary. |
HIT RATIO | The percentage of times that a block was found in the shared buffer cache. |
The information displayed in the DATA from pg_buffercache
section of the report includes:
Column name | Description |
---|---|
RELATION | The name of the table |
BUFFERS | The number of shared buffers used by the relation |
Note
To obtain the report for DATA from pg_buffercache
, the pg_buffercache
module must be installed in the database. Perform the installation using the CREATE EXTENSION
command.
For more information on the CREATE EXTENSION
command, see the PostgreSQL core documentation.
The information displayed in the DATA from pg_stat_all_tables ordered by seq scan
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
SEQ SCAN | The number of sequential scans initiated on this table |
REL TUP READ | The number of tuples read in the table |
IDX SCAN | The number of index scans initiated on the table |
IDX TUP READ | The number of index tuples read |
INS | The number of rows inserted |
UPD | The number of rows updated |
DEL | The number of rows deleted |
The information displayed in the DATA from pg_stat_all_tables ordered by rel tup read
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
SEQ SCAN | The number of sequential scans performed on the table |
REL TUP READ | The number of tuples read from the table |
IDX SCAN | The number of index scans performed on the table |
IDX TUP READ | The number of index tuples read |
INS | The number of rows inserted |
UPD | The number of rows updated |
DEL | The number of rows deleted |
The information displayed in the DATA from pg_statio_all_tables
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
HEAP READ | The number of heap blocks read |
HEAP HIT | The number of heap blocks hit |
IDX READ | The number of index blocks read |
IDX HIT | The number of index blocks hit |
TOAST READ | The number of toast blocks read |
TOAST HIT | The number of toast blocks hit |
TIDX READ | The number of toast index blocks read |
TIDX HIT | The number of toast index blocks hit |
The information displayed in the DATA from pg_stat_all_indexes
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the index resides |
RELATION | The name of the table on which the index is defined |
INDEX | The name of the index |
IDX SCAN | The number of indexes scans initiated on this index |
IDX TUP READ | Number of index entries returned by scans on this index |
IDX TUP FETCH | Number of live table rows fetched by simple index scans using this index |
The information displayed in the DATA from pg_statio_all_indexes
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the index resides |
RELATION | The name of the table on which the index is defined |
INDEX | The name of the index |
IDX BLKS READ | The number of index blocks read |
IDX BLKS HIT | The number of index blocks hit |
The information displayed in the System Wait Information
section includes:
Column name | Description |
---|---|
WAIT NAME | The name of the wait |
COUNT | The number of times that the wait event occurred |
WAIT TIME | The length of the wait time in seconds |
% WAIT | The percentage of the total wait time used by this wait for this session |
The information displayed in the Database Parameters from postgresql.conf
section includes:
Column name | Description |
---|---|
PARAMETER | The name of the parameter |
SETTING | The current value assigned to the parameter |
CONTEXT | The context required to set the parameter value |
MINVAL | The minimum value allowed for the parameter |
MAXVAL | The maximum value allowed for the parameter |
stat_db_rpt()
The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
This example shows the stat_db_rpt()
function:
The information displayed in the DATA from pg_stat_database
section of the report includes:
Column name | Description |
---|---|
DATABASE | The name of the database. |
NUMBACKENDS | Number of backends currently connected to this database. This is the only column in this view that returns a value reflecting current state. All other columns return the accumulated values since the last reset. |
XACT COMMIT | The number of transactions in this database that were committed. |
XACT ROLLBACK | The number of transactions in this database that were rolled back. |
BLKS READ | The number of blocks read. |
BLKS HIT | The number of blocks hit. |
HIT RATIO | The percentage of times that a block was found in the shared buffer cache. |
stat_tables_rpt()
The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
scope
Determines the tables the function returns statistics about. Specify SYS
, USER
, or ALL
:
- Use
SYS
to return information about system-defined tables. A table is considered a system table if it's stored in thepg_catalog
,information_schema
, orsys
schema. - Use
USER
to return information about user-defined tables. - Use
ALL
to return information about all tables.
The stat_tables_rpt()
function returns a two-part report. The first portion of the report contains:
The information displayed in the DATA from pg_stat_all_tables ordered by seq scan
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
SEQ SCAN | The number of sequential scans on the table |
REL TUP READ | The number of tuples read from the table |
IDX SCAN | The number of index scans performed on the table |
IDX TUP READ | The number of index tuples read from the table |
INS | The number of rows inserted |
UPD | The number of rows updated |
DEL | The number of rows deleted |
The second portion of the report contains:
The information displayed in the DATA from pg_stat_all_tables ordered by rel tup read
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the table resides |
RELATION | The name of the table |
SEQ SCAN | The number of sequential scans performed on the table |
REL TUP READ | The number of tuples read from the table |
IDX SCAN | The number of index scans performed on the table |
IDX TUP READ | The number of live rows fetched by index scans |
INS | The number of rows inserted |
UPD | The number of rows updated |
DEL | The number of rows deleted |
statio_tables_rpt()
The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
scope
Determines the tables the function returns statistics about. Specify SYS
, USER
or ALL
:
- Use
SYS
to return information about system-defined tables. A table is considered a system table if it's stored thepg_catalog
,information_schema
, orsys
schema. - Use
USER
to return information about user-defined tables. - Use
ALL
to return information about all tables.
The statio_tables_rpt()
function returns a report that contains:
The information displayed in the DATA from pg_statio_all_tables
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the relation resides |
RELATION | The name of the relation |
HEAP READ | The number of heap blocks read |
HEAP HIT | The number of heap blocks hit |
IDX READ | The number of index blocks read |
IDX HIT | The number of index blocks hit |
TOAST READ | The number of toast blocks read |
TOAST HIT | The number of toast blocks hit |
TIDX READ | The number of toast index blocks read |
TIDX HIT | The number of toast index blocks hit |
stat_indexes_rpt()
The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
scope
Determines the tables the function returns statistics about. Specify SYS
, USER
or ALL
:
- Use
SYS
to return information about system-defined tables. A table is considered a system table if it's stored in thepg_catalog
,information_schema
, orsys
schema. - Use
USER
to return information about user-defined tables. - Use
ALL
to return information about all tables.
The stat_indexes_rpt()
function returns a report that contains:
The information displayed in the DATA from pg_stat_all_indexes
section includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the relation resides |
RELATION | The name of the relation |
INDEX | The name of the index |
IDX SCAN | The number of indexes scanned |
IDX TUP READ | The number of index tuples read |
IDX TUP FETCH | The number of index tuples fetched |
statio_indexes_rpt()
The signature is:
Parameters
beginning_id
An integer value that represents the beginning session identifier.
ending_id
An integer value that represents the ending session identifier.
top_n
The number of rows to return.
scope
Determines the tables the function returns statistics about. Specify SYS
, USER
or ALL
:
- Use
SYS
to return information about system-defined tables. A table is considered a system table if it's stored in thepg_catalog
,information_schema
, orsys
schema. - Use
USER
to return information about user-defined tables. - Use
ALL
to return information about all tables.
The statio_indexes_rpt()
function returns a report that contains:
The information displayed in the DATA from pg_statio_all_indexes
report includes:
Column name | Description |
---|---|
SCHEMA | The name of the schema in which the relation resides |
RELATION | The name of the table on which the index is defined |
INDEX | The name of the index |
IDX BLKS READ | The number of index blocks read |
IDX BLKS HIT | The number of index blocks hit |
Performance tuning recommendations
To use DRITA reports for performance tuning, review the top five events in a report. Look for any event that takes an especially large percentage of resources. In a streamlined system, user I/O generally makes up the largest number of waits. Evaluate waits in the context of CPU usage and total time. An event might not be significant if it takes two minutes out of a total measurement interval of two hours and the rest of the time is consumed by CPU time. Evaluate the component of response time (CPU "work" time or other "wait" time) that consumes the highest percentage of overall time.
When evaluating events, watch for:
Event type | Description |
---|---|
Checkpoint waits | Checkpoint waits might indicate that checkpoint parameters need to be adjusted (checkpoint_segments and checkpoint_timeout ). |
WAL-related waits | WAL-related waits might indicate wal_buffers are undersized. |
SQL Parse waits | If the number of waits is high, try to use prepared statements. |
db file random reads | If high, check for appropriate indexes and statistics. |
db file random writes | If high, might need to decrease bgwriter_delay . |
btree random lock acquires | Might indicate indexes are being rebuilt. Schedule index builds during less active time. |
Also look at the hardware, the operating system, the network, and the application SQL statements in performance reviews.
Event descriptions
The following table lists the basic wait events that are displayed by DRITA.
Event name | Description |
---|---|
add in shmem lock acquire | Obsolete/unused. |
bgwriter communication lock acquire | The bgwriter (background writer) process has waited for the short-term lock that synchronizes messages between the bgwriter and a backend process. |
btree vacuum lock acquire | The server has waited for the short-term lock that synchronizes access to the next available vacuum cycle ID. |
buffer free list lock acquire | The server has waited for the short-term lock that synchronizes access to the list of free buffers (in shared memory). |
checkpoint lock acquire | A server process has waited for the short-term lock that prevents simultaneous checkpoints. |
checkpoint start lock acquire | The server has waited for the short-term lock that synchronizes access to the bgwriter checkpoint schedule. |
clog control lock acquire | The server has waited for the short-term lock that synchronizes access to the commit log. |
control file lock acquire | The server has waited for the short-term lock that synchronizes write access to the control file. This is usually a low number. |
db file extend | A server process has waited for the operating system while adding a new page to the end of a file. |
db file read | A server process has waited for a read from disk to complete. |
db file write | A server process has waited for a write to disk to complete. |
db file sync | A server process has waited for the operating system to flush all changes to disk. |
first buf mapping lock acquire | The server has waited for a short-term lock that synchronizes access to the shared-buffer mapping table. |
freespace lock acquire | The server has waited for the short-term lock that synchronizes access to the freespace map. |
lwlock acquire | The server has waited for a short-term lock that isn't described elsewhere in this table. |
multi xact gen lock acquire | The server has waited for the short-term lock that synchronizes access to the next available multi-transaction ID (when a SELECT...FOR SHARE statement executes). |
multi xact member lock acquire | The server has waited for the short-term lock that synchronizes access to the multi-transaction member file (when a SELECT...FOR SHARE statement executes). |
multi xact offset lock acquire | The server has waited for the short-term lock that synchronizes access to the multi-transaction offset file (when a SELECT...FOR SHARE statement executes). |
oid gen lock acquire | The server has waited for the short-term lock that synchronizes access to the next available OID (object ID). |
query plan | The server has computed the execution plan for a SQL statement. |
rel cache init lock acquire | The server has waited for the short-term lock that prevents simultaneous relation-cache loads/unloads. |
shmem index lock acquire | The server has waited for the short-term lock that synchronizes access to the shared-memory map. |
sinval lock acquire | The server has waited for the short-term lock that synchronizes access to the cache invalidation state. |
sql parse | The server has parsed a SQL statement. |
subtrans control lock acquire | The server has waited for the short-term lock that synchronizes access to the subtransaction log. |
tablespace create lock acquire | The server has waited for the short-term lock that prevents simultaneous CREATE TABLESPACE or DROP TABLESPACE commands. |
two phase state lock acquire | The server has waited for the short-term lock that synchronizes access to the list of prepared transactions. |
wal insert lock acquire | The server has waited for the short-term lock that synchronizes write access to the write-ahead log. A high number can indicate that WAL buffers are sized too small. |
wal write lock acquire | The server has waited for the short-term lock that synchronizes write-ahead log flushes. |
wal file sync | The server has waited for the write-ahead log to sync to disk. This is related to the wal_sync_method parameter which, by default, is 'fsync'. You can gain better performance by changing this parameter to open_sync . |
wal flush | The server has waited for the write-ahead log to flush to disk. |
wal write | The server has waited for a write to the write-ahead log buffer. Expect this value to be high. |
xid gen lock acquire | The server has waited for the short-term lock that synchronizes access to the next available transaction ID. |
When wait events occur for lightweight locks, DRITA displays them as well. It uses a lightweight lock to protect a particular data structure in shared memory.
Certain wait events can be due to the server process waiting for one of a group of related lightweight locks, which is referred to as a lightweight lock tranche. DRITA doesn't display individual lightweight lock tranches, but it displays their summation with a single event named other lwlock acquire
.
For a list and description of lightweight locks displayed by DRITA, see the PostgreSQL core documentation. Under Viewing Statistics, see the Wait Event Type table for more details.
This example displays lightweight locks ProcArrayLock
, CLogControlLock
, WALBufMappingLock
, and XidGenLock
.
DRITA also displays wait events that are related to certain EDB Postgres Advanced Server product features. These events and the other lwlock acquire
event are listed in the following table.
Event name | Description |
---|---|
BulkLoadLock | The server has waited for access related to EDB*Loader. |
EDBResoureManagerLock | The server has waited for access related to EDB Resource Manager. |
other lwlock acquire | Summation of waits for lightweight lock tranches. |