Wednesday, September 10, 2008

V$LOCK

Oracle 11gR1

V$LOCK lists the locks currently held by the Oracle Database and outstanding requests for a lock or latch.

Column

Datatype

Description

ADDR

RAW(4 | 8)

Address of lock state object

KADDR

RAW(4 | 8)

Address of lock

SID

NUMBER

Identifier for session holding or acquiring the lock

TYPE

VARCHAR2(2)

Type of user or system lock

The locks on the user types are obtained by user applications. Any process that is blocking others is likely to be holding one of these locks. The user type locks are:

TM - DML enqueue

TX - Transaction enqueue

UL - User supplied

The locks on the system types are held for extremely short periods of time. The system type locks are listed below.

ID1

NUMBER

Lock identifier #1 (depends on type)

ID2

NUMBER

Lock identifier #2 (depends on type)

LMODE

NUMBER

Lock mode in which the session holds the lock:

· 0 - none

· 1 - null (NULL)

· 2 - row-S (SS)

· 3 - row-X (SX)

· 4 - share (S)

· 5 - S/Row-X (SSX)

· 6 - exclusive (X)

REQUEST

NUMBER

Lock mode in which the process requests the lock:

· 0 - none

· 1 - null (NULL)

· 2 - row-S (SS)

· 3 - row-X (SX)

· 4 - share (S)

· 5 - S/Row-X (SSX)

· 6 - exclusive (X)

CTIME

NUMBER

Time since current mode was granted

BLOCK

NUMBER

A value of either 0 or 1, depending on whether or not the lock in question is the blocker.

Values for the TYPE Column: System Types

System Type

Description

System Type

Description

BL

Buffer hash table instance

NA..NZ

Library cache pin instance (A..Z = namespace)

CF

Control file schema global enqueue

PF

Password File

CI

Cross-instance function invocation instance

PI, PS

Parallel operation

CU

Cursor bind

PR

Process startup

DF

datafile instance

QA..QZ

Row cache instance (A..Z = cache)

DL

Direct loader parallel index create

RT

Redo thread global enqueue

DM

Mount/startup db primary/secondary instance

SC

System change number instance

DR

Distributed recovery process

SM

SMON

DX

Distributed transaction entry

SN

Sequence number instance

FS

File set

SQ

Sequence number enqueue

HW

Space management operations on a specific segment

SS

Sort segment

IN

Instance number

ST

Space transaction enqueue

IR

Instance recovery serialization global enqueue

SV

Sequence number value

IS

Instance state

TA

Generic enqueue

IV

Library cache invalidation instance

TS

Temporary segment enqueue (ID2=0)

JQ

Job queue

TS

New block allocation enqueue (ID2=1)

KK

Thread kick

TT

Temporary table enqueue

LA .. LP

Library cache lock instance lock (A..P = namespace)

UN

User name

MM

Mount definition global enqueue

US

Undo segment DDL

MR

Media recovery

WL

Being-written redo log instance

Note:

1. Show sessions that are blocking each other

select 'SID ' || l1.sid ||' is blocking ' || l2.sid blocking

from v$lock l1, v$lock l2

where l1.block =1 and l2.request > 0

and l1.id1=l2.id1

and l1.id2=l2.id2;

2. Show locked objects

select oracle_username || ' (' || s.osuser || ')' username

, s.sid || ',' || s.serial# sess_id

, owner || '.' || object_name object

, object_type

, decode( l.block

, 0, 'Not Blocking'

, 1, 'Blocking'

, 2, 'Global') status

, decode(v.locked_mode

, 0, 'None'

, 1, 'Null'

, 2, 'Row-S (SS)'

, 3, 'Row-X (SX)'

, 4, 'Share'

, 5, 'S/Row-X (SSX)'

, 6, 'Exclusive', TO_CHAR(lmode)) mode_held

from v$locked_object v

, dba_objects d

, v$lock l

, v$session s

where v.object_id = d.object_id

and v.object_id = l.id1

and v.session_id = s.sid

order by oracle_username

, session_id;

Oracle dynamic performance views

Oracle data dictionary views

No comments:

Post a Comment