Note
This view is available starting with V4.0.0.
Purpose
The V$OB_SQL_AUDIT view displays the source and execution status of each SQL request on the current OBServer node. This view is tenant-specific and can only be queried within the same tenant, except for the sys tenant.
Columns
| Column | Type | Nullable | Description |
|---|---|---|---|
| SVR_IP | varchar(46) | NO | IP address. |
| SVR_PORT | bigint(20) | NO | Port number. |
| REQUEST_ID | bigint(20) | NO | Request ID. |
| SQL_EXEC_ID | bigint(20) | NO | Execution ID. |
| TRACE_ID | varchar(128) | NO | Trace ID of the statement. |
| SID | bigint(20) unsigned | NO | For V4.2.x:
|
| CLIENT_IP | varchar(46) | NO | |
| CLIENT_PORT | bigint(20) | NO | Port number of the client that sends the request. |
| TENANT_ID | bigint(20) | NO | Tenant ID.
NoteStarting from V4.2.3, this field indicates the same value as the |
| TENANT_NAME | varchar(64) | NO | Tenant name. |
| EFFECTIVE_TENANT_ID | bigint(20) | NO | Tenant ID. |
| USER_ID | bigint(20) | NO | User ID of the client that sends the request. |
| USER_NAME | varchar(64) | NO | User name of the client that sends the request. |
| USER_GROUP | bigint(20) | NO | Resource group ID to which the user belongs. |
| USER_CLIENT_IP | varchar(46) | NO | IP address of the client that sends the request. |
| DB_ID | bigint(20) unsigned | NO | Database ID. |
| DB_NAME | varchar(128) | NO | Database name. |
| SQL_ID | varchar(32) | NO | ID of the SQL statement.
NoteStarting from V4.2.3, for PL requests executed by using anonymous blocks or by using the CALL statement, this field indicates the actual MD5 value generated. |
| QUERY_SQL | longtext | NO | The actual SQL statement. |
| PLAN_ID | bigint(20) | NO | The ID of the execution plan. |
| AFFECTED_ROWS | bigint(20) | NO | The number of affected rows. |
| RETURN_ROWS | bigint(20) | NO | The number of returned rows. |
| PARTITION_CNT | bigint(20) | NO | The number of partitions involved in the request. |
| RET_CODE | bigint(20) | NO | The return code of the execution result: |
| QC_ID | bigint(20) unsigned | NO | The ID of the scheduler in parallel execution scenarios. |
| DFO_ID | bigint(20) | NO | The ID of the current subplan in parallel execution scenarios. |
| SQC_ID | bigint(20) | NO | The ID of the local coordinator in parallel execution scenarios. |
| WORKER_ID | bigint(20) | NO | The ID of the worker thread in parallel execution scenarios. |
| EVENT | varchar(64) | NO | The longest waiting event name. |
| P1TEXT | varchar(64) | NO | Parameter 1 of the waiting event. |
| P1 | bigint(20) unsigned | NO | The value of parameter 1 of the waiting event. |
| P2TEXT | varchar(64) | NO | Parameter 2 of the waiting event. |
| P2 | bigint(20) unsigned | NO | The value of parameter 2 of the waiting event. |
| P3TEXT | varchar(64) | NO | Parameter 3 of the waiting event. |
| P3 | bigint(20) unsigned | NO | The value of parameter 3 of the waiting event. |
| LEVEL | bigint(20) | NO | The level of the waiting event. |
| WAIT_CLASS_ID | bigint(20) | NO | The ID of the class to which the waiting event belongs. |
| WAIT_CLASS# | bigint(20) | NO | The index of the class to which the waiting event belongs. |
| WAIT_CLASS | varchar(64) | NO | The name of the class to which the waiting event belongs. |
| STATE | varchar(19) | NO | The state of the waiting event. |
| WAIT_TIME_MICRO | bigint(20) | NO | The time that the wait event waited for, in microseconds. |
| TOTAL_WAIT_TIME_MICRO | bigint(20) | NO | The total time of all waits during the execution process, in microseconds. |
| TOTAL_WAITS | bigint(20) | NO | The total number of waits during the execution process. |
| RPC_COUNT | bigint(20) | NO | The number of RPC requests sent. |
| PLAN_TYPE | bigint(20) | NO | The type of the execution plan. Valid values: |
| IS_INNER_SQL | tinyint(4) | NO | Indicates whether the request is an internal SQL request. |
| IS_EXECUTOR_RPC | tinyint(4) | NO | Indicates whether the request is an RPC request. |
| IS_HIT_PLAN | tinyint(4) | NO | Indicates whether the plan cache was hit. |
| REQUEST_TIME | bigint(20) | NO | The start time of the execution, in microseconds. |
| ELAPSED_TIME | bigint(20) | NO | The total time consumed from receiving the request to the end of the execution, in microseconds. |
| NET_TIME | bigint(20) | NO | The time from sending the RPC to receiving the request, in microseconds. |
| NET_WAIT_TIME | bigint(20) | NO | The time from receiving the request to entering the queue, in microseconds. |
| QUEUE_TIME | bigint(20) | NO | The waiting time of the request in the queue, in microseconds. |
| DECODE_TIME | bigint(20) | NO | The time for decoding after the request is dequeued, in microseconds. |
| GET_PLAN_TIME | bigint(20) | NO | The time from the start of the process to obtaining the plan, in microseconds. |
| EXECUTE_TIME | bigint(20) | NO | The time consumed for plan execution, in microseconds. |
| APPLICATION_WAIT_TIME | bigint(20) unsigned | NO | The total time of all Application events, in microseconds. |
| CONCURRENCY_WAIT_TIME | bigint(20) unsigned | NO | The total time of all Concurrency events, in microseconds. |
| USER_IO_WAIT_TIME | bigint(20) unsigned | NO | The total time of all user_io events, in microseconds. |
| SCHEDULE_TIME | bigint(20) unsigned | NO | The time of all Schedule events, in microseconds. |
| ROW_CACHE_HIT | bigint(20) | NO | The number of row cache hits. |
| BLOOM_FILTER_CACHE_HIT | bigint(20) | NO | The number of Bloom Filter cache hits. |
| BLOCK_CACHE_HIT | bigint(20) | NO | The number of cache hits. |
| DISK_READS | bigint(20) | NO | The number of disk reads. |
| RETRY_CNT | bigint(20) | NO | The number of retries. |
| TABLE_SCAN | tinyint(4) | NO | The type of the request. If the value is 1, the request contains a full table scan. If the value is 0, the request does not contain a full table scan. |
| CONSISTENCY_LEVEL | bigint(20) | NO | The consistency level. Valid values are as follows:
|
| MEMSTORE_READ_ROW_COUNT | bigint(20) | NO | The number of rows read from the MemStore. |
| SSSTORE_READ_ROW_COUNT | bigint(20) | NO | The number of rows read from the SSStore. |
| DATA_BLOCK_READ_CNT | bigint(20) | NO | The number of data blocks read. |
| DATA_BLOCK_CACHE_HIT | bigint(20) | NO | The number of data blocks that hit the cache. |
| INDEX_BLOCK_READ_CNT | bigint(20) | NO | The number of index blocks read. |
| INDEX_BLOCK_CACHE_HIT | bigint(20) | NO | The number of index blocks that hit the cache. |
| BLOCKSCAN_BLOCK_CNT | bigint(20) | NO | The number of data blocks scanned on one side. |
| BLOCKSCAN_ROW_CNT | bigint(20) | NO | The number of rows scanned on one side. |
| PUSHDOWN_STORAGE_FILTER_ROW_CNT | bigint(20) | NO | The number of rows filtered by the pushed-down storage filter. |
| REQUEST_MEMORY_USED | bigint(20) | NO | The memory consumed by the request. |
| EXPECTED_WORKER_COUNT | bigint(20) | NO | The expected number of worker threads. |
| USED_WORKER_COUNT | bigint(20) | NO | The number of worker threads used by the request. |
| SCHED_INFO | varchar(16384) | NO | The request scheduling information. |
| FUSE_ROW_CACHE_HIT | bigint(20) | NO | This field is not supported. The value of the field is NULL by default. |
| PS_CLIENT_STMT_ID | bigint(20) | NO | The prepare ID corresponding to the request:
|
| PS_INNER_STMT_ID | bigint(20) | NO | The prepare ID corresponding to the request:
|
| TX_ID | bigint(20) | NO | The transaction ID corresponding to the request. |
| SNAPSHOT_VERSION | bigint(20) | NO | SQL statement read snapshot version. |
| REQUEST_TYPE | bigint(20) | NO | Request type: |
| IS_BATCHED_MULTI_STMT | tinyint(4) | NO | Whether to optimize for Batch Multi Stmt. |
| OB_TRACE_INFO | varchar(4096) | NO | User-defined trace information. |
| PLAN_HASH | bigint(20) unsigned | NO | Hash value of the execution plan. |
| LOCK_FOR_READ_TIME | bigint(20) | NO | Time spent waiting for a lock during data read, in microseconds. |
| PARAMS_VALUE | longtext | NO | Parameter values bound to the prepared statement (PS). |
| RULE_NAME | varchar(256) | NO | Rule name.
NoteThis column is available starting with V4.1.0. |
| PARTITION_HIT | tinyint(4) | NO |
NoteThis column is available starting with V4.1.0. |
| TX_INTERNAL_ROUTING | bigint(20) | NO | Indicates whether transaction routing is enabled for the current transaction:
Note
|
| TX_STATE_VERSION | bigint(20) unsigned | NO | If transaction routing is enabled, the version number increments when the transaction state changes after executing a statement. If the transaction state does not change, the version number remains unchanged.
Note
|
| FLT_TRACE_ID | varchar(1024) | NO | The trace ID for full-link tracing of this record. If this field is empty, it indicates that the record is not monitored by full-link tracing. This field is a UUID, which is different from Trace. The format is similar to: 000600d6-a5de-038c-6c80-df07e4e79149
NoteThis column is available starting with V4.2.1. |
| PL_TRACE_ID | varchar(128) | NO | The trace ID of the outer PL for the current SQL statement. If there is no outer PL, this value is NULL.
NoteThis column is available starting with V4.2.2. |
| PLSQL_EXEC_TIME | bigint(20) | NO | The time spent executing PL statements, excluding SQL execution time, in microseconds.
NoteThis column is available starting with V4.2.2. |
| FORMAT_SQL_ID | varchar(32) | NO | The MD5 value generated by the Format SQL text for this record.
NoteThis column is available starting with V4.2.3. |
| NETWORK_WAIT_TIME | bigint(20) unsigned | YES | The total time of all network-related events, in microseconds.
NoteThis column is available starting with V4.2.3. |
| STMT_TYPE | varchar(128) | YES | The DML type is returned as needed:
NoteThis column is available starting with V4.2.3. |
| TOTAL_MEMSTORE_READ_ROW_COUNT | bigint(20) | NO | The total number of rows read from the MemStore during the entire operation. (This variable is displayed only in the thread that shows the query_text.)
NoteThis column is available starting with V4.2.3. |
| TOTAL_SSSTORE_READ_ROW_COUNT | bigint(20) | NO | The total number of rows read from the SSSTORE during the entire process. This variable is displayed only in threads that show query_text.
NoteThis column is available starting with V4.2.3. |
| PROXY_USER | varchar(128) | NO |
NoteThis column is available starting with V4.2.3. |
| SEQ_NUM | bigint(20) | NUMBER(38) | The sequence number of the statement in the transaction.
NoteThis column is available starting with V4.2.5, and the default value is NULL. |
| PLSQL_COMPILE_TIME | bigint(20) | NUMBER(38) | The PL compilation time.
NoteThis column is available starting with V4.2.5 BP2, and the default value is NULL. |
| USER_CLIENT_PORT | bigint(20) | NUMBER(38) | The client port number.
NoteThis column is available starting with V4.2.5 BP2. |
| TRANS_STATUS | varchar(256) | VARCHAR2(256) | Displays whether a transaction is explicitly started, implicitly started, or not started.
NoteThis column is available starting with V4.2.5 BP2. |
Sample query
Query the statistics of each SQL request on the current OBServer node, such as the source and execution status.
obclient [oceanbase]> SELECT * FROM oceanbase.V$OB_SQL_AUDIT LIMIT 1\G
The query result is as follows:
*************************** 1. row ***************************
SVR_IP: 172.xx.xx.xx
SVR_PORT: 2882
REQUEST_ID: 350000
SQL_EXEC_ID: 1074897
TRACE_ID: YB4XXXXXXXXX-000XXXXXXXXXXXX-0-0
SID: 3221603043
CLIENT_IP: 0.0.0.0
CLIENT_PORT: 0
TENANT_ID: 1
TENANT_NAME: sys
EFFECTIVE_TENANT_ID: 1
USER_ID: 200001
USER_NAME: root
USER_GROUP: 0
USER_CLIENT_IP: 0.0.0.0
DB_ID: 201001
DB_NAME: oceanbase
SQL_ID: 6F3109B2EDC153980E1722318E4F6240
QUERY_SQL: SELECT value FROM __all_zone where zone='zone1' and name='status'
PLAN_ID: 1041
AFFECTED_ROWS: 0
RETURN_ROWS: 1
PARTITION_CNT: 1
RET_CODE: 0
QC_ID: 0
DFO_ID: 0
SQC_ID: 0
WORKER_ID: 0
EVENT:
P1TEXT:
P1: 0
P2TEXT:
P2: 0
P3TEXT:
P3: 0
LEVEL: 0
WAIT_CLASS_ID: 100
WAIT_CLASS#: 0
WAIT_CLASS: OTHER
STATE: MAX_WAIT TIME ZERO
WAIT_TIME_MICRO: 0
TOTAL_WAIT_TIME_MICRO: 0
TOTAL_WAITS: 0
RPC_COUNT: 0
PLAN_TYPE: 1
IS_INNER_SQL: 1
IS_EXECUTOR_RPC: 0
IS_HIT_PLAN: 1
REQUEST_TIME: 1722834750062616
ELAPSED_TIME: 76
NET_TIME: 0
NET_WAIT_TIME: 0
QUEUE_TIME: 0
DECODE_TIME: 0
GET_PLAN_TIME: 40
EXECUTE_TIME: 36
APPLICATION_WAIT_TIME: 0
CONCURRENCY_WAIT_TIME: 0
USER_IO_WAIT_TIME: 0
SCHEDULE_TIME: 0
ROW_CACHE_HIT: 0
BLOOM_FILTER_CACHE_HIT: 0
BLOCK_CACHE_HIT: 0
DISK_READS: 0
RETRY_CNT: 0
TABLE_SCAN: 0
CONSISTENCY_LEVEL: 3
MEMSTORE_READ_ROW_COUNT: 0
SSSTORE_READ_ROW_COUNT: 0
DATA_BLOCK_READ_CNT: 0
DATA_BLOCK_CACHE_HIT: 0
INDEX_BLOCK_READ_CNT: 0
INDEX_BLOCK_CACHE_HIT: 0
BLOCKSCAN_BLOCK_CNT: 0
BLOCKSCAN_ROW_CNT: 0
PUSHDOWN_STORAGE_FILTER_ROW_CNT: 0
REQUEST_MEMORY_USED: 65536
EXPECTED_WORKER_COUNT: 0
USED_WORKER_COUNT: 0
SCHED_INFO: NULL
FUSE_ROW_CACHE_HIT: 0
PS_CLIENT_STMT_ID: -1
PS_INNER_STMT_ID: -1
TX_ID: 0
SNAPSHOT_VERSION: 1722834749960817000
REQUEST_TYPE: 1
IS_BATCHED_MULTI_STMT: 0
OB_TRACE_INFO: NULL
PLAN_HASH: 4393714422578885891
LOCK_FOR_READ_TIME: 0
PARAMS_VALUE:
RULE_NAME:
PARTITION_HIT: 1
TX_INTERNAL_ROUTING: 0
TX_STATE_VERSION: 0
FLT_TRACE_ID:
PL_TRACE_ID: NULL
PLSQL_EXEC_TIME: 0
FORMAT_SQL_ID:
NETWORK_WAIT_TIME: 0
STMT_TYPE: SELECT
TOTAL_MEMSTORE_READ_ROW_COUNT: 0
TOTAL_SSSTORE_READ_ROW_COUNT: 0
PROXY_USER:
1 row in set