The DBMS_LOCK
package provides an interface to Oracle Lock Management services. You can request a lock of a specific mode, give it a unique name recognizable in another procedure in the same or another instance, change the lock mode, and release it.
See Also:
For more information, and an example of how to use theDBMS_LOCK
package, see "About User Locks" in Oracle Database Advanced Application Developer's GuideThis chapter contains the following topics:
Overview
Security Model
Constants
Rules and Limits
Operational Notes
Some uses of user locks:
Providing exclusive access to a device, such as a terminal
Providing application-level enforcement of read locks
Detecting when a lock is released and cleanup after the application
Synchronizing applications and enforcing sequential processing
There might be operating system-specific limits on the maximum number of total locks available. This must be considered when using locks or making this package available to other users. Consider granting the EXECUTE
privilege only to specific users or roles.
A better alternative would be to create a cover package limiting the number of locks used and grant EXECUTE
privilege to specific users. An example of a cover package is documented in the DBMS_LOCK.SQL
package specification file. The abbreviations for these locks as they appear in Enterprise Manager monitors are in parentheses.
The DBMS_LOCK
package uses the constants shown in Table 83-1.
Table 83-1 DBMS_LOCK Constants
Name | Alternate Name(s) | Type | Value | OEM Abbreviation | Description |
---|---|---|---|---|---|
|
|
|
|
- |
- |
|
|
|
|
|
This can be used on an aggregate object to indicate that share locks are being acquired on subparts of the object. |
|
|
|
|
|
This can be used on an aggregate object to indicate that exclusive locks are being acquired on sub-parts of the object. |
|
|
|
|
|
- |
|
|
|
|
- |
This indicates that the entire aggregate object has a share lock, but some of the sub-parts may additionally have exclusive locks. |
|
|
|
|
|
- |
These are the various lock modes (nl -> "NuLl", ss -> "Sub Shared", sx -> "Sub eXclusive", s -> "Shared", ssx -> "Shared Sub eXclusive", x -> "eXclusive").
When another process holds "held", an attempt to get "get" does the following:
HELD MODE | GET NL | GET SS | GET SX | GET S | GET SSX | GET X |
---|---|---|---|---|---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
maxwait constant integer := 32767;
The constant maxwait
waits forever.
User locks never conflict with Oracle locks because they are identified with the prefix "UL". You can view these locks using the Enterprise Manager lock monitor screen or the appropriate fixed views. User locks are automatically released when a session terminates.The lock identifier is a number in the range of 0 to 1073741823.
Because a reserved user lock is the same as an Oracle lock, it has all the functionality of an Oracle lock, such as deadlock detection. Be certain that any user locks used in distributed transactions are released upon COMMIT
, or an undetected deadlock may occur.
DBMS_LOCK
is most efficient with a limit of a few hundred locks for each session. Oracle strongly recommends that you develop a standard convention for using these locks in order to avoid conflicts among procedures trying to use the same locks. For example, include your company name as part of your lock names.
Table 83-3 DBMS_LOCK Package Subprograms
Subprogram | Description |
---|---|
Allocates a unique lock ID to a named lock |
|
Converts a lock from one mode to another |
|
Releases a lock |
|
Requests a lock of a specific mode. |
|
Puts a session to sleep for a specific time |
This procedure allocates a unique lock identifier (in the range of 1073741824 to 1999999999) a specifiedlock name. Lock identifiers are used to enable applications to coordinate their use of locks. This is provided because it may be easier for applications to coordinate their use of locks based on lock names rather than lock numbers.
DBMS_LOCK.ALLOCATE_UNIQUE ( lockname IN VARCHAR2, lockhandle OUT VARCHAR2, expiration_secs IN INTEGER DEFAULT 864000);
Table 83-4 ALLOCATE_UNIQUE Procedure Parameters
Parameter | Description |
---|---|
|
Name of the lock for which you want to generate a unique ID. Do not use lock names beginning with |
|
Returns the handle to the lock ID generated by You can use this handle in subsequent calls to A handle is returned instead of the actual lock ID to reduce the chance that a programming error accidentally creates an incorrect, but valid, lock ID. This provides better isolation between different applications that are using this package.
All sessions using a lock handle returned by |
|
Number of seconds to wait after the last The default waiting period is 10 days. You should not delete locks from this table. Subsequent calls to |
If you choose to identify locks by name, you can use ALLOCATE_UNIQUE
to generate a unique lock identification number for these named locks.
The first session to call ALLOCATE_UNIQUE
with a new lock name causes a unique lock ID to be generated and stored in the dbms_lock_allocated
table. Subsequent calls (usually by other sessions) return the lock ID previously generated.
A lock name is associated with the returned lock ID for at least expiration_secs
(defaults to 10 days) past the last call to ALLOCATE_UNIQUE
with the specified lock name. After this time, the row in the dbms_lock_allocated
table for this lock name may be deleted in order to recover space. ALLOCATE_UNIQUE
performs a commit.
Note:
Named user locks may be less efficient, because Oracle uses SQL to determine the lock associated with a specified name.
This function converts a lock from one mode to another. CONVERT
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
DBMS_LOCK.CONVERT( id IN INTEGER || lockhandle IN VARCHAR2, lockmode IN INTEGER, timeout IN NUMBER DEFAULT MAXWAIT) RETURN INTEGER;
Table 83-5 CONVERT Function Parameters
Parameter | Description |
---|---|
|
User assigned lock identifier, from 0 to 1073741823, or the lock handle, returned by |
|
New mode that you want to assign to the specified lock. For the available modes and their associated integer identifiers, see Constants. |
|
Number of seconds to continue trying to change the lock mode. If the lock cannot be converted within this time period, then the call returns a value of 1 (timeout). |
This function explicitly releases a lock previously acquired using the REQUEST
function. Locks are automatically released at the end of a session. RELEASE
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
DBMS_LOCK.RELEASE ( id IN INTEGER) RETURN INTEGER; DBMS_LOCK.RELEASE ( lockhandle IN VARCHAR2) RETURN INTEGER;
This function requests a lock with a specified mode. REQUEST
is an overloaded function that accepts either a user-defined lock identifier, or the lock handle returned by the ALLOCATE_UNIQUE
procedure.
DBMS_LOCK.REQUEST( id IN INTEGER || lockhandle IN VARCHAR2, lockmode IN INTEGER DEFAULT X_MODE, timeout IN INTEGER DEFAULT MAXWAIT, release_on_commit IN BOOLEAN DEFAULT FALSE) RETURN INTEGER;
The current default values, such as X_MODE
and MAXWAIT
, are defined in the DBMS_LOCK
package specification.
Table 83-9 REQUEST Function Parameters
Parameter | Description |
---|---|
|
User assigned lock identifier, from 0 to 1073741823, or the lock handle, returned by |
|
Mode that you are requesting for the lock. For the available modes and their associated integer identifiers, see Constants. |
|
Number of seconds to continue trying to grant the lock. If the lock cannot be granted within this time period, then the call returns a value of 1 ( |
|
Set this parameter to Otherwise, the lock is held until it is explicitly released or until the end of the session. |