atomic value update?

  • 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.

  • 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![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply