High contention for write locks on a table used by multiple users can impact processing, if most of the transactions are able to obtain the lock. The sample stored procedure in this section is an example of a method to manage the contention for a write lock on a table. This procedure does not eliminate the write lock contention on the table, but does manage the contention, so that transactions are able to get the write lock.
The following stored procedure code manages the lock contention on a table named dbo.event that is used to record events. The procedure returns the event_id to the caller. This table is in high contention for write locks. The stored procedure dbo.log_event records information in the table dbo.event. If an access error occurs, the error is captured, the hopeful writer sleeps for a five second interval, and then attempts to write to the table again. The five second re-try interval is usually long enough for the contention to be resolved, so the write lock on the dbo.event table is available.
You can modify this code to perform other similar tasks.
if exists (select 1 from sys.sysprocedure a join sys.sysuserperm b on a.creator = b.user_id where a.proc_name = 'log_event' and b.user_name = 'dbo') then drop procedure dbo.log_event; end if; create procedure dbo.log_event(in @event varchar(255)) on exception resume begin declare @event_id bigint; declare @res char(5); set @event_id=0; loop1: loop commit work; select max(event_id)+1 into @event_id from dbo.event; insert dbo.event values (@event_id,@event,current timestamp,null,null); set @res=sqlstate; if @res = ' ' or(@res <> 'QDA29' and @res <> 'QDA11') then leave loop1 end if; call dbo.sleep(5); end loop loop1; commit work; return @event_id end
For more information on using stored procedures, see Chapter 1, “Using Procedures and Batches,” in the System Administration Guide: Volume 2.
To prevent a critical update operation from failing, you may reserve WRITE locks on all required tables in advance. For example, the following example reserves WRITE locks on the tables SalesOrders, Customers, and SalesOrderItems, which are required for a hypothetical update:
BEGIN WHILE TRUE LOOP LOCK TABLE SalesOrders, SalesOrderItems, Customers IN WRITE MODE WAIT '30:00:00'; If SQLCODE indicates that lock could not be acquired then SET status_msg = 'lock for required tables not yet acquired – retrying'; Message to client status_msg; ELSE BREAK; ENDIF; END LOOP; // Locks on SalesOrders, SalesOrderItems, Customers are acquired Update table SalesOrders …; INSERT INTO SalesOrderItems …; LOAD INTO Customers …; COMMIT; END;
For more information on locking and managing locks, see “How locking works”.