The DBMS_XPLAN package provides features for managing logical plans, for example, optimizing and tracing logical plans.
Overview
display_cursor
Description
OceanBase Database stores all executed query plans, including physical and logical plans, to facilitate subsequent troubleshooting. To help you interpret historical query plans, OceanBase Database provides DBMS packages for formatting plans. Unlike the plans retrieved by using the EXPLAIN statement, plans that you executed are retained in the database even if you have logged out. The database clears stored query plans only when you restart the cluster.
Syntax
-- display sql plan table`s plan
function display_cursor(plan_id integer default 0, -- default value: last plan
format varchar2 default 'TYPICAL',
svr_ip varchar2 default null, -- default value: server connected by client
svr_port integer default 0, -- default value: server connected by client
tenant_id integer default 0 -- default value: current tenant
)
return dbms_xplan_type_table;
The parameters are described as follows:
plan_id: the ID of the plan. If this parameter is not specified, the plan executed last time is used.format: the format of the plan. If this parameter is not specified, the format of the plan executed last time is used.svr_ipandsvr_port: the IP address and port number of the OBServer node where the plan is stored. By default, the IP address and port number of the OBServer node to which the session is connected are used.tenant_id: the ID of the tenant to which the plan belongs. By default, the ID of the tenant to which the session is connected is used.
Related data dictionaries
Plans are stored in the __all_virtual_sql_plan data dictionary. Each tenant contains corresponding system views gv$ob_sql_plan and v$ob_sql_plan. The gv$ob_sql_plan view displays the plans on all OBServer nodes of the current tenant. The v$ob_sql_plan view displays the plans on the current OBServer node of the current tenant.
+--------------------+---------------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+--------------------+---------------------+------+-----+---------+-------+
| tenant_id | bigint(20) | NO | PRI | NULL | |
| plan_id | bigint(20) | NO | PRI | NULL | |
| svr_ip | varchar(46) | NO | PRI | NULL | |
| svr_port | bigint(20) | NO | PRI | NULL | |
| sql_id | varchar(32) | NO | | NULL | |
| db_id | bigint(20) | NO | | NULL | |
| plan_hash | bigint(20) unsigned | NO | | NULL | |
| gmt_create | timestamp(6) | NO | | NULL | |
| operator | varchar(255) | NO | | NULL | |
| options | varchar(255) | NO | | NULL | |
| object_node | varchar(40) | NO | | NULL | |
| object_id | bigint(20) | NO | | NULL | |
| object_owner | varchar(128) | NO | | NULL | |
| object_name | varchar(128) | NO | | NULL | |
| object_alias | varchar(261) | NO | | NULL | |
| object_type | varchar(20) | NO | | NULL | |
| optimizer | varchar(4000) | NO | | NULL | |
| id | bigint(20) | NO | | NULL | |
| parent_id | bigint(20) | NO | | NULL | |
| depth | bigint(20) | NO | | NULL | |
| position | bigint(20) | NO | | NULL | |
| search_columns | bigint(20) | NO | | NULL | |
| is_last_child | bigint(20) | NO | | NULL | |
| cost | bigint(20) | NO | | NULL | |
| real_cost | bigint(20) | NO | | NULL | |
| cardinality | bigint(20) | NO | | NULL | |
| real_cardinality | bigint(20) | NO | | NULL | |
| bytes | bigint(20) | NO | | NULL | |
| rowset | bigint(20) | NO | | NULL | |
| other_tag | varchar(4000) | NO | | NULL | |
| partition_start | varchar(4000) | NO | | NULL | |
| partition_stop | varchar(4000) | NO | | NULL | |
| partition_id | bigint(20) | NO | | NULL | |
| other | varchar(4000) | NO | | NULL | |
| distribution | varchar(64) | NO | | NULL | |
| cpu_cost | bigint(20) | NO | | NULL | |
| io_cost | bigint(20) | NO | | NULL | |
| temp_space | bigint(20) | NO | | NULL | |
| access_predicates | varchar(4000) | NO | | NULL | |
| filter_predicates | varchar(4000) | NO | | NULL | |
| startup_predicates | varchar(4000) | NO | | NULL | |
| projection | varchar(4000) | NO | | NULL | |
| special_predicates | varchar(4000) | NO | | NULL | |
| time | bigint(20) | NO | | NULL | |
| qblock_name | varchar(128) | NO | | NULL | |
| remarks | varchar(4000) | NO | | NULL | |
| other_xml | varchar(4000) | NO | | NULL | |
+--------------------+---------------------+------+-----+---------+-------+
display_active_session_plan
Description
Assume that the execution of a large SQL statement has lasted for a long time and you want to know the execution information, such as the execution plan and execution process, of the statement. In this scenario, the current session is occupied by the large SQL statement, and you must establish a new connection. Then, execute the SHOW FULL PROCESSLIST statement to find the session in which the large SQL statement is executed, and execute the display_active_session_plan function based on the obtained session ID to obtain the execution details of the large SQL statement.
Syntax
-- disable real time plan
function display_active_session_plan(
session_id integer default 0,
format varchar2 default 'TYPICAL',
svr_ip varchar2 default null, -- default value: server connected by client
svr_port integer default 0 -- default value: server connected by client
)
return dbms_xplan_type_table;
session_id: the session ID of the user connection. Note that the value is not the session ID of OceanBase Database Proxy (ODP) but the session ID of the connected OBServer node.format: the format of the plan. Valid values:BASIC,TYPICAL,ALL, andADVANCED.svr_ipandsvr_port: the IP address and port number of the OBServer node where the session resides. By default, the IP address and port number of the OBServer node to which the session is connected are used.
enable_opt_trace
Description
The process of generating plans by the optimizer is complex. It takes a lot of time to collect information during troubleshooting for suboptimal plans. This feature provides an end-to-end tracing mechanism to collect at a time all information required by the optimizer to generate a plan. This helps analyze the cause of suboptimal plans. This feature collects the following trace information:
- env:
- System and session information
- User SQL statements
- Optimizer-related variables
- transformer:
- SQL statements before and after rewriting based on each rewrite rule
- Detailed reasons why each rewrite rule triggers or does not trigger rewriting: For example, rewriting is controlled by a hint, or specific conditions are not met.
- optimizer:
- Statistics used
- Base table path generation logs, including process conditions, the number of rows, cost estimation information, and skyline pruning rules and processes
- Detailed process of join order enumeration
- Allocation and optimization processes of top N operators
Syntax
DBMS_XPLAN.ENABLE_OPT_TRACE
DEFAULT_INENTIFIER constant VARCHAR2(20) := '';
DEFAULT_LEVEL constant INT := 1;
PROCEDURE enable_opt_trace(
sql_id IN VARCHAR2 DEFAULT '',
identifier IN VARCHAR2 DEFAULT DEFAULT_INENTIFIER,
level IN INT DEFAULT DEFAULT_LEVEL
);
You can use the DBMS_XPLAN.ENABLE_OPT_TRACE function to enable end-to-end tracing for the optimizer of the current session. After end-to-end tracing is enabled, the generation process of each plan in the current session is traced.
The parameters are described as follows:
sql_id: the ID of the SQL statement to be traced. For example, you can specify this parameter if you need to run PL programs in the current test and you want to trace only a specific SQL statement in PL functions. If this parameter is not specified, all SQL statements are traced.level: the level of tracing. Valid values:0: Default actions are performed.1: Memory usage and running duration of each module are recorded, in addition to level-0 tracing actions.2: The SQL statement corresponding to each rewrite query block is recorded regardless of whether the SQL statement is rewritten, in addition to level-0 and level-1 tracing actions.
Notice
levelis a database keyword and therefore must be enclosed by double quotation marks (" ") in an Oracle tenant and by grave accents (` `) in a MySQL tenant.identifier: the file name extension of the trace file, which helps you find the trace file.
DBMS_XPLAN.DISABLE_OPT_TRACE
PROCEDURE disable_opt_trace;
You can use the DBMS_XPLAN.DISABLE_OPT_TRACE function to disable end-to-end tracing for the optimizer of the current session.
DBMS_XPLAN.SET_OPT_TRACE_PARAMETER
PROCEDURE set_opt_trace_parameter(
sql_id IN VARCHAR2 DEFAULT '',
identifier IN VARCHAR2 DEFAULT DEFAULT_INENTIFIER,
level IN INT DEFAULT DEFAULT_LEVEL
);
You can use the DBMS_XPLAN.SET_OPT_TRACE_PARAMETER function to set end-to-end tracing parameters for the optimizer of the current session.
Typical diagnostics scenarios
Query executed with slow speed
Collect query execution details
Use ODP to retain the session.
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;Execute the query.
select * from t1;Use the
DBMS_XPLANpackage to display the plan executed last time.select * from table(dbms_xplan.display_cursor(format=>'all')); +--------------------------------------------------------------------------------------------------+ | COLUMN_VALUE | +--------------------------------------------------------------------------------------------------+ | ================================================================================================ | | |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)|REAL.ROWS|REAL.TIME(us)|IO TIME(us)|CPU TIME(us)| | | ------------------------------------------------------------------------------------------------ | | |0 |TABLE FULL SCAN|T1 |1 |2 |0 |0 |0 |0 | | | ================================================================================================ | | Outputs & filters: | | ------------------------------------- | | 0 - output([T1.C1]), filter(nil), rowset=256 | | access([T1.C1]), partitions(p0) | | is_index_back=false, is_global_index=false, | | range_key([T1.__pk_increment]), range(MIN ; MAX)always true | +--------------------------------------------------------------------------------------------------+
Use ODP to retain the session.
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;Execute the query.
select * from t1;Use the
DBMS_XPLANpackage with the SQL audit feature to display the plan executed last time.select dbms_xplan.display_cursor(0, 'all'); +--------------------------------------------------------------------------------------------------+ | COLUMN_VALUE | +--------------------------------------------------------------------------------------------------+ | ================================================================================================ | | |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)|REAL.ROWS|REAL.TIME(us)|IO TIME(us)|CPU TIME(us)| | | ------------------------------------------------------------------------------------------------ | | |0 |TABLE FULL SCAN|T1 |1 |2 |0 |0 |0 |0 | | | ================================================================================================ | | Outputs & filters: | | ------------------------------------- | | 0 - output([T1.C1]), filter(nil), rowset=256 | | access([T1.C1]), partitions(p0) | | is_index_back=false, is_global_index=false, | | range_key([T1.__pk_increment]), range(MIN ; MAX)always true | +--------------------------------------------------------------------------------------------------+
Query executed slowly and stalled
Collect plan execution details:
Execute a slow SQL statement over connection A.
select count(*) from table(generator(100000)) A, table(generator(10000))B;Log on to the
systenant and query the__all_virtual_processlistview for thesession_id,svr_ip, andsvr_portinformation of the session in which the slow SQL statement is executed.select id, svr_ip, svr_ip, svr_port, info from __all_virtual_processlist where info like "%select%"\G id: 3221489189 svr_ip: 11.162.218.196 svr_port: 50000 info: select count(*) from table(generator(100000)) A, table(generator(10000))BQuery details of plans in the session.
select dbms_xplan.display_active_session_plan(3221668463, 'all', '11.162.218.196', 50000); +--------------------------------------------------------------------------------------------------------------------+ | COLUMN_VALUE | +--------------------------------------------------------------------------------------------------------------------+ | ============================================================================================================== | | |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)|REAL.ROWS|REAL.TIME(us)|IO TIME(us)|CPU TIME(us)| | | -------------------------------------------------------------------------------------------------------------- | | |0 |SCALAR GROUP BY | |1 |1794 |0 |0 |0 |0 | | | |1 |└─NESTED-LOOP JOIN CARTESIAN | |39601 |1076 |0 |0 |0 |0 | | | |2 | ├─FUNCTION_TABLE |A |199 |1 |0 |0 |0 |0 | | | |3 | └─MATERIAL | |199 |80 |0 |0 |0 |0 | | | |4 | └─FUNCTION_TABLE |B |199 |1 |0 |0 |0 |0 | | | ============================================================================================================== | | Outputs & filters: | | ------------------------------------- | | 0 - output([T_FUN_COUNT(*)]), filter(nil), rowset=256 | | group(nil), agg_func([T_FUN_COUNT(*)]) | | 1 - output(nil), filter(nil), rowset=256 | | conds(nil), nl_params_(nil), use_batch=false | | 2 - output(nil), filter(nil) | | value(GENERATOR(cast(:0, BIGINT(-1, 0)))) | | 3 - output(nil), filter(nil), rowset=256 | | 4 - output(nil), filter(nil) | | value(GENERATOR(cast(:1, BIGINT(-1, 0)))) | +--------------------------------------------------------------------------------------------------------------------+
Execute a slow SQL statement over connection A.
select count(*) from table(generator(100000)) A, table(generator(10000))B;Log on to the
systenant and query the__all_virtual_processlistview for thesession_id,svr_ip, andsvr_portinformation of the session in which the slow SQL statement is executed.select id, svr_ip, svr_ip, svr_port, info from __all_virtual_processlist where info like "%select%"\G id: 3221489189 svr_ip: 11.162.218.196 svr_port: 50000 info: select count(*) from table(generator(100000)) A, table(generator(10000))BQuery details of plans in the session.
select dbms_xplan.display_active_session_plan(3221668463, 'all', '11.162.218.196', 50000); +--------------------------------------------------------------------------------------------------------------------+ | COLUMN_VALUE | +--------------------------------------------------------------------------------------------------------------------+ | ============================================================================================================== | | |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)|REAL.ROWS|REAL.TIME(us)|IO TIME(us)|CPU TIME(us)| | | -------------------------------------------------------------------------------------------------------------- | | |0 |SCALAR GROUP BY | |1 |1794 |0 |0 |0 |0 | | | |1 |└─NESTED-LOOP JOIN CARTESIAN | |39601 |1076 |0 |0 |0 |0 | | | |2 | ├─FUNCTION_TABLE |A |199 |1 |0 |0 |0 |0 | | | |3 | └─MATERIAL | |199 |80 |0 |0 |0 |0 | | | |4 | └─FUNCTION_TABLE |B |199 |1 |0 |0 |0 |0 | | | ============================================================================================================== | | Outputs & filters: | | ------------------------------------- | | 0 - output([T_FUN_COUNT(*)]), filter(nil), rowset=256 | | group(nil), agg_func([T_FUN_COUNT(*)]) | | 1 - output(nil), filter(nil), rowset=256 | | conds(nil), nl_params_(nil), use_batch=false | | 2 - output(nil), filter(nil) | | value(GENERATOR(cast(:0, BIGINT(-1, 0)))) | | 3 - output(nil), filter(nil), rowset=256 | | 4 - output(nil), filter(nil) | | value(GENERATOR(cast(:1, BIGINT(-1, 0)))) | +--------------------------------------------------------------------------------------------------------------------+
Plan generated slowly or unexpected plan generated due to insufficient memory
Collect query optimization information:
Use ODP to retain the session.
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;Enable tracing for the optimizer of the current session.
call dbms_xplan.enable_opt_trace();Specify the tracing level and the file name extension of the trace log file.
call dbms_xplan.set_opt_trace_parameter(identifier=>'trace_test', "level"=>3);Query plans.
explain select * from t1;Query trace log files whose file name extensions are
trace_testfrom the log directory of the OBServer node.vi /home/admin/oceanbase/log/optimizer_trace_BkkGn1_trace_test.tracDisable tracing for the optimizer of the current session.
call dbms_xplan.disable_opt_trace();
Use ODP to retain the session.
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;Enable tracing for the optimizer of the current session.
call dbms_xplan.enable_opt_trace();Specify the tracing level and the file name extension of the trace log file.
call dbms_xplan.set_opt_trace_parameter(identifier=>'trace_test', `level`=>3);Query plans.
explain select * from t1;Query trace log files whose file name extensions are
trace_testfrom the log directory of the OBServer node.vi /home/admin/oceanbase/log/optimizer_trace_BkkGn1_trace_test.tracDisable tracing for the optimizer of the current session.
call dbms_xplan.disable_opt_trace();
Information interpretation
Fields of the plan table
| Field | Description |
|---|---|
| OPERATOR | The name of the operator. |
| NAME | The name of the table to be scanned. |
| EST.ROWS | The number of rows to be returned by the current operator, which is estimated by the optimizer. |
| EST.TIME(us) | The time when the evaluation of the current operator is to complete, which is estimated by the optimizer. |
| REAL.ROWS | The actual number of rows returned by the current operator. |
| REAL.TIME(us) | The actual time when the evaluation of the current operator completed. |
| IO TIME(us) | The wait time of the current operator, in microseconds. For the EXCHANGE IN, EXCHANGE OUT, and PX COORD operators, the wait time indicates the network latency. |
| CPU TIME(us) | The CPU time of the current operator, in microseconds. For the EXCHANGE IN, EXCHANGE OUT, and PX COORD operators, the CPU time is not counted in network overheads and can be ignored. |
Optimization information
Optimization Info:
-------------------------------------
t1:
table_rows:3
physical_range_rows:1
logical_range_rows:1
index_back_rows:0
output_rows:1
table_dop:1
dop_method:Table DOP
avaiable_index_name:[idx_ct, idx_pc, t1]
pruned_index_name:[idx_ct, idx_pc]
stats version:0
dynamic sampling level:0
estimation method:[DEFAULT]
Plan Type:
DISTRIBUTED
Note:
Degree of Parallelisim is 1 because of table property
| Attribute | Description |
|---|---|
| table_rows | The original number of rows of the t1 table. |
| physical_range_rows | The number of physical rows of the t1 table to be scanned in the index. |
| logical_range_rows | The number of logical rows of the t1 table to be scanned in the index. |
| index_back_rows | The number of rows of the t1 table to be returned by the operation of table access by index primary key. |
| output_rows | The number of rows of the t1 table that are output after filtering. |
| table_dop | The degree of parallelism (DOP) for scanning the t1 table. |
| dop_method | The method for determining the DOP for scanning the table. The value TableDOP indicates that the DOP is defined by the table. The value AutoDop indicates that the DOP is selected by the optimizer based on the cost. In this case, the auto DOP feature must be enabled. The value global parallel indicates that the DOP is specified by the PARALLEL hint or a system variable. |
| available_index_name | The list of indexes available for the t1 table. |
| pruned_index_name | The list of indexes deleted by the current query based on specified rules. |
| stats_version | The version of statistics about the t1 table. The value 0 indicates that no statistics are collected for the table. To ensure correct generation of a plan, you must manually collect statistics about the table. |
| dynamic_sampling_level | The level of dynamic sampling. Dynamic sampling is an optimization tool for the optimizer. For more information, see the documentation at the official website of OceanBase. The value 0 indicates that dynamic sampling is not enabled for the table. |
| estimation_method | The method for estimating the number of rows of the t1 table. The value DEFAULT indicates that the number of rows is estimated based on default statistics. In this case, the estimated number of rows is inaccurate and must be optimized by the database administrator (DBA). The value STORAGE indicates that the number of rows is estimated in real time based on the storage layer. The value STATS indicates that the number of rows is estimated based on statistics. |
| Plan Type | The type of the current plan. Valid values: LOCAL, REMOTE, and DISTRIBUTED. |
| Note | The additional information for generating the plan. For example, Degree of Parallelisim is 1 because of table property indicates that the DOP of the current query is set to 1 because the DOP of the current table is set to 1. |
Analyze the cause of poor performance of a plan
Locate the top N operators with the longest CPU time, excluding the
EXCHANGE IN,EXCHANGE OUT, andPX COORDoperators. Assume that the following operators have long CPU time:TABLE SCAN: Check whether the value of theis_index_backfield istruein theOutputs & filterssection. If yes, check the value of theindex_back_rowsfield in theOptimization Infosection. If the value is large, optimize the index. If the value of theREAL.ROWSfield is much greater than that of theEST.ROWSfield, check whether statistics have been collected, or check the value of thestats versionfield in theOptimization Infosection to see if statistics have expired. If statistics have been collected and not expired, check for complex filtering conditions such asCASE WHENandLIKE. If complex filtering conditions exist, you can enable dynamic sampling by using the /+dynamic_sampling(1)/ hint to improve the accuracy of row estimation. If this operator is on the right side of theNESTED-LOOP JOINorSUBPLAN FILTERoperator, high overheads are caused by too many rescans.NESTED-LOOP JOIN: Check the estimated number of rows to be returned by the operator on the left side. If the number of rows is inaccurate, check the status of the statistics, or enable dynamic sampling by using the /+dynamic_sampling(1)/ hint to improve the accuracy of row estimation. If the performance is still poor, use the /+use_hash(xxx)/ hint to bind another plan. If the estimated number of rows is approximate but the performance is still poor, check the information in theOutputs & filterssection to determine whether a batch join is performed.SUBPLAN FILTER: Check the estimated number of rows to be returned by the operator on the left side. If the number of rows is inaccurate, check the status of the statistics, or enable dynamic sampling by using the /+dynamic_sampling(1)/ hint to improve the accuracy of row estimation. If the estimated number of rows is approximate but the performance is still poor, check the information in theOutputs & filterssection to determine whether a batch operation is performed. If the poor performance is not caused by the preceding factors, find the corresponding subquery in the SQL statement and attempt to rewrite and optimize the query by using the /+unnest/ hint.
If other operators run slowly, check the estimated number of rows and the status of statistics. If performance is still poor after you collect statistics or enable dynamic sampling, the amount of data is excessively large. In this case, you must enable and execute the /+parallel(xxx)/ hint. For the
INSERT,UPDATE,DELETE, andMERGEoperators, you must enable parallel DML (PDML) by using the /+parallel(xxx) enable_parallel_dml/ hint to optimize the query.If the
HASH DISTINCT,SORT,HASH GROUP BY, andHASH JOINoperators consume I/O time, results of these operators are flushed to the disk. In this case, you can modify thesql_work_area_sizeparameter as needed.
About the opt_trace log file
To understand the opt_trace log file, you must familiarize yourself with basic working principles of the OceanBase optimizer, including the iterative query rewriting process, index optimization, join enumeration, and distributed plan optimization.
The opt_trace log file records the following information:
transformer:
- SQL statements before and after rewriting based on each rewrite rule
- Detailed reasons why each rewrite rule triggers or does not trigger rewriting: For example, rewriting is controlled by a hint, or specific conditions are not met.
optimizer:
- Statistics used
- Base table path generation logs, including process conditions, the number of rows, cost estimation information, and skyline pruning rules and processes
- Detailed process of join order enumeration
- Allocation and optimization processes of top N operators
The log file also records the time and memory used at the end of each module.
SECTION TIME USAGE: 233135 us
TOTAL TIME USAGE: 233135 us
SECTION MEM USAGE: 48744 KB
TOTAL MEM USAGE: 62961 KB
SECTION TIME USAGEindicates the time elapsed from the end of the last optimization step to the end of the current optimization step.TOTAL TIME USAGEindicates the time elapsed from the beginning of query optimization to the end of the current optimization step.SECTION MEM USAGEindicates the tenant memory used from the end of the last optimization step to the end of the current optimization step.TOTAL MEM USAGEindicates the tenant memory used from the beginning of query optimization to the end of the current optimization step.
The preceding information helps you quickly identify time-consuming and memory-consuming optimization steps during plan generation. You can use a hint to disable the corresponding optimization feature, instead of using the NO_REWRITE hint to disable rewriting to reduce plan generation overheads.
References
- For more information about the
DBMS_XPLANpackage, see DBMS_XPLAN (MySQL mode) and DBMS_XPLAN (Oracle mode).