Record Lock Info from SQL - IBM i
Record Locks
Record locks often causes the programs to crash if not handled properly. Identifying which job is locking the record is essential to resolve the issue (specially if the locking job is interactive idle for long time).
One way of identifying the Record locks is by using the command DSPRCDLCK (Display Record Locks).
This command accepts the below parameters and allows checking for the locks at the file, member and record level. Output of this command can only be either display or print.
Display Record Locks (DSPRCDLCK)
Type choices, press Enter.
Physical file . . . . . . . . . > TESTFILE Name
Library . . . . . . . . . . . > PREDDY1 Name, *LIBL, *CURLIB
Member . . . . . . . . . . . . . *FIRST Name, *FIRST
Record number . . . . . . . . . *ALL 1-4294967288, *ALL
Output . . . . . . . . . . . . . * *, *PRINT
Physical File - Name of the physical file for which record locks are to be checked. Locks can be checked only for one physical file at a time.
Library - Library in which the physical file is present. Valid values are library name, *LIBL (default) and *CURLIB.
Member - Name of the physical file member for which record locks are to be checked. Specific member name can be entered otherwise *FIRST (default) is considered. Record locks can be checked for only one member at a time.
Record number - Record number can be entered for which we need to check if the specific record is locked. *ALL (default) checks for all the records in the file/member specified.
Output - Output can either be displayed (by using * in Interactive job) or printed to spool file (by using * in Batch job or *PRINT in Interactive/Batch job).
This looks straight forward when we need to check the record locks for a single file or couple of files. And, If we need to resolve the locks manually.
But, If we need to
- Identify the record locks for a group of files.
- Identify the record locks for all the members of a file.
- Identify the record locks for all the files in a Library.
- Identify the record locks by a specific Job.
This can be easily achieved from SQL by running a query on the view RECORD_LOCK_INFO in QSYS2 (System name - RCD_LOCK).
E.g.:
Identify the record locks for a group of files.
SELECT * FROM QSYS2/RECORD_LOCK_INFO WHERE TABLE_NAME IN ('TESTFILE', 'TESTFILE1', 'TESTFILE2') ;
Identify the record locks for all members of a file - Just querying for a file name (and library) would return the locks present in all members of the file.
SELECT * FROM QSYS2/RECORD_LOCK_INFO WHERE TABLE_SCHEMA = 'PREDDY1' AND TABLE_NAME = 'TESTFILE' ;
Identify the record locks for all the files in a Library.
SELECT * FROM QSYS2/RECORD_LOCK_INFO WHERE TABLE_SCHEMA = 'PREDDY1' ;
Identify the record locks by a specific Job.
SELECT * FROM QSYS2/RECORD_LOCK_INFO WHERE JOB_NAME = '123456/PREDDY/QPADEV1234' ;
Apart from these, the query can be run based on any of the columns available in the view RECORD_LOCK_INFO.
Below are the columns present in the view.
TABLE_SCHEMA (TABSCHEMA) - Name of the schema.
TABLE_NAME (TABNAME) - Name of the table.
TABLE_PARTITION (TABPART) - Name of the table partition or member that contains the locked record.
SYSTEM_TABLE_SCHEMA (SYS_DNAME) - System name of the schema.
SYSTEM_TABLE_NAME (SYS_TNAME) - System name of the table
SYSTEM_TABLE_MEMBER (SYS_MNAME) - The name of the member that contains the locked record.
RELATIVE_RECORD_NUMBER (RRN) - The relative record number (RRN) of the record that is locked.
LOCK_STATE (LOCK_STATE) - The lock condition for the record. Valid values are READ (The record is locked for read. Another job may read the same record but cannot lock the record for update intent. The record cannot be changed by another job as long as one job holds a read lock on the record.), UPDATE (The record is locked for update intent. Another job may read the record but may not obtain a read or update lock on it until the lock is released.) and INTERNAL (The row is locked internally for read. For a short time the operating system holds an internal lock to access the row. Another job may read the same row and may even have the row locked for update intent. However, if another job does have the row locked for update intent, the actual change of the row will not proceed until the internal lock is released.)
LOCK_STATUS (STATUS) - The status of the lock. Valid values are HELD (The lock is currently held by the job.), WAITING (The job is waiting for the lock.)
LOCK_SCOPE (LOCK_SCOPE) - The scope of the lock. Valid values are JOB, THREAD and LOCK SPACE
JOB_NAME (JOB_NAME) - The qualified job name.
THREAD_ID (THREAD_ID) - The thread that is associated with the lock. If a held lock is job scoped, returns the null value. If a held lock is thread scoped, contains the identifier for the thread holding the lock. If the scope of the lock is to the lock space and the lock is not held, contains the identifier of the thread requesting the lock. If the lock is requested but not yet available, contains the identifier of the thread requesting the lock.
LOCK_SPACE_ID (LOCKID) - When the LOCK_SCOPE column value is LOCK SPACE and the lock is being waited on by a thread, contains the lock space ID value for which the lock is being waited on. Otherwise, contains the null value.
If you have any Suggestions or Feedback, Please leave a comment below or use Contact Form.
Comments
Post a Comment