Added promise output in balance.

This commit is contained in:
Florian "flowdy" Heß 2016-05-22 14:35:43 +02:00
parent f9e3ee6ec5
commit 7a0d08ae50
2 changed files with 43 additions and 36 deletions

View File

@ -5,8 +5,8 @@ CREATE TABLE Account (
IBAN -- Zielkonto für etwaige Rückzahlungen. IBAN -- Zielkonto für etwaige Rückzahlungen.
); );
CREATE TABLE Debit ( CREATE TABLE Debit (
receiptId PRIMARY KEY NOT NULL, billId PRIMARY KEY NOT NULL,
debitor NOT NULL, -- Account charged debtor NOT NULL, -- Account charged
targetCredit INTEGER, -- record id in Credit table to pay into. targetCredit INTEGER, -- record id in Credit table to pay into.
-- just understand it as virtual payment -- just understand it as virtual payment
-- NULL when debit is a bank transfer from the club account -- NULL when debit is a bank transfer from the club account
@ -14,7 +14,7 @@ CREATE TABLE Debit (
purpose NOT NULL, -- description of receipt purpose NOT NULL, -- description of receipt
value INTEGER NOT NULL, -- Euro-Cent value INTEGER NOT NULL, -- Euro-Cent
paid INTEGER DEFAULT 0, -- Euro-Cent, set and changed automatically (Cache) paid INTEGER DEFAULT 0, -- Euro-Cent, set and changed automatically (Cache)
FOREIGN KEY (debitor) REFERENCES Account(ID), FOREIGN KEY (debtor) REFERENCES Account(ID),
FOREIGN KEY (targetCredit) REFERENCES Credit(Id) FOREIGN KEY (targetCredit) REFERENCES Credit(Id)
); );
CREATE TABLE Credit ( CREATE TABLE Credit (
@ -38,12 +38,12 @@ CREATE TABLE Credit (
-- for payment of newly inserted debts. -- for payment of newly inserted debts.
CREATE TABLE Transfer ( CREATE TABLE Transfer (
timestamp DATE DEFAULT CURRENT_TIMESTAMP, timestamp DATE DEFAULT CURRENT_TIMESTAMP,
receiptId INTEGER NOT NULL, billId INTEGER NOT NULL,
fromCredit INTEGER NOT NULL, fromCredit INTEGER NOT NULL,
amount INTEGER, -- für spätere Nachvollziehbarkeit. Nötig auch bei Widerruf amount INTEGER, -- für spätere Nachvollziehbarkeit. Nötig auch bei Widerruf
FOREIGN KEY (receiptId) REFERENCES Debit(receiptId), FOREIGN KEY (billId) REFERENCES Debit(billId),
FOREIGN KEY (fromCredit) REFERENCES Credit(Id), FOREIGN KEY (fromCredit) REFERENCES Credit(Id),
UNIQUE (receiptId, fromCredit) UNIQUE (billId, fromCredit)
); );
CREATE TABLE IF NOT EXISTS _temp (d, c, m); CREATE TABLE IF NOT EXISTS _temp (d, c, m);
@ -51,15 +51,15 @@ CREATE TRIGGER balanceTransfer
AFTER INSERT ON Transfer AFTER INSERT ON Transfer
BEGIN BEGIN
SELECT RAISE(FAIL, "It is not the debitor who pays") SELECT RAISE(FAIL, "It is not the debtor who pays")
WHERE (SELECT debitor FROM Debit WHERE receiptId=NEW.receiptId) WHERE (SELECT debtor FROM Debit WHERE billId=NEW.billId)
!= (SELECT account FROM Credit WHERE Id=NEW.fromCredit) != (SELECT account FROM Credit WHERE Id=NEW.fromCredit)
; ;
INSERT INTO _temp INSERT INTO _temp
SELECT remainingDebt, remainingCredit, min(remainingDebt,remainingCredit) SELECT remainingDebt, remainingCredit, min(remainingDebt,remainingCredit)
FROM (SELECT FROM (SELECT
(SELECT value - paid FROM Debit WHERE receiptId=NEW.receiptId) AS remainingDebt, (SELECT value - paid FROM Debit WHERE billId=NEW.billId) AS remainingDebt,
(SELECT value - spent FROM Credit WHERE Id=NEW.fromCredit) AS remainingCredit (SELECT value - spent FROM Credit WHERE Id=NEW.fromCredit) AS remainingCredit
) AS microbalance ) AS microbalance
; ;
@ -71,14 +71,14 @@ BEGIN
ELSE ELSE
(SELECT m FROM _temp) (SELECT m FROM _temp)
END END
WHERE receiptId=NEW.receiptId; WHERE billId=NEW.billId;
UPDATE Credit UPDATE Credit
SET value = value + (SELECT m FROM _temp) SET value = value + (SELECT m FROM _temp)
WHERE Id = ( WHERE Id = (
SELECT targetCredit SELECT targetCredit
FROM Debit FROM Debit
WHERE receiptId=NEW.receiptId WHERE billId=NEW.billId
); );
UPDATE Credit UPDATE Credit
@ -92,7 +92,7 @@ BEGIN
UPDATE Transfer UPDATE Transfer
SET amount = (SELECT m FROM _temp) SET amount = (SELECT m FROM _temp)
WHERE receiptId=NEW.receiptId AND fromCredit=NEW.fromCredit WHERE billId=NEW.billId AND fromCredit=NEW.fromCredit
; ;
DELETE FROM _temp; DELETE FROM _temp;
@ -107,7 +107,7 @@ BEGIN
UPDATE Debit UPDATE Debit
SET paid = paid - OLD.amount SET paid = paid - OLD.amount
WHERE receiptId=OLD.receiptId WHERE billId=OLD.billId
; ;
UPDATE Credit UPDATE Credit
@ -115,7 +115,7 @@ BEGIN
WHERE Id = ( WHERE Id = (
SELECT targetCredit SELECT targetCredit
FROM Debit FROM Debit
WHERE receiptId=OLD.receiptId WHERE billId=OLD.billId
); );
UPDATE Credit UPDATE Credit
@ -144,7 +144,7 @@ END;
-- when new transfer records are inserted -- when new transfer records are inserted
CREATE TRIGGER enforceDebtImmutableOutsideTrigger CREATE TRIGGER enforceDebtImmutableOutsideTrigger
BEFORE UPDATE OF paid ON Debit BEFORE UPDATE OF paid ON Debit
WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.receiptId=t.receiptId AND amount IS NULL) WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.billId=t.billId AND amount IS NULL)
BEGIN BEGIN
SELECT RAISE(FAIL, "paid is set and adjusted automatically according to added Transfer records") SELECT RAISE(FAIL, "paid is set and adjusted automatically according to added Transfer records")
WHERE (NEW.paid + IFNULL((SELECT m FROM _temp WHERE c IS NULL AND d IS NULL),0) ) <> OLD.paid; WHERE (NEW.paid + IFNULL((SELECT m FROM _temp WHERE c IS NULL AND d IS NULL),0) ) <> OLD.paid;
@ -152,7 +152,7 @@ END;
CREATE TRIGGER enforceFixedDebits CREATE TRIGGER enforceFixedDebits
BEFORE UPDATE OF value ON Debit BEFORE UPDATE OF value ON Debit
WHEN EXISTS (SELECT * FROM Transfer WHERE receiptId=NEW.receiptId) WHEN EXISTS (SELECT * FROM Transfer WHERE billId=NEW.billId)
BEGIN BEGIN
SELECT RAISE(FAIL, "Debt is involved in transfers to revoke at first"); SELECT RAISE(FAIL, "Debt is involved in transfers to revoke at first");
END; END;
@ -186,12 +186,15 @@ CREATE TRIGGER checkIBANatTransfer
WHEN NEW.targetCredit IS NULL WHEN NEW.targetCredit IS NULL
BEGIN BEGIN
SELECT RAISE(FAIL, "IBAN used does not match IBAN currently stored in account record") SELECT RAISE(FAIL, "IBAN used does not match IBAN currently stored in account record")
FROM (SELECT instr(NEW.purpose, IBAN) AS fnd FROM Account WHERE ID=NEW.debitor) AS matchingIBAN FROM (SELECT instr(NEW.purpose, IBAN) AS fnd FROM Account WHERE ID=NEW.debtor) AS matchingIBAN
WHERE fnd IS NULL OR fnd = 0; WHERE fnd IS NULL OR fnd = 0;
END; END;
CREATE VIEW CurrentDebts AS CREATE VIEW CurrentDebts AS
SELECT debitor, purpose, date, SELECT debtor,
targetCredit,
purpose,
date,
value - paid AS difference value - paid AS difference
FROM Debit FROM Debit
WHERE value != paid WHERE value != paid
@ -205,9 +208,27 @@ CREATE VIEW AvailableCredits AS
; ;
CREATE VIEW Balance AS CREATE VIEW Balance AS
SELECT ID, IFNULL(ac.allCredits,0) credit, IFNULL(cd.allDebts, 0) debit SELECT Account.ID AS ID,
IFNULL(ac.allCredits,0) AS credit,
IFNULL(pr.allPromises, 0) AS promised,
IFNULL(cd.allDebts, 0) AS debt
FROM Account FROM Account
LEFT OUTER JOIN (SELECT debitor, sum(difference) AS allDebts FROM CurrentDebts GROUP BY debitor) AS cd ON ID=cd.debitor LEFT OUTER JOIN (
LEFT OUTER JOIN (SELECT account, sum(difference) AS allCredits FROM AvailableCredits GROUP BY account) AS ac ON ID=ac.account SELECT debtor, sum(difference) AS allDebts
FROM CurrentDebts
GROUP BY debtor
) AS cd ON Account.ID=cd.debtor
LEFT OUTER JOIN (
SELECT account, sum(difference) AS allCredits
FROM AvailableCredits
GROUP BY account
) AS ac ON Account.ID=ac.account
LEFT OUTER JOIN (
SELECT a.ID AS ID, sum(difference) AS allPromises
FROM CurrentDebts cd
JOIN Credit c ON cd.targetCredit = c.Id
JOIN Account a ON a.ID = c.account
GROUP BY a.ID
) AS pr ON Account.ID=pr.ID
; ;

View File

@ -1,15 +1 @@
diff -q <(cat schema{,.t}.sql | sqlite3 2>&1) - <<OUT && echo "Tests passed." diff -q schema.t.out <(cat schema{,.t}.sql | sqlite3 2>&1) && echo "Tests passed."
Balance of Club's account: 0 -23450
Balance of john's account: 7200 -7200
Balance of Club's account: 7200 -23450
Balance of john's account: 0 0
Balance of Club's Account: 0 -16250
Balance of alex's Account: 7200 0
Error: near line 242: paid is set and adjusted automatically according to added Transfer records
Error: near line 243: Debt is involved in transfers to revoke at first
Error: near line 244: FOREIGN KEY constraint failed
Balance of Club's Account: 7200 0
Balance of alex's Account: 0 0
Balance of Club's Account: 0 -16250
Balance of alex's Account: 7200 0
OUT