Note
This view is available starting with V4.0.0.
Purpose
The GV$OB_SQL_AUDIT view displays statistics such as the source and execution status of every SQL request on all OBServer nodes. This view is tenant-specific. Except for the sys tenant, other tenants cannot perform cross-tenant queries.
Columns
| Column | Type | Nullable | Description |
|---|---|---|---|
| SVR_IP | VARCHAR2(46) | NO | IP address |
| SVR_PORT | NUMBER(38) | NO | Port number |
| REQUEST_ID | NUMBER(38) | NO | Request ID |
| SQL_EXEC_ID | NUMBER(38) | NO | Execution ID |
| 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 | 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 | Tenant ID. |
| 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) | YES | 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 | Database ID. |
| DB_NAME | VARCHAR2(128) | NO | Database name. |
| 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 | Execution plan ID. |
| 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 execution result return code: |
| QC_ID | NUMBER(38) | NO | The scheduler ID in parallel execution scenarios. |
| DFO_ID | NUMBER(38) | NO | The ID of the current subplan 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 scenarios. |
| EVENT | VARCHAR2(64) | YES | The name of the longest waiting event. |
| P1TEXT | VARCHAR2(64) | YES | Parameter 1 of the waiting event. |
| P1 | NUMBER(38) | YES | The value of parameter 1 of the waiting event. |
| P2TEXT | VARCHAR2(64) | YES | Parameter 2 of the waiting event. |
| P2 | NUMBER(38) | YES | The value of parameter 2 of the waiting event. |
| P3TEXT | VARCHAR2(64) | YES | Parameter 3 of the waiting event. |
| P3 | NUMBER(38) | YES | The value of parameter 3 of the waiting event. |
| LEVEL | NUMBER(38) | YES | The level of the waiting event. |
| WAIT_CLASS_ID | NUMBER(38) | YES | The class ID to which the waiting event belongs. |
| WAIT_CLASS# | NUMBER(38) | YES | The index of the class to which the waiting event belongs. |
| WAIT_CLASS | VARCHAR2(64) | YES | The name of the class to which the waiting event belongs. |
| STATE | VARCHAR2(19) | YES | The state of the waiting event. |
| WAIT_TIME_MICRO | NUMBER(38) | YES | The time waited for the waiting event, in microseconds. |
| TOTAL_WAIT_TIME_MICRO | NUMBER(38) | YES | The total time waited for all events in the execution process, in microseconds. |
| TOTAL_WAITS | NUMBER(38) | YES | The number of total waits in the execution process. |
| RPC_COUNT | NUMBER(38) | YES | The number of sent RPCs. |
| 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 is hit. |
| REQUEST_TIME | NUMBER(38) | NO | The start execution time point, 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 an 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 time the request waits in the queue, in microseconds. |
| DECODE_TIME | NUMBER(38) | NO | The time after the request is dequeued for decoding, in microseconds. |
| GET_PLAN_TIME | NUMBER(38) | NO | The time from the start of processing to obtaining the plan, in microseconds. |
| EXECUTE_TIME | NUMBER(38) | NO | The time consumed for plan execution, in microseconds. |
| APPLICATION_WAIT_TIME | NUMBER(38) | YES | The total time for all application events, in microseconds. |
| CONCURRENCY_WAIT_TIME | NUMBER(38) | YES | The total time for all concurrency events, in microseconds. |
| USER_IO_WAIT_TIME | NUMBER(38) | YES | The total time for all user_io events, in microseconds. |
| SCHEDULE_TIME | NUMBER(38) | YES | The time for all schedule events, in microseconds. |
| ROW_CACHE_HIT | NUMBER(38) | YES | The number of row cache hits. |
| BLOOM_FILTER_CACHE_HIT | NUMBER(38) | YES | The number of Bloom Filter cache hits. |
| BLOCK_CACHE_HIT | NUMBER(38) | YES | The number of block cache hits. |
| DISK_READS | NUMBER(38) | YES | 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. The value can be one of the following:
|
| MEMSTORE_READ_ROW_COUNT | NUMBER(38) | YES | The number of rows read from MemStore. |
| SSSTORE_READ_ROW_COUNT | NUMBER(38) | YES | The number of rows read from Ssstore. |
| DATA_BLOCK_READ_CNT | bigint(20) | YES | The number of data microblocks accessed. |
| DATA_BLOCK_CACHE_HIT | bigint(20) | YES | The number of data microblock cache hits. |
| INDEX_BLOCK_READ_CNT | bigint(20) | YES | The number of intermediate-layer microblocks accessed. |
| INDEX_BLOCK_CACHE_HIT | bigint(20) | YES | The number of intermediate-layer microblock cache hits. |
| BLOCKSCAN_BLOCK_CNT | bigint(20) | YES | The number of data microblocks scanned on one side. |
| BLOCKSCAN_ROW_CNT | bigint(20) | YES | The number of data rows scanned on one side. |
| PUSHDOWN_STORAGE_FILTER_ROW_CNT | bigint(20) | YES | The number of rows after the storage filter is pushed down. |
| REQUEST_MEMORY_USED | NUMBER(38) | NO | The memory consumed by the request, in bytes. |
| EXPECT_WORKER_COUNT | NUMBER(38) | NO | The number of worker threads expected for the request. |
| USED_WORKER_COUNT | NUMBER(38) | NO | The number of worker threads actually used for the request. |
| SCHED_INFO | VARCHAR2(16384) | YES | The scheduling information of the request. |
| PS_CLIENT_STMT_ID | NUMBER(38) | NO | This field records the client Prepare ID corresponding to the request:
|
| PS_INNER_STMT_ID | NUMBER(38) | NO | This field records the internal (database internal) Prepare ID corresponding to the request:
|
| TX_ID | bigint(20) | NO | The transaction ID corresponding to the request. |
| SNAPSHOT_VERSION | bigint(20) | NO | The read snapshot version used by the SQL statement. |
| REQUEST_TYPE | NUMBER(38) | NO | The type of the request: |
| IS_BATCHED_MULTI_STMT | NUMBER(38) | NO | Indicates whether the batch multi-statement optimization is performed. |
| OB_TRACE_INFO | VARCHAR2(4096) | NO | The trace information specified by the user. |
| PLAN_HASH | NUMBER(38) | NO | The hash value of the execution plan. |
| PARAMS_VALUE | CLOB | NO | The values of the parameters bound to the PS. |
| RULE_NAME | VARCHAR2(256) | NO | Rule name
NoteThis field is introduced in V4.1.0. |
| TX_INTERNAL_ROUTING | NUMBER | NO | Indicates whether the SQL statement is routed internally:
NoteThis field is introduced in V4.1.0. |
| TX_STATE_VERSION | NUMBER(38) | NO | The transaction state version of the SQL statement
NoteThis field is introduced in V4.1.0. |
| FLT_TRACE_ID | VARCHAR2(1024) | NO | The end-to-end trace ID of the record. If this field is empty, the record is not monitored by end-to-end tracing. This field is a UUID, which is different from a trace. Its format is similar to: 000600d6-a5de-038c-6c80-df07e4e79149
NoteThis field is introduced in V4.2.1. |
| PL_TRACE_ID | VARCHAR2(128) | NO | The trace ID of the outer PL statement (NULL if no outer PL statement exists)
Note
|
| PLSQL_EXEC_TIME | NUMBER(38) | NO | The time consumed for PL execution (excluding SQL execution time), in microseconds.
Note
|
| FORMAT_SQL_ID | VARCHAR2(32) | NO | The MD5 value generated by formatting the SQL text of the record.
Note
|
| STMT_TYPE | VARCHAR2(128) | YES | The DML type is returned as needed:
Note
|
| TOTAL_MEMSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The total number of rows read from MemStore during the entire operation (this variable is displayed only in the thread that displays query_text).
Note
|
| TOTAL_SSSTORE_READ_ROW_COUNT | NUMBER(38) | NO | The total number of rows read from SSSTORE during the entire operation (this variable is displayed only in the thread that displays query_text).
Note
|
| PROXY_USER | VARCHAR2(128) | NO |
Note
|
| SEQ_NUM | NUMBER(38) | NO | The statement sequence number in the transaction.
Note
|
| USER_CLIENT_PORT | bigint(20) | NO | The client port number.
NoteThis field is introduced in V4.3.5 BP4 and is NULL by default. |
| TRANS_STATUS | varchar(256) | NO | The status of whether the transaction is enabled.
NoteThis field is introduced in V4.3.5 BP4 and is NULL by default. |
| NETWORK_WAIT_TIME | NUMBER(38) | NO | The total time for all network events, in microseconds.
Note
|
| PLSQL_COMPILE_TIME | NUMBER(38) | NO | The PL compilation time.
Note
|
| INSERT_DUPLICATE_ROW_COUNT | NUMBER(38) | YES | The number of duplicate rows during insertup or replace into operations.
Note |
Query examples
Query the statistics of each SQL request, such as the source and execution status, on all OBServer nodes.
obclient [SYS]> SELECT * FROM SYS.GV$OB_SQL_AUDIT WHERE ROWNUM <= 1\G
The query result is as follows:
*************************** 1. row ***************************
SVR_IP: 172.30.xxx.xxx
SVR_PORT: 2882
REQUEST_ID: 2990386
SQL_EXEC_ID: 31896008
TRACE_ID: YB42AC1E87EA-00063DDBF14821DA-0-0
SID: 3221683954
CLIENT_IP: 0.0.0.0
CLIENT_PORT: 0
TENANT_ID: 1004
EFFECTIVE_TENANT_ID: 1004
TENANT_NAME: oracle001
USER_ID: 200001
USER_NAME: SYS
USER_GROUP: 0
USER_CLIENT_IP: 0.0.0.0
DB_ID: 201001
DB_NAME: oceanbase
SQL_ID: 2EAAA3C495632AB97F13659E429FC9CD
QUERY_SQL: NULL
PLAN_ID: 163
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: NULL
P1TEXT: NULL
P1: 0
P2TEXT: NULL
P2: 0
P3TEXT: NULL
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: 1757063507754411
ELAPSED_TIME: 181
NET_TIME: 0
NET_WAIT_TIME: 0
QUEUE_TIME: 0
DECODE_TIME: 0
GET_PLAN_TIME: 116
EXECUTE_TIME: 65
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: 2226688
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: 1757063507426217000
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: 85A53C335E5CDD6B53D59D654E7B1C2B
STMT_TYPE: SELECT
TOTAL_MEMSTORE_READ_ROW_COUNT: 0
TOTAL_SSSTORE_READ_ROW_COUNT: 0
PROXY_USER: NULL
SEQ_NUM: 1757063507689566
NETWORK_WAIT_TIME: 0
PLSQL_COMPILE_TIME: 0
INSERT_DUPLICATE_ROW_COUNT: 0
CCL_RULE_ID: 0
CCL_MATCH_TIME: 0
USER_CLIENT_PORT: 0
TRANS_STATUS: Transaction not opened
1 row in set (0.011 sec)