Avoiding Lost Updates: Protecting Data in a Multi-user environment

There is a particular problem with Oracle and other databases where access to data is not serialized (by default), and there are a number of ways this problem is generally dealt with. The problem crops up when you have many users, some of whom may wish to update the same data at around the same time. The process that takes place when a user wishes to update a row is:

Session #1:

  1. Read the data from the database into the client memory.
  2. Make the changes in the client memory.
  3. Write the changes from the client memory to the database.

Between steps 1 and 2 another session (#2) might read the same data (unless you’re in a particularly poorly designed database in which writers block readers; e.g. one database I helped to refactor did just that – it issued exclusive locks on rows every time they were read into a form(!) – this was the first thing we got rid of in the new system), and modify it.

The row isn’t locked, so the other user makes their changes and clicks their “Save” button which commits the changes to the database. Meanwhile, session #1 finally gets to step 3 and saves their changes. If no checks happened, they would overwrite the changes made by session #2.

To illustrate:

  • Session #1 reads the row “Joe Bloggs”.
  • Session #2 reads the row “Joe Bloggs”.
  • Session #2 changes the row to “Jane Bloggs” and saves.
    – now, Session #1 is still looking at “Joe Bloggs” on their screen.
  • Session #1 changes the row to “Joe Jones” and saves.

The problem is that Session #1 has unwittingly undone the change that Session #2 made.

There are a number of ways this problems is approached that I know of:

  1. “Last Update Wins” – just allow the update.
  2. “Column Compare” – all the columns to be updated are compared when updating, and if any are different to the values originally read, an error is returned (e.g. Oracle Forms does this and issues “FRM-40654: Record has been updated by another user. Re-query to see change.”).
  3. “Hash Compare” – this is a variant on the “Column Compare” method used by HTMLDB. It compares a hash of the combined data for the row.
  4. “Timestamp Compare” – the table has a “timestamp” column, which is automatically set to the last date/time when the row was inserted or most recently updated. An update will only succeed if the timestamp of the updated row is the same as the timestamp originally read.
  5. “Version Compare” – the table has a “version” column, which is set to 1 on insert and incremented on update. An update will only succeed if the version of the updated row is the same as the version originally read.

Note: all the “Compare” approaches above do not necessarily require a second query-and-lock on the row prior to the update; the best way to implement these is to add the compare as a predicate for the update – then, if no rows are updated, the caller can tell that the update failed (because the row had been updated or deleted by another session).

Comparison

  1. “Last Update Wins” – This approach may be acceptable for some applications.
  2. “Column Compare” – If only the updated columns are compared, this method means that two sessions can modify different columns in the same row independently.
  3. “Hash Compare” – This method stops two sessions modifying the same row, even if they’re touching different sets of columns.
  4. “Timestamp Compare” – This method requires the timestamp to have sufficient granularity so that a read by one session, followed by an update by another session, will not occur at exactly the same timestamp. Generally milliseconds or microseconds are needed at least, although even this granularity might not be sufficient for some situations. This method also stops two sessions modifying the same row, even if they’re touching different sets of columns.
  5. “Version Compare” – This is a favourite for Java developers and works very well. It is simple to code, computationally cheap, and doesn’t suffer from the timestamp granularity problem. This method also stops two sessions modifying the same row, even if they’re touching different sets of columns.

From the above comments you might think I prefer #5 (Version Compare) but I think it can depend on the requirements of the system you’re working with. Of course, if you’re using Forms or HTMLDB you don’t need to worry about it too much because it’s been largely taken care of for you.

In my next entry I describe how this works when you’re working with updateable views.

Further Reading

User-named locks with DBMS_LOCK
Avoiding Lost Updates #2: Updateable Views

Comments

  1. Web PL/SQL applications generated by Oracle Designer use method #2, column compare by putting the before image of each field in hidden fields on the page. This works fine most of the time. However, long text fields tend get changes in white space characters when you put them on the page. So the field you return in the update is not identical to the field as it appears in the database, even though no-one has really changed it.

    I modify the generated code to ignore these differences – but modifying generated code outside of a generator is a pain because you have to do it EVERY TIME you generate.

Leave a Reply

Your email address will not be published / Required fields are marked *