rewording in schema.sh; move test scripts to t/; add executable test.sh
This commit is contained in:
parent
480177e841
commit
f2f1bdf036
36
schema.sql
36
schema.sql
@ -1,8 +1,9 @@
|
|||||||
CREATE TABLE Account (
|
CREATE TABLE Account (
|
||||||
ID PRIMARY KEY NOT NULL,
|
ID PRIMARY KEY NOT NULL,
|
||||||
type NOT NULL,
|
type NOT NULL,
|
||||||
altId NOT NULL, -- z.B. bei Typ "Mitglied" Nr. laut externer Mitgliedertabelle
|
altId NOT NULL, -- e.g. when type "member", no. in external member table
|
||||||
IBAN -- Zielkonto für etwaige Rückzahlungen.
|
IBAN -- target account for returned payments (set '' to enable
|
||||||
|
-- outgoing bank transfers to commercial partners from that account).
|
||||||
);
|
);
|
||||||
CREATE TABLE Debit (
|
CREATE TABLE Debit (
|
||||||
billId PRIMARY KEY NOT NULL,
|
billId PRIMARY KEY NOT NULL,
|
||||||
@ -29,18 +30,19 @@ CREATE TABLE Credit (
|
|||||||
FOREIGN KEY (account) REFERENCES Account(ID)
|
FOREIGN KEY (account) REFERENCES Account(ID)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Which credit pays/paid down which debt is recorded traceably so as to clarify any case of reminder
|
-- Which credit pays/paid down which debt is recorded traceably so as to clarify any case of reminder,
|
||||||
-- without ambuiguity about which debt is due yet. The user specifies, in accordance with any indicated
|
-- without ambuiguity about, which debt is actually due yet, or to clarify which transfer is used for
|
||||||
-- purpose of a received bank transfer, which credit is intended for which debt. Following triggers
|
-- which debts. The user specifies which credit is intended for which debt, in accordance with the
|
||||||
-- verify this relation and mark a debit as paid and/or a credit as paid.
|
-- purpose if any is indicated in a received bank transfer. Following triggers verify this relation
|
||||||
-- Debits to which applies value > paid, are meant to be suggested for assignment to newly inserted
|
-- and mark a debit as paid and/or a credit as paid.
|
||||||
-- credit records without indicated purpose. Likewise, credits to which applies value > spent are candidates
|
-- Debits to which applies value > paid are meant to be suggested for assignment to newly inserted
|
||||||
-- for payment of newly inserted debts.
|
-- credit records without indicated purpose. Likewise, credits without indicated purpose to which
|
||||||
|
-- applies value > spent are candidates for payment of newly inserted debts.
|
||||||
CREATE TABLE Transfer (
|
CREATE TABLE Transfer (
|
||||||
timestamp DATE DEFAULT CURRENT_TIMESTAMP,
|
timestamp DATE DEFAULT CURRENT_TIMESTAMP,
|
||||||
billId 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, -- for later traceability, necessary when revoking transfers
|
||||||
FOREIGN KEY (billId) REFERENCES Debit(billId),
|
FOREIGN KEY (billId) REFERENCES Debit(billId),
|
||||||
FOREIGN KEY (fromCredit) REFERENCES Credit(Id),
|
FOREIGN KEY (fromCredit) REFERENCES Credit(Id),
|
||||||
UNIQUE (billId, fromCredit)
|
UNIQUE (billId, fromCredit)
|
||||||
@ -51,7 +53,7 @@ CREATE TRIGGER balanceTransfer
|
|||||||
AFTER INSERT ON Transfer
|
AFTER INSERT ON Transfer
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
SELECT RAISE(FAIL, "It is not the debtor who pays")
|
SELECT RAISE(FAIL, "It is not the debtor who is set to pay")
|
||||||
WHERE (SELECT debtor FROM Debit WHERE billId=NEW.billId)
|
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)
|
||||||
;
|
;
|
||||||
@ -61,13 +63,13 @@ BEGIN
|
|||||||
FROM (SELECT
|
FROM (SELECT
|
||||||
(SELECT value - paid FROM Debit WHERE billId=NEW.billId) 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
|
)
|
||||||
;
|
;
|
||||||
|
|
||||||
UPDATE Debit
|
UPDATE Debit
|
||||||
SET paid = paid + CASE
|
SET paid = paid + CASE
|
||||||
WHEN (SELECT d FROM _temp) <= 0
|
WHEN (SELECT d FROM _temp) <= 0
|
||||||
THEN RAISE(ROLLBACK, "Debt is already paid")
|
THEN RAISE(FAIL, "Debt is already paid")
|
||||||
ELSE
|
ELSE
|
||||||
(SELECT m FROM _temp)
|
(SELECT m FROM _temp)
|
||||||
END
|
END
|
||||||
@ -164,7 +166,7 @@ BEGIN
|
|||||||
WHERE NEW.spent != 0;
|
WHERE NEW.spent != 0;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
-- Prevent modification with spent value outside triggers which must adjust it exclusively
|
-- Prevent modification of spent value outside triggers which must adjust it exclusively
|
||||||
-- when new transfer records are inserted
|
-- when new transfer records are inserted
|
||||||
CREATE TRIGGER enforceSpentImmutableOutsideTrigger
|
CREATE TRIGGER enforceSpentImmutableOutsideTrigger
|
||||||
BEFORE UPDATE OF spent ON Credit
|
BEFORE UPDATE OF spent ON Credit
|
||||||
@ -186,7 +188,11 @@ 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.debtor) 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;
|
||||||
|
|
||||||
|
@ -1 +0,0 @@
|
|||||||
diff -q schema.t.out <(cat schema{,.t}.sql | sqlite3 2>&1) && echo "Tests passed."
|
|
@ -9,9 +9,9 @@ john: 0 +0 0
|
|||||||
Club: 0 +0 -16250
|
Club: 0 +0 -16250
|
||||||
alex: 7200 +16250 0
|
alex: 7200 +16250 0
|
||||||
# Some updates and deletes that could, unless denied, destroy consistency ...
|
# Some updates and deletes that could, unless denied, destroy consistency ...
|
||||||
Error: near line 274: paid is set and adjusted automatically according to added Transfer records
|
Error: near line 280: paid is set and adjusted automatically according to added Transfer records
|
||||||
Error: near line 275: Debt is involved in transfers to revoke at first
|
Error: near line 281: Debt is involved in transfers to revoke at first
|
||||||
Error: near line 276: FOREIGN KEY constraint failed
|
Error: near line 282: FOREIGN KEY constraint failed
|
||||||
# After revoking transactions, you are free to change or delete debts and credits ...
|
# After revoking transactions, you are free to change or delete debts and credits ...
|
||||||
Club: 7200 +0 0
|
Club: 7200 +0 0
|
||||||
alex: 0 +0 0
|
alex: 0 +0 0
|
1
t/schema.sh
Normal file
1
t/schema.sh
Normal file
@ -0,0 +1 @@
|
|||||||
|
diff t/schema.out <(cat {,t/}schema.sql | sqlite3 2>&1)
|
Loading…
Reference in New Issue
Block a user