整理:Fenng 日期:24-Oct-2004 出处:http://www.dbanotes.net 版本:0.9 --------------------------------------------------------------------------------
DBMS_SUPPORT是Oracle提供的一个软件包。供内部支持人员使用以更有效地跟踪SQL。这个包没有正式的说明文件,默认情况下,系统不安装这个包。假如需要使用的话,需进行单独设置。在你的$ORACLE_HOME/rdbms/admin/目录下应该存在dbmssupp.sql,prvtsupp.plb这两个文件。 SQL> connect / as sysdba Connected. SQL> @$ORACLE_HOME/rdbms/admin/dbmssupp.sqlPackage created.Package body created.SQL> 假如要其他用户也可以使用这个包,可以考虑提交如下授权操作(PUBLIC可以替换为具体的用户)并创建同义词: SQL> GRANT EXECUTE ON dbms_support TO PUBLIC;Grant sUCceeded.SQL> CREATE PUBLIC SYNONYM dbms_support FOR dbms_support; DBMS_SUPPORT的结构并不复杂: SQL> desc DBMS_SUPPORTFUNCTION MYSID RETURNS NUMBER FUNCTION PACKAGE_VERSION RETURNS VARCHAR2 PROCEDURE START_TRACE Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- WAITS BOOLEAN IN DEFAULT BINDS BOOLEAN IN DEFAULT PROCEDURE START_TRACE_IN_SESSION Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- SID NUMBER IN SERIAL NUMBER IN WAITS BOOLEAN IN DEFAULT BINDS BOOLEAN IN DEFAULT PROCEDURE STOP_TRACE PROCEDURE STOP_TRACE_IN_SESSION Argument Name Type In/Out Default? ------------------------------ ----------------------- ------ -------- SID NUMBER IN SERIAL NUMBER IN
SQL> 其中通过MYSID可以获得当前会话(Session)的SID(以及serial#): SQL> SELECT SYS.dbms_support.mysid FROM DUAL; MYSID ---------- 25SQL> SQL>SELECT SID, serial# FROM v$session WHERE SID = dbms_support.mysid; SID SERIAL# ---------- ---------- 25 4328SQL> 通过package_version可以得到软件包所能支持的最低的PL/SQL的版本: SQL> SELECT dbms_support.package_version 2 FROM dual;PACKAGE_VERSION -------------------------------------------------------------------- DBMS_SUPPORT Version 1.0 (17-Aug-1998) - Requires Oracle 7.2 - 8.0.5 如何激活SQL跟踪? START_TRACE有两个参数:WAITS和BINDS。其中WAITS默认为TRUE,BINDS默认为FALSE。假如简单的提交: SQL>EXECUTE dbms_support.start_trace;则默认激活10046事件,level 1。也即等同于: SQL>ALTER SESSION SET EVENTS '10046 trace name context forever, level 1';假如提交: SQL>EXECUTE dbms_support.start_trace (BINDS=>true);则激活10046事件,level 4。等同于: SQL>ALTER SESSION SET EVENTS '10046 trace name context forever, level 4';假如提交: SQL>EXECUTE dbms_support.start_trace (WAITS=>true);则激活10046事件,level 8。等同于: SQL>ALTER SESSION SET EVENTS '10046 trace name context forever, level 8';停止跟踪提交: SQL>EXECUTE dbms_support.stop_trace; start_trace_in_session有四个参数,可参考上面DESCRIBE的输出。假如要跟踪其他用户的会话,就要用上它了。以上面的输出举例(需要SID和SERIAL#): SQL>EXECUTE dbms_support.start_trace_in_session (25, 4328, waits->true,binds=>true,); 上面这条命令和以下语句起到同样功能: SQL>EXECUTE dbms_system.set_ev (25, 4328, 10046, 4, 8); 停止跟踪提交: SQL>EXECUTE dbms_support.stop_trace_in_session (25, 4328); 其他问题这个包从Oracle RDBMS 7.2 开始就有提供。但在某些版本/平台上可能不存在。注:各个Level的基本解释: Level 0 = No statistics generated Level 1 = standard trace output including parsing, executes and fetches plus more. Level 2 = Same as level 1. Level 4 = Same as level 1 but includes bind information Level 8 = Same as level 1 but includes wait's information Level 12 = Same as level 1 but includes binds and waits
|