Oracle database internals by Riyaj

Discussions about Oracle performance tuning, RAC, Oracle internal & E-business suite.

Library cache lock and library cache pin waits

Posted by Riyaj Shamsudeen on June 2, 2009

I encountered few customer issues centered around library cache lock and library cache pin waits. Library cache lock and pin waits can hang instance, and in few cases, whole clusters of RAC instances can be hung due to library cache lock and pin waits.

Why Library cache locks are needed?

Library cache locks aka parse locks are needed to maintain dependency mechanism between objects and their dependent objects like SQL etc. For example, if an object definition need to be modified or if parse locks are to be broken, then dependent objects objects must be invalidated. This dependency is maintained using library cache locks. For example, if a column is dropped from a table then all SQLs dependent upon the table must be invalidated and reparsed during next access to that object. Library cache locks are designed to implement this tracking mechanism.

In a regular enqueue locking scenarios there is a resource (example TM table level lock) and sessions enqueue to lock that resource. More discussion on enqueue locking can be found in Internal of locks. Similarly, library cache locks uses object handles as resource structures and locks are taken on that resource. If the resources are not available in a compatible mode, then sessions must wait for library cache objects to be available.

Why Library cache pins are needed?

Library cache pins deals with current execution of dependent objects. For example, an underlying objects should not be modified when a session is executing or accessing a dependent object. So, before parse locks on a library cache object can be broken, library cache pins must be acquired in an Exclusive mode and then only library cache objects can be dropped. If a session is executing a stored object, then the library cache pins will not be available and there will be waits for library cache pins. Typically, this happens for a long running statement executing a stored object.

x$kgllk, x$kglpn and x$kglob

Library cache locks and pins are externalized in three x$ tables. x$kgllk is externalizing all locking structures on an object. Entries in x$kglob acts as a resource structure. x$kglpn is externalizing all library cache pins.

x$kglob.kglhdadr acts as a pointer to the resource structure. Presumably, kglhdadr stands KGL handle address. x$kgllk acts as a lock structure and x$kgllk.kgllkhdl points to x$kglob.kglhdadr. Also, x$kglpn acts as a pin stucture and x$kglpn.kglpnhdl points to x$kglob.kglhdadr to pin a resource. To give an analogy between object locking scenarios, x$kglob acts as resource structure and x$kgllk acts as lock structures for library cache locks. For library cache pins, x$kglpn acts as pin structure. x$kglpn also pins that resource using kglpnhdl. This might be clear after reviewing the example below.

Test case

We will create a simple test case to create library cache locks and pin waits

create or replace procedure backup.test_kgllk (l_sleep in boolean , l_compile in boolean)
as
 begin
  if (l_sleep ) then
	sys.dbms_lock.sleep(60);
  elsif (l_compile )  then
  	execute immediate 'alter procedure test_kgllk compile';
  end if;
 end;
/

In this test case above, we create a procedure and it accepts two boolean parameters: sleep and compile. Passing true to first argument will enable the procedure to sleep for a minute and passing true for the second argument will enable the procedure to recompile itself.

Let’s create two sessions in the database and then execute them as below.

Session #1: exec test_kgllk ( true, false); — Sleep for 1 minutes and no compile
Session #2: exec test_kgllk ( false, true); — No sleep,but compile..

At this point both sessions are waiting. Following SQL can be used to print session wait details.

select
 distinct
   ses.ksusenum sid, ses.ksuseser serial#, ses.ksuudlna username,ses.ksuseunm machine,
   ob.kglnaown obj_owner, ob.kglnaobj obj_name
   ,pn.kglpncnt pin_cnt, pn.kglpnmod pin_mode, pn.kglpnreq pin_req
   , w.state, w.event, w.wait_Time, w.seconds_in_Wait
   -- lk.kglnaobj, lk.user_name, lk.kgllksnm,
   --,lk.kgllkhdl,lk.kglhdpar
   --,trim(lk.kgllkcnt) lock_cnt, lk.kgllkmod lock_mode, lk.kgllkreq lock_req,
   --,lk.kgllkpns, lk.kgllkpnc,pn.kglpnhdl
 from
  x$kglpn pn,  x$kglob ob,x$ksuse ses 
   , v$session_wait w
where pn.kglpnhdl in
(select kglpnhdl from x$kglpn where kglpnreq >0 )
and ob.kglhdadr = pn.kglpnhdl
and pn.kglpnuse = ses.addr
and w.sid = ses.indx
order by seconds_in_wait desc
/

Output of above SQL is:

                                                                pin  pin  pin                                 wait seconds
  SID   SERIAL# USERNAME     MACHINE   OBJ_OWNER  OBJ_NAME      cnt  mode req  STATE      EVENT               time in_wait
----- --------- ------------ --------- ---------- ------------- ---- ---- ---- ---------- ------------------- ----- -------
  268     12409 SYS          orap      SYS        TEST_KGLLK    3    2    0    WAITING    PL/SQL lock timer       0       7
  313     45572 SYS          orap      SYS        TEST_KGLLK    0    0    3    WAITING    library cache pin       0       3
  313     45572 SYS          orap      SYS        TEST_KGLLK    3    2    0    WAITING    library cache pin       0       3

  1. Session 268 (session #1) is sleeping while holding library cache pin on test_kgllk object (waiting on PL/SQL lock timer more accurately).
  2. Session 313 is holding library cache pin in mode 2 and waiting for library cache pin in mode 3.

Obviously, session 313 is waiting for session 268 to release library cache pins. Since session 268 is executing, session 313 should not be allowed to modify test_kgllk library cache object. That’s exactly why library cache pins are needed.

Adding another session to this mix..

Let’s add one more session as below

 
exec test_kgllk (false, true);

Output of above query is:

 
                                                                                   pin  pin  pin                                            wait seconds
  SID   SERIAL# USERNAME     MACHINE              OBJ_OWNER  OBJ_NAME              cnt mode  req STATE      EVENT                           time in_wait
----- --------- ------------ -------------------- ---------- -------------------- ---- ---- ---- ---------- ------------------------------ ----- -------
  268     12409 SYS          oraperf              SYS        TEST_KGLLK              3    2    0 WAITING    PL/SQL lock timer                  0      34
  313     45572 SYS          oraperf              SYS        TEST_KGLLK              0    0    3 WAITING    library cache pin                  0      29
  313     45572 SYS          oraperf              SYS        TEST_KGLLK              3    2    0 WAITING    library cache pin                  0      29
  442      4142 SYS          oraperf              SYS        TEST_KGLLK              0    0    2 WAITING    library cache pin                  0       3

Well, no surprise there. New session 442 also waiting for library cache pin. But, notice the request mode for session 442. It is 2. Session 442 needs that library cache pin in share mode to start execution. But 313 has already requested that library cache pin in mode 3. A queue is building up here. Many processes can queue behind session 313 at this point leading to an hung instance.

library cache locks..

Let’s execute same package but both with same parameters.

 Session #1: exec test_kgllk(false, true);
 Session #2: exec test_kgllk(false, true);

Rerunning above query tells us that session 313 is waiting for the self. Eventually, this will lead library cache pin self deadlock.


Library cache pin holders/waiters
---------------------------------
                                                                                   pin  pin  pin                                            wait seconds
  SID   SERIAL# USERNAME     MACHINE              OBJ_OWNER  OBJ_NAME              cnt mode  req STATE      EVENT                           time in_wait
----- --------- ------------ -------------------- ---------- -------------------- ---- ---- ---- ---------- ------------------------------ ----- -------
  313     45572 SYS          oraperf              SYS        TEST_KGLLK              0    0    3 WAITING    library cache pin                  0      26
  313     45572 SYS          oraperf              SYS        TEST_KGLLK              3    2    0 WAITING    library cache pin                  0      26

Wait, what happened to session #2? It is not visible in x$kglpn. Querying v$session_wait shows that Session #2 is waiting for library cache lock. We will run yet another query against x$kgllk to see library cache lock waits.

 
  Querying x$kgllk with the query below: 
select
 distinct
   ses.ksusenum sid, ses.ksuseser serial#, ses.ksuudlna username,KSUSEMNM module,
   ob.kglnaown obj_owner, ob.kglnaobj obj_name
   ,lk.kgllkcnt lck_cnt, lk.kgllkmod lock_mode, lk.kgllkreq lock_req
   , w.state, w.event, w.wait_Time, w.seconds_in_Wait
 from
  x$kgllk lk,  x$kglob ob,x$ksuse ses
  , v$session_wait w
where lk.kgllkhdl in
(select kgllkhdl from x$kgllk where kgllkreq >0 )
and ob.kglhdadr = lk.kgllkhdl
and lk.kgllkuse = ses.addr
and w.sid = ses.indx
order by seconds_in_wait desc
/

Library cache lock holders/waiters
---------------------------------
                                                                                   lock lock                                            wait seconds
  SID   SERIAL# USERNAME     MODULE     OBJ_OWNER  OBJ_NAME                LCK_CNT mode  req STATE      EVENT                           time in_wait
----- --------- ------------ ---------- ---------- -------------------- ---------- ---- ---- ---------- ------------------------------ ----- -------
  313     45572 SYS          wsqfinc1a  SYS        TEST_KGLLK                    1    1    0 WAITING    library cache pin                  0      29
  313     45572 SYS          wsqfinc1a  SYS        TEST_KGLLK                    1    3    0 WAITING    library cache pin                  0      29
  268     12409 SYS          wsqfinc1a  SYS        TEST_KGLLK                    0    0    2 WAITING    library cache lock                 0      12
  268     12409 SYS          wsqfinc1a  SYS        TEST_KGLLK                    1    1    0 WAITING    library cache lock                 0      12

Session 313 is holding library cache lock on that object in mode 3 and session 268 is requesting lock on that library cache object in mode 2. So, session 268 is waiting for library cache lock while session 313 is waiting for library cache pin (self ). Again, point here is that session 268 is trying to access library cache object and need to acquire library cache lock in correct mode. That library cache lock is not available leading to a wait.

Complete script can be downloaded from my script archive.

RAC, library cache locks and pins

Things are different in RAC. Library cache locks and pins are global resources controlled by GES layer. So, these scripts might not work if these library cache lock and pin waits are global events. Let’s look at what happens in a RAC environment

exec test_kgllk ( false, true); — node 1
exec test_kgllk ( false, true); — node 2

In node1, only one session is visible.

Library cache pin holders/waiters
----------------------------------
                                                                                   pin  pin  pin                                            wait seconds
  SID   SERIAL# USERNAME     MACHINE              OBJ_OWNER  OBJ_NAME              cnt mode  req STATE      EVENT                           time in_wait
----- --------- ------------ -------------------- ---------- -------------------- ---- ---- ---- ---------- ------------------------------ ----- -------
  268     12409 SYS          oraperf              SYS        TEST_KGLLK              0    0    3 WAITING    library cache pin                  0      18
  268     12409 SYS          oraperf              SYS        TEST_KGLLK              3    2    0 WAITING    library cache pin                  0      18

 In node 2, only requestor of the lock is visible. 

lock lock wait seconds SID SERIAL# USERNAME MODULE OBJ_OWNER OBJ_NAME LCK_CNT mode req STATE EVENT time in_wait ----- --------- ------------ ---------- ---------- -------------------- ---------- ---- ---- ---------- ------------------------------ ----- ------- 377 43558 SYS wsqfinc2a SYS TEST_KGLLK 0 0 2 WAITING library cache lock 0 86

Essentially, this script does not work in a RAC environment since it accesses x$ tables directly, which are local to an instance. To understand the issue in a RAC environment we need to access gv$ views, based on x$kgllk, x$kglpn etc. But, I don’t see gv$ views over these x$ tables. We are out of luck there unless we do some more coding.

Nevertheless, we can see lockers and waiters accessing gv$ges_blocking_enqneue to understand locking in RAC.

  1  select inst_id, handle, grant_level, request_level, resource_name1, resource_name2, pid , transaction_id0, transaction_id1
  2* ,owner_node, blocked, blocker, state from gv$ges_blocking_enqueue
SQL> /

   INST_ID HANDLE           GRANT_LEV REQUEST_L RESOURCE_NAME1                 RESOURCE_NAME2                        PID
---------- ---------------- --------- --------- ------------------------------ ------------------------------ ----------
TRANSACTION_ID0 TRANSACTION_ID1 OWNER_NODE    BLOCKED    BLOCKER
--------------- --------------- ---------- ---------- ----------
STATE
----------------------------------------------------------------
         2 00000008DD779258 KJUSERNL  KJUSERPR  [0x45993b44][0x3a1b9eee],[LB]  1167670084,974888686,LB              8700
              0               0          1          1          0
OPENING

         1 00000008E8123878 KJUSEREX  KJUSEREX  [0x45993b44][0x3a1b9eee],[LB]  1167670084,974888686,LB             12741
              0               0          0          0          1
GRANTED


We can see that PID 12741 from instance 1 is holding a library cache global lock [LB]. Global resource in this case is [0x45993b44][0x3a1b9eee],[LB] which uniquely identifies a library cache object at the cluster level. Grant_level is KJUSEREX or Exclusive level and request_level from node 2 is KJUSERPR which is Protected Read level. PID 8700 in node 2 is waiting for library cache lock held by PID 12741 in node1. Using this output and our script output, we can pin point which process is holding library cache lock or pin. While Library cache locks are globalized as global locks in the range of [LA] – [LZ], Library cache pins are also globalized as lock types in the range [NA]-[NZ].

This blog can be read in a document format from
Library_cache_locks_and_library_cache_pin_waits
Update #1: Updated broken links.
Update #2: Updated verbatim after a reader comment.

46 Responses to “Library cache lock and library cache pin waits”

  1. Yasser said

    Excellent article!!!!

    Every month i use to wait for your new articles curiously on this blog…

    Please keep posting articles…

    -Yasser

  2. Really good article. I appreciate alot the small function to provoke an lock/pin.

  3. […] https://orainternals.wordpress.com/2009/06/02/library-cache-lock-and-library-cache-pin-waits/ […]

  4. I have used your brilliant test case today to successfully investigate a nasty ‘library cache lock’ waiting scenario.

    Thank you very much for sharing both the knowledge and the test case !

    Alberto

  5. Rakesh said

    Thanks orainternal. very informative article.

    I also did a small test case on basis of information provided here.

    In my testing scenario, when 1st session (blocker session) is done with its sleeps and complete its execution, even then other session’s (blocking session) are waiting on Latch wait event.
    I thought other session’s (blocking session) will continue their job once 1st session (blocker session) completes its execution but i guess i was wrong. Dont know WHY and HOW.

    That time we doesnt get information about the blocker session but other session are still waiting/hang.

    In real world we can get this situation very often and if we cant get information about the blocker session, we actually cant solve the issue.

    I tried hanganalyze also but couldnt get the information about the blocker session once its gone.

    Can you put some more information on how to get the blocker/culprit session even though its gone or completed its execution.

    –Rakesh

    • Rakesh
      Thanks for visiting my blog. Sorry I don’t have much details in your comment to do further analysis.
      Can you provide more information such as output and scripts etc?

      Cheers
      Riyaj

  6. Rakesh said

    HI Riyaj

    I did my testing on 10.2.0.1 and my testing was exactly as it is mentioned on this blog.

    Session#1 exec test_kgllk(false, true);
    Session #2: exec test_kgllk(true, flase);
    Session #3: exec test_kgllk(true, flase);

    While session #1 was sleeping I executed bot the queries and got the result as execpted and mentioned in blog but after 2 minutes when session #1 was done with sleeping and completed its execution I noticed other 2 sessions were still waiting, so I executed those 2 queries again and got surprised to know that both the sessions are still waiting for the Latch Library cache though no other activity was happenning on the database.

    I hope this information gives u more detail about my test case.

    –Rakesh

  7. Bala said

    Hi,

    It is indeed a good article. Thanks for it.

    I have a question (may be silly).

    An example of, i noticed a library cache lock and i have cleared it by identifying the session causing this event and terminated it (ofcourse with the confirmation that the session is a zombie).

    Just given another thought, will flushing share pool will clear the library cache locks?

    Am looking for some confirmation.

    Thanks in advance.
    Bala

  8. Hans-Peter said

    Hi Riyaj,

    I had a library cache lock issue on an Exadata machine.
    Strange enough the pid given in the query further below could not be related to the pid column in v$process.

    regards Hans-peter

    select inst_id, handle, grant_level, request_level, resource_name1, resource_name2, pid , transaction_id0, transaction_id1
    ,owner_node, blocked, blocker, state from gv$ges_blocking_enqueue

    SQL> /

    INST_ID HANDLE GRANT_LEV REQUEST_L RESOURCE_NAME1 RESOURCE_NAME2 PID TRANSACTION_ID0
    ———- —————- ——— ——— —————————— —————————— ———- —————
    TRANSACTION_ID1 OWNER_NODE BLOCKED BLOCKER STATE
    ————— ———- ———- ———- —————————————————————-
    3 000000034B5A27E0 KJUSEREX KJUSEREX [0x815044d][0x3d81e70],[LB] 135595085,64495216,LB 5324 6946819
    7702 2 0 1 GRANTED

    3 0000000349004C40 KJUSERNL KJUSEREX [0x19][0x2],[RS] 25,2,RS 16371 0
    0 2 1 0 OPENING

    1 00000003494E5BF0 KJUSERNL KJUSERPR [0x815044d][0x3d81e70],[LB] 135595085,64495216,LB 22303 7208961
    1554 0 1 0 OPENING

    1 000000034D5ECF90 KJUSERNL KJUSEREX [0x19][0x2],[RS] 25,2,RS 7019 0
    0 0 1 0 OPENING

    2 0000000349004C40 KJUSERNL KJUSEREX [0x19][0x2],[RS] 25,2,RS 5902 0
    0 1 1 0 OPENING

    4 0000000349004C40 KJUSEREX KJUSEREX [0x19][0x2],[RS] 25,2,RS 24319 0
    0 3 0 1 GRANTED

    6 rows selected.

  9. sriram Sanka said

    Excellent One very helpful !

  10. Eloy said

    Excelent Riyaj. Thanks a lot to public those scripts.

  11. Kamus said

    Thank you very much for sharing this article. Very useful.

  12. Vikram Sharma said

    Hi Riyaz.

    I tried a similar test in 11.2.0.2 version enc. I created a simple proc with an infinite loop;

    create or replace procedure infil
    as
    loop_idx NUMBER:=0;

    begin
    LOOP
    loop_idx:=loop_idx+1;
    END LOOP;

    end;
    Then did the following

    Session 212 ; exec infil;
    session 62 :alter procedure infil compile;
    sessoin 114;exec infil;

    A query on pin waits revealed the following.

    SYS@db1 02-DEC-2011 02:28:09> /

    SID SERIAL# USERNAME MACHINE OBJ_OWNER OBJ_NAME PIN_CNT PIN_MODE PIN_REQ STATE EVENT WAIT_TIME LOCK_REQ
    ———- ———- —————————— —————————— ———- ———- ———- ———- ———- ——————- —————————————————————- ———- ———-
    212 38797 SYS SYS INFIL 3 2 0 WAITED KNOWN TIME SQL*Net message from client 16263 439
    62 58589 SYS SYS INFIL 0 0 3 WAITING library cache pin 0 260
    114 18227 SYS SYS INFIL 0 0 2 WAITING library cache pin 0 2

    However, I am unable to explain this . After some time session 114 acquired the pin.

    SYS@db1 02-DEC-2011 02:28:45> /

    SID SERIAL# USERNAME MACHINE OBJ_OWNER OBJ_NAME PIN_CNT PIN_MODE PIN_REQ STATE EVENT WAIT_TIME LOCK_REQ
    ———- ———- —————————— —————————— ———- ———- ———- ———- ———- ——————- —————————————————————- ———- ———-
    212 38797 SYS SYS INFIL 3 2 0 WAITED KNOWN TIME SQL*Net message from client 16263 441
    62 58589 SYS SYS INFIL 0 0 3 WAITING library cache pin 0 262
    114 18227 SYS SYS INFIL 3 2 0 WAITED KNOWN TIME library cache pin 300 4

    Has something changed in 11g.

    Also how can we check the namespace in 11g from p3 parameters. In 10g it was 100*namespace+mode.

    In 11g i see this in my p3(272876452249603). I believe I can still look at the last digit for mode (here its 3).

    SID STATUS SQL_ID PROGRAM MACHINE WAIT_CLASS USERNAME EVENT STATE
    —— ——– ————- —————————— ————————- —————————————————————- —————————— ——————————————— ——————-
    P1 P2 P3 P1RAW P2RAW BSID BSTATUS waits obj# file# block# ROW#
    ———- ———- ——————————– —————- —————- —— ———– ———- ——- —– ——— —-
    62 ACTIVE 8g07j11zxs7xw sqlplus@db1 (TNS V1-V3) db1 Concurrency SYS library cache pin WAITING
    5.0440E+17 5.0440E+17 272876452249603 070000002CF5DA00 070000003EB04310 114 VALID 572 -1 0 0 0

  13. Naresh said

    Hello Riyaj,

    Your “internals of locks” link is not accessible – can you kindly correct? Thank you for your really good articles.

    Naresh

  14. Nishtha said

    But how do I get rid of these library cache pins? One of my Development servers which is a 2 Node RAC gives this issue very often, and I had to keep killing the sessions that gets blocked due to deadlocks. is that the only solution?

    • Hello Nishta
      Did you meant to say library cache pins? or deadlocks due to library cache pin? I am going to assume that there are no deadlocks and reply.

      Without looking at details, I would guess that your developers are executing some stored object, then trying to recompile the object (may be, their “fix” didn’t work).
      Please go through my blog and print the output of the scripts in the blog. May be, I can review details and help you.
      If this is a deadlock, then I would need a deadlock trace file to understand the issue.

      Thanks
      Riyaj

  15. Artem Gorbyk said

    Hello Riyaj,

    Many thanks for the great article!

    I’m trying your library cache lock example and looks like in 11.2 RAC the self-deadlock (when you compiles your procedure from inside the same procedure ) is now auto detected and the “ORA-04020: deadlock detected while trying to lock object” exception is thrown. Maybe because in RAC it’s a global resource and since 11.2 they added checks to detect this kind of deadlocks.

    In 10.2 RAC and 11.2 single instance it works exactly like you explained – the session hangs trying to compile the procedure while executing it and x$kglpn shows two rows for the same session.

  16. Reblogged this on Christoph's 2 Oracle Cents and commented:
    I came accross 100% library cache pin waits, while trying to compile a procedure which was currently executing.
    After a little research, I came across this fantastic article by Riyaj Shamsudeen.

  17. sam said

    Hi Riyaj,

    The above from a 2-node prod RAC ;
    INST_ID HANDLE GRANT_LEVEL REQUEST_LEVEL RESOURCE_NAME1 RESOURCE_NAME2 PID TRANSACTION_ID0 TRANSACTION_ID1 OWNER_NODE BLOCKED BLOCKER STATE
    1 C0000001BB9A3B40 KJUSEREX KJUSEREX [0x19][0x2],[RS] 25,2,RS 1313 0 0 0 0 1 GRANTED
    2 C0000001BB9A3C90 KJUSERNL KJUSEREX [0x19][0x2],[RS] 25,2,RS 20612 0 0 1 1 0 OPENING

    both pointing to CKPT background process of node 1 blocking node2 ; what is the reason for this ?

    Also ; is there a script to identify the session as well in the same query ?

    Thanks.

  18. VJ said

    Excellent article and well articulated. I found it to be extremely useful . Thanks a bunch!!!!

  19. lytton said

    Did the library cache lock has any relation with dadabase forcelogging ?

  20. Mohammed said

    Reblogged this on Apps DBA notes.

  21. Hi,

    Thanks very much for this article. I just fixed a major fault on a production environment with your solution, avoiding an unneccessary database bounce and further interruption to service.

    Andy
    2nd line Support DBA at BT

  22. rhys said

    hi,
    Thanks very much for this article.But I have a question,you said that’Library cache pins deals with current execution of dependent objects. For example, an underlying objects should not be modified when a session is executing or accessing a dependent object (SQL). So, before parse locks on a library cache object can be broken, library cache pins must be acquired in Exclusive mode and then only library cache objects can be dropped. If a session is executing an SQL, then library cache pins will not be available and there will be waits for library cache pins. Typically, this happens for long running SQL statement. ‘
    if I perform a select query a table,and then i can drop this table in another session,so why do i can drop the table?

    • Hello rhys
      Good question. I updated verbatim to specify stored object. But, to answer your question specifically, If I recall correctly, library cache pins are downgraded to null mode after the start of cursor fetch operation. That’s why you can drop the table in another session while fetching through a cursor. However, you can get ‘object no longer exists’ if the fetch continues beyond after the drop statement.

      Cheers
      Riyaj

  23. Mahadev said

    Hi, can any one tell me to how to remove the cache Library lock from database

  24. […] I also found this helpful blog post that briefly addresses finding the session across RAC nodes: url […]

  25. […] Oracle Core : Essential Internals  for DBA’s and Developers By Jonathan Lewis https://orainternals.wordpress.com/2009/06/02/library-cache-lock-and-library-cache-pin-waits/ […]

  26. […] https://orainternals.wordpress.com/2009/06/02/library-cache-lock-and-library-cache-pin-waits/ […]

  27. […] https://orainternals.wordpress.com/2009/06/02/library-cache-lock-and-library-cache-pin-waits/ […]

  28. I tried to find the answer to my question but did not find any where on the internet therefore I thought of asking you. My question when we use SELECT SYS_CONTEXT(‘USERENV’,’SESSION_USER’) etc.. where does the data comes from, what are different types of context and it’s variables, I mean where is that stored in the database? I did trace 46,53 but did not find any answer. Doc does give you list but I need from database. Please help..

  29. Dabliop said

    Hi Riyaj,

    First of all, thanks for always sharing good information in your blog.
    I would like some advice about a problem. I have opened a SR in MOS but the answers of the support was pratically a copy paste of this blog post (in which I had already read before opening SR.) So, I prefer ask you directly 🙂

    In our RAC 2 nodes production database environment, we are running a session in instance 1 (and only this session is active in this time, “serial execution”) and this session hang’s for a long, interminable time with the event Library cache pin.

    The instance 2 is only used in failover case. Nothing running there.

    In our analysis, we didn’t find out the blocker session (because we have only one execution session). I thought that could be some kind of self-deadlock but the session never end’s (about 5-10 hours in waiting for “Library cache pin” )

    The process is something like this:

    1. Session call a package
    2. This package call another package/procedure
    3. The QUERY (in which be in waiting “LB”) in the from clause and some AND’s call’s another package.function for format data.

    In no time there are another session’s or code in that package’s that execute a compile/re-compile / dbms_lock and so on.

    Here is part of our analysis where didn’t show any request mode being necessary:

    select p.KGLPNSID,p.KGLPNCNT,p.KGLPNMOD,p.KGLPNREQ,o.kglnaobj,s.event
    from x$kglpn p ,x$kglob o,v$session s
    where p.kglpnuse=s.saddr and o.kglhdadr=p.kglpnhdl;

    KGLPNSID KGLPNCNT KGLPNMOD KGLPNREQ KGLNAOBJ EVENT
    ———- ———- ———- ———- ————————- —————————————————————-
    399 6 2 0 EPC_TAB_CADASTRO library cache pin
    399 22 2 0 EPC_LAYOUT library cache pin
    399 1932 2 0 DBMS_SQL library cache pin
    399 498 2 0 LIB_PARAMETROS library cache pin
    399 65 2 0 LIB_STR library cache pin
    399 4 2 0 EPC_LAYOUT_AP_MAN library cache pin
    399 647 2 0 STANDARD library cache pin
    399 26 2 0 PLITBLM library cache pin
    399 4 2 0 DBMS_SQL library cache pin
    399 8 2 0 LIB_PARAMETROS library cache pin
    399 2 2 0 DBMS_SYS_SQL library cache pin
    399 4 2 0 EPC_GRAVA_DADOS library cache pin
    399 -2 2 0 EPC_PARAMETROS library cache pin
    399 6 2 0 EPC_SPED_FPROC library cache pin
    399 6 2 0 EPC_SPED_FPROC library cache pin
    399 2 2 0 LIB_DYN library cache pin
    399 12 2 0 PKG_LOG library cache pin
    399 90 2 0 LIB_RELATORIO_UTIL library cache pin
    399 2 2 0 LIB_RELATORIO_UTIL library cache pin
    399 -2 2 0 EPC_TAB_CADASTRO library cache pin
    399 4 2 0 STANDARD library cache pin
    399 39 2 0 EPC_GRAVA_DADOS library cache pin
    399 5 2 0 EPC_LAYOUT_AP_MAN library cache pin
    399 -2 2 0 EPC_DICIONARIO library cache pin
    399 1 2 0 EPCCP_DICDADOS library cache pin
    399 2 2 0 DBMS_SYS_SQL library cache pin
    399 2 2 0 LIB_STR library cache pin
    399 2 2 0 EPCCP_PROCESSO library cache pin
    399 3 2 0 EPCCP_DICDADOS library cache pin
    399 -2 2 0 LIB_PROC library cache pin
    399 2 2 0 EPCCP_PROCESSO library cache pin
    399 -2 2 0 PKG_LOG library cache pin
    399 3 2 0 LIB_DYN library cache pin
    399 -2 2 0 LIB_PROC library cache pin
    399 24 2 0 EPC_DICIONARIO library cache pin
    399 -2 2 0 EPC_PARAMETROS library cache pin
    399 -2 2 0 EPC_LAYOUT library cache pin

    After change the execution plan the problem gone, but I still don’t know the reason for this only session wait for library cache pin for unlimited time. (I had to kill)..

    Some guesses about this ?

    Oracle EE 11.2.0.4 64 bits on Linux 6.0

    Thank you veru much!

    Cheers.

    Dab

    • Hi Dab,
      Thanks for your kind words.
      Do you have hanganalyze or systemstate dump that shows that the session was waiting for library cache pin? You are querying one node when you query x$ views, do you have any output from the other instance? I know, the other instance is idle, but the resources are still distributed. Any other problems such as gc lost block waits etc?
      I am sorry, I am asking more questions, however, you have not given me enough data to give you an intelligent answer.

      Thanks
      Riyaj

  30. Dabliop said

    Hi Riyaj,

    Yeah, I know I have not given many information, But to be honest I have too much information about this that I got worried to put all here and you to spend a lot of time to see and I be inappropriate !!!

    So, can I send a email to you with this information ? I think it’s better to send the attach files than put all here. What Do you prefer ? What’s better for you.

    Thank you so much.

    Dab

  31. Sankarakumar Ramalingam said

    Hello Riyaj, Nice article. I wanted to ask if I can ask further questions on avoiding this. We have a situation of online users using the package to process transactions and at the same time deploy ddl changes that make the package invalid. when we try to compile we get into this whirlpool of pin locks by application sessions as well as the session trying to recompile.
    I had to kill most of the sessions from one end and simultaneously open sqlplus to issue a recompile using alter package.
    Is there a way we can get around this with minimal hit?
    We met in Hotsos back in 2012 with your AT&T colleagues… Hoping to meet you soon.
    Regards
    Sankarakumar Ramalingam

  32. Jo Holvoet said

    Hello Riyaj,

    first of all of course : thanks for the in-depth article; it has already helped me clear up many issues (even after almost 9 years since you wrote it !). But now I have a situation where I know I have library cache pin waits but I can’t find the info I need to resolve it.

    I’m on 10.2.0.4 RAC. I can reproduce as follows :
    on node 1 : exec test_kgllk ( true, false); sleep / no compile
    on node 2 : exec test_kgllk ( false, true); no sleep / compile

    in this case gv$ges_blocking_enqueue returns nothing …

    Any ideas ?

    kind regards
    Jo

  33. Rakesh RA said

    Hi Riyaz,

    Thanks for the information.

    I am not able to get the scripts from scripts archive. Can you paste the correct link pls?

    Regards,
    Rakesh RA

  34. Debangan said

    Hi Rijaz,

    Thanks for posting the article. A particular insert(insert into x(a,b,c) values (:a,:b,:c)) gets fired multiple times from application parallely in multiple threads is taking around 1 sec in average.The table is partitioned table. AWR report says maximum time consumed was by library cache lock which had consumed around 40% db time.Can you please throw some insights as how to proceed in such cases.

    Regards
    Debangan

    • Using an AWR report to understand a specific SQL statement performance issue is usually not correct, as the scope of AWR is much wider than a SQL statement. So, you should trace the statement further to verify that SQL statement is causing the issue or not.

      Also, I probably need version, whether table has special data types etc.

Leave a comment