首页 > 技术文章 > 获取v$latch数据源实验

Clark-cloud-database 2017-11-10 10:40 原文

实验环境:Oracle Rac 11.2.0.3

首先获取v$latch的定义:
通过PL/SQL或者get ddl等常规途径只能获取到v_$latch相关的视图信息。
需要通过特殊方法获取v$latch的ddl
可以通过set autotrace traceonly开启状态下执行select * from v$latch;得知表的数据来源是x$kslltr,结果如下:
-----------------------------------------------------------------------------
| Id  | Operation        | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT |          |     1 |   352 |     0   (0)| 00:00:01 |
|*  1 |  FIXED TABLE FULL| X$KSLLTR |     1 |   352 |     0   (0)| 00:00:01 |

通过sql_trace的方式因为版本问题,trace的输出结构略有不同,在11.2.0.4.5中可以获取的ddl,但是在我的实验环境中无法获取,方法如下
alter session set sql_trace=true;
select * from v$latch;
alter session set sql_trace=false;
select * from v$diag_info where name='Default Trace File';
tkprof xxxx.trc

通过10053trace的方式获取到v$latch的具体底层数据来源,方法如下
alter session set events '10053 trace name context forever,level 1'; 
select * from v$latch;
alter session set events '10053 trace name context off';
select * from v$diag_info where name='Default Trace File';

vim /u01/app/oracle/diag/rdbms/irac/IRAC1/trace/IRAC1_ora_16791.trc
注意!请不要使用sys用户做10053 trace,你是得不到结果的。
得到如下结果,从输出可以看出,最终转换的sql语句如下;
Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "LT"."KSLLTADDR" "ADDR","LT"."KSLLTNUM" "LATCH#","LT"."KSLLTLVL" "LEVEL#","LT"."KSLLTNAM" "NAME","LT"."KSLLTHSH" "HASH","LT"."KSLLTWGT" "GETS","LT"."KSLLTWFF" "MISSES","LT"."KSLLTWSL" "SLEEPS","LT"."KSLLTNGT" "IMMEDIATE_GETS","LT"."KSLLTNFA" "IMMEDIATE_MISSES","LT"."KSLLTWKC" "WAITERS_WOKEN","LT"."KSLLTWTH" "WAITS_HOLDING_LATCH","LT"."KSLLTHST0" "SPIN_GETS","LT"."KSLLTHST1" "SLEEP1","LT"."KSLLTHST2" "SLEEP2","LT"."KSLLTHST3" "SLEEP3","LT"."KSLLTHST4" "SLEEP4","LT"."KSLLTHST5" "SLEEP5","LT"."KSLLTHST6" "SLEEP6","LT"."KSLLTHST7" "SLEEP7","LT"."KSLLTHST8" "SLEEP8","LT"."KSLLTHST9" "SLEEP9","LT"."KSLLTHST10" "SLEEP10","LT"."KSLLTHST11" "SLEEP11","LT"."KSLLTWTT" "WAIT_TIME" FROM SYS."X$KSLLTR" "LT" WHERE "LT"."INST_ID"=USERENV('INSTANCE')
kkoqbc: optimizing query block SEL$88122447 (#0) 
从而得到v$latch的底层数据来源。

当然,如果每次想看到官方文档中没有记载的视图就去做一个10053trace,实在麻烦,可以使用如下方式,简单方便的查询到视图的数据源:
SQL> SELECT * FROM v$fixed_view_definition WHERE view_name = 'V$LATCH';

VIEW_NAME
--------------------------------------------------------------------------------
VIEW_DEFINITION
--------------------------------------------------------------------------------
V$LATCH
select addr,latch#,level#,name,hash,gets,misses,sleeps,immediate_gets, immediate
_misses,waiters_woken,waits_holding_latch,spin_gets, sleep1,sleep2,sleep3,sleep4
,sleep5,sleep6,sleep7,sleep8,sleep9, sleep10,sleep11,wait_time from gv$latch whe
re inst_id = USERENV('Instance')

SQL> SELECT * FROM v$fixed_view_definition WHERE view_name = 'GV$LATCH';

VIEW_NAME
--------------------------------------------------------------------------------
VIEW_DEFINITION
--------------------------------------------------------------------------------
GV$LATCH
select lt.inst_id,lt.kslltaddr,lt.kslltnum,lt.kslltlvl,lt.kslltnam,        lt.ks
llthsh,lt.kslltwgt,lt.kslltwff,        lt.kslltwsl,lt.kslltngt,lt.kslltnfa,lt.ks
lltwkc,        lt.kslltwth,lt.ksllthst0,lt.ksllthst1,lt.ksllthst2,        lt.ksl
lthst3,lt.ksllthst4,lt.ksllthst5,lt.ksllthst6,lt.ksllthst7,        lt.ksllthst8,
lt.ksllthst9,lt.ksllthst10, lt.ksllthst11, lt.kslltwtt from x$kslltr lt

SQL>

功夫不负有心人,经过不懈的努力终于得到了v$latch是如何产生的,那么这个视图究竟有什么用处呢,以后的博客会分享。

推荐阅读