STATEMENT_HISTORY
STATEMENT_HISTORY displays information about execution statements on the current node. To query this system catalog, you must have the **sysadmin **permission. The result can be queried only in the system database but cannot be queried in the user database.
The constraints on the query of this system catalog are as follows:
- Data must be queried in the Postgres database. No data exists in other databases.
- This system catalog is controlled by track_stmt_stat_level. The default value is OFF,L0, where the first part controls full SQL statements, and the second part controls slow SQL statements. For details about the record level of each field, see the following table.
- For slow SQL statements, if the value of track_stmt_stat_level is not OFF and the SQL execution time exceeds the value of log_min_duration_statement, the SQL statement is recorded as a slow SQL statement.
Table 1 STATEMENT_HISTORY columns
Number of soft parsing times. The value of n_soft_parse plus the value of n_hard_parse may be greater than the value of n_calls because the number of subqueries is not counted in the value of n_calls. | |||
Number of hard parsing times. The value of n_soft_parse plus the value of n_hard_parse may be greater than the value of n_calls because the number of subqueries is not counted in the value of n_calls. | |||
Number of rows in the result set returned by the SELECT statement. | |||
Valid DB time, which is accumulated if multiple threads are involved (unit: μs). | |||
Network status of messages sent through a physical connection, including the time (unit: μs), number of calls, and throughput (unit: byte). This can be used to analyze the network overhead of SQL statements in a distributed system and is not supported in standalone system. Example: {"time":xxx, "n_calls":xxx, "size":xxx}. | |||
Network status of messages received through a physical connection, including the time (unit: μs), number of calls, and throughput (unit: byte). This column can be used to analyze the network overhead of SQL in a distributed system. This column is not supported in a standalone mode. Example: {"time":xxx, "n_calls":xxx, "size":xxx}. | |||
Network status of messages sent through a logical connection, including the time (unit: μs), number of calls, and throughput (unit: byte). This column can be used to analyze the network overhead of SQL in a distributed system. This column is not supported in a standalone mode. Example: {"time":xxx, "n_calls":xxx, "size":xxx}. | |||
Network status of messages received through a logical connection, including the time (unit: μs), number of calls, and throughput (unit: byte). This column can be used to analyze the network overhead of SQL in a distributed system. This column is not supported in a standalone mode. Example: {"time":xxx, "n_calls":xxx, "size":xxx}. | |||
List of wait events and statement lock events. When the value of the record level is L0, the wait events starts to be recorded to the list. Statistics about the wait event of the current statement are displayed. For details about events, see Waiting status list, List of wait events corresponding to lightweight locks, List of wait events corresponding to I/Os, and List of wait events corresponding to transaction locks. For details about the impact of each transaction lock on services, see LOCK. When the record level is L2, the statement lock events starts to be recorded to the list. The events are recorded in time sequence. The number of records is affected by the track\_stmt\_details\_size parameter.
| |||
Whether the SQL statement is a slow SQL statement. | |||
Driver-specific trace ID, which is associated with an application request. |
Related Feature
This feature corresponding to the system catalog statement_history
. Its main purpose is to record SQL statements and running information generated during the database running, to ensure that the SQL information can still be queried even if the database is restarted.
General usage syntax:
openGauss=# select * from DBE_PERF.statement_history;
It is mainly controlled by the following parameters:
log_duration
: indicates whether to record slow queries.log_min_duration_statement
: marks the slow query time (unit: millisecond) of a SQL statement.0
indicates that the slow query time of all SQL statements is recorded.-1
indicates that no information is recorded.track_stmt_stat_level
: The default value isOFF, L0
. If the first value is notOFF
, all SQL statements are recorded. If the first value isOFF
and the second value is notOFF
, only slow SQL statements are recorded.track_stmt_parameter
: tracks the statement in detail.
The code logic needs to meet one of the following conditions:
Dynamic statement tracking is enabled: STMT is tracked using
dynamic_func_control
.track_stmt_stat_level
tracks a SQL statement whose first value isL0
or higher.track_stmt_stat_level
tracks a SQL statement whose second value isL0
or higher. The statement runtime is greater than the value oflog_min_duration_statement
, the value oflog_min_duration_statement
is greater than or equal to 0, andtrack_stmt_statement
is not enabled.track_stmt_parameter
is enabled and the first value oftrack_stmt_stat_level
(consumed DBTIME) is greater than 0.