From f68ca7ac6e38ebaf7ad31d82c9e642013c2ca7df Mon Sep 17 00:00:00 2001 From: Stefan Kostic Date: Tue, 8 Mar 2022 18:38:53 +0100 Subject: [PATCH 1/2] Revert constraint migration --- .../20220120000700_add_constraints.up.go | 17 +++-------------- 1 file changed, 3 insertions(+), 14 deletions(-) diff --git a/db/migrations/20220120000700_add_constraints.up.go b/db/migrations/20220120000700_add_constraints.up.go index 6d09e1f..cdbd438 100644 --- a/db/migrations/20220120000700_add_constraints.up.go +++ b/db/migrations/20220120000700_add_constraints.up.go @@ -34,7 +34,6 @@ func init() { DECLARE sum BIGINT; debit_account_type VARCHAR; - credit_account_type VARCHAR; BEGIN -- LOCK the account if the transaction is not from an incoming account @@ -49,18 +48,8 @@ func init() { -- This can happen when two transactions try to access the same account FOR UPDATE NOWAIT; - -- check if credit_account type is fees, if it's fees we don't check for negative balance constraint - SELECT INTO credit_account_type type - FROM accounts - WHERE id = NEW.credit_account_id AND type <> 'fees' - -- IMPORTANT: lock rows but do not wait for another lock to be released. - -- Waiting would result in a deadlock because two parallel transactions could try to lock the same rows - -- NOWAIT reports an error rather than waiting for the lock to be released - -- This can happen when two transactions try to access the same account - FOR UPDATE NOWAIT; - - -- If it is an debit incoming account or fees credit account return; otherwise check the balance - IF debit_account_type IS NULL OR credit_account_type IS NULL + -- If it is an incoming account return; otherwise check the balance + IF debit_account_type IS NULL THEN RETURN NEW; END IF; @@ -71,7 +60,7 @@ func init() { WHERE account_ledgers.account_id = NEW.debit_account_id; -- IF the account would go negative raise an exception - IF sum < 0 + IF sum < 0 AND debit_account_type != 'incoming' THEN RAISE EXCEPTION 'invalid balance [user_id:%] [debit_account_id:%] balance [%]', NEW.user_id, From 64c77d4ebb1e5d57e061ba5581bd498cb95ade91 Mon Sep 17 00:00:00 2001 From: Stefan Kostic Date: Tue, 8 Mar 2022 18:51:16 +0100 Subject: [PATCH 2/2] Add new migration to alter check balance trigger --- ...20220308103000_replace_check_balance.up.go | 86 +++++++++++++++++++ 1 file changed, 86 insertions(+) create mode 100644 db/migrations/20220308103000_replace_check_balance.up.go diff --git a/db/migrations/20220308103000_replace_check_balance.up.go b/db/migrations/20220308103000_replace_check_balance.up.go new file mode 100644 index 0000000..4b0707b --- /dev/null +++ b/db/migrations/20220308103000_replace_check_balance.up.go @@ -0,0 +1,86 @@ +package migrations + +import ( + "context" + "fmt" + + "github.com/uptrace/bun" +) + +func init() { + Migrations.MustRegister(func(ctx context.Context, db *bun.DB) error { + + if db.Dialect().Name().String() != "pg" { + fmt.Printf("\033[1;31m%s\033[0m", "You are not using PostgreSQL. DB level checks can not be enabled!\n") + return nil + } + sql := ` + -- make sure that account balances >= 0 (except for incoming and fees accounts) + CREATE OR REPLACE FUNCTION check_balance() + RETURNS TRIGGER AS $$ + DECLARE + sum BIGINT; + debit_account_type VARCHAR; + credit_account_type VARCHAR; + BEGIN + + -- LOCK the account if the transaction is not from an incoming account + -- This makes sure we always check the balance of the account before commiting a transaction + -- (incoming accounts can be negative, so we do not care about those) + SELECT INTO debit_account_type type + FROM accounts + WHERE id = NEW.debit_account_id AND type <> 'incoming' + -- IMPORTANT: lock rows but do not wait for another lock to be released. + -- Waiting would result in a deadlock because two parallel transactions could try to lock the same rows + -- NOWAIT reports an error rather than waiting for the lock to be released + -- This can happen when two transactions try to access the same account + FOR UPDATE NOWAIT; + + -- check if credit_account type is fees, if it's fees we don't check for negative balance constraint + SELECT INTO credit_account_type type + FROM accounts + WHERE id = NEW.credit_account_id AND type <> 'fees' + -- IMPORTANT: lock rows but do not wait for another lock to be released. + -- Waiting would result in a deadlock because two parallel transactions could try to lock the same rows + -- NOWAIT reports an error rather than waiting for the lock to be released + -- This can happen when two transactions try to access the same account + FOR UPDATE NOWAIT; + + -- If it is an debit incoming account or fees credit account return; otherwise check the balance + IF debit_account_type IS NULL OR credit_account_type IS NULL + THEN + RETURN NEW; + END IF; + + -- Calculate the account balance + SELECT INTO sum SUM(amount) + FROM account_ledgers + WHERE account_ledgers.account_id = NEW.debit_account_id; + + -- IF the account would go negative raise an exception + IF sum < 0 + THEN + RAISE EXCEPTION 'invalid balance [user_id:%] [debit_account_id:%] balance [%]', + NEW.user_id, + NEW.debit_account_id, + sum; + END IF; + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + + -- first we drop trigger and re-add it again with modified function + DROP TRIGGER IF EXISTS check_balance ON transaction_entries; + + -- create deferrable trigger which is executed at the end of the transaction to check the balance for each inserted transaction entry + CREATE CONSTRAINT TRIGGER check_balance + AFTER INSERT OR UPDATE ON transaction_entries + DEFERRABLE + FOR EACH ROW EXECUTE PROCEDURE check_balance(); + ` + if _, err := db.Exec(sql); err != nil { + return err + } + return nil + }, nil) +}