MySQL Forums
Forum List  »  InnoDB

Re: does repeatable read prevent lost update with pessimistic locking?
Posted by: Heikki Tuuri
Date: December 02, 2005 07:07PM

Tapio,

InnoDB's default isolation level is called REPEATABLE READ. But remember that a plain SELECT is still a consistent, non-locking read, and a 'lost update' can happen.

If you are going to use some SELECT result in an UPDATE, or in some way in the logic of your transaction so that the SELECT result affect INSERTs, UPDATEs, or DELETEs, then it is often safest to use SELECT ... FOR UPDATE or SELECT ... LOCK IN SHARE MODE to lock the rows you read with that SELECT. A consistent read does not lock the rows: nothing prevents someone from modifying the rows meanwhile, which can break the logic of your application.

An example of an incorrect program:

counter := SELECT c FROM t WHERE a = 10;
UPDATE t SET c = counter + 1 WHERE a = 10;

You will end up with with a lost update problem. Two transactions can read column a and increment it at the same time.

The correct program:

counter := SELECT c FROM t WHERE a = 10 FOR UPDATE;
UPDATE t SET c = counter + 1 WHERE a = 10;

You must lock the row that you read, to prevent it from being updated by someone else meanwhile.

The isolation level READ UNCOMMITTED (= 'dirty read') is usually not recommended. It has little use in a multiversioning (MVCC) database like InnoDB.

Best regards,

Heikki
Oracle Corp./Innobase Oy
InnoDB - transactions, row level locking, and foreign keys for MySQL

InnoDB Hot Backup - a hot backup tool for InnoDB which also backs up MyISAM tables
http://www.innodb.com/order.php

Options: ReplyQuote


Subject
Views
Written By
Posted
Re: does repeatable read prevent lost update with pessimistic locking?
5740
December 02, 2005 07:07PM


Sorry, you can't reply to this topic. It has been closed.

Content reproduced on this site is the property of the respective copyright holders. It is not reviewed in advance by Oracle and does not necessarily represent the opinion of Oracle or any other party.