Showing posts with label Locks. Show all posts
Showing posts with label Locks. Show all posts

Thursday, June 28, 2018

How to solve ORA-00069: cannot acquire lock -- table locks disabled

Unfortunately, the only known way out of this is to

1. stop the database
2. start in restricted mode with "startup restrict"
3. enable table locks:
 alter table scott.emp enable table lock;
4. startup the database in normal mode, and you will now be able to aquire locks on the table.

Wednesday, June 13, 2018

Display the current locks in a tree-like fashion



Oracle provides some built-in scripts and views that can be used to monitor locks in the database


http://docs.oracle.com/database/121/ADMIN/monitoring.htm#ADMIN11255

To illustrate this, I will open a session that updates a table, then create another session that updates the same table:

Session# 1:
select SYS_CONTEXT('userenv','con_name') "container name",
       SYS_CONTEXT('userenv','con_id') "container id",
       SYS_CONTEXT('userenv','CURRENT_SCHEMA') "Current schema",
       SYS_CONTEXT('userenv','SID') "SID"
FROM DUAL

container name       container id         Current schema                 SID
-------------------- -------------------- ------------------------------ -----
VEGDB01              3                    SCOTT                          362

--Update a the table rows:
 update emp set sal=1000;

14 rows updated.


I will keep the session alive, without doing commit/rollback.

From session# 2:
select SYS_CONTEXT('userenv','con_name') "container name",
        SYS_CONTEXT('userenv','con_id') "container id",
        SYS_CONTEXT('userenv','CURRENT_SCHEMA') "Current schema",
        SYS_CONTEXT('userenv','SID') "SID"
FROM DUAL;

container name       container id         Current schema                 SID
-------------------- -------------------- ------------------------------ -----
VEGDB01              3                    SCOTT                          130

--Update the same rows as in session# 1:
update emp set sal=2000;

This session will not give you the prompt back, as it is trying to aquire a lock on the table rows.

I then ran the utllockt.sql script:
sqlplus / as sysdba @$ORACLE_HOME/rdbms/admin/utllockt.sql

Output (abbreviated):
WAITING_SESSION   LOCK_TYPE         MODE_REQUESTED  MODE_HELD     LOCK_ID1          LOCK_ID2
----------------- ----------------- --------------- ------------ ----------------- -----------------
362               None                
   130            Transaction       Exclusive       Exclusive     524308             17836


The leftmost session (362) is blocking the sessions listed underneath it.

Let's check what the session with SID = 130 is doing:
SELECT sess.sid,sess.serial#,sess.sql_id,s.plan_hash_value, s.child_number,sess.client_info,substr(sql_text,1,30) "sql text",sess.program,sess.pq_status,
        decode(sess.blocking_session_status,'VALID','blocked', 'NO HOLDER','Not blocked') "blocked?",
        sess.blocking_session "blocking session SID",sess.event
FROM V$SESSION sess inner join v$sql s 
on (sess.sql_id = s.sql_id)
WHERE sess.SID IN (130)
and sess.sql_child_number = s.child_number;

This query confirms the output from the Oracle supplied utllockt.sql, and reveals what the blocking session is trying to do, in this case, to execute DML on table rows as that are already being locked for update:

SID SERIAL# SQL_ID PLAN_HASH_VALUE sql text PROGRAM PQ_STATUS blocked? blocking session SID EVENT
130
9755
1gpj28ptjj43p
1494045816
update emp set sal=2000 sqlplus@ ENABLED blocked
362
enq: TX - row lock contention


Thursday, February 15, 2018

How to use dbms_application_info to create session details



The package dbms_application_info lets you add supplemental information in your session, which can be picked up in the V$SESSION view.

A very useful package, which I have used many times myself, but for some reason it is rarely used by Developers. It should typically be called before beginning a transaction in order to register and name a transaction/client_info/module for later use when measuring performance across an application.

exec dbms_application_info.set_client_info('Step one.');
exec dbms_application_info.set_module('module1','gettrades');

Here is an example where I was troubleshooting a "hanging" delete statement for a customer.
Turned out the problem was concurrency locks:
select SID,SERIAL#,SQL_ID,STATUS,osuser,machine,schemaname,MODULE,ACTION,CLIENT_INFO,LOGON_TIME,EVENT,STATE,FINAL_BLOCKING_SESSION "blocking"
from v$session 
WHERE schemaname='SALES'
AND STATUS='ACTIVE'
UNION
select SID,SERIAL#,SQL_ID,STATUS,osuser,machine,schemaname,MODULE,ACTION,CLIENT_INFO,LOGON_TIME,EVENT,STATE,FINAL_BLOCKING_SESSION "blocking"
from v$session 
where SID = (SELECT FINAL_BLOCKING_SESSION FROM V$SESSION WHERE schemaname='SALES' AND STATUS='ACTIVE');

In the resulting two rows, the first one is mine, the second is the blocking session:
SID SERIAL# SQL_ID STATUS OSUSER MACHINE SCHEMANAME MODULE ACTION CLIENT_INFO LOGON_TIME EVENT STATE blocking
32
4759
5jg1839cyxzgh ACTIVE oracle mytestserver.com SALES DELETE MODULE DELETE_SCHEMA Delete XSD. 15.02.2018 12:04:43 library cache lock WAITING
2285
2285
48625
g3bc37vx8fy3u INACTIVE JIM COMPANY\PC-157 SALES SQL*Plus     14.02.2018 14:08:57 SQL*Net message from client WAITING
NULL

For more information, check the documentation
Tracing Enhancements Using DBMS_MONITOR (In 10g, 11g and Above) (Doc ID 293661.1) at My Oracle Support.

Wednesday, January 20, 2016

What is the package SYS.USER_LOCK?

Recenty I was migrating a database with a package that wouldn't compile because it couldn't find the package called upon in its code:

SQL> ALTER PACKAGE mypackage compile body; 

Warning: Package body altered with compilation errors.

SQL> show errors
Errors for PACKAGE BODY MVA3.MYPACKAGE:

PLS-00201: identifier 'USER_LOCK.SLEEP' must be declared

According to PSOUG, there are "four separate ways to induce a sleep into PL/SQL."

•dbms_backup_restore
•dbms_drs
•dbms_lock
•user_lock


PSOUG continues: "Note that USER_LOCK package is not part of the default Oracle installation"

Install as follows:
cd $ORACLE_HOME/rdbms/admin
sqlplus / as sysdba @userlock.sql

Friday, August 29, 2014

Login storm against database caused exhausted library cache

One of our databases experienced massive contention in the shared pool, in form of wait events alerted as "library cache locks".

The database was very small indeed, so my natural instinct was to throw some more memory at the virtual host, and rearrange the memory parameters.

This turned out to be a misconception; the resources were sufficient for the instance to work properly.

The problem was caused by an incorrect password configuration on the application server.

What we could observe was:

  • A totally exhausted shared pool, caused by "library cache lock"
  • The SQL that seemed to be repeatedly executed was
    SELECT /*+ connect_by_filtering */
              privilege#, LEVEL
          FROM sysauth$
    CONNECT BY grantee# = PRIOR privilege# AND privilege# > 0
    START WITH grantee# = :1 AND privilege# > 0;
    
    
    SELECT privilege#
      FROM sysauth$
    WHERE (grantee# = :1 OR grantee# = 1) AND privilege# > 0;
    
  • The V$EVENT_NAME view showed that the wait event was accompanied by the additional information found in the columns parameter1 through parameter3, which turned out to be helpful further on:
    select  name, wait_class,parameter1,parameter2,parameter3
    from v$event_name
    where wait_class = 'Concurrency'
    and name = 'library cache lock';
    

    NAME WAIT_CLASS PARAMETER1 PARAMETER2 PARAMETER3
    library cache lock Concurrency handle address lock address 100*mode+namespace

    Further research showed that the problem was due to a built-in delay between failed login attempts in Oracle 11g:

    "The 'library cache lock' wait is seen due to the fact that the account status gets updated due to incorrect login.
    To prevent password guessing attack, there's a sleep() in the code when incorrect login attempts exceed count of 3.
    And because of this sleep() you see a wait on library cache, as the process is yet to release the lock."


  • In release 11.1.0.7, patch 7715339 was released to remove this delay.
  • In release 11.2.X, the DBA must set an event to remove the delay, as follows:

    alter system set events '28401 trace name context forever, level 1'; 
    

    According to Oracle, the purpose of the built-sleep is to make it harder to succeed in a "password guessing attack", particularly in cases where FAILED_LOGIN_ATTEMPTS is set to UNLIMITED. Oracle Development is pointing out that disabling the sleep-function is not recommended. A better solution is to set the FAILED_LOGIN_ATTEMPTS to a reasonable value.
    When the number of failed login attempts for a session hits the limit, the account will be locked. Subsequent logon attempts with incorrect password will then be rejected immediately without any contention in the library cache.

    See Bug 15882590 : 'LIBRARY CACHE LOCK' DURING WRONG PASSWORD LOGON ATTEMPTS on My Oracle Support (MOS) for further information.


  • Thursday, February 13, 2014

    An easy way to find DML locks

    The view DBA_DML_LOCKS is a convenient view to use if you want to identify locks caused by uncommited DML statements.

    Consider the following simple example:

    INSERT INTO FAMILY_TREE
    (PERSON_ID, FULL_NAME, GENDER, CITIZENSHIP, COUNTRY_OF_RESIDENCE)
    VALUES
    (5, 'Arne Kåsa', 'M', 'Norwegian', 'Sweden');

    -- Do not commit --

    Logged in as a privileged user from another session, execute:

    SELECT * FROM DBA_DML_LOCKS WHERE OWNER = 'VEGARDK';

    SESSION_ID OWNER NAME MODE_HELD MODE_REQUESTED LAST_CONVERT BLOCKING_OTHERS
    362 VEGARDK FAMILY_TREE Row-X (SX) None 39 Not Blocking

    COMMIT;

    SELECT * FROM DBA_DML_LOCKS WHERE OWNER = 'VEGARDK';

    No rows returned.