Note
Introduced in version 4.0.0.
Purpose
The V$OB_SQL_AUDIT view displays statistics such as the source and execution status of each SQL request on the current OBServer node. The view is tenant-scoped. Tenants other than the system tenant cannot query data across tenants.
Columns
| Column | Type | Nullable? | Description |
|---|---|---|---|
| SVR_IP | VARCHAR2(46) | NO | IP address. |
| SVR_PORT | NUMBER(38) | NO | Port number. |
| REQUEST_ID | NUMBER(38) | NO | ID of the request. |
| SQL_EXEC_ID | NUMBER(38) | NO | ID of the current execution. |
| TRACE_ID | VARCHAR2(128) | NO | Trace ID of the statement. |
| SID | NUMBER(38) | NO | For V4.3.x:
|
| CLIENT_IP | VARCHAR2(46) | NO | |
| CLIENT_PORT | NUMBER(38) | NO | Port number of the client that sends the request. |
| TENANT_ID | NUMBER(38) | NO | ID of the tenant that sends the request. |
| EFFECTIVE_TENANT_ID | NUMBER(38) | NO | ID of the tenant. |
| TENANT_NAME | VARCHAR2(64) | NO | Name of the tenant that sends the request. |
| USER_ID | NUMBER(38) | NO | ID of the user that sends the request. |
| USER_NAME | VARCHAR2(64) | NO | Name of the user that sends the request. |
| USER_GROUP | NUMBER(38) | NO | ID of the resource group to which the user belongs. |
| USER_CLIENT_IP | VARCHAR2(32) | NO | IP address of the client that sends the request. |
| DB_ID | NUMBER(38) | NO | ID of the database. |
| DB_NAME | VARCHAR2(128) | NO | Name of the database. |
| SQL_ID | VARCHAR2(32) | NO | ID of the SQL statement.
Note
|
| QUERY_SQL | CLOB | NO | Actual SQL statement. |
| PLAN_ID | NUMBER(38) | NO | ID of the execution plan. |
| AFFECTED_ROWS | NUMBER(38) | NO | Number of affected rows. |
| RETURN_ROWS | NUMBER(38) | NO | Number of returned rows. |
| PARTITION_CNT | NUMBER(38) | NO | Number of partitions involved in the request. |
| RET_CODE | NUMBER(38) | NO | Return code of the execution result: |
| QC_ID | NUMBER(38) | NO | ID of the scheduler in parallel execution scenarios. |
| DFO_ID | NUMBER(38) | NO | ID of the current subplan in parallel execution scenarios. |
| SQC_ID | NUMBER(38) | NO | ID of the local coordinator in parallel execution scenarios. |
| WORKER_ID | NUMBER(38) | NO | ID of the worker thread in parallel execution scenarios. |
| EVENT | VARCHAR2(64) | NO | Name of the longest waiting event. |
| P1TEXT | VARCHAR2(64) | NO | Parameter 1 of the waiting event. |
| P1 | NUMBER(38) | NO | Value of parameter 1 of the waiting event. |
| P2TEXT | VARCHAR2(64) | NO | Parameter 2 of the waiting event. |
| P2 | NUMBER(38) | NO | Value of parameter 2 of the waiting event. |
| P3TEXT | VARCHAR2(64) | NO | Parameter 3 of the waiting event. |
| P3 | NUMBER(38) | NO | Value of parameter 3 of the waiting event. |
| LEVEL | NUMBER(38) | NO | Level of the waiting event. |
| WAIT_CLASS_ID | NUMBER(38) | NO | Class ID of the waiting event. |
| WAIT_CLASS# | NUMBER(38) | NO | Index of the waiting event in its class. |
| WAIT_CLASS | VARCHAR2(64) | NO | Name of the class to which the waiting event belongs. |
| STATE | VARCHAR2(19) | NO | Status of the waiting event. |
| WAIT_TIME_MICRO | NUMBER(38) | NO | Duration of the waiting event in microseconds. |
| TOTAL_WAIT_TIME_MICRO | NUMBER(38) | NO | Total duration of all waits in microseconds. |
| TOTAL_WAITS | NUMBER(38) | NO | Total number of waits. |
| RPC_COUNT | NUMBER(38) | NO | Number of RPCs sent. |
| PLAN_TYPE | NUMBER(38) | NO | Type of the execution plan: |
| IS_INNER_SQL | NUMBER(38) | NO | Whether the request is an internal SQL request. |
| IS_EXECUTOR_RPC | NUMBER(38) | NO | Whether the current request is an RPC request. |
| IS_HIT_PLAN | NUMBER(38) | NO | Whether the request hits the plan cache. |
| REQUEST_TIME | NUMBER(38) | NO | Start time of the execution in microseconds. |
| ELAPSED_TIME | NUMBER(38) | NO | Total time consumed from receiving the request to the end of execution in microseconds. |
| NET_TIME | NUMBER(38) | NO | Duration of sending an RPC to receiving the request in microseconds. |
| NET_WAIT_TIME | NUMBER(38) | NO | Duration of receiving the request to entering the queue in microseconds. |
| QUEUE_TIME | NUMBER(38) | NO | Duration of waiting in the queue in microseconds. |
| DECODE_TIME | NUMBER(38) | NO | Duration of decoding after leaving the queue in microseconds. |
| GET_PLAN_TIME | NUMBER(38) | NO | Duration from the start of processing to obtaining the execution plan in microseconds. |
| EXECUTE_TIME | NUMBER(38) | NO | Duration of executing the plan in microseconds. |
| APPLICATION_WAIT_TIME | NUMBER(38) | NO | Total duration of all application events in microseconds. |
| CONCURRENCY_WAIT_TIME | NUMBER(38) | NO | Total duration of all concurrency events in microseconds. |
| USER_IO_WAIT_TIME | NUMBER(38) | NO | Total duration of all user_io events in microseconds. |
| SCHEDULE_TIME | NUMBER(38) | NO | Total duration of all schedule events in microseconds. |
| ROW_CACHE_HIT | NUMBER(38) | NO | Number of cache hits in the row cache. |
| BLOOM_FILTER_CACHE_HIT | NUMBER(38) | NO | Number of cache hits in the Bloom filter cache. |
| BLOCK_CACHE_HIT | NUMBER(38) | NO | Number of cache hits in the block cache. |
| DISK_READS | NUMBER(38) | NO | Number of physical reads. |
| RETRY_CNT | NUMBER(38) | NO | Number of retries. |
| TABLE_SCAN | NUMBER(38) | NO | Whether the request contains a full table scan. |
| CONSISTENCY_LEVEL | NUMBER(38) | NO | Consistency level. The value can be one of the following:
|
| MEMSTORE_READ_ROW_COUNT | NUMBER(38) | NO | Number of rows read from the memstore. |
| SSSTORE_READ_ROW_COUNT | NUMBER(38) | NO | Number of rows read from the ssstore. |
| REQUEST_MEMORY_USED | NUMBER(38) | NO | Memory consumed by the request. |
| EXPECT_WORKER_COUNT | NUMBER(38) | NO | Number of expected worker threads. |
| USED_WORKER_COUNT | NUMBER(38) | NO | Number of worker threads actually used. |
| SCHED_INFO | VARCHAR2(16384) | NO | Scheduling information of the request. |
| PS_STMT_ID | NUMBER(38) | NO | Prepare ID corresponding to the request: -1: indicates that the SQL statement does not use the PS protocol.-1: indicates that the SQL statement uses the PS protocol, which is the unique identifier returned by the PS protocol for the statement. |
| TRANSACTION_HASH | NUMBER(38) | NO | Hash value of the transaction corresponding to the request. |
| REQUEST_TYPE | NUMBER(38) | NO | Type of the request: |
| IS_BATCHED_MULTI_STMT | NUMBER(38) | NO | Whether to optimize batch multi stmt. |
| OB_TRACE_INFO | VARCHAR2(4096) | NO | Trace information set by the user. |
| PLAN_HASH | NUMBER(38) | NO | Hash value of the execution plan. |
| PARAMS_VALUE | CLOB | NO | Values of the PS-bound parameters. |
| RULE_NAME | VARCHAR2(256) | NO | Rule name
NoteThis field was introduced in V4.1.0. |
| TX_INTERNAL_ROUTING | NUMBER | NO | Indicates whether the SQL statement is routed internally:
NoteThis field was introduced in V4.1.0. |
| TX_STATE_VERSION | NUMBER(38) | NO | Transaction status version of the SQL statement
NoteThis field was introduced in V4.1.0. |
| FLT_TRACE_ID | VARCHAR2(1024) | NO | Trace ID of the full-link trace of this record. If this field is empty, it indicates that the full-link trace is not monitored. This field is a UUID, which is different from the trace ID. Its value is in the format of 000600d6-a5de-038c-6c80-df07e4e79149.
NoteThis field was introduced in V4.2.1. |
| PL_TRACE_ID | VARCHAR2(128) | NO | Trace ID of the outer PL of the current SQL statement (NULL if there is no outer PL).
Note
|
| PLSQL_EXEC_TIME | NUMBER(38) | NO | Duration of PL execution (excluding SQL execution time) in microseconds.
Note
|
| TOTAL_MEMSTORE_READ_ROW_COUNT | NUMBER(38) | NO | Total number of rows read from the memstore during the entire process (displayed only in the thread that displays the query text).
Note
|
| TOTAL_SSSTORE_READ_ROW_COUNT | NUMBER(38) | NO | Total number of rows read from the ssstore during the entire process (displayed only in the thread that displays the query text).
Note
|
| PROXY_USER | VARCHAR2(128) | NO |
Note
|
| SEQ_NUM | NUMBER(38) | NO | Statement sequence number in the transaction
Note
|
| NETWORK_WAIT_TIME | NUMBER(38) | NO | Total duration of all network events in microseconds
Note
|
Sample query
Query the statistics of each SQL request, including the source and execution status, of the current OBServer node.
obclient [SYS]> SELECT * FROM SYS.V$OB_SQL_AUDIT WHERE ROWNUM <= 1\G
The query result is as follows:
*************************** 1. row ***************************
SVR_IP: xx.xx.xx.xx
SVR_PORT: 2882
REQUEST_ID: 7576831
SQL_EXEC_ID: 94317229
TRACE_ID: YB42AC1E87E9-000XXXXXXXXXX1-0-0
SID: 3221582368
CLIENT_IP: 0.0.0.0
CLIENT_PORT: 0
TENANT_ID: 1004
EFFECTIVE_TENANT_ID: 1004
TENANT_NAME: sys
USER_ID: 200001
USER_NAME: root
USER_GROUP: 0
USER_CLIENT_IP: 0.0.0.0
DB_ID: 201001
DB_NAME: oceanbase
SQL_ID: 2EAAA3C495632AB97F13659E429FC9CD
QUERY_SQL: select * from __all_balance_task where parent_list is null or parent_list = ''
PLAN_ID: 4728
AFFECTED_ROWS: 0
RETURN_ROWS: 0
PARTITION_CNT: 1
RET_CODE: 0
QC_ID: 0
DFO_ID: 0
SQC_ID: 0
WORKER_ID: 0
EVENT: exec inner sql wait
P1TEXT: wait inner sql class
P1: 0
P2TEXT: inner session id
P2: 4611686018500104803
P3TEXT: NULL
P3: 0
LEVEL: 0
WAIT_CLASS_ID: 100
WAIT_CLASS#: 0
WAIT_CLASS: OTHER
STATE: WAITED SHORT TIME
WAIT_TIME_MICRO: 70
TOTAL_WAIT_TIME_MICRO: 70
TOTAL_WAITS: 1
RPC_COUNT: 0
PLAN_TYPE: 1
IS_INNER_SQL: 1
IS_EXECUTOR_RPC: 0
IS_HIT_PLAN: 1
REQUEST_TIME: 1745731919396962
ELAPSED_TIME: 179
NET_TIME: 0
NET_WAIT_TIME: 0
QUEUE_TIME: 0
DECODE_TIME: 0
GET_PLAN_TIME: 108
EXECUTE_TIME: 71
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: 1
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: 2161408
EXPECTED_WORKER_COUNT: 0
USED_WORKER_COUNT: 0
SCHED_INFO: NULL
PS_CLIENT_STMT_ID: -1
PS_INNER_STMT_ID: -1
TX_ID: 0
SNAPSHOT_VERSION: 1745731919220670000
REQUEST_TYPE: 1
IS_BATCHED_MULTI_STMT: 0
OB_TRACE_INFO: NULL
PLAN_HASH: 1945082731509197303
PARAMS_VALUE: NULL
RULE_NAME: NULL
TX_INTERNAL_ROUTING: 0
TX_STATE_VERSION: 0
FLT_TRACE_ID: NULL
PL_TRACE_ID: NULL
PLSQL_EXEC_TIME: 0
FORMAT_SQL_ID: NULL
STMT_TYPE: SELECT
TOTAL_MEMSTORE_READ_ROW_COUNT: 0
TOTAL_SSSTORE_READ_ROW_COUNT: 0
PROXY_USER: NULL
SEQ_NUM: 1745731919361793
NETWORK_WAIT_TIME: 0
PLSQL_COMPILE_TIME: 0
INSERT_DUPLICATE_ROW_COUNT: 0