On Fri, Mar 10, 2006 at 02:57:51PM -0600, Larry Rosenman wrote: > Flavio Suguimoto wrote: > > I need to mark a row with a value in a column, but first i need to > > select the first row without this mark. But in some concurrents cases > > i mark the row twice. How can i lock the row to avoid others session > > get it? > > > > TABLE TICKET > > TICKET_NUMBER | MARK > > 00001 | 1 > > 00002 | 0 > > > > I need to select the first row with 0 in MARK column and then mark it > > with 1. > > look at the FOR UPDATE in the select docs.
If you use FOR UPDATE with LIMIT then see the following in the SELECT documentation: It is possible for a SELECT command using both LIMIT and FOR UPDATE/SHARE clauses to return fewer rows than specified by LIMIT. This is because LIMIT is applied first. The command selects the specified number of rows, but might then block trying to obtain lock on one or more of them. Once the SELECT unblocks, the row might have been deleted or updated so that it does not meet the query WHERE condition anymore, in which case it will not be returned. For example, suppose you have the following data: ticket_number | mark ---------------+------ 00001 | 1 00002 | 0 00003 | 0 (3 rows) Two concurrent transactions, T1 and T2, both run the following query: SELECT * FROM ticket WHERE mark = 0 LIMIT 1 FOR UPDATE; One transaction, say T1, will get the following row: ticket_number | mark ---------------+------ 00002 | 0 (1 row) T2 will block until T1 ends. If T1 rolls back or doesn't update the row then T2 will get the above row. But if T1 updates the row so that mark = 1 and then commits, then T2 will get an empty result set instead of getting the next row with mark = 0. The queries could use LIMIT 2 instead of LIMIT 1 and update only the first row that came back, but then you'd have the same problem with a third concurrent transaction (and with LIMIT 3 and a fourth transaction, and so on). -- Michael Fuhr ---------------------------(end of broadcast)--------------------------- TIP 1: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly