oracle 在9i之后引入了bind peeking,通过bind peeking,oracle可以在硬解析的时候窥探绑定变量的值,并根据当前绑定变量的值生成
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_id 3rg5r8sghcvb3, 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_id 3rg5r8sghcvb3, 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_id 3rg5r8sghcvb3, 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行。