Re: Locking row

Поиск
Список
Период
Сортировка
От Michael Fuhr
Тема Re: Locking row
Дата
Msg-id 20060311063308.GA98138@winnie.fuhr.org
обсуждение исходный текст
Ответ на Re: Locking row  ("Larry Rosenman" <ler@lerctr.org>)
Список pgsql-sql
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
specifiedby   LIMIT.  This is because LIMIT is applied first.  The command   selects the specified number of rows, but
mightthen block   trying to obtain lock on one or more of them.  Once the SELECT   unblocks, the row might have been
deletedor 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         |    100002         |    000003         |    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


В списке pgsql-sql по дате отправления:

Предыдущее
От: "Jaime Casanova"
Дата:
Сообщение: Re: READ COMMITTE without START TRANSACTION?
Следующее
От: Michael Glaesemann
Дата:
Сообщение: Re: How can I selet rows which have 2 columns values cross equal?