ITPub博客

首页 > Linux操作系统 > Linux操作系统 > 在OUTLINE中使用绑定变量

在OUTLINE中使用绑定变量

原创 Linux操作系统 作者:fengjin821 时间:2009-06-12 23:33:10 0 删除 编辑

在OUTLINE中存储如下一条语句的执行计划.

select * from t where object_id=:v1;

表T在object_id列建有索引,默认会走索引.可以通过修改其执行计划让其强制走全表扫描.具体示例如下:

SQL> variable v1 number;
SQL> exec :v1:=20;

PL/SQL 过程已成功完成。

SQL> select * from t where object_id=:v1;

OWNER
------------------------------
OBJECT_NAME
--------------------------------------------------------------------------------
SUBOBJECT_NAME                  OBJECT_ID DATA_OBJECT_ID OBJECT_TYPE
------------------------------ ---------- -------------- -------------------
CREATED        LAST_DDL_TIME  TIMESTAMP           STATUS  T G S
-------------- -------------- ------------------- ------- - - -
SYS
ICOL$
                                       20              2 TABLE
30-8月 -05     30-8月 -05     2005-08-30:13:50:24 VALID   N N N

 

执行计划
----------------------------------------------------------
Plan hash value: 1243986182

--------------------------------------------------------------------------------
-------

| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Tim
e     |

--------------------------------------------------------------------------------
-------

|   0 | SELECT STATEMENT            |         |     1 |    93 |     2   (0)| 00:
00:01 |

|   1 |  TABLE ACCESS BY INDEX ROWID| T       |     1 |    93 |     2   (0)| 00:
00:01 |

|*  2 |   INDEX RANGE SCAN          | T_INDEX |     1 |       |     1   (0)| 00:
00:01 |

--------------------------------------------------------------------------------
-------


Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OBJECT_ID"=TO_NUMBER(:V1))


统计信息
----------------------------------------------------------
          1  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
       1198  bytes sent via SQL*Net to client
        385  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

在未建OUTLINE之前,可以看到是走索引的.

SQL>  CREATE OR REPLACE OUTLINE ol_bind_var ON select * from t where object_id=:v1;

大纲已创建。

SQL> select * from t where object_id=:v1;

OWNER
------------------------------
OBJECT_NAME
--------------------------------------------------------------------------------
SUBOBJECT_NAME                  OBJECT_ID DATA_OBJECT_ID OBJECT_TYPE
------------------------------ ---------- -------------- -------------------
CREATED        LAST_DDL_TIME  TIMESTAMP           STATUS  T G S
-------------- -------------- ------------------- ------- - - -
SYS
ICOL$
                                       20              2 TABLE
30-8月 -05     30-8月 -05     2005-08-30:13:50:24 VALID   N N N

 

执行计划
----------------------------------------------------------
Plan hash value: 1243986182

--------------------------------------------------------------------------------
-------

| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Tim
e     |

--------------------------------------------------------------------------------
-------

|   0 | SELECT STATEMENT            |         |     1 |    93 |     2   (0)| 00:
00:01 |

|   1 |  TABLE ACCESS BY INDEX ROWID| T       |     1 |    93 |     2   (0)| 00:
00:01 |

|*  2 |   INDEX RANGE SCAN          | T_INDEX |     1 |       |     1   (0)| 00:
00:01 |

--------------------------------------------------------------------------------
-------


Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OBJECT_ID"=TO_NUMBER(:V1))

Note
-----
   - outline "OL_BIND_VAR" used for this statement


统计信息
----------------------------------------------------------
         35  recursive calls
        123  db block gets
         25  consistent gets
          0  physical reads
        568  redo size
       1198  bytes sent via SQL*Net to client
        385  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          1  rows processed


创建OUTLINE之后,使用这条查询也是走索引扫描.

现在生成新的OUTLINE,强制其走全表扫描.

SQL>  CREATE OR REPLACE OUTLINE ol_full_t ON select /*+ full(t) */ * from t where object_id=:v1;

大纲已创建。

SQL>
SQL> UPDATE OUTLN.OL$HINTS
  2     SET OL_NAME = DECODE(OL_NAME,
  3                          'OL_BIND_VAR',
  4                          'OL_FULL_T',
  5                          'OL_FULL_T',
  6                          'OL_BIND_VAR')
  7   WHERE OL_NAME IN ('OL_BIND_VAR', 'OL_FULL_T');

已更新10行。


执行计划
----------------------------------------------------------
Plan hash value: 1559483460

--------------------------------------------------------------------------------
-

| Id  | Operation          | Name       | Rows  | Bytes | Cost (%CPU)| Time
|

--------------------------------------------------------------------------------
-

|   0 | UPDATE STATEMENT   |            |    16 |   496 |     2   (0)| 00:00:01
|

|   1 |  UPDATE            | OL$HINTS   |       |       |            |
|

|   2 |   INLIST ITERATOR  |            |       |       |            |
|

|*  3 |    INDEX RANGE SCAN| OL$HNT_NUM |    16 |   496 |     2   (0)| 00:00:01
|

--------------------------------------------------------------------------------
-


Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("OL_NAME"='OL_BIND_VAR' OR "OL_NAME"='OL_FULL_T')


统计信息
----------------------------------------------------------
         10  recursive calls
         58  db block gets
         10  consistent gets
          1  physical reads
       7940  redo size
        674  bytes sent via SQL*Net to client
        794  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
         10  rows processed

SQL> COMMIT;

提交完成。

--清空共享池,重新生成新的执行计划

SQL> ALTER SYSTEM FLUSH SHARED_POOL;

系统已更改。

SQL> select * from t where object_id=:v1;

OWNER
------------------------------
OBJECT_NAME
--------------------------------------------------------------------------------
SUBOBJECT_NAME                  OBJECT_ID DATA_OBJECT_ID OBJECT_TYPE
------------------------------ ---------- -------------- -------------------
CREATED        LAST_DDL_TIME  TIMESTAMP           STATUS  T G S
-------------- -------------- ------------------- ------- - - -
SYS
I_COBJ#
                                       30             30 INDEX
30-8月 -05     30-8月 -05     2005-08-30:13:50:24 VALID   N N N

 

执行计划
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    93 |   160   (3)| 00:00:02 |
|* 1 |  TABLE ACCESS FULL| T    |     1 |    93 |   160   (3)| 00:00:02 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJECT_ID"=TO_NUMBER(:V1))

Note
-----
   -outline "OL_BIND_VAR" used for this statement


统计信息
----------------------------------------------------------
       2530  recursive calls
        120  db block gets
       1107  consistent gets
          0  physical reads
          0  redo size
       1196  bytes sent via SQL*Net to client
        385  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
         30  sorts (memory)
          0  sorts (disk)
          1  rows processed

可以看见在使用OUTLINE的情况下,此查询的确是使用全表扫描的.

来自 “ ITPUB博客 ” ,链接:http://blog.itpub.net/13165828/viewspace-606155/,如需转载,请注明出处,否则将追究法律责任。

上一篇: 大牛的空间
请登录后发表评论 登录
全部评论

注册时间:2009-04-29

  • 博文量
    191
  • 访问量
    506631