Oracle Scratchpad

October 3, 2019

Trace Files

Filed under: 12c,Infrastructure,Oracle,trace files,Troubleshooting — Jonathan Lewis @ 1:38 pm BST Oct 3,2019

A recent blog note by Martin Berger about reading trace files in 12.2 popped up in my twitter timeline yesterday and reminded me of a script I wrote a while ago to create a simple view I could query to read the tracefile generated by the current session while the session was still connected. You either have to create the view and a public synonym through the SYS schema, or you have to use the SYS schema to grant select privileges on several dynamic performance views to the user to allow the user to create the view in the their own schema. For my scratch database I tend to create the view in the SYS schema.

Script to be run by SYS:

rem
rem     Script: read_trace_122.sql
rem     Author: Jonathan Lewis
rem     Dated:  Sept 2018
rem
rem     Last tested
rem             12.2.0.1

create or replace view my_trace_file as
select 
        *
from 
        v$diag_trace_file_contents
where
        (adr_home, trace_filename) = (
                select
                --      substr(tracefile, 1, instr(tracefile,'/',-1)-1),
                        substr(
                                substr(tracefile, 1, instr(tracefile,'/',-1)-1),
                                1,
                                instr(
                                        substr(tracefile, 1, instr(tracefile,'/',-1)),
                                        'trace'
                                ) - 2
                        ),
                        substr(tracefile, instr(tracefile,'/',-1)+1) trace_filename
                from 
                        v$process
                where   addr = (
                                select  paddr
                                from    v$session
                                where   sid = (
                                        sys_context('userenv','sid')
                                        -- select sid from v$mystat where rownum = 1
                                        -- select dbms_support.mysid from dual
                                )
                        )
        )
;


create public synonym my_trace_file for sys.my_trace_file;
grant select on my_trace_file to {some role};

Alternatively, the privileges you could grant to a user from SYS so that they could create their own view:


grant select on v_$process to some_user;
grant select on v_$session to some_user;
grant select on v_$diag_trace_file_contents to some_user;
and optionally one of:
        grant select on v_$mystat to some_user;
        grant execute on dbms_support to some_user;
                but dbms_support is no longer installed by default.

The references to package dbms_support and view v$mystat are historic ones I have lurking in various scripts from the days when the session id (SID) wasn’t available in any simpler way.

Once the view exists and is available, you can enable some sort of tracing from your session then query the view to read back the trace file. For example, here’s a simple “self-reporting” (it’s going to report the trace file that it causes) script that I’ve run from 12.2.0.1 as a demo:


alter system flush shared_pool;
alter session set sql_trace true;

set linesize 180
set trimspool on
set pagesize 60

column line_number      format  999,999
column piece            format  a150    
column plan             noprint
column cursor#          noprint

break on plan skip 1 on cursor# skip 1

select
        line_number,
        line_number - row_number() over (order by line_number) plan,
        substr(payload,1,instr(payload,' id=')) cursor#,
        substr(payload, 1,150) piece
from
        my_trace_file
where
        file_name = 'xpl.c'
order by
        line_number
/

alter session set sql_trace false;

The script flushes the shared pool to make sure that it’s going to trigger some recursive SQL then enables a simple SQL trace. The query then picks out all the lines in the trace file generated by code in the Oracle source file xpl.c (execution plans seems like a likely guess) which happens to pick out all the STAT lines in the trace (i.e. the ones showing the execution plans).

I’ve used the “tabibitosan” method to identify all the lines that belong to a single execution plan by assuming that they will be consecutive lines in the output starting from a line which includes the text ” id=1 “ (the surrounding spaces are important), but I’ve also extracted the bit of the line which includes the cursor number (STAT #nnnnnnnnnnnnnnn) because two plans may be dumped one after the other if multiple cursors close at the same time. There is still a little flaw in the script because sometimes Oracle will run a sys-recursive statement in the middle of dumping a plan to turn an object_id into an object_name, and this will cause a break in the output.

The result of the query is to extract all the execution plans in the trace file and print them in the order they appear – here’s a sample of the output:


LINE_NUMBER PIECE
----------- ------------------------------------------------------------------------------------------------------------------------------------------------------
         38 STAT #140392790549064 id=1 cnt=0 pid=0 pos=1 obj=18 op='TABLE ACCESS BY INDEX ROWID BATCHED OBJ$ (cr=3 pr=0 pw=0 str=1 time=53 us cost=4 size=113 card
         39 STAT #140392790549064 id=2 cnt=0 pid=1 pos=1 obj=37 op='INDEX RANGE SCAN I_OBJ2 (cr=3 pr=0 pw=0 str=1 time=47 us cost=3 size=0 card=1)'


         53 STAT #140392790535800 id=1 cnt=1 pid=0 pos=1 obj=0 op='MERGE JOIN OUTER (cr=5 pr=0 pw=0 str=1 time=95 us cost=2 size=178 card=1)'
         54 STAT #140392790535800 id=2 cnt=1 pid=1 pos=1 obj=4 op='TABLE ACCESS CLUSTER TAB$ (cr=3 pr=0 pw=0 str=1 time=57 us cost=2 size=138 card=1)'
         55 STAT #140392790535800 id=3 cnt=1 pid=2 pos=1 obj=3 op='INDEX UNIQUE SCAN I_OBJ# (cr=2 pr=0 pw=0 str=1 time=11 us cost=1 size=0 card=1)'
         56 STAT #140392790535800 id=4 cnt=0 pid=1 pos=2 obj=0 op='BUFFER SORT (cr=2 pr=0 pw=0 str=1 time=29 us cost=0 size=40 card=1)'
         57 STAT #140392790535800 id=5 cnt=0 pid=4 pos=1 obj=73 op='TABLE ACCESS BY INDEX ROWID TAB_STATS$ (cr=2 pr=0 pw=0 str=1 time=10 us cost=0 size=40 card=1)
         58 STAT #140392790535800 id=6 cnt=0 pid=5 pos=1 obj=74 op='INDEX UNIQUE SCAN I_TAB_STATS$_OBJ# (cr=2 pr=0 pw=0 str=1 time=8 us cost=0 size=0 card=1)'


         84 STAT #140392791412824 id=1 cnt=1 pid=0 pos=1 obj=20 op='TABLE ACCESS BY INDEX ROWID BATCHED ICOL$ (cr=4 pr=0 pw=0 str=1 time=25 us cost=2 size=54 card
         85 STAT #140392791412824 id=2 cnt=1 pid=1 pos=1 obj=42 op='INDEX RANGE SCAN I_ICOL1 (cr=3 pr=0 pw=0 str=1 time=23 us cost=1 size=0 card=2)'


         94 STAT #140392790504512 id=1 cnt=2 pid=0 pos=1 obj=0 op='SORT ORDER BY (cr=7 pr=0 pw=0 str=1 time=432 us cost=6 size=374 card=2)'
         95 STAT #140392790504512 id=2 cnt=2 pid=1 pos=1 obj=0 op='HASH JOIN OUTER (cr=7 pr=0 pw=0 str=1 time=375 us cost=5 size=374 card=2)'
         96 STAT #140392790504512 id=3 cnt=2 pid=2 pos=1 obj=0 op='NESTED LOOPS OUTER (cr=4 pr=0 pw=0 str=1 time=115 us cost=2 size=288 card=2)'
         97 STAT #140392790504512 id=4 cnt=2 pid=3 pos=1 obj=19 op='TABLE ACCESS CLUSTER IND$ (cr=3 pr=0 pw=0 str=1 time=100 us cost=2 size=184 card=2)'
         98 STAT #140392790504512 id=5 cnt=1 pid=4 pos=1 obj=3 op='INDEX UNIQUE SCAN I_OBJ# (cr=2 pr=0 pw=0 str=1 time=85 us cost=1 size=0 card=1)'
         99 STAT #140392790504512 id=6 cnt=0 pid=3 pos=2 obj=75 op='TABLE ACCESS BY INDEX ROWID IND_STATS$ (cr=1 pr=0 pw=0 str=2 time=8 us cost=0 size=52 card=1)'
        100 STAT #140392790504512 id=7 cnt=0 pid=6 pos=1 obj=76 op='INDEX UNIQUE SCAN I_IND_STATS$_OBJ# (cr=1 pr=0 pw=0 str=2 time=7 us cost=0 size=0 card=1)'
        101 STAT #140392790504512 id=8 cnt=0 pid=2 pos=2 obj=0 op='VIEW  (cr=3 pr=0 pw=0 str=1 time=47 us cost=3 size=43 card=1)'
        102 STAT #140392790504512 id=9 cnt=0 pid=8 pos=1 obj=0 op='SORT GROUP BY (cr=3 pr=0 pw=0 str=1 time=44 us cost=3 size=15 card=1)'
        103 STAT #140392790504512 id=10 cnt=0 pid=9 pos=1 obj=31 op='TABLE ACCESS CLUSTER CDEF$ (cr=3 pr=0 pw=0 str=1 time=21 us cost=2 size=15 card=1)'
        104 STAT #140392790504512 id=11 cnt=1 pid=10 pos=1 obj=30 op='INDEX UNIQUE SCAN I_COBJ# (cr=2 pr=0 pw=0 str=1 time=11 us cost=1 size=0 card=1)'


        116 STAT #140392791480168 id=1 cnt=4 pid=0 pos=1 obj=0 op='SORT ORDER BY (cr=3 pr=0 pw=0 str=1 time=62 us cost=3 size=858 card=13)'
        117 STAT #140392791480168 id=2 cnt=4 pid=1 pos=1 obj=21 op='TABLE ACCESS CLUSTER COL$ (cr=3 pr=0 pw=0 str=1 time=24 us cost=2 size=858 card=13)'
        118 STAT #140392791480168 id=3 cnt=1 pid=2 pos=1 obj=3 op='INDEX UNIQUE SCAN I_OBJ# (cr=2 pr=0 pw=0 str=1 time=11 us cost=1 size=0 card=1)'


        126 STAT #140392789565328 id=1 cnt=1 pid=0 pos=1 obj=14 op='TABLE ACCESS CLUSTER SEG$ (cr=3 pr=0 pw=0 str=1 time=21 us cost=2 size=68 card=1)'
        127 STAT #140392789565328 id=2 cnt=1 pid=1 pos=1 obj=9 op='INDEX UNIQUE SCAN I_FILE#_BLOCK# (cr=2 pr=0 pw=0 str=1 time=12 us cost=1 size=0 card=1)'


        135 STAT #140392789722208 id=1 cnt=1 pid=0 pos=1 obj=18 op='TABLE ACCESS BY INDEX ROWID BATCHED OBJ$ (cr=3 pr=0 pw=0 str=1 time=22 us cost=3 size=51 card=
        136 STAT #140392789722208 id=2 cnt=1 pid=1 pos=1 obj=36 op='INDEX RANGE SCAN I_OBJ1 (cr=2 pr=0 pw=0 str=1 time=16 us cost=2 size=0 card=1)'


        153 STAT #140392792055264 id=1 cnt=1 pid=0 pos=1 obj=68 op='TABLE ACCESS BY INDEX ROWID HIST_HEAD$ (cr=3 pr=0 pw=0 str=1 time=25 us)'
        154 STAT #140392792055264 id=2 cnt=1 pid=1 pos=1 obj=70 op='INDEX RANGE SCAN I_HH_OBJ#_INTCOL# (cr=2 pr=0 pw=0 str=1 time=19 us)'

If you want to investigate further, the “interesting” columns in the underlying view are probably: section_name, component_name, operation_name, file_name, and function_name. The possible names of functions, files, etc. vary with the trace event you’ve enabled.

 

7 Comments »

  1. Hi Jonathan! Thank you, that was an interesting reading.

    Though, I was thinking, what if we get the adr_home and trace_filename from v$diag_info? Say, like that:

    select adh, 
           regexp_substr(DTF, '\/([A-z0-9_\.]+)$',1,1,'',1) as tracefile_name  
    from v$diag_info
        pivot (max(value) for name in ('ADR Home' as ADH, 'Default Trace File' as DTF));
    

    I mean, someone could of course throw an egg at me for such an ugly use of pivot, and regex may need some refinement. But now we need a couple of grants less, and the whole thing is a bit more compact and readable. Also, should require less resources, since only one dictionary is addressed

    Comment by Viacheslav Andzhich — October 9, 2019 @ 4:27 pm BST Oct 9,2019 | Reply

    • Viacheslav,

      Thanks for the comment. I’m always open to hearing alternatives – and your solution is, indeed, a lot shorter and more compact than mine.

      For reference (for the benefit of people like me who have to think hard to get regex() and pivot() doing what they want) I’ve posted the contents of v$diag_info below followed by the results of your query on this set :

      column name format a22
      column value format a70
      
      set linesize 100
      
      select name, value from V$diag_info;
      
      NAME                   VALUE
      ---------------------- ----------------------------------------------------------------------
      Diag Enabled           TRUE
      ADR Base               /u01/app/oracle
      ADR Home               /u01/app/oracle/diag/rdbms/orcl12c/orcl12c
      Diag Trace             /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/trace
      Diag Alert             /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/alert
      Diag Incident          /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/incident
      Diag Cdump             /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/cdump
      Health Monitor         /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/hm
      Default Trace File     /u01/app/oracle/diag/rdbms/orcl12c/orcl12c/trace/orcl12c_ora_11008.trc
      Active Problem Count   0
      Active Incident Count  0
      
      11 rows selected.
      
      column adh format a60
      column tracefile_name format a30
      
      select adh, 
             regexp_substr(DTF, '\/([A-z0-9_\.]+)$',1,1,'',1) as tracefile_name  
      from v$diag_info
          pivot (max(value) for name in ('ADR Home' as ADH, 'Default Trace File' as DTF));
      
      
      ADH                                                          TRACEFILE_NAME
      ------------------------------------------------------------ ------------------------------
      /u01/app/oracle/diag/rdbms/orcl12c/orcl12c                   orcl12c_ora_11008.trc
      
      

      Given your pointer to use v$diag_info, I think I’d be happy to avoid the new tech bits and run with code like:

      
      select
              payload
      from
              v$diag_trace_file_contents
      where
              (adr_home, trace_filename) = (
                      (
                              (select value from v$diag_info where name = 'ADR Home'),
                              (select substr(value, instr(value,'trace') + 6) from v$diag_info where name = 'Default Trace File')
                      )
              )
      /
      
      
      

      I don’t know why the final predicate seems to need doubled parentheses, but it does in 12.2.0.1

      Comment by Jonathan Lewis — October 9, 2019 @ 5:52 pm BST Oct 9,2019 | Reply

  2. […] From Oracle 12.2.0.1 you could arrange to read your own trace file – while your session is connected – through the dynamic performance view v$diag_trace_file_contents. […]

    Pingback by Tracing Errors | Oracle Scratchpad — August 31, 2020 @ 10:16 am BST Aug 31,2020 | Reply

  3. […] a trace file – and we can read trace files from SQL by making use of external tables; [update: but see this note for a more modern option for reading trace fles] and we can collapse data down to a more reasonable size by using analytic functions like the […]

    Pingback by Treedump – 2 | Oracle Scratchpad — February 18, 2022 @ 4:34 pm GMT Feb 18,2022 | Reply

  4. […] the trace file may be the only option – and don’t forget that you may be able to read your trace file from v$diag_trace_file_contents through an SQL*Plus […]

    Pingback by v$_fixed_view_definition | Oracle Scratchpad — March 21, 2022 @ 7:08 pm GMT Mar 21,2022 | Reply

  5. Hi @Jonathan, I am seeing empty content on table v$diag_trace_file_contents while trace files are there in the server . Is there any reason will be empty .Db version 19.13

    Comment by Saroj — October 24, 2022 @ 9:58 pm BST Oct 24,2022 | Reply

  6. Saroj,

    It may be something to do with the container ID; the view may be restricted to trace file content that was generated by your PDB. Also, if those trace files are for background processes their content may only be visible to the root.

    At present, having started a PDB, run the create view script as is (with a relevant role name included) and then running the test I can see from the PDB’s SYS account just the trace file data from the xxx_ora_xxx.trc file. But from the root SYS, at the same time, I can also see trace file data from diag two lgnn slaves and a couple of other background processes – and the root view of my trace file holds more rows than the PDB view:

    From the PDB

    
    SQL> l
      1* select trace_filename, count(*) from sys.v$diag_trace_file_contents group by trace_filename
    SQL> /
    
    TRACE_FILENAME                                                         COUNT(*)
    -------------------------------------------------------------------- ----------
    or19_ora_8644.trc                                                          1734
    
    1 row selected.
    
    
    

    From the root

    
    SQL> l
      1* select trace_filename, count(*) from sys.v$diag_trace_file_contents group by trace_filename
    SQL> /
    
    TRACE_FILENAME                                                         COUNT(*)
    -------------------------------------------------------------------- ----------
    or19_dia0_7434_base_1.trc                                                    53
    or19_lg00_7448.trc                                                           25
    or19_vkrm_7426.trc                                                           28
    or19_dbrm_7422.trc                                                           30
    or19_ora_8644.trc                                                          1972
    or19_lg01_7454.trc                                                           25
    
    6 rows selected.
    
    

    Regards
    Jonathan Lewis

    Comment by Jonathan Lewis — October 25, 2022 @ 9:56 am BST Oct 25,2022 | Reply


RSS feed for comments on this post. TrackBack URI

Comments and related questions are welcome.

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Website Powered by WordPress.com.