- 相关推荐
Oracle认证:ORACLE绑定变量BINDPEEKING
ORACLE 在9i之后引入了bind peeking,通过bind peeking,oracle可以在硬解析的时候窥探绑定变量的值,并根据当前绑定变量的值生成执行计划。在oracle 9i之前的版本中,oracle仅仅通过统计信息来生成执行计划。
下面看一下不同版本oracle下绑定变量对执行计划的影响
SQL> alter system flush shared_pool;
系统已更改。
SQL> alter system set optimizer_features_enable='8.1.7';
系统已更改。
SQL> var v number;
SQL> exec :v := 1;
PL/SQL 过程已成功完成。
SQL> select count(*) from acs_test_tab where record_type = :v;
COUNT(*)
----------
1
SQL> select * from table(dbms_xplan.display_cursor(null,null,'advanced'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID3rg5r8sghcvb3, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = :v
Plan hash value: 2956728990
--------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
--------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 3 |
| 1 | SORT AGGREGATE | | 1 | 4 | |
|* 2 | INDEX RANGE SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 2 | 8 | 3 |
--------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("RECORD_TYPE"=:V)
已选择47行。
SQL> alter system flush shared_pool;
系统已更改。
SQL> alter system set optimizer_features_enable='11.2.0.3.1';
系统已更改。
SQL> var v number;
SQL> exec :v := 1;
PL/SQL 过程已成功完成。
SQL> select count(*) from acs_test_tab where record_type = :v;
COUNT(*)
----------
1
SQL> select * from table(dbms_xplan.display_cursor(null,null,'advanced'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID3rg5r8sghcvb3, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = :v
Plan hash value: 2956728990
------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 3 (100)| |
| 1 | SORT AGGREGATE | | 1 | 4 | | |
|* 2 | INDEX RANGE SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 1 | 4 | 3 (0)| 00:00:01 |
------------------------------------------------------------------------------------------------
Peeked Binds (identified by position):
--------------------------------------
1 - :V (NUMBER): 1 --绑定变量窥探
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("RECORD_TYPE"=:V)
已选择49行。
SQL> alter system flush shared_pool;
系统已更改。
SQL> exec :v := 2;
PL/SQL 过程已成功完成。
SQL> select count(*) from acs_test_tab where record_type = :v;
COUNT(*)
----------
50000
SQL> select * from table(dbms_xplan.display_cursor(null,null,'advanced'));
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID3rg5r8sghcvb3, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = :v
Plan hash value: 2957754476
----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 136 (100)| |
| 1 | SORT AGGREGATE | | 1 | 4 || |
|* 2 | INDEX FAST FULL SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 48031 | 187K| 136 (1)| 00:00:02 |
----------------------------------------------------------------------------------------------------
Peeked Binds (identified by position):
--------------------------------------
1 - :V (NUMBER): 2 --绑定变量窥探,绑定变量会影响最初硬解析的执行计划
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("RECORD_TYPE"=:V)
已选择49行。
使用绑定变量窥测的好处是:可以帮助优化器在第一次硬解析时选择最优的执行计划。但是同时这也是其弊端:在第一次硬解析后,后面发生的所有解析都会使用第一次硬解析生成的执行计划,如果数据的分布是均匀的,问题不大,如果数据分布式倾斜的,那么第一次硬解析生成的执行计划未必是最优的,甚至可能是非常糟糕的。例如:
SQL> show parameter optimizer_feat
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
optimizer_features_enable string 11.2.0.3.1
SQL> alter system flush shared_pool;
系统已更改。
SQL> var v number;
SQL> exec :v := 2;
PL/SQL 过程已成功完成。
SQL> select count(*) from acs_test_tab where record_type = :v;
COUNT(*)
----------
50000
SQL> select * from table(dbms_xplan.display_cursor);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID3rg5r8sghcvb3, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = :v
Plan hash value: 2957754476
----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 136 (100)| |
| 1 | SORT AGGREGATE | | 1 | 4 || |
|* 2 | INDEX FAST FULL SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 48031 | 187K| 136 (1)| 00:00:02 |
----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("RECORD_TYPE"=:V)
已选择19行。
SQL> exec :v := 1
PL/SQL 过程已成功完成。
SQL> select count(*) from acs_test_tab where record_type = :v;
COUNT(*)
----------
1
SQL> select * from table(dbms_xplan.display_cursor);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID3rg5r8sghcvb3, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = :v
Plan hash value: 2957754476
----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 136 (100)| |
| 1 | SORT AGGREGATE | | 1 | 4 || |
|* 2 | INDEX FAST FULL SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 48031 | 187K| 136 (1)| 00:00:02 |
----------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("RECORD_TYPE"=:V)
已选择19行。
SQL> select count(*) from acs_test_tab where record_type = 1;
COUNT(*)
----------
1
SQL> select * from table(dbms_xplan.display_cursor);
PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID1pxm87f6yd0bp, child number 0
-------------------------------------
select count(*) from acs_test_tab where record_type = 1
Plan hash value: 2956728990
------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 3 (100)| |
| 1 | SORT AGGREGATE | | 1 | 4 | | |
|* 2 | INDEX RANGE SCAN| ACS_TEST_TAB_RECORD_TYPE_I | 1 | 4 | 3 (0)| 00:00:01 |
------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("RECORD_TYPE"=1)
已选择19行。
对于变量v的取值为1的执行计划和采用常量1的执行计划性能差距还是比较大的。
总结:oracle在9i后引入变量窥测技术,该技术对于数据分布均匀的数据是非常合适的,但是对于分布倾斜的数据或者在OLAP系统中是不建议使用的。
【Oracle认证:ORACLE绑定变量BINDPEEKING】相关文章:
Oracle认证作用03-19
Oracle认证简介11-30
Oracle最新认证03-09
Oracle认证途径03-20
Oracle认证:Oracle内存结构研究-PGA篇03-08
Oracle认证职业前景03-19
Oracle认证考试技巧03-19