Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

Wait events with v$system views

Oracle Tips by Burleson Consulting

What waits are occurring in your database?

In our final example of the power of the V$ tables, we can see what waits are happening in our database. Waits are conditions where a session is waiting for something to happen. Waits can be caused by a number of things from slow disks, to locking situations (like the one we saw above) to various kinds of internal Oracle contention.

See my notes on Oracle wait event scripts and see Oracle code depot for full wait event monitoring scripts.

Waits come in two main kinds of flavors, system-level and session level. The system-level waits represent a high level summary of all session-level waits. Session-level waits then are session specific waits for specific sessions.

System waits come in different wait classes. Classes such as �idle waits� have no real impact on the database at all in most cases (there are some rare exceptions). You can see the current wait class waits by querying the v$system_wait_class view as seen in this example:

SQL> Select wait_class, sum(time_waited), sum(time_waited)/sum(total_waits)
2 Sum_Waits
3 From v$system_wait_class
see code depot for full script
4 Group by wait_class
5 Order by 3 desc;
 
 
WAIT_CLASS      SUM(time_waited)  SUM_WAITS
--------------- ---------------- ----------
Idle                  9899040431 151.750403
Application              3147344 77.2183812
Concurrency               491226 26.0846432
Other                     431875 6.65036957
Administrative               718 5.52307692
Configuration              23691 1.85114862
Commit                     89282 .302570846
User I/O                 2826520 .289489185
System I/O                646700   .1372763
Network                   415446 .007569151

Note that in this output we find that the idle wait class far outweighs the other wait event classes, which is often the case for healthy databases. We do see some other waits of interest; particularly the application and concurrency waits have some time accumulated. Let�s see what waits are causing us problems.

To do this, we drill down to the next level of wait events, using the v$system_event view. This gives us more detailed wait event information, and we can associate the waits with our wait classes as we have done in the following SQL:

SQL> Select a.event, a.total_waits, a.time_waited, a.average_wait
  2  From v$system_event a, v$event_name b, v$system_wait_class c
  3  Where a.event_id=b.event_id
  4  And b.wait_class#=c.wait_class#
    see code depot for full script
  5  And c.wait_class in ('Application','Concurrency')
  6 order by average_wait desc;
 
EVENT                          TOTAL_WAITS time_waited average_wait
------------------------------ ----------- ----------- ------------
enq: TX - row lock contention        10669     3197011          300
buffer busy waits                    14218      470221           33
library cache pin                      270        4462           17
library cache load lock                177        1783           10
latch: library cache                  3673       14115            4
latch: cache buffers chains            329         494            2
latch: In memory undo latch             13          26            2
row cache lock                           2           4            2
latch: library cache lock               55          46            1
latch: library cache pin                95          74            1
enq: RO - fast object reuse            303          49            0
enq: TM - contention                     1           0            0
SQL*Net break/reset to client        29689        1106            0
SQL*Net break/reset to dblink          280           1            0

In this report we find that the top problem appears to be Enqueue waits, that's the enq: TX  row lock contention event is an enqueue. There are a huge number of events in Oracle Database 10g (811 in my 10g database!) so you can't possibly know what each one means. They are all documented in the Oracle reference guide. Also, if you go out to a search engine such as Google and search for the event, you will often find someone who has had problems with it, and you will find lots of help in correcting the problem.

In this case an Enqueue wait has to do with the blocking locks we looked at earlier in this chapter. So in Oracle an enqueue is just another word for lock. If we saw that this was the big problem, I'd start monitoring my sessions to try to figure out what is causing locking issues.   We can drill down even further into the session level if we like. In this case, let's see if anyone is causing locking still:

select a.sid, a.event, a.total_waits, a.time_waited, a.average_wait
from v$session_event a, v$session b
where time_waited > 0
and a.sid=b.sid
see code depot for full script
and b.username is not NULL
and a.event='enq: TX - row lock contention';
 
       SID EVENT                          TOTAL_WAITS time_waited average_wait
---------- ------------------------------ ----------- ----------- ------------
       110 enq: TX - row lock contention           14        4211          301

Note the time_waited and average_wait columns are in Centaseconds in this view.  If we wanted to see the time in seconds we would have to divide the time by 100. Hence, we can see that we have waited for this blocking lock for 4 seconds, up until now.

As we see, SID 110 is blocked right now!! Quickly, let�s see who is blocking this session by re-running our earlier query:

SQL> Select blocking_session, sid, serial#, wait_class,
  2  seconds_in_wait
  3  From v$session
  4  where blocking_session is not NULL
  5 order by blocking_session;
 
BLOCKING_SESSION        SID    SERIAL# WAIT_CLASS      SECONDS_IN_WAIT
---------------- ---------- ---------- --------------- ---------------
             161        110        561 Application                 246

This is clearly a problem. We see that the block continues to be held (now 246 seconds into the blocking event!). We need to go find out who SID 161 is and run them out of town. We do that by returning to the query at the beginning of this section with a slight modification:

SQL> select sid, serial#, username, osuser, machine from v$session
  2 where username is not NULL;
 
       SID    SERIAL# USERNAME                  OSUSER     MACHINE
---------- ---------- ------------------------- ---------- -------------------
       161      43123 GRUMPY                    grummy     htmldb.com
 

Guy Harrison notes this query for wait events using the v$sys_time_model ASH table:

COLUMN wait_class format a20
COLUMN name       format a30
COLUMN time_secs  format 999,999,999,999.99
COLUMN pct        format 99.99

SELECT   
   wait_class,
   NAME,
   ROUND (time_secs, 2) time_secs,
   ROUND (time_secs * 100 / SUM (time_secs) OVER (), 2) pct
FROM
   (SELECT
      n.wait_class,
      e.event NAME,
      e.time_waited / 100 time_secs
    FROM
      v$system_event e,
      v$event_name n
    WHERE
       n.NAME = e.event AND n.wait_class <> 'Idle'
    AND
       time_waited > 0
    UNION
    SELECT
      'CPU',
      'server CPU',
      SUM (VALUE / 1000000) time_secs
    FROM
      v$sys_time_model
    WHERE
      stat_name IN ('background cpu time', 'DB CPU'))
ORDER BY
   time_secs DESC;

   
Oracle Training from Don Burleson 

The best on site "Oracle training classes" are just a phone call away! You can get personalized Oracle training by Donald Burleson, right at your shop!

Oracle training
 
 

 


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational