Oracle 11gR1
V$LOCK
lists the locks currently held by the Oracle Database and outstanding requests for a lock or latch.
Column | Datatype | Description |
|
| Address of lock state object |
|
| Address of lock |
|
| Identifier for session holding or acquiring the lock |
|
| 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:
The locks on the system types are held for extremely short periods of time. The system type locks are listed below. |
|
| Lock identifier #1 (depends on type) |
|
| Lock identifier #2 (depends on type) |
|
| Lock mode in which the session holds the lock: · · · · · · · |
|
| Lock mode in which the process requests the lock: · · · · · · · |
|
| Time since current mode was granted |
|
| 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 |
| Buffer hash table instance |
| Library cache pin instance ( |
| Control file schema global enqueue |
| Password File |
| Cross-instance function invocation instance |
| Parallel operation |
| Cursor bind |
| Process startup |
| datafile instance |
| Row cache instance ( |
| Direct loader parallel index create |
| Redo thread global enqueue |
| Mount/startup db primary/secondary instance |
| System change number instance |
| Distributed recovery process |
| SMON |
| Distributed transaction entry |
| Sequence number instance |
| File set |
| Sequence number enqueue |
| Space management operations on a specific segment |
| Sort segment |
| Instance number |
| Space transaction enqueue |
| Instance recovery serialization global enqueue |
| Sequence number value |
| Instance state |
| Generic enqueue |
| Library cache invalidation instance |
| Temporary segment enqueue (ID2=0) |
| Job queue |
| New block allocation enqueue (ID2=1) |
| Thread kick |
| Temporary table enqueue |
| Library cache lock instance lock (A..P = namespace) |
| User name |
| Mount definition global enqueue |
| Undo segment DDL |
| Media recovery |
| 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
No comments:
Post a Comment