diff --git a/schema/tables.sql b/schema/tables.sql index 39ef90d..7e46740 100644 --- a/schema/tables.sql +++ b/schema/tables.sql @@ -59,7 +59,8 @@ CREATE TABLE Transfer ( ); -- For internal purposes: Memory of rebalance triggers -CREATE TABLE __DO_NOT_MANIPULATE__trigger_memory (d, c, m); +-- Do not fiddle with it! I.e. if you do, don't expect any support. +CREATE TABLE __INTERNAL_TRIGGER_STACK (id, d, c, m); -- Only for use of HTTP interface CREATE TABLE web_auth ( user_id primary key, password, grade not null, username, email ); diff --git a/schema/triggers/balanceTransfer.sql b/schema/triggers/balanceTransfer.sql index febe753..a4a0d76 100644 --- a/schema/triggers/balanceTransfer.sql +++ b/schema/triggers/balanceTransfer.sql @@ -1,5 +1,5 @@ -CREATE TRIGGER balanceTransfer - AFTER INSERT ON Transfer +CREATE TRIGGER linkTransferTightly + AFTER INSERT ON Transfer BEGIN SELECT RAISE(FAIL, "It is not the debtor who is set to pay") @@ -16,51 +16,58 @@ BEGIN HAVING count(d.billId) == 0 ; - INSERT INTO __DO_NOT_MANIPULATE__trigger_memory - SELECT remainingDebt, remainingCredit, min(remainingDebt,remainingCredit) - FROM (SELECT - (SELECT value - paid FROM Debit WHERE billId=NEW.billId) AS remainingDebt, - (SELECT value - spent FROM Credit WHERE credId=NEW.credId) AS remainingCredit - ) - ; - - UPDATE Debit - SET paid = paid + CASE - WHEN (SELECT d FROM __DO_NOT_MANIPULATE__trigger_memory) <= 0 - THEN RAISE(FAIL, "Debt settled") - ELSE - (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory) - END - WHERE billId=NEW.billId; - - UPDATE Credit - SET spent = spent + CASE - WHEN (SELECT c FROM __DO_NOT_MANIPULATE__trigger_memory) <= 0 - THEN RAISE(FAIL, "Credit spent") - ELSE IFNULL( - (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory), - RAISE(FAIL,"Oops, lost __DO_NOT_MANIPULATE__trigger_memory record before increasing spent") - ) - END - WHERE credId=NEW.credId; - - UPDATE Transfer - SET amount = (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory) - WHERE billId=NEW.billId AND credId=NEW.credId - ; - - UPDATE Credit - SET value = value + IFNULL( - (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory), - RAISE(FAIL, "Oops, lost __DO_NOT_MANIPULATE__trigger_memory record before increasing value") + INSERT INTO __INTERNAL_TRIGGER_STACK + SELECT NEW.ROWID, + CASE remainingDebt WHEN 0 THEN RAISE(FAIL, "Debt settled") ELSE NEW.billId END, + CASE remainingCredit WHEN 0 THEN RAISE(FAIL, "Credit spent") ELSE NEW.credId END, + min(remainingDebt, remainingCredit) + FROM (SELECT + (SELECT value - paid FROM Debit WHERE billId=NEW.billId) AS remainingDebt, + (SELECT value - spent FROM Credit WHERE credId=NEW.credId) AS remainingCredit ) - WHERE credId = ( - SELECT targetCredit - FROM Debit - WHERE billId=NEW.billId - ); - - DELETE FROM __DO_NOT_MANIPULATE__trigger_memory; + ; + +END; + +CREATE TRIGGER reflectTransfer + AFTER INSERT ON __INTERNAL_TRIGGER_STACK + WHEN NEW.id > 0 +BEGIN + + UPDATE Debit + SET paid = paid + NEW.m + WHERE billId = NEW.d; + + UPDATE Credit + SET spent = spent + NEW.m + WHERE credId = NEW.c; + + UPDATE Transfer + SET amount = ifnull(amount,0) + NEW.m + WHERE ROWID = NEW.id; + + UPDATE Credit + SET value = value + NEW.m + WHERE credId = ( + SELECT targetCredit + FROM Debit + WHERE billId = NEW.d + ); + + DELETE FROM __INTERNAL_TRIGGER_STACK WHERE id=NEW.id; + +END; + +CREATE TRIGGER refreshTransfer + AFTER UPDATE OF amount ON Transfer +BEGIN + + DELETE FROM Transfer + WHERE ROWID = NEW.ROWID AND amount = 0; + + UPDATE Transfer + SET timestamp=CURRENT_TIMESTAMP + WHERE ROWID=NEW.ROWID; END; diff --git a/schema/triggers/enforcDebtImmutableOutsideTrigger.sql b/schema/triggers/enforceDebtImmutableOutsideTrigger.sql similarity index 50% rename from schema/triggers/enforcDebtImmutableOutsideTrigger.sql rename to schema/triggers/enforceDebtImmutableOutsideTrigger.sql index 3ff1342..1310f87 100644 --- a/schema/triggers/enforcDebtImmutableOutsideTrigger.sql +++ b/schema/triggers/enforceDebtImmutableOutsideTrigger.sql @@ -2,11 +2,8 @@ -- when new transfer records are inserted CREATE TRIGGER enforceDebtImmutableOutsideTrigger BEFORE UPDATE OF paid ON Debit - WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.billId=t.billId AND amount IS NULL) + WHEN NOT EXISTS (SELECT * FROM __INTERNAL_TRIGGER_STACK LIMIT 1) BEGIN - SELECT RAISE(FAIL, "paid is set and adjusted automatically according to added Transfer records") - WHERE (NEW.paid + IFNULL( - (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory WHERE c IS NULL AND d IS NULL), 0 - ) ) <> OLD.paid; + SELECT RAISE(FAIL, "paid is set and adjusted automatically according to added Transfer records"); END; diff --git a/schema/triggers/enforceFixedCredit.sql b/schema/triggers/enforceFixedCredit.sql index dfe4376..037a86f 100644 --- a/schema/triggers/enforceFixedCredit.sql +++ b/schema/triggers/enforceFixedCredit.sql @@ -1,7 +1,7 @@ CREATE TRIGGER enforceFixedCredit BEFORE UPDATE OF account, value ON Credit WHEN EXISTS (SELECT * FROM Transfer WHERE credId=NEW.credId) - AND NOT EXISTS (SELECT * FROM __DO_NOT_MANIPULATE__trigger_memory) + AND NOT EXISTS (SELECT * FROM __INTERNAL_TRIGGER_STACK) BEGIN SELECT RAISE(FAIL, "Credit involved in transactions to revoke at first"); END; diff --git a/schema/triggers/enforceFixedDebit.sql b/schema/triggers/enforceFixedDebit.sql index 9075522..01dfded 100644 --- a/schema/triggers/enforceFixedDebit.sql +++ b/schema/triggers/enforceFixedDebit.sql @@ -1,6 +1,7 @@ CREATE TRIGGER enforceFixedDebit BEFORE UPDATE OF debtor, transferCredit, value ON Debit WHEN EXISTS (SELECT * FROM Transfer WHERE billId=NEW.billId) + AND NOT EXISTS (SELECT * FROM __INTERNAL_TRIGGER_STACK LIMIT 1) BEGIN SELECT RAISE(FAIL, "Debt is involved in transfers to revoke at first"); END; diff --git a/schema/triggers/enforceImmutableTransfer.sql b/schema/triggers/enforceImmutableTransfer.sql index dcabe5d..1fbe5de 100644 --- a/schema/triggers/enforceImmutableTransfer.sql +++ b/schema/triggers/enforceImmutableTransfer.sql @@ -1,6 +1,7 @@ CREATE TRIGGER enforceImmutableTransfer BEFORE UPDATE ON Transfer WHEN OLD.amount IS NOT NULL + AND NOT EXISTS (SELECT * FROM __INTERNAL_TRIGGER_STACK) BEGIN SELECT RAISE(FAIL, "Transfer cannot be updated, but needs to be replaced to make triggers run"); END; diff --git a/schema/triggers/enforceSpentImmutableOutsideTrigger.sql b/schema/triggers/enforceSpentImmutableOutsideTrigger.sql index 0470c6c..77fec39 100644 --- a/schema/triggers/enforceSpentImmutableOutsideTrigger.sql +++ b/schema/triggers/enforceSpentImmutableOutsideTrigger.sql @@ -2,11 +2,8 @@ -- when new transfer records are inserted CREATE TRIGGER enforceSpentImmutableOutsideTrigger BEFORE UPDATE OF spent ON Credit - WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.credId=t.credId AND amount IS NULL) + WHEN NOT EXISTS (SELECT * FROM __INTERNAL_TRIGGER_STACK) BEGIN - SELECT RAISE(FAIL, "spent is set and adjusted automatically according to added Transfer records") - WHERE (NEW.spent + IFNULL( - (SELECT m FROM __DO_NOT_MANIPULATE__trigger_memory WHERE c IS NULL AND d IS NULL), 0 - ) ) <> OLD.spent; + SELECT RAISE(FAIL, "spent is set and adjusted automatically according to added Transfer records"); END; diff --git a/schema/triggers/rebalanceIncreasedCredit.sql b/schema/triggers/rebalanceIncreasedCredit.sql index 514cce7..43a0841 100644 --- a/schema/triggers/rebalanceIncreasedCredit.sql +++ b/schema/triggers/rebalanceIncreasedCredit.sql @@ -3,11 +3,12 @@ -- That way, a transfer may issue recursively chained transfers. CREATE TRIGGER rebalanceIncreasedCredit AFTER UPDATE OF value ON Credit -WHEN NEW.value > OLD.spent + WHEN NEW.value > OLD.value BEGIN - REPLACE INTO Transfer (credId, billId) - SELECT OLD.credId, t.billId + INSERT INTO __INTERNAL_TRIGGER_STACK + SELECT t.ROWID, NEW.value, ca.difference, + min(ca.difference, NEW.value - OLD.value) FROM Transfer t JOIN CurrentArrears ca ON t.billId = ca.billId WHERE OLD.credId = t.credId diff --git a/schema/triggers/rebalanceReducedCredit.sql b/schema/triggers/rebalanceReducedCredit.sql index d848052..519f2d3 100644 --- a/schema/triggers/rebalanceReducedCredit.sql +++ b/schema/triggers/rebalanceReducedCredit.sql @@ -2,42 +2,50 @@ -- check if we can still have paid the debts linked to this transfer in an "is paid from" relation, -- otherwise we have to revoke these transfers as well. CREATE TRIGGER rebalanceReducedCredit - AFTER UPDATE OF value ON Credit -WHEN NEW.value < OLD.spent + BEFORE UPDATE OF value ON Credit + WHEN NEW.value < OLD.spent BEGIN - - REPLACE INTO __DO_NOT_MANIPULATE__trigger_memory (d, m) - SELECT - 'from_' || NEW.credId, - billId - FROM Transfer - WHERE credId = NEW.credId - ORDER BY timestamp DESC - LIMIT 1 - ; - - DELETE - FROM Transfer - WHERE credId = NEW.credId - AND billId IN ( - SELECT billId - FROM __DO_NOT_MANIPULATE__trigger_memory - WHERE c = 'from_' || NEW.credId - ) - ; - - INSERT INTO Transfer (credId, billId) - SELECT NEW.credId, m - FROM __DO_NOT_MANIPULATE__trigger_memory - WHERE d = 'from_' || NEW.credId - AND NEW.value > ( - SELECT spent - FROM Credit - WHERE credId = NEW.credId - ) - ; - - DELETE FROM __DO_NOT_MANIPULATE__trigger_memory WHERE d = 'from_' || NEW.credId; - + INSERT INTO __INTERNAL_TRIGGER_STACK (id) VALUES (-NEW.credId); + UPDATE __INTERNAL_TRIGGER_STACK SET c=OLD.spent-NEW.value; + DELETE FROM __INTERNAL_TRIGGER_STACK WHERE id=-NEW.credId; END; +CREATE TRIGGER _inner_rebalanceReducedCredit + AFTER UPDATE OF c ON __INTERNAL_TRIGGER_STACK +BEGIN + + UPDATE __INTERNAL_TRIGGER_STACK + SET d = ( + SELECT ROWID + FROM Transfer + WHERE credId = abs(OLD.id) + ORDER BY timestamp DESC + LIMIT 1 + ) + WHERE id = OLD.id + ; + + UPDATE __INTERNAL_TRIGGER_STACK + SET m = min(( + SELECT amount + FROM Transfer + WHERE credId = abs(OLD.id) + ORDER BY timestamp DESC + LIMIT 1 + ), NEW.c) + WHERE id = OLD.id + ; + + INSERT INTO __INTERNAL_TRIGGER_STACK + SELECT d, billId, abs(OLD.id), -m + FROM __INTERNAL_TRIGGER_STACK s + JOIN Transfer t ON t.ROWID=d + WHERE id = OLD.id AND m > 0 + ; + + UPDATE __INTERNAL_TRIGGER_STACK + SET c = NEW.c-m + WHERE id = OLD.id AND m > 0 + ; -- recurse + +END; diff --git a/schema/triggers/revokeTransfer.sql b/schema/triggers/revokeTransfer.sql index ea58ac7..2efd7bf 100644 --- a/schema/triggers/revokeTransfer.sql +++ b/schema/triggers/revokeTransfer.sql @@ -1,27 +1,11 @@ CREATE TRIGGER revokeTransfer BEFORE DELETE ON Transfer + WHEN OLD.amount > 0 BEGIN - INSERT INTO __DO_NOT_MANIPULATE__trigger_memory VALUES (null,null,OLD.amount); - - UPDATE Debit - SET paid = paid - OLD.amount - WHERE billId=OLD.billId - ; - - UPDATE Credit - SET value = value - OLD.amount - WHERE credId = ( - SELECT targetCredit - FROM Debit - WHERE billId=OLD.billId - ); - - UPDATE Credit - SET spent = spent - OLD.amount - WHERE credId = OLD.credId; - - DELETE FROM __DO_NOT_MANIPULATE__trigger_memory; + INSERT INTO __INTERNAL_TRIGGER_STACK VALUES ( + OLD.ROWID, OLD.billId, OLD.credId, -OLD.amount + ); END; diff --git a/t/schema.t b/t/schema.t index db5c79f..74a7fdd 100644 --- a/t/schema.t +++ b/t/schema.t @@ -125,5 +125,6 @@ $db->make_transfers( q{*} => q{*} ); is $rose->available_credits->get_column("difference")->sum, 3600, "partial use of credit"; is $db->resultset("Balance")->find("alex")->earned, '10800', 'indirect transfers'; +is $db->resultset("Balance")->find("Club")->available, '0', ' ... spent increased'; done_testing();