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

 
 Home
 E-mail Us
 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 


 

 

 


 

 

 
 

 

Oracle library cache load lock tips

Oracle Tips by Burleson Consulting

 

The library cache load lock Oracle metric occurs when the process is waiting for the opportunity to load an object or a piece of an object into the library cache.  The loads of SQL statements are serialized and locked in exclusive mode, such that only one process can load an object or a piece of an object at a time.  In general, all library cache waits are associated with non-reentrant SQL or an undersized shared pool.

Also see these notes on generic library cache locks.

In general the library cache load lock occurs during periods of high activity within the library cache, especially with databases that do not use host variables and have a hard parsing due to non-reusable SQL.

Interrogating dba_hist_sqlstat for SQL statements with executions=1 indicates non-reusable SQL (and an opportunity for cursor_sharing=force), but barring problems with SQL with literals, the most common remedy for high library cache load locks is a dynamic increase to the shared_pool_size.

Below, we see this library cache load lock wait manifested in a busy Oracle database averaging 1,000 disk writes per second and over 50,000 logical reads per second:

 

Load Profile                            Per Second       Per Transaction
                                   ---------------       ---------------
                  Redo size:            196,617.69                632.75
              Logical reads:             36,311.98                116.86
              Block changes:              1,114.83                  3.59
             Physical reads:              2,164.71                  6.97
            Physical writes:                958.11                  3.08
 
 . . .
 
Instance Efficiency Percentages (Target 100%)      ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
            Buffer Nowait %:   99.99       Redo NoWait %:  100.00
            Buffer  Hit   %:   96.56    In-memory Sort %:   99.97
            Library Hit   %:   96.51        Soft Parse %:   91.50
         Execute to Parse %:   75.35         Latch Hit %:   99.17
Parse CPU to Parse Elapsd %:    0.64     % Non-Parse CPU:   96.07
 
 Shared Pool Statistics        Begin   End                                                  ------  ------
             Memory Usage %:   85.55   89.99
    % SQL with executions>1:   57.79   53.57
  % Memory for SQL w/exec>1:   72.61   68.39
 
Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                                     % Total
Event                                               Waits    Time (s) Ela Time
-------------------------------------------- ------------ ----------- --------
library cache load lock                             9,708      13,194    49.20
library cache pin                                   8,084       9,425    35.14
CPU time                                                        1,538     5.73
kksfbc child completion                           152,610       1,495     5.57
db file sequential read                           190,283         738     2.75
                                    -------------------------------------------------------------

 

An increase of the shared pool size remedied this problem.

MOSC Note 444560.1 contains a complete description of the library cache load lock, and for specific blocking and waiting sessions, MOSC note 169139.1 has detailed instructions on diagnosing library cache load lock issues, and provides this snippet to locate the waiting and holding sessions:

select /*+ ordered */ w1.sid waiting_session, h1.sid holding_session,
w.kgllktype lock_or_pin,
w.kgllkhdl address,
decode(h.kgllkmod, 0, 'None', 1, 'Null', 2, 'Share', 3, 'Exclusive',
'Unknown') mode_held,
decode(w.kgllkreq, 0, 'None', 1, 'Null', 2, 'Share', 3, 'Exclusive',
'Unknown') mode_requested
from dba_kgllock w, dba_kgllock h, v$session w1, v$session h1 where
(
(
(h.kgllkmod != 0)
and (h.kgllkmod != 1)
and ((h.kgllkreq = 0) or (h.kgllkreq = 1)) )
and
(
(
(w.kgllkmod = 0)
or (w.kgllkmod= 1)
)
and (
(
w.kgllkreq != 0)
and (w.kgllkreq != 1)
)
)
)
and w.kgllktype = h.kgllktype
and w.kgllkhdl = h.kgllkhdl
and w.kgllkuse = w1.saddr
and h.kgllkuse = h1.saddr;

You can monitor the library cache with Ion ( www.ion-dba.com ):

     

For Oracle versions 9.0.2.5 and 9.1.2.7 offer information on the Bug 4084154, and the enhancement: optimization to library cache load lock allocation code. 

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 


 

 

��  
 
 
 
 

 
 
 

 
 
Oracle performance tuning software 
 
oracle dba poster
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 -  2014

All rights reserved by Burleson

Oracle is the registered trademark of Oracle Corporation.