Search Postgresql Archives

Re: Actual row order in UPDATE and SELECT FOR UPDATE

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



On 2/15/16, Nikolai Zhubr <n-a-zhubr@xxxxxxxxx> wrote:
> Hello all,
>
> I can't find any clear description of how to reliably figure and/or
> enforce specific row (locking) order within UPDATE and SELECT FOR UPDATE
> statements dealing with multiple rows.
> I'd like to get rid of some deadlocks (caused by share locks). While the
> manual explains locks and deadlocks themselves pretty fine (in e.g.
> http://www.postgresql.org/docs/9.5/static/explicit-locking.html
> ) it somehow avoids discussing multi-row updates there. On the other
> hand, the UPDATE section of the manual somehow avoids discussing actual
> update order and respective locking too.

UPDATE deals with rows in order they are fetched from a heap. In a
common case it can be considered as unordered.

> So is it defined anywhere explicitely? Or do I rather have to convert
> all multi-row UPDATE statements into single-row updates and then wrap
> them into e.g. plpgsql loops?

Not a good thought: it'll ruin performance at all.

> That would look quite strange...
> Any hints?

However SELECT can fetch rows in a specific order and locking by FOR
UPDATE clause is applied _after_ sorting. Then you can use CTE[1] with
SELECT ... ORDER BY ... FOR UPDATE to pass all necessary data to the
UPDATE statement. Since UPDATE still deals with unordered rows they
have already locked, and parallel queries are waiting in SELECT
statement rather than in UPDATE:

WITH lck AS (
    SELECT
       id,  -- for WHERE clause in UPDATE

-- you can do calculations here or in-place (see "field2" below)
       field1 + 1 as field1,
       ...
    FROM your_table
    WHERE ...
    ORDER BY id  -- for example
    FOR UPDATE
)
UPDATE your_table t
SET
  field1=lck.field1,  -- lhs is always field of updatable table;
-- rhs must be pointed by a "table" if they are the same in both "tables"

  field2=field2 + 2, -- or if you make changes in-place and it doesn't appear
--in a table mentioned in "FROM" clause, you can avoid table/alias name
...
FROM lck
WHERE
    t.id=lck.id

>
> Thank you,
> Nikolai

[1]http://www.postgresql.org/docs/current/static/queries-with.html
-- 
Best regards,
Vitaly Burovoy


-- 
Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general



[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]
  Powered by Linux