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

Name

Type

Description

Record Level

db_name

name

Database name.

L0

schema_name

name

Schema name.

L0

origin_node

integer

Node name.

L0

user_name

name

Username.

L0

application_name

text

Name of the application that sends a request.

L0

client_addr

text

IP address of the client that sends a request.

L0

client_port

integer

Port number of the client that sends a request.

L0

unique_query_id

bigint

ID of the unique SQL statement.

L0

debug_query_id

bigint

ID of the unique SQL statement.

L0

query

text

Normalized SQL statement.

L0

start_time

timestamp with time zone

Time when a statement starts.

L0

finish_time

timestamp with time zone

Time when a statement ends.

L0

slow_sql_threshold

bigint

Standard for slow SQL statement execution.

L0

transaction_id

bigint

Transaction ID.

L0

thread_id

bigint

ID of an execution thread.

L0

session_id

bigint

Session ID of a user.

L0

n_soft_parse

bigint

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.

L0

n_hard_parse

bigint

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.

L0

query_plan

text

Statement execution plan.

L0

n_returned_rows

bigint

Number of rows in the result set returned by the SELECT statement.

L0

n_tuples_fetched

bigint

Number of rows randomly scanned.

L0

n_tuples_returned

bigint

Number of rows sequentially scanned.

L0

n_tuples_inserted

bigint

Number of rows inserted.

L0

n_tuples_updated

bigint

Number of rows updated.

L0

n_tuples_deleted

bigint

Number of rows deleted.

L0

n_blocks_fetched

bigint

Number of buffer block access times.

L0

n_blocks_hit

bigint

Number of buffer block hits.

L0

db_time

bigint

Valid DB time, which is accumulated if multiple threads are involved (unit: μs).

L0

cpu_time

bigint

CPU time (unit: μs).

L0

execution_time

bigint

Execution time in the executor (unit: μs).

L0

parse_time

bigint

SQL parsing time (unit: μs).

L0

plan_time

bigint

SQL plan generation time (unit: μs).

L0

rewrite_time

bigint

SQL rewriting time (unit: μs).

L0

pl_execution_time

bigint

Execution time of PL/pgSQL (unit: μs).

L0

pl_compilation_time

bigint

Compilation time of PL/pgSQL (unit: μs).

L0

data_io_time

bigint

I/O time (unit: μs).

L0

net_send_info

text

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}.

L0

net_recv_info

text

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}.

L0

net_stream_send_info

text

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}.

L0

net_stream_recv_info

text

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}.

L0

lock_count

bigint

Number of locks.

L0

lock_time

bigint

Time required for locking.

L1

lock_wait_count

bigint

Number of lock waits.

L0

lock_wait_time

bigint

Time required for lock waiting.

L1

lock_max_count

bigint

Maximum number of locks.

L0

lwlock_count

bigint

Number of lightweight locks (reserved).

L0

lwlock_wait_count

bigint

Number of lightweight lock waits.

L0

lwlock_time

bigint

Time required for lightweight locking (reserved).

L1

lwlock_wait_time

bigint

Time required for lightweight lock waiting.

L1

details

bytea

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.

Events include:

  • Start locking.
  • Complete locking.
  • Start lock waiting.
  • Complete lock waiting.
  • Start unlocking.
  • Complete unlocking.
  • Start lightweight lock waiting.
  • Complete lightweight lock waiting.

L2

is_slow_sql

boolean

Whether the SQL statement is a slow SQL statement.

  • t (true): yes
  • f (false): no

L0

trace_id

text

Driver-specific trace ID, which is associated with an application request.

L0

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 is OFF, L0. If the first value is not OFF, all SQL statements are recorded. If the first value is OFF and the second value is not OFF, 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:

  1. Dynamic statement tracking is enabled: STMT is tracked using dynamic_func_control.

  2. track_stmt_stat_level tracks a SQL statement whose first value is L0 or higher.

  3. track_stmt_stat_level tracks a SQL statement whose second value is L0 or higher. The statement runtime is greater than the value of log_min_duration_statement, the value of log_min_duration_statement is greater than or equal to 0, and track_stmt_statement is not enabled.

  4. track_stmt_parameter is enabled and the first value of track_stmt_stat_level (consumed DBTIME) is greater than 0.

Feedback
编组 3备份
    openGauss 2024-11-22 00:52:56
    cancel