PostgreSQL 9.5 is just around the corner and many cool new features have been added to this wonderful release. One of the most exciting ones is definitely SKIP LOCKED.
To make sure that concurrent operations don't lead to race conditions, SELECT FOR UPDATE has been supported for many years now and it is essential to many applications. The problem, however, is: If two SELECT FOR UPDATE statements are executed concurrently, it might happen that one has to wait for a long period of time. In case of high-concurrency this can lead to bottlenecks and to subsequent troubles.
In addition to that there is one more thing to consider: Let us assume somebody has locked a line because he wants to book an airline ticket. It makes sense that some other person does not see this seat anymore because it is most likely being booked anyway. Skipping locked rows can therefore make sense from a business point of view.
One more example would be: Give me all trouble tickets, which are still open, but which are not currently being worked on (= SELECT FOR UPDATE).
Here is a simple demo table containing 4 rows:
1 2 3 4 |
test=# CREATE TABLE t_demo AS SELECT * FROM generate_series(1, 4) AS id; SELECT 4 |
The content is not too surprising:
1 2 3 4 5 6 7 8 |
test=# TABLE t_demo; id ---- 1 2 3 4 (4 rows) |
Now let us assume that one user locks a row:
1 2 3 4 5 6 7 |
test=# BEGIN; BEGIN test=# SELECT * FROM t_demo WHERE id = 2 FOR UPDATE; id ---- 2 (1 row) |
If somebody else reads all the data but skips locked rows, one row is missing from the result set:
1 2 3 4 5 6 7 8 9 |
test=# BEGIN; BEGIN test=# SELECT * FROM t_demo FOR UPDATE SKIP LOCKED; id ---- 1 3 4 (3 rows) |
As you can see, the second row has been excluded because it is already locked. Note that the second user is NOT blocked - it can proceed concurrently. This is highly important because transactions can co-exist nicely.
Read further about PostgreSQL and locks in our blog spot.
+43 (0) 2622 93022-0
office@cybertec.at
You are currently viewing a placeholder content from Facebook. To access the actual content, click the button below. Please note that doing so will share data with third-party providers.
More InformationYou are currently viewing a placeholder content from X. To access the actual content, click the button below. Please note that doing so will share data with third-party providers.
More Information
Leave a Reply