« EMC损坏硬盘更换及恢复过程 | Blog首页 | Oracle数据字典说明 »
Oracle10gR2 autotrace function was changed and enhanced
作者:eygle | 【转载请注出处】|【云和恩墨 领先的zData数据库一体机 | zCloud PaaS云管平台 | SQM SQL审核平台 | ZDBM 数据库备份一体机】
链接:https://www.eygle.com/archives/2005/09/oracle10gr2_aut.html
今天在测试过程中,偶然发现在Oracle10g Release 2中,Autotrace的功能已经被极大加强和改变。链接:https://www.eygle.com/archives/2005/09/oracle10gr2_aut.html
这是一个很有意思的小的变化,关于autotrace的使用,请参考:启用AutoTrace
接下来让我们先来看一下什么地方发生了改变:
SQL> set linesize 120 SQL> set autotrace on SQL> select count(*) from v$session 2 / COUNT(*) ---------- 21 Execution Plan ---------------------------------------------------------- Plan hash value: 2376410614 --------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 65 | 0 (0)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 65 | | | | 2 | NESTED LOOPS | | 1 | 65 | 0 (0)| 00:00:01 | |* 3 | FIXED TABLE FULL | X$KSUSE | 1 | 52 | 0 (0)| 00:00:01 | |* 4 | FIXED TABLE FIXED INDEX| X$KSLED (ind:2) | 1 | 13 | 0 (0)| 00:00:01 | --------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - filter("S"."INST_ID"=USERENV('INSTANCE') AND BITAND("S"."KSSPAFLG",1)<>0 AND BITAND("S"."KSUSEFLG",1)<>0) 4 - filter("S"."KSUSEOPC"="E"."INDX") Statistics ---------------------------------------------------------- 1 recursive calls 0 db block gets 0 consistent gets 0 physical reads 0 redo size 411 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 |
注意,此时autotrace的输出被良好格式化,并给出关于执行计划部分的简要注释。
其实这里并没有带来新的东西,从Oracle9i开始,Oracle提供了一个新的工具dbms_xplan用以格式化和查看SQL的执行计划。其原理是通过对plan_table的查询和格式化提供更友好的用户输出。
dbms_xplan的调用的语法类似:
select * from table(dbms_xplan.display(format=>'BASIC'))
使用 TABLE() 操作符,或者 CAST 操作。
具体用法可以参考Oracle官方文档。
实际上从Oracle9i开始我们就经常使用如下方式调用dbms_xplan:
Connected to: Oracle9i Enterprise Edition Release 9.2.0.4.0 - Production With the Partitioning option JServer Release 9.2.0.4.0 - Production SQL> explain plan for 2 select count(*) from dual; Explained. SQL> @?/rdbms/admin/utlxplp; PLAN_TABLE_OUTPUT ---------------------------------------------------------------------------------- -------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost | -------------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | | | 1 | SORT AGGREGATE | | | | | | 2 | TABLE ACCESS FULL | DUAL | | | | -------------------------------------------------------------------- Note: rule based optimization 10 rows selected. |
utlxplp.sql脚本中正是调用了dbms_xplan:
SQL> get ?/rdbms/admin/utlxplp; 1 Rem 2 Rem $Header: utlxplp.sql 23-jan-2002.08:55:23 bdagevil Exp $ 3 Rem 4 Rem utlxplp.sql 5 Rem 6 Rem Copyright (c) 1998, 2002, Oracle Corporation. All rights reserved. 7 Rem 8 Rem NAME 9 Rem utlxplp.sql - UTiLity eXPLain Parallel plans 10 Rem 11 Rem DESCRIPTION 12 Rem script utility to display the explain plan of the last explain plan 13 Rem command. Display also Parallel Query information if the plan happens to 14 Rem run parallel 15 Rem 16 Rem NOTES 17 Rem Assume that the table PLAN_TABLE has been created. The script 18 Rem utlxplan.sql should be used to create that table 19 Rem 20 Rem With SQL*plus, it is recomended to set linesize and pagesize before 21 Rem running this script. For example: 22 Rem set linesize 130 23 Rem set pagesize 0 24 Rem 25 Rem MODIFIED (MM/DD/YY) 26 Rem bdagevil 01/23/02 - rewrite with new dbms_xplan package 27 Rem bdagevil 04/05/01 - include CPU cost 28 Rem bdagevil 02/27/01 - increase Name column 29 Rem jihuang 06/14/00 - change order by to order siblings by. 30 Rem jihuang 05/10/00 - include plan info for recursive SQL in LE row source 31 Rem bdagevil 01/05/00 - make deterministic with order-by 32 Rem bdagevil 05/07/98 - Explain plan script for parallel plans 33 Rem bdagevil 05/07/98 - Created 34 Rem 35 set markup html preformat on 36 Rem 37 Rem Use the display table function from the dbms_xplan package to display the last 38 Rem explain plan. Use default mode which will display only relevant information 39 Rem 40* select * from table(dbms_xplan.display()); 41 SQL> |
而在Oracle10gR2中,Oracle帮我们简化了这个过程,一个autotrace就完成了所有的输出,这也是易用性上的一个进步吧。在使用Oracle的过程中,我们经常能够感受到Oracle针对用户需求或易用性的改进,这也许是很多人喜爱Oracle的一个原因吧。
如果足够信息我们还会注意到,在Oracle10g中PLAN_TABLE不再需要创建,Oracle缺省增加了一个字典表PLAN_TABLE$,然后基于PLAN_TABLE$创建公用同义词供用户使用。
关于dbms_xplan工具的使用还可以参考Itpub上的讨论:使用dbms_xplan工具查看执行计划.
历史上的今天...
>> 2009-09-15文章:
>> 2007-09-15文章:
>> 2006-09-15文章:
By eygle on 2005-09-15 00:35 | Comments (0) | Oracle12c/11g | 434 |