RE: db file sequential read - again

  • To: "Herring Dave - dherri" <Dave.Herring@xxxxxxxxxx>, <jherrick@xxxxxxx>, "Wolfgang Breitling" <breitliw@xxxxxxxxxxxxx>
  • Date: Tue, 13 Mar 2007 19:59:52 -0400

Dave,

You're absolutely right!  Good point.  I come from a very OLTP-centric
view of the world....

Here's a modified version of the query which will account for physical
reads direct:
column owner format a20
column statistic_name format a15
select * from(
  select vss1.owner,
         vss1.object_name,
         vss1.statistic_name,
         vss1.value-vss2.value value,
         ds.bytes/1048576 "SEGSIZE (MB)",
         ds.buffer_pool
    from v$segment_statistics vss1,
         v$segment_statistics vss2,
         dba_segments ds
   where vss1.statistic_name ='physical reads'
     and vss2.statistic_name = 'physical reads direct'
     and ds.segment_type = vss1.object_type
     and ds.segment_name = vss1.object_name
     and ds.owner=vss1.owner
     and ds.segment_type = vss2.object_type
     and ds.segment_name = vss2.object_name
     and ds.owner=vss2.owner
     and ds.buffer_pool = 'DEFAULT'
order by (vss1.value-vss2.value) desc
)
where rownum <=20
/

Note that, while I was tinkering, I made a few other changes too:
 - It no longer needs the threshold value, 5,000,000, or whatever.  It
will automatically return the top 20 segments w/ the most non-direct
physical I/O.

 - The order of the output is reversed, worst is on top.

 - Segment size is displayed in MB.

 - Added some reasonable column formatting, for a wide terminal (at
least 132 columns)

-Mark

--
Mark J. Bobak
Senior Oracle Architect
ProQuest/CSA

"There are 10 types of people in the world:  Those who understand
binary, and those who don't."

-----Original Message-----
From: Herring Dave - dherri [mailto:Dave.Herring@xxxxxxxxxx] 
Sent: Tuesday, March 13, 2007 6:14 PM
To: Bobak, Mark; jherrick@xxxxxxx; Wolfgang Breitling
Cc: oracle-l@xxxxxxxxxxxxx
Subject: RE: db file sequential read - again

Aren't 'physical reads direct' included in 'physical reads'?  If so, I
think you'd want to subtract out that value since direct reads won't be
affected by any pool definition.  Maybe that's not a big deal for most
folks, but with a DW and consequently lots of parallelism, direct reads
are the most frequent physical read, so non-direct physical reads are
important to spot for us.

> The query I came up with is:
>   select vss.owner,
>          vss.object_name,
>          vss.statistic_name,
>          vss.value,
>          ds.bytes segsize,
>          ds.buffer_pool
>     from v$segment_statistics vss,
>          dba_segments ds
>    where vss.statistic_name ='physical reads'
>      and vss.value > 5000000 ---You may need to play with this
threshold
> value for your environment
>      and ds.segment_type = vss.object_type
>      and ds.segment_name = vss.object_name
>      and ds.owner=vss.owner
>      and ds.buffer_pool = 'DEFAULT'
> order by value
> /

Dave

___________________________________

David C. Herring, DBA  |   A c x i o m  Delivery Center Organization

630-944-4762 office | 630-430-5988 wireless | 630-944-4989 fax
************************************************************************
*
The information contained in this communication is confidential, is
intended only for the use of the recipient named above, and may be
legally privileged.

If the reader of this message is not the intended recipient, you are
hereby notified that any dissemination, distribution or copying of this
communication is strictly prohibited.

If you have received this communication in error, please resend this
communication to the sender and delete the original message or any copy
of it from your computer system.

Thank you.
************************************************************************
*
--
//www.freelists.org/webpage/oracle-l


Other related posts: