fix potential zap deadlock

This commit is contained in:
keyan 2024-07-25 20:45:54 -05:00
parent 628a0466fd
commit 3d1f7834ca
2 changed files with 67 additions and 1 deletions

View File

@ -201,4 +201,69 @@ From the [postgres docs](https://www.postgresql.org/docs/current/transaction-iso
> UPDATE, DELETE, SELECT FOR UPDATE, and SELECT FOR SHARE commands behave the same as SELECT in terms of searching for target rows: they will only find target rows that were committed as of the command start time. However, such a target row might have already been updated (or deleted or locked) by another concurrent transaction by the time it is found. In this case, the would-be updater will wait for the first updating transaction to commit or roll back (if it is still in progress). If the first updater rolls back, then its effects are negated and the second updater can proceed with updating the originally found row. If the first updater commits, the second updater will ignore the row if the first updater deleted it, otherwise it will attempt to apply its operation to the updated version of the row. The search condition of the command (the WHERE clause) is re-evaluated to see if the updated version of the row still matches the search condition. If so, the second updater proceeds with its operation using the updated version of the row. In the case of SELECT FOR UPDATE and SELECT FOR SHARE, this means it is the updated version of the row that is locked and returned to the client.
From the [postgres source docs](https://git.postgresql.org/gitweb/?p=postgresql.git;a=blob;f=src/backend/executor/README#l350):
> It is also possible that there are relations in the query that are not to be locked (they are neither the UPDATE/DELETE/MERGE target nor specified to be locked in SELECT FOR UPDATE/SHARE). When re-running the test query ***we want to use the same rows*** from these relations that were joined to the locked rows.
> It is also possible that there are relations in the query that are not to be locked (they are neither the UPDATE/DELETE/MERGE target nor specified to be locked in SELECT FOR UPDATE/SHARE). When re-running the test query ***we want to use the same rows*** from these relations that were joined to the locked rows.
## `IMPORTANT: deadlocks`
Deadlocks can occur when two transactions are waiting for each other to release locks. This can happen when two transactions lock rows in different orders whether explicit or implicit.
### Incorrect
```sql
-- transaction 1
BEGIN;
UPDATE users set msats = msats + 1 WHERE id = 1;
-- transaction 2
BEGIN;
UPDATE users set msats = msats + 1 WHERE id = 2;
-- transaction 1 (blocks here until transaction 2 commits)
UPDATE users set msats = msats + 1 WHERE id = 2;
-- transaction 2 (blocks here until transaction 1 commits)
UPDATE users set msats = msats + 1 WHERE id = 1;
-- deadlock occurs because neither transaction can proceed to here
```
If both transactions lock the rows in the same order, the deadlock is avoided.
Most often this occurs when selecting multiple rows for update in different orders. Recently, we had a deadlock when spliting zaps to multiple users. The solution was to select the rows for update in the same order.
### Incorrect
```sql
WITH forwardees AS (
SELECT "userId", (($1::BIGINT * pct) / 100)::BIGINT AS msats
FROM "ItemForward"
WHERE "itemId" = $2::INTEGER
),
UPDATE users
SET
msats = users.msats + forwardees.msats,
"stackedMsats" = users."stackedMsats" + forwardees.msats
FROM forwardees
WHERE users.id = forwardees."userId";
```
If forwardees are selected in a different order in two concurrent transactions, e.g. (1,2) in tx 1 and (2,1) in tx 2, a deadlock can occur. To avoid this, always select rows for update in the same order.
### Correct
We fixed the deadlock by selecting the forwardees in the same order in these transactions.
```sql
WITH forwardees AS (
SELECT "userId", (($1::BIGINT * pct) / 100)::BIGINT AS msats
FROM "ItemForward"
WHERE "itemId" = $2::INTEGER
ORDER BY "userId" ASC
),
UPDATE users
SET
msats = users.msats + forwardees.msats,
"stackedMsats" = users."stackedMsats" + forwardees.msats
FROM forwardees
WHERE users.id = forwardees."userId";
```
### More resources
- https://www.postgresql.org/docs/current/explicit-locking.html#LOCKING-DEADLOCKS

View File

@ -74,6 +74,7 @@ export async function onPaid ({ invoice, actIds }, { models, tx }) {
SELECT "userId", ((${itemAct.msats}::BIGINT * pct) / 100)::BIGINT AS msats
FROM "ItemForward"
WHERE "itemId" = ${itemAct.itemId}::INTEGER
ORDER BY "userId" ASC -- order to prevent deadlocks
), total_forwarded AS (
SELECT COALESCE(SUM(msats), 0) as msats
FROM forwardees