Note
This view is available starting with V4.0.0.
Purpose
The V$OB_SQL_AUDIT view displays the statistics of each SQL request on the current OBServer node, including the source and execution status. This view is tenant-separated. Only the system tenant can query it. Other tenants cannot query it across tenants.
Columns
| Column | Type | Nullable? | Description |
|---|---|---|---|
| SVR_IP | VARCHAR2(46) | NO | The IP address. |
| SVR_PORT | NUMBER(38) | NO | The port number. |
| REQUEST_ID | NUMBER(38) | NO | The ID of the request. |
| SQL_EXEC_ID | NUMBER(38) | NO | The ID of the execution. |
| TRACE_ID | VARCHAR2(128) | NO | The trace_id of the statement. |
| SID | NUMBER(38) | NO | For V4.3.x:
|
| CLIENT_IP | VARCHAR2(46) | NO | |
| CLIENT_PORT | NUMBER(38) | NO | The port number of the client that sends the request. |
| TENANT_ID | NUMBER(38) | NO | The ID of the tenant that sends the request. |
| EFFECTIVE_TENANT_ID | NUMBER(38) | NO | The ID of the tenant. |
| TENANT_NAME | VARCHAR2(64) | NO | The name of the tenant that sends the request. |
| USER_ID | NUMBER(38) | NO | The ID of the user that sends the request. |
| USER_NAME | VARCHAR2(64) | NO | The name of the user that sends the request. |
| USER_GROUP | NUMBER(38) | NO | The ID of the resource group to which the user belongs. |
| USER_CLIENT_IP | VARCHAR2(32) | NO | The IP address of the client that sends the request. |
| DB_ID | NUMBER(38) | NO | The ID of the database. |
| DB_NAME | VARCHAR2(128) | NO | The name of the database. |
| SQL_ID | VARCHAR2(32) | NO | The ID of the SQL statement.
Note
|
| QUERY_SQL | CLOB | NO | The actual SQL statement. |
| PLAN_ID | NUMBER(38) | NO | The ID of the execution plan. |
| AFFECTED_ROWS | NUMBER(38) | NO | The number of affected rows. |
| RETURN_ROWS | NUMBER(38) | NO | The number of returned rows. |
| PARTITION_CNT | NUMBER(38) | NO | The number of partitions involved in the request. |
| RET_CODE | NUMBER(38) | NO | The return code of the execution result: |
| QC_ID | NUMBER(38) | NO | The ID of the scheduler in parallel execution scenarios. |
| DFO_ID | NUMBER(38) | NO | The ID of the subplan being executed in parallel execution scenarios. |
| SQC_ID | NUMBER(38) | NO | The ID of the local coordinator in parallel execution scenarios. |
| WORKER_ID | NUMBER(38) | NO | The ID of the worker thread in parallel execution. |
| EVENT | VARCHAR2(64) | NO | The name of the longest waiting event. |
| P1TEXT | VARCHAR2(64) | NO | The name of the first parameter of the waiting event. |
| P1 | NUMBER(38) | NO | The value of the first parameter of the waiting event. |
| P2TEXT | VARCHAR2(64) | NO | The name of the second parameter of the waiting event. |
| P2 | NUMBER(38) | NO | The value of the second parameter of the waiting event. |
| P3TEXT | VARCHAR2(64) | NO | The name of the third parameter of the waiting event. |
| P3 | NUMBER(38) | NO | The value of the third parameter of the waiting event. |
| LEVEL | NUMBER(38) | NO | The level of the waiting event. |
| WAIT_CLASS_ID | NUMBER(38) | NO | The ID of the class to which the waiting event belongs. |
| WAIT_CLASS# | NUMBER(38) | NO | The index of the class to which the waiting event belongs. |
| WAIT_CLASS | VARCHAR2(64) | NO | The name of the class to which the waiting event belongs. |
| STATE | VARCHAR2(19) | NO | The state of the waiting event. |
| WAIT_TIME_MICRO | NUMBER(38) | NO | The time that the waiting event waited, in microseconds. |
| TOTAL_WAIT_TIME_MICRO | NUMBER(38) | NO | The total time of all waits during the execution, in microseconds. |
| TOTAL_WAITS | NUMBER(38) | NO | The total number of waits during the execution. |
| RPC_COUNT | NUMBER(38) | NO | The number of RPCs sent. |
| PLAN_TYPE | NUMBER(38) | NO | The execution plan type: |
| IS_INNER_SQL | NUMBER(38) | NO | Indicates whether the request is an internal SQL request. |
| IS_EXECUTOR_RPC | NUMBER(38) | NO | Indicates whether the current request is an RPC request. |
| IS_HIT_PLAN | NUMBER(38) | NO | Indicates whether the plan cache was hit. |
| REQUEST_TIME | NUMBER(38) | NO | The start time of the execution, in microseconds. |
| ELAPSED_TIME | NUMBER(38) | NO | The total time consumed from receiving the request to the end of the execution, in microseconds. |
| NET_TIME | NUMBER(38) | NO | The time from sending the RPC to receiving the request, in microseconds. |
| NET_WAIT_TIME | NUMBER(38) | NO | The time from receiving the request to entering the queue, in microseconds. |
| QUEUE_TIME | NUMBER(38) | NO | The waiting time of the request in the queue, in microseconds. |
| DECODE_TIME | NUMBER(38) | NO | The time for decoding after the request is dequeued, in microseconds. |
| GET_PLAN_TIME | NUMBER(38) | NO | The time from the start of the process to obtaining the plan, in microseconds. |
| EXECUTE_TIME | NUMBER(38) | NO | The time consumed for executing the plan, in microseconds. |
| APPLICATION_WAIT_TIME | NUMBER(38) | NO | The total time of all Application events, in microseconds. |
| CONCURRENCY_WAIT_TIME | NUMBER(38) | NO | The total time of all Concurrency events, in microseconds. |
| USER_IO_WAIT_TIME | NUMBER(38) | NO | The total time of all user_io events, in microseconds. |
| SCHEDULE_TIME | NUMBER(38) | NO | The time of all Schedule events, in microseconds. |
| ROW_CACHE_HIT | NUMBER(38) | NO | The number of row cache hits. |
| BLOOM_FILTER_CACHE_HIT | NUMBER(38) | NO | The number of Bloom filter cache hits. |
| BLOCK_CACHE_HIT | NUMBER(38) | NO | The number of block cache hits. |
| DISK_READS | NUMBER(38) | NO | The number of physical reads. |
| RETRY_CNT | NUMBER(38) | NO | The number of retries. |
| TABLE_SCAN | NUMBER(38) | NO | Indicates whether the request contains a full table scan. |
| CONSISTENCY_LEVEL | NUMBER(38) | NO | The consistency level. Valid values:
|
| MEMSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The number of rows read from the MemStore. |
| SSSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The number of rows read from the SsStore. |
| REQUEST_MEMORY_USED | NUMBER(38) | NO | The memory consumed by the request. |
| EXPECT_WORKER_COUNT | NUMBER(38) | NO | The expected number of worker threads for the request. |
| USED_WORKER_COUNT | NUMBER(38) | NO | The actual number of worker threads used for the request. |
| SCHED_INFO | VARCHAR2(16384) | NO | The scheduling information of the request. |
| PS_STMT_ID | NUMBER(38) | NO | The 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, and the value is the unique identifier returned by the PS protocol for the statement. |
| TRANSACTION_HASH | NUMBER(38) | NO | The hash value of the transaction corresponding to the request. |
| REQUEST_TYPE | NUMBER(38) | NO | The type of the request: |
| IS_BATCHED_MULTI_STMT | NUMBER(38) | NO | Indicates whether the Batch Multi Stmt optimization is performed. |
| OB_TRACE_INFO | VARCHAR2(4096) | NO | The trace information set by the user. |
| PLAN_HASH | NUMBER(38) | NO | The hash value of the execution plan. |
| PARAMS_VALUE | CLOB | NO | The parameter values bound by the PS protocol. |
| RULE_NAME | VARCHAR2(256) | NO | The name of the rule.
NoteThis column is available starting with V4.1.0. |
| TX_INTERNAL_ROUTING | NUMBER | NO | Indicates whether the SQL statement is internally routed:
NoteThis column is available starting with V4.1.0. |
| TX_STATE_VERSION | NUMBER(38) | NO | The transaction state version of the SQL statement.
NoteThis column is available starting with V4.1.0. |
| FLT_TRACE_ID | VARCHAR2(1024) | NO | The trace_id of the full chain trace for the record. If this field is empty, it indicates that the record is not monitored by the full chain trace. This field is a UUID, which is different from the trace. Its format is similar to: 000600d6-a5de-038c-6c80-df07e4e79149
NoteThis column is available starting with V4.2.1. |
| PL_TRACE_ID | VARCHAR2(128) | NO | The Trace ID of the outer PL of the current SQL statement. If there is no outer PL, this value is NULL.
Note
|
| PLSQL_EXEC_TIME | NUMBER(38) | NO | The time consumed by the PL execution (excluding the SQL execution time), in microseconds.
Note
|
| FORMAT_SQL_ID | VARCHAR2(32) | NO | The MD5 value generated by the Format SQL text for the record.
Note
|
| STMT_TYPE | VARCHAR2(128) | YES | DML types are returned as follows:
Note
|
| TOTAL_MEMSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The total number of rows read from the MemStore during the entire process. This variable is displayed only in the thread that shows query_text.
Note
|
| TOTAL_SSSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The total number of rows read from the SSSTORE during the entire process. This variable is displayed only in the thread that shows query_text.
Note
|
| PROXY_USER | VARCHAR2(128) | NO |
Note
|
| SEQ_NUM | NUMBER(38) | NO | The sequence number of the statement in the transaction.
Note
|
| NETWORK_WAIT_TIME | NUMBER(38) | NO | The total time of all Network events, in microseconds.
Note
|
| PLSQL_COMPILE_TIME | NUMBER(38) | NO | The time taken to compile the PL procedure.
Note
|
| INSERT_DUPLICATE_ROW_COUNT | NUMBER(38) | NO | The number of duplicate rows when you execute the insertup or replace into statement.
Note
|
Sample query
Query the statistics such as the source and execution status of each SQL request on 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