Wednesday, April 23, 2008

TX Transaction locks - Example wait scenarios (enqueue)

Subject: TX Transaction locks - Example wait scenarios
Doc ID: Note:62354.1 Type: TROUBLESHOOTING
Last Revision Date: 28-FEB-2008 Status: PUBLISHED


Introduction
~~~~~~~~~~~~
This short article gives examples of TX locks and the waits which can
occur in various circumstances. Often such waits will go unnoticed unless
they are of a long duration or when they trigger a deadlock scenario (which
raises an ORA-60 error).

The examples here demonstrate fundamental locking scenarios which should
be understood by application developers and DBA's alike.


Useful SQL statements
~~~~~~~~~~~~~~~~~~~~~
If you encounter a lock related hang scenario the following SQL statements
can be used to help isolate the waiters and blockers:

Show all sessions waiting for any lock:

select event,p1,p2,p3 from v$session_wait
where wait_time=0 and event='enqueue';

Show sessions waiting for a TX lock:

select * from v$lock where type='TX' and request>0;

Show sessions holding a TX lock:

select * from v$lock where type='TX' and lmode>0;


What is a TX lock ?
~~~~~~~~~~~~~~~~~~~
A TX lock is acquired when a transaction initiates its first change and is
held until the transaction does a COMMIT or ROLLBACK. It is used mainly as
a queuing mechanism so that other sessions can wait for the transaction to
complete. The lock name (ID1 and ID2) of the TX lock reflect the transaction
ID of the active transaction.


Example Tables
~~~~~~~~~~~~~~
The lock waits which can occur are demonstrated using the following
tables. Connect as SCOTT/TIGER or some dummy user to set up the test
environment using the following SQL:

DROP TABLE tx_eg;
CREATE TABLE tx_eg ( num number, txt varchar2(10), sex varchar2(10) )
INITRANS 1 MAXTRANS 1;
INSERT into tx_eg VALUES ( 1, 'First','FEMALE' );
INSERT into tx_eg VALUES ( 2, 'Second','MALE' );
INSERT into tx_eg VALUES ( 3, 'Third','MALE' );
INSERT into tx_eg VALUES ( 4, 'Fourth','MALE' );
INSERT into tx_eg VALUES ( 5, 'Fifth','MALE' );
COMMIT;

In the examples below three sessions are required:

Ses#1 indicates the TX_EG table owners first session
Ses#2 indicates the TX_EG table owners second session
DBA indicates a SYSDBA user with access to


The examples covered below include:

Waits due to Row being locked by an active Transaction
Waits due to Unique or Primary Key Constraint enforcement
Waits due to Insufficient 'ITL' slots in the Block
Waits due to rows being covered by the same BITMAP index fragment


Waits due to Row being locked by an active Transaction
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
When a session updates a row in a table the row is locked by the sessions
transaction. Other users may SELECT that row and will see row as it was
BEFORE the UPDATE occurred. If another session wishes to UPDATE the same
row it has to wait for the first session to commit or rollback. The
second session waits for the first sessions TX lock in EXCLUSIVE mode.

Eg:
Ses#1: update tx_eg set txt='Garbage' where num=1;
Ses#2: update tx_eg set txt='Garbage' where num=1;
DBA: select SID,TYPE,ID1,ID2,LMODE,REQUEST
from v$lock where type='TX';

SID TY ID1 ID2 LMODE REQUEST
---------- -- ---------- ---------- ---------- ----------
8 TX 131075 597 6 0
10 TX 131075 597 0 6

> This shows SID 10 is waiting for the TX lock held by SID 8 and it
> wants the lock in exclusive mode (as REQUEST=6).

The select below is included to demonstrate that a session waiting
on a lock will show as waiting on an 'enqueue' in V$SESSION_WAIT
and that the values of P1RAW, P2 and P3 indicate the actual lock
being waited for. When using Parallel Server the EVENT will be
'DFS enqueue lock acquisition' rather than 'enqueue'.
This select will be omitted from the following examples.

DBA: select sid,p1raw, p2, p3
from v$session_wait
where wait_time=0 and event='enqueue';

SID P1RAW P2 P3
---------- -------- ---------- ----------
10 54580006 131075 597
> ~~~~ ~~ ~~~~~~ ~~~
> type|mode id1 id2
> T X 6 131075 597


The next select shows the object_id and the exact row that the
session is waiting for. This information is only valid in V$SESSION
when a session is waiting due to a row level lock. The statement
is only valid in Oracle 7.3 onwards. As SID 10 is the waiter above
then this is the session to look at in V$SESSION:

DBA: select ROW_WAIT_OBJ#,
ROW_WAIT_FILE#,ROW_WAIT_BLOCK#,ROW_WAIT_ROW#
from v$session
where sid=10;

ROW_WAIT_O ROW_WAIT_F ROW_WAIT_B ROW_WAIT_R
---------- ---------- ---------- ----------
3058 4 2683 0

> The waiter is waiting for the TX lock in order to lock row 0
> in file 4, block 2683 of object 3058.

Ses#1: rollback;
Ses#2: rollback;


Waits due to Unique or Primary Key Constraint enforcement
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
If a table has a primary key constraint, a unique constraint
or a unique index then the uniqueness of the column/s referenced by
the constraint is enforced by a unique index. If two sessions try to
insert the same key value the second session has to wait to see if an
ORA-0001 should be raised or not.

Eg:
Ses#1: ALTER TABLE tx_eg ADD CONSTRAINT tx_eg_pk PRIMARY KEY( num );
Ses#1: insert into tx_eg values (10,'New','MALE');
Ses#2: insert into tx_eg values (10,'OtherNew',null);
DBA: select SID,TYPE,ID1,ID2,LMODE,REQUEST
from v$lock where type='TX';

SID TY ID1 ID2 LMODE REQUEST
---------- -- ---------- ---------- ---------- ----------
8 TX 196625 39 6 0
10 TX 262155 65 6 0
10 TX 196625 39 0 4

This shows SID 10 is waiting for the TX lock held by SID 8 and it
wants the lock in share mode (as REQUEST=4). SID 10 holds a TX lock
for its own transaction.

Ses#1: commit;
Ses#2: ORA-00001: unique constraint (SCOTT.TX_EG_PK) violated
Ses#2: rollback;


Waits due to Insufficient 'ITL' slots in a Block
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
Oracle keeps note of which rows are locked by which transaction in an area
at the top of each data block known as the 'interested transaction list'.
The number of ITL slots in any block in an object is controlled by
the INITRANS and MAXTRANS attributes. INITRANS is the number of slots
initially created in a block when it is first used, while MAXTRANS places
an upper bound on the number of entries allowed. Each transaction which
wants to modify a block requires a slot in this 'ITL' list in the block.

MAXTRANS places an upper bound on the number of concurrent transactions
which can be active at any single point in time within a block.

INITRANS provides a minimum guaranteed 'per-block' concurrency.

If more than INITRANS but less than MAXTRANS transactions want to be
active concurrently within the same block then the ITL list will be extended
BUT ONLY IF THERE IS SPACE AVAILABLE TO DO SO WITHIN THE BLOCK.

If there is no free 'ITL' then the requesting session will wait on one
of the active transaction locks in mode 4.

Eg: Ses#1: update tx_eg set txt='Garbage' where num=1;
Ses#2: update tx_eg set txt='Different' where num=2;
DBA: select SID,TYPE,ID1,ID2,LMODE,REQUEST
from v$lock where type='TX';

SID TY ID1 ID2 LMODE REQUEST
---------- -- ---------- ---------- ---------- ----------
8 TX 327688 48 6 0
10 TX 327688 48 0 4

This shows SID 10 is waiting for the TX lock held by SID 8 and it
wants the lock in share mode (as REQUEST=4).

Ses#1: commit;
Ses#2: commit;
Ses#1: ALTER TABLE tx_eg MAXTRANS 2;
Ses#1: update tx_eg set txt='First' where num=1;
Ses#2: update tx_eg set txt='Second' where num=2;

Both rows update as there is space to grow the ITL list to
accommodate both transactions.

Ses#1: commit;
Ses#2: commit;

Also from 9.2 you can check the ITL Waits in v$segment_statistics
with a query like :
SELECT t.OWNER, t.OBJECT_NAME, t.OBJECT_TYPE, t.STATISTIC_NAME, t.VALUE
FROM v$segment_statistics t
WHERE t.STATISTIC_NAME = 'ITL waits'
AND t.VALUE > 0;

If need be, increase INITTRANS and MAXTRANS.

Waits due to rows being covered by the same BITMAP index fragment
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

Bitmap indexes index key values and a range of ROWIDs. Each 'entry'
in a bitmap index can cover many rows in the actual table.
If 2 sessions wish to update rows covered by the same bitmap index
fragment then the second session waits for the first transaction to
either COMMIT or ROLLBACK by waiting for the TX lock in mode 4.

Eg: Ses#1: CREATE Bitmap Index tx_eg_bitmap on tx_eg ( sex );
Ses#1: update tx_eg set sex='FEMALE' where num=3;
Ses#2: update tx_eg set sex='FEMALE' where num=4;
DBA: select SID,TYPE,ID1,ID2,LMODE,REQUEST
from v$lock where type='TX';

SID TY ID1 ID2 LMODE REQUEST
---------- -- ---------- ---------- ---------- ----------
8 TX 262151 62 6 0
10 TX 327680 60 6 0
10 TX 262151 62 0 4

This shows SID 10 is waiting for the TX lock held by SID 8 and it
wants the lock in share mode (as REQUEST=4).

Ses#1: commit;
Ses#2: commit;


Other Scenarios
~~~~~~~~~~~~~~~
There are other wait scenarios which can result in a SHARE mode wait for a TX
lock but these are rare compared to the examples given above.
Eg: If a session wants to read a row locked by a transaction in a PREPARED
state then it will wait on the relevant TX lock in SHARE mode (REQUEST=4).
As a PREPARED transaction should COMMIT , ROLLBACK or go to an in-doubt
state very soon after the prepare this is not generally noticeable..

Tuesday, April 22, 2008

Finding root blocker (enqueue)

Subject: Detecting Blocking Sessions in RAC and non-RAC (Enqueue Locks) Environments
Doc ID: Note:398519.1 Type: SCRIPT
Last Revision Date: 12-JAN-2007 Status: PUBLISHED

In this Document
Purpose
Software Requirements/Prerequisites
Configuring the Script
Running the Script
Caution
Script
Script Output
References



--------------------------------------------------------------------------------



Applies to: Oracle Server - Enterprise Edition - Version: 7.3.4 to 10.2
Information in this document applies to any platform.
PurposeScript and explanation for finding blocking and blocked sessions in both RAC (multi instance) and non-RAC (single instance) environments.
.
Locking Mechanism
Resources (rows, tables, control files ...) represented by enqueues (TX, TM, CF, ...) can be locked in various modes (i.e. shared, exclusive, ...). Concurrent locking requests can conflict as per compatibility rules. Resources (enqueues) are externalized via GV$RESOURCE and lock requests via GV$LOCK views. Details can be found in
'Oracle® Database Concepts' -> chapter 'Data Concurrency and Consistency' (10.2. version)
.
Locking Conflict Types
1. Local locking conflict (block) - conflicting sessions are connected to the same instance (also applies to one instance of RAC)
Drawback: V$LOCK column BLOCK contains value 1 for blocking lock (session)
2. Global locking conflict (block) - conflicting sessions are connected to different instances (multi instance RAC only)
Drawback: V$LOCK column BLOCK contains value 2 to mark potential conflict (value is always 2 in RAC environments unless there is local conflict)
@ as per Bug:3230663 in 10.2 we should be able to detect global conflict (but still reproducible in 10.2.0.2 @ Linux x86 )
.

Script Principle
Display all sessions holding or requesting lock of resource some session is waiting for. Waiting session has non-zero value of column GV$LOCK.REQUEST. Resource is identified by (TYPE,ID1,ID2 columns of GV$LOCK view).
.
We cannot use GV$LOCK.BLOCK in RAC as it always contains value 2 ("potential locking conflict") unless there is local conflict detected.
.
Finding root blocker
Run query provided in Script section and do one of the following.
(1) Find and kill root blockers
a) - Find oldest resource request - row with highest CTIME (this is row L1)
b) - Exists there another row with the same SID as L1? (this is row L2 if exists)
NOT - this is root blocker, kill it
YES - Find row with the same values of ID1,ID2 columns as in L2 where LOCK > 0 (this is row L3)
- Repeat (b) with L3 (L3 becomes L1) until You find root blocker
(2) Or use simple rule (may not be best)
a) Kill oldest blocking session (highest CTIME)
b) Run script again and repeat (a) until blocking session exists
.

Detecting Object of Locking Conflict
Typically problematic conflicts happen with "DML Locks" (transaction - TX and table - TM lock types) and sometimes it is important to find out subject of the conflict (i.e. fix application design error to prevent issue).
Object name for TM lock can be easily identified as V$LOCK.ID1 is matching to DBA_OBJECTS.OBJECT_ID.
select OBJECT_ID, OWNER,OBJECT_NAME from dba_objects o, V$LOCK l
where l.SID=&sid and l.ID1=o.OBJECT_ID;
Contrary there is no easy way (select) to find out which row (TX) is the session waiting for i.e. to match TX request to TM lock (table name). This is due to locking implementation - pointer in database block points to assigned slot in undo segment (transaction id - XID). It is possible to make a guess of table name (using similarity of CTIME column value). I.e. session is waiting for TX lock for 100s and TM lock on table A has been placed 100s ago (this is just a guess as TM lock could have been acquired for earlier update in the same transaction).
Note: For simplicity GV$LOCK is referred as view but actually this is synonym for view GV_$LOCK (the same applies to V$LOCK).
Software Requirements/PrerequisitesSQL*Plus
Configuring the ScriptThere are no steps required.
Running the ScriptConnect as user able to select from GV$LOCK (typically user having DBA role).
sqlplus '/ as sysdba'
@
CautionThis script is provided for educational purposes only and not supported by Oracle Support Services. It has been tested internally, however, and works as documented. We do not guarantee that it will work for you, so be sure to test it in your environment before relying on it.
Proofread this script before using it! Due to the differences in the way text editors, e-mail packages and operating systems handle text formatting (spaces, tabs and carriage returns), this script may not be in an executable state when you first receive it. Check over the script to ensure that errors of this type are corrected.

Script
-- Author: daniel.x.simon@oracle.com
prompt CTIME is in Seconds
set lines 120
col BLOCK for 9
col LMODE for 9
col INST_ID for 9
col REQUEST for 9
col SID for 999999
select INST_ID, SID, TYPE, ID1, ID2, LMODE, REQUEST, CTIME, BLOCK
from gv$lock where (ID1,ID2,TYPE) in
(select ID1,ID2,TYPE from gv$lock where request>0);

Script Output- example output showing two independent root conflicts
- there can be noted oldest conflict (sid 64 vs 38) is not the root as session 38 is blocked by session 67
INST_ID SID TYPE ID1 ID2 LMODE REQUEST CTIME BLOCK
---------- -------- ---------- --------- ------- ---------- ---------- ---------- ----------
2 212 TX 1114116 1399221 6 0 308 2
1 248 TX 1114116 1399221 0 6 304 0
4 67 TX 6225949 1244199 6 0 26 2
1 38 TX 6225949 1244199 0 6 23 0
2 64 TX 131103 2270514 0 6 117 0
1 38 TX 131103 2270514 6 0 171 2




ReferencesKeywords'RAC' 'BLOCKING~LOCKS' 'ENQUEUE' 'V$LOCK' 'V$LOCK'

Thursday, April 10, 2008

Advanced Features of Oracle Net Services

Address List Parameter LOAD_BALANCE(Client Load Balancing):
When set to on, instructs Oracle Net to progress through the list of protocol addresses in a random sequence, balancing the load on the various listeners. When set to off, instructs Oracle Net to try the addresses sequentially until one succeeds.

This is different from runtime connection load balancing feature which is based on load. (This feature is automatically enabled in shared server configuration and uou must use remote_listener to enable this feature in dedicated server configuration)

Transparent Application Failover(TAF) which is also called runtime failover is controlled by parameter failover_mode and connect-time failover is controlled by parameter failover.