Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


atomic value update?


atomic value update?

Author
Message
aerojockey
aerojockey
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 7
I have an application that needs to make an atomic update to an item in a table. It has to read the value, do something complicated to it, and write it back, and in the meantime no one else should be able to overwrite the value. So what I'm doing is like this:

SELECT state FROM tab WHERE id=7



Then the program does something complex based on value of state. Then:

UPDATE tab SET state=some_new_value WHERE id=7



Problem is, between the SELECT and UPDATE, some other user can come in an overwrite state, because the table hasn't been locked at that point.

My solution was to make a trivial update to the table first, like this:

UPDATE table SET id=7 WHERE id=7



This locks the table from overwriting by other users. Then I can proceed with the SELECT, and COMMIT the transaction after the UPDATE. This does what I want to, mostly, but it feels icky, and I am afraid it make my code prone to unpleasant corner cases if another user deletes the row.

This app is otherwise vanilla SQL with simple data requirements. I don't know much about SQL Server in particular.

Thanks for any suggestions.
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4259 Visits: 6431
aerojockey (1/7/2013)
I have an application that needs to make an atomic update to an item in a table. It has to read the value, do something complicated to it, and write it back, and in the meantime no one else should be able to overwrite the value. So what I'm doing is like this:

SELECT state FROM tab WHERE id=7



Then the program does something complex based on value of state. Then:

UPDATE tab SET state=some_new_value WHERE id=7



Problem is, between the SELECT and UPDATE, some other user can come in an overwrite state, because the table hasn't been locked at that point.

My solution was to make a trivial update to the table first, like this:

UPDATE table SET id=7 WHERE id=7



This locks the table from overwriting by other users. Then I can proceed with the SELECT, and COMMIT the transaction after the UPDATE. This does what I want to, mostly, but it feels icky, and I am afraid it make my code prone to unpleasant corner cases if another user deletes the row.

This app is otherwise vanilla SQL with simple data requirements. I don't know much about SQL Server in particular.

Thanks for any suggestions.


This can be done as follows (designed exactly for this case):


BEGIN TRAN T1;
SELECT state FROM tab WHERE id=7 WITH (UPDLOCK);
UPDATE tab SET state=some_new_value WHERE id=7;
COMMIT TRAN T1;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search