Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««1234»»»

Record locking Expand / Collapse
Author
Message
Posted Monday, December 31, 2012 9:33 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 4:53 PM
Points: 1,746, Visits: 2,553
MS provides "sp_getapplock", and the corresponding "sp_releaseapplock", to help you do this. With them, you can leverage SQL's already-built-and-tested locking mechanisms for your own logical locking. You also want to look at APPLOCK_TEST() (and maybe APPLOCK_MODE()).

SQL DBA,SQL Server MVP('07, '08, '09)
I'm not fat, I'm gravity challenged.
Post #1401422
Posted Monday, December 31, 2012 11:17 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Friday, August 16, 2013 8:28 AM
Points: 249, Visits: 460
You could take another approach and move the concept of locking or checking out a record and subsequent notifications of said lock to a middle tier, perhaps a WCF service or something similar. That would be far simpler, than reinventing the locking mechanisms and all that it entails.

Post #1401456
Posted Monday, December 31, 2012 12:24 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 3:16 PM
Points: 5,986, Visits: 6,931
Scott, the trouble with sp_applock is that it's designed around single user - single process aspects. My understanding of the OP's question revolves around multiple dentists accessing multiple clients simultaneously, but he wants to make sure that none can step on the other's work.

Instead of rebuilding the wheel, there's another method of dealing with this but I personally hate it, because like the other method, so many things can go wrong. Just less moving parts.

Look into Transactions and Serializable isolation. What you'll be looking to do is have the application code control your transactions (and do NOT share connections) so that you begin this process by setting the connection to serializable isolation, then opening a transaction, then reading the particular rows you need from all tables. This share-locks them to that account. But, what you do during that read is force the exclusive lock via join hints.

From there, you let them do their work and close the transaction when they're done.

Be aware, however, that this is NOT as granular as you think it is. This approach can hose you up very quickly depending on how much data you're pulling, as you won't be doing just row locks, but page and table locks because of the way memory and data storage is managed in SQL Server. It requires JUST as much testing and even more optimization than the other method to make sure you're locking as little as possible for each user's access.

So, since we've been telling you just how hard this could be, let me make a recommendation for a much easier to approach method that is less likely to shoot you in both feet.

Start with adding a last access datetime column to all the tables that you're looking to lock for a particular user's modification. Pull said data for the user. When they choose to edit any data, have the system go through and check to make sure noone's tried to edit in the last five minutes via this column, then update all the records just for the datetime piece. Have your code disallow editing to proceed blindly after five minutes, where it would have to go through and re-check the timestamps (to make sure another user didn't come in while they got their coffee and talked to the assistant) to make sure their allowable edits are still valid. If they're still allowed, let them commit the changes.

Does this do exactly what you were looking for? No. But it is MUCH easier to implement and much less likely to end up with your system locked out requiring massive developer involvement to get the production system to re-release. At worst, everyone just has to wait five minutes.



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1401476
Posted Monday, December 31, 2012 12:36 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 4:53 PM
Points: 1,746, Visits: 2,553
You could also add an "in-use" column to each row which is set when someone accesses it, and unset when they close it and/or after a certain period of time has elapsed.

SQL DBA,SQL Server MVP('07, '08, '09)
I'm not fat, I'm gravity challenged.
Post #1401481
Posted Thursday, January 03, 2013 6:49 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, February 07, 2013 11:57 PM
Points: 20, Visits: 36
Many thanks for your replies. I did some research and found out the following:

Scott regarding "sp_getapplock", it appears that from what I read, it should not be the first choice, especially if the record will be checked out for some time.

Craig are you referring to something like this, where there should be a check if the record is not committed in a reasonable amount of time?
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;

BEGIN TRANSACTION;

select * from ...

update ...

COMMIT TRANSACTION;

Post #1402341
Posted Thursday, January 03, 2013 9:41 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, February 07, 2013 11:57 PM
Points: 20, Visits: 36
After some more read maybe this would lock a record (and only one record) until all work is done,

BEGIN TRAN

SELECT * FROM tblName WITH (HOLDLOCK, ROWLOCK)
WHERE ID = someID

/* While the record is locked do work*/

COMMIT TRAN

Post #1402453
Posted Thursday, January 03, 2013 9:47 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 12:20 PM
Points: 41,529, Visits: 34,445
john 60195 (1/3/2013)
After some more read maybe this would lock a record (and only one record) until all work is done


No.
Rowlock just says *start* with row locks. Not only ever take row locks. If there's a lot of row locks taken, SQL escalates to table locks.

It is a very, very bad idea to start a transaction and then allow the user to input stuff, watch the screen, go for lunch, take the weekend off, etc. You'll end up with major blocking and probably a tonne of support calls for 'my session's hanging/timing out'. Transactions should always start and commit in a single database call.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1402456
Posted Thursday, January 03, 2013 1:24 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 3:16 PM
Points: 5,986, Visits: 6,931
john 60195 (1/3/2013)
After some more read maybe this would lock a record (and only one record) until all work is done,



I just want to second what Gail said above. You cannot force the system to only lock a particular row. You can suggest and optimize to that's what it *wants* to do, but you can't force it. Cross platform transactions also come with their own issues, but I just wanted to present an alternative to rebuilding the wheel from scratch.

You really want to use a self-releasing indicator, like a 'last updater' timestamp, on the record. This way it's self managing in case of user disconnects, network issues, and anything else of the like.



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1402527
Posted Saturday, January 05, 2013 1:25 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, February 07, 2013 11:57 PM
Points: 20, Visits: 36
Thanks Gail & Craig for your input,

Would use of the TIMESTAMP data type be of any help? As I understand it, it is used for version-stamping table rows. I have not tried it yet, but an UPDATE could go ahead WHERE ID = specificID AND LOGTIMESTAMP = SpecificTimeStamp. If the record is changed while another user had it in edit mode the Update would generate an error. Will try it and report.

John
Post #1403201
Posted Saturday, January 05, 2013 1:48 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 12:20 PM
Points: 41,529, Visits: 34,445
Yup, that's an alternative way of doing things. Your original version we would call pessimistic concurrency (I expect someone else to try to change the same data, hence I'll lock it). The version with a rowversion (don't call it a timestamp, that type name is deprecated) is optimistic concurrency (I don't thing anyone will change the data, but I'll check when I save, just in case)

You can do it with a row version, you can do it with a datetime column last modification date, you can do it by comparing the columns with what they were when you read the row. All work.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1403203
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse