Dealing with deadlocks in a DB2 database |
|
Release 9.3 |
NOTE: Applies to geodatabases created with an ArcGIS Server Enterprise license only
Tuning your database to reduce disk I/O contention will help alleviate deadlocks, but it still may not be an uncommon occurrence that the new_edit_state stored procedure call deadlocks the calling application and blocks all other use of the SDE database. Imagine a scenario where the stored procedure acquires a large number of row locks on the STATE_LINEAGES table, exceeding the threshold for the maximum number of locks and attempting to escalate to an exclusive table lock. Unfortunately, the calling application's query already holds a shared lock on the STATE_LINEAGES table, thus leading to a deadlock. Large numbers of row locks arise from having a deep state lineage. This, along with having a low setting for lock list size, guarantees that there will be problems. Given how lock escalation is handled, other deadlock scenarios are also possible. The implication here is that deadlocks may not be an uncommon occurrence at certain sites, depending on one's application and the database configuration. Once again, note that the problem may be aggravated with deep states lineages. Fortunately, DB2 provides tuning parameters to control the size of the lock list (LOCKLIST), the maximum percentage of locks an application can hold (MAXLOCKS), the amount of time a request will wait for a lock to be acquired (LOCKTIMEOUT), frequency interval for deadlock detection (DLCHKTIME) and deadlock rollback behavior (DB2LOCK_TO_RB). Briefly, to increase the lock list capacity and lock escalation threshold, modify the LOCKLIST and MAXLOCKS parameters, respectively. The default value for LOCKLIST and MAXLOCKS in DB2 9 is AUTOMATIC, which enables these parameters for self tuning. This allows DB2's memory tuner to dynamically size the memory resources between different memory consumers. Automatic tuning only occurs if self tuning memory is enabled for the database (SELF_TUNING_MEM=ON). Additionally, you may be able to improve concurrency through lock avoidance by using DB2's Lock Deferral registry variables DB2_EVALUNCOMMITED, DB2_SKIPDELETED, and DB2_SKIPINSERTED. These registry variables permit scans to unconditionally skip uncommitted deletes and inserts. For more detailed information, refer to http://www.ibm.com/developerworks/db2/library/techarticle/dm-0509schuetz/ By default, a lock time-out will roll back the request transaction. To change this behavior to only roll back the statement making the lock request, modify DB2LOCK_TO_RB with db2set DB2LOCK_TO_RB=STATEMENT. The default behavior should be fine for ArcSDE, though. See the DB2 documentation or performance tuning guides for detailed information on properly setting these parameters. An overview of using these parameters is given below.db2 get db cfg
Max storage for lock list (4KB) (LOCKLIST) = 50
Interval for checking deadlock (ms) (DLCHKTIME) = 10000
Percent. of lock lists per application (MAXLOCKS) = 22
Lock time out (sec) (LOCKTIMEOUT) = -1
Max number of active applications (MAXAPPLS) = AUTOMATIC
(Avg # locks per application * 36 * MAXAPPLS) / 4096
(Avg # locks per application * 72 * MAXAPPLS) / 4096
db2 update db cfg using LOCKLIST 200
100 * (Avg # locks per application * 2 * 72 bytes per lock)
/ (LOCKLIST * 4096 bytes)
db2 update db cfg using MAXLOCKS 22
SELECT appl_id FROM TABLE(SNAPSHOT_APPL_INFO('SDE',-1))
as SNAPSHOT_APPL_INFO where appl_name like 'gsrvr%'
SELECT appl_id,appl_name FROM TABLE(SNAPSHOT_APPL_INFO('SDE',-1))
db2 get snapshot for locks on sde > all_locks.txt
db2 get snapshot for locks for application applid
'*LOCAL.DB2.00AB42215335' > app_locks.txt
db2 get snapshot for application applid '*LOCAL.DB2.00AB42215335' > app_info.txt
Application status = Lock-wait
Locks held by application = 1254
Number of SQL requests since last commit = 12
Open local cursors = 1
Most recent operation = Execute
Object type = Table
Tablespace name = USERSPACE1
Table schema = SDE
Table name = STATE_LINEAGES
Mode = X
Status = Converting
Current mode = IX
Lock escalation = YES
select count(*) from state_lineages group by lineage_name
select max(a.depth) from (select count(*) from state_lineages group by lineage_name) a(depth)