added README.md and schema.*
This commit is contained in:
		
						commit
						f9e3ee6ec5
					
				
							
								
								
									
										42
									
								
								README.md
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										42
									
								
								README.md
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,42 @@
 | 
			
		||||
README
 | 
			
		||||
======
 | 
			
		||||
 | 
			
		||||
TreasureDB is a plain SQLite database application to observe and trace the finances of a
 | 
			
		||||
non-profit registered society or club. In Germany, such clubs may not accumulate reserves.
 | 
			
		||||
Therefore, the ideal state of balance is zero both in debit and in credit because they even
 | 
			
		||||
out.
 | 
			
		||||
 | 
			
		||||
How does it work?
 | 
			
		||||
-----------------
 | 
			
		||||
 | 
			
		||||
There are four tables: Account, Credit, Debit and Transfers.
 | 
			
		||||
 | 
			
		||||
Account table stores the static details, i.e. the type of account, the record identifier for
 | 
			
		||||
another table that stores more information about the account owner, and the IBAN for outgoing
 | 
			
		||||
bank transfers.
 | 
			
		||||
 | 
			
		||||
The Credit table stores bank transfers from the member to the club, and also the target
 | 
			
		||||
records of internal transfers to the club and other members performing services for it.
 | 
			
		||||
The value of the former sort is initially >0 and normally not altered afterwards. The latter's
 | 
			
		||||
value always starts at 0 and is increased by transfers linked to it.
 | 
			
		||||
 | 
			
		||||
The Debit table stores the receipts documenting a debt, their link to the credit record of the
 | 
			
		||||
respective recipient as well as to the account from which it is paid.
 | 
			
		||||
 | 
			
		||||
The Transfer stores when which amount is transferred from which credit record to settle which debt.
 | 
			
		||||
So, a debt can be associated with n source credits, and a souce credit can settle multiple debts.
 | 
			
		||||
Transfers cannot be altered once inserted, they need to be revoked and re-entered. This is due to
 | 
			
		||||
triggers that have to rerun.
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
Installation
 | 
			
		||||
------------
 | 
			
		||||
 | 
			
		||||
As it is a SQLite3 database with all consistency and calculatory logic built in, you only
 | 
			
		||||
need the `sqlite3` binary or any sqlite3 GUI software to run it.
 | 
			
		||||
 | 
			
		||||
1. Ensure sqlite3 is installed
 | 
			
		||||
1. Run the test suite: `bash schema.t.sh` (on Linux and unix systems)
 | 
			
		||||
1. Setup the database: `sqlite3 treasure.db < schema.sql`
 | 
			
		||||
1. Study the files to learn how to work with the system: `less schema.*`
 | 
			
		||||
 | 
			
		||||
							
								
								
									
										213
									
								
								schema.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										213
									
								
								schema.sql
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,213 @@
 | 
			
		||||
CREATE TABLE Account (
 | 
			
		||||
  ID PRIMARY KEY NOT NULL,
 | 
			
		||||
  type NOT NULL,
 | 
			
		||||
  altId NOT NULL, -- z.B. bei Typ "Mitglied" Nr. laut externer Mitgliedertabelle 
 | 
			
		||||
  IBAN -- Zielkonto für etwaige Rückzahlungen.
 | 
			
		||||
);
 | 
			
		||||
CREATE TABLE Debit (
 | 
			
		||||
  receiptId PRIMARY KEY NOT NULL,
 | 
			
		||||
  debitor NOT NULL, -- Account charged
 | 
			
		||||
  targetCredit INTEGER, -- record id in Credit table to pay into.
 | 
			
		||||
                   -- just understand it as virtual payment
 | 
			
		||||
                   -- NULL when debit is a bank transfer from the club account
 | 
			
		||||
  date DATE NOT NULL,
 | 
			
		||||
  purpose NOT NULL, -- description of receipt
 | 
			
		||||
  value INTEGER NOT NULL, -- Euro-Cent
 | 
			
		||||
  paid INTEGER DEFAULT 0, -- Euro-Cent, set and changed automatically (Cache)
 | 
			
		||||
  FOREIGN KEY (debitor) REFERENCES Account(ID),
 | 
			
		||||
  FOREIGN KEY (targetCredit) REFERENCES Credit(Id)
 | 
			
		||||
);
 | 
			
		||||
CREATE TABLE Credit (
 | 
			
		||||
  Id INTEGER PRIMARY KEY NOT NULL,
 | 
			
		||||
  account NOT NULL, -- Account des Begünstigten
 | 
			
		||||
  date DATE NOT NULL,
 | 
			
		||||
  purpose NOT NULL, -- as originally indicated in statement of bank account
 | 
			
		||||
  value INTEGER NOT NULL, -- Euro-Cent. Caution, two distinct cases need to be considered:
 | 
			
		||||
                         --  Either deposit by bank transfer (>0) or target of internal payments (=0)
 | 
			
		||||
  spent INTEGER DEFAULT 0, -- Euro-Cent, set and changed automatically (Cache)
 | 
			
		||||
                           -- for later traceability, necessary when revoking transfers
 | 
			
		||||
  FOREIGN KEY (account) REFERENCES Account(ID)
 | 
			
		||||
);
 | 
			
		||||
 | 
			
		||||
-- 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
 | 
			
		||||
-- purpose of a received bank transfer, which credit is intended for which debt. Following triggers
 | 
			
		||||
-- verify this relation and mark a debit as paid and/or a credit as paid.
 | 
			
		||||
-- Debits to which applies value > paid, are meant to be suggested for assignment to newly inserted
 | 
			
		||||
-- credit records without indicated purpose. Likewise, credits to which applies value > spent are candidates
 | 
			
		||||
-- for payment of newly inserted debts.
 | 
			
		||||
CREATE TABLE Transfer (
 | 
			
		||||
  timestamp DATE DEFAULT CURRENT_TIMESTAMP,
 | 
			
		||||
  receiptId INTEGER NOT NULL,
 | 
			
		||||
  fromCredit INTEGER NOT NULL, 
 | 
			
		||||
  amount INTEGER, -- für spätere Nachvollziehbarkeit. Nötig auch bei Widerruf
 | 
			
		||||
  FOREIGN KEY (receiptId) REFERENCES Debit(receiptId),
 | 
			
		||||
  FOREIGN KEY (fromCredit) REFERENCES Credit(Id),
 | 
			
		||||
  UNIQUE (receiptId, fromCredit)
 | 
			
		||||
);
 | 
			
		||||
 | 
			
		||||
CREATE TABLE IF NOT EXISTS _temp (d, c, m);
 | 
			
		||||
CREATE TRIGGER balanceTransfer
 | 
			
		||||
     AFTER INSERT ON Transfer 
 | 
			
		||||
BEGIN
 | 
			
		||||
 | 
			
		||||
  SELECT RAISE(FAIL, "It is not the debitor who pays")
 | 
			
		||||
    WHERE (SELECT debitor FROM Debit WHERE receiptId=NEW.receiptId)
 | 
			
		||||
       != (SELECT account FROM Credit WHERE Id=NEW.fromCredit)
 | 
			
		||||
    ;
 | 
			
		||||
 | 
			
		||||
  INSERT INTO _temp
 | 
			
		||||
     SELECT remainingDebt, remainingCredit, min(remainingDebt,remainingCredit) 
 | 
			
		||||
     FROM (SELECT
 | 
			
		||||
         (SELECT value - paid FROM Debit WHERE receiptId=NEW.receiptId) AS remainingDebt, 
 | 
			
		||||
         (SELECT value - spent FROM Credit WHERE Id=NEW.fromCredit) AS remainingCredit
 | 
			
		||||
     ) AS microbalance
 | 
			
		||||
  ;
 | 
			
		||||
 | 
			
		||||
  UPDATE Debit
 | 
			
		||||
      SET paid = paid + CASE
 | 
			
		||||
        WHEN (SELECT d FROM _temp) <= 0
 | 
			
		||||
          THEN RAISE(ROLLBACK, "Debt is already paid")
 | 
			
		||||
        ELSE
 | 
			
		||||
          (SELECT m FROM _temp)
 | 
			
		||||
      END
 | 
			
		||||
      WHERE receiptId=NEW.receiptId;
 | 
			
		||||
 | 
			
		||||
  UPDATE Credit
 | 
			
		||||
      SET value = value + (SELECT m FROM _temp)
 | 
			
		||||
      WHERE Id = (
 | 
			
		||||
          SELECT targetCredit
 | 
			
		||||
          FROM Debit
 | 
			
		||||
          WHERE receiptId=NEW.receiptId
 | 
			
		||||
      );
 | 
			
		||||
 | 
			
		||||
  UPDATE Credit
 | 
			
		||||
      SET spent = spent + CASE
 | 
			
		||||
        WHEN (SELECT c FROM _temp) <= 0
 | 
			
		||||
          THEN RAISE(FAIL, "Credit is already spent")
 | 
			
		||||
        ELSE
 | 
			
		||||
          (SELECT m FROM _temp)
 | 
			
		||||
      END
 | 
			
		||||
      WHERE Id=NEW.fromCredit;
 | 
			
		||||
 | 
			
		||||
  UPDATE Transfer
 | 
			
		||||
      SET amount = (SELECT m FROM _temp)
 | 
			
		||||
      WHERE receiptId=NEW.receiptId AND fromCredit=NEW.fromCredit
 | 
			
		||||
        ;
 | 
			
		||||
 | 
			
		||||
  DELETE FROM _temp;
 | 
			
		||||
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER revokeTransfer
 | 
			
		||||
    BEFORE DELETE ON Transfer
 | 
			
		||||
BEGIN
 | 
			
		||||
 | 
			
		||||
  INSERT INTO _temp VALUES (null,null,OLD.amount);
 | 
			
		||||
 | 
			
		||||
  UPDATE Debit
 | 
			
		||||
      SET paid = paid - OLD.amount
 | 
			
		||||
      WHERE receiptId=OLD.receiptId
 | 
			
		||||
      ;
 | 
			
		||||
 | 
			
		||||
  UPDATE Credit
 | 
			
		||||
      SET value = value - OLD.amount
 | 
			
		||||
      WHERE Id = (
 | 
			
		||||
          SELECT targetCredit
 | 
			
		||||
          FROM Debit
 | 
			
		||||
          WHERE receiptId=OLD.receiptId
 | 
			
		||||
      );
 | 
			
		||||
 | 
			
		||||
  UPDATE Credit
 | 
			
		||||
      SET spent = spent - OLD.amount
 | 
			
		||||
      WHERE Id = OLD.fromCredit;
 | 
			
		||||
 | 
			
		||||
  DELETE FROM _temp;
 | 
			
		||||
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER enforceImmutableTransfer
 | 
			
		||||
    BEFORE UPDATE ON Transfer
 | 
			
		||||
    WHEN OLD.amount IS NOT NULL
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "Transfer cannot be updated, but needs to be revoked and re-inserted to ensure the triggers run");
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER enforceiZeroPaidAtStart
 | 
			
		||||
    BEFORE INSERT ON Debit
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "debt must be initially unpaid")
 | 
			
		||||
    WHERE NEW.paid <> 0;
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
-- Prevent modification with paid value outside triggers which must adjust it exclusively
 | 
			
		||||
-- when new transfer records are inserted
 | 
			
		||||
CREATE TRIGGER enforceDebtImmutableOutsideTrigger
 | 
			
		||||
    BEFORE UPDATE OF paid ON Debit
 | 
			
		||||
    WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.receiptId=t.receiptId AND amount IS NULL)
 | 
			
		||||
BEGIN
 | 
			
		||||
    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;
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER enforceFixedDebits
 | 
			
		||||
    BEFORE UPDATE OF value ON Debit
 | 
			
		||||
    WHEN EXISTS (SELECT * FROM Transfer WHERE receiptId=NEW.receiptId)
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "Debt is involved in transfers to revoke at first");
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER enforceZeroSpentAtStart
 | 
			
		||||
    BEFORE INSERT ON Credit
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "credit must be initially unused")
 | 
			
		||||
    WHERE NEW.spent != 0;
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
-- Prevent modification with spent value outside triggers which must adjust it exclusively
 | 
			
		||||
-- when new transfer records are inserted
 | 
			
		||||
CREATE TRIGGER enforceSpentImmutableOutsideTrigger
 | 
			
		||||
    BEFORE UPDATE OF spent ON Credit
 | 
			
		||||
    WHEN NOT EXISTS (SELECT * FROM Transfer t WHERE NEW.Id=t.fromCredit AND amount IS NULL)
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "spent is set and adjusted automatically according to added Transfer records")
 | 
			
		||||
    WHERE (NEW.spent + IFNULL((SELECT m FROM _temp WHERE c IS NULL AND d IS NULL),0) ) <> OLD.spent;
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER enforceFixedCredit
 | 
			
		||||
    BEFORE UPDATE OF value ON Credit
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT RAISE(FAIL, "Credit involved in transactions to revoke at first")
 | 
			
		||||
    WHERE EXISTS (SELECT * FROM Transfer WHERE fromCredit=NEW.Id);
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE TRIGGER checkIBANatTransfer
 | 
			
		||||
    BEFORE INSERT ON Debit
 | 
			
		||||
    WHEN NEW.targetCredit IS NULL
 | 
			
		||||
BEGIN
 | 
			
		||||
   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
 | 
			
		||||
   WHERE fnd IS NULL OR fnd = 0;
 | 
			
		||||
END;
 | 
			
		||||
 | 
			
		||||
CREATE VIEW CurrentDebts AS
 | 
			
		||||
    SELECT debitor, purpose, date,
 | 
			
		||||
           value - paid AS difference
 | 
			
		||||
    FROM Debit
 | 
			
		||||
    WHERE value != paid
 | 
			
		||||
;
 | 
			
		||||
      
 | 
			
		||||
CREATE VIEW AvailableCredits AS
 | 
			
		||||
    SELECT account, purpose, date,
 | 
			
		||||
           value - spent AS difference
 | 
			
		||||
    FROM Credit
 | 
			
		||||
    WHERE value != spent
 | 
			
		||||
;
 | 
			
		||||
      
 | 
			
		||||
CREATE VIEW Balance AS
 | 
			
		||||
  SELECT ID, IFNULL(ac.allCredits,0) credit, IFNULL(cd.allDebts, 0) debit
 | 
			
		||||
  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 (SELECT account, sum(difference) AS allCredits FROM AvailableCredits GROUP BY account) AS ac ON ID=ac.account
 | 
			
		||||
  ;
 | 
			
		||||
 | 
			
		||||
							
								
								
									
										15
									
								
								schema.t.sh
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										15
									
								
								schema.t.sh
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,15 @@
 | 
			
		||||
diff -q <(cat schema{,.t}.sql | sqlite3 2>&1) - <<OUT && 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
 | 
			
		||||
							
								
								
									
										38
									
								
								schema.t.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										38
									
								
								schema.t.sql
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,38 @@
 | 
			
		||||
PRAGMA foreign_keys = ON;
 | 
			
		||||
 | 
			
		||||
INSERT INTO Account VALUES ("Club", "eV", 1, NULL), ("john", "Member", 44, NULL), ("alex", "Member", 6, "DE1234567890123456");
 | 
			
		||||
 | 
			
		||||
INSERT INTO Credit VALUES (1, "Club", "2016-01-01", "Membership fees May 2016 until incl. April 2017", 0, 0),
 | 
			
		||||
                         (2, "john", "2016-04-23", "Membership fee 2016f.", 7200, 0),
 | 
			
		||||
                         (3, "alex", "2016-01-15", "Payment for Server Hosting 2016", 0, 0);
 | 
			
		||||
 | 
			
		||||
INSERT INTO Debit VALUES ("MB1605-john", "john", 1, "2016-05-01", "Membership fee May 2016", 600, 0),
 | 
			
		||||
                        ("MB1606-john", "john", 1, "2016-05-01", "Membership fee June 2016", 600, 0),
 | 
			
		||||
                        ("MB1607-john", "john", 1, "2016-05-01", "Membership fee July 2016", 600, 0),
 | 
			
		||||
                        ("MB1608-john", "john", 1, "2016-05-01", "Membership fee August 2016", 600, 0),
 | 
			
		||||
                        ("MB1609-john", "john", 1, "2016-05-01", "Membership fee September 2016", 600, 0),
 | 
			
		||||
                        ("MB1610-john", "john", 1, "2016-05-01", "Membership fee October 2016", 600, 0),
 | 
			
		||||
                        ("MB1611-john", "john", 1, "2016-05-01", "Membership fee November 2016", 600, 0),
 | 
			
		||||
                        ("MB1612-john", "john", 1, "2016-05-01", "Membership fee December 2016", 600, 0),
 | 
			
		||||
                        ("MB1701-john", "john", 1, "2016-05-01", "Membership fee January 2017", 600, 0),
 | 
			
		||||
                        ("MB1702-john", "john", 1, "2016-05-01", "Membership fee February 2017", 600, 0),
 | 
			
		||||
                        ("MB1703-john", "john", 1, "2016-05-01", "Membership fee March 2017", 600, 0),
 | 
			
		||||
                        ("MB1704-john", "john", 1, "2016-05-01", "Membership fee April 2017", 600, 0),
 | 
			
		||||
                        ("TWX2016/123", "Club", 3, "2016-01-15", "Server Hosting 2016", 23450, 0);
 | 
			
		||||
 | 
			
		||||
.separator " "
 | 
			
		||||
SELECT "Balance of " || ID || "'s account:", credit, debit * -1 FROM Balance WHERE ID in ("john", "Club");
 | 
			
		||||
INSERT INTO Transfer (receiptId, fromCredit) VALUES ("MB1605-john", 2), ("MB1606-john", 2), ("MB1607-john", 2), ("MB1608-john", 2), ("MB1609-john", 2), ("MB1610-john", 2), ("MB1611-john", 2), ("MB1612-john", 2), ("MB1701-john", 2), ("MB1702-john", 2), ("MB1703-john", 2), ("MB1704-john", 2); 
 | 
			
		||||
SELECT "Balance of " || ID || "'s account:", credit, debit * -1 FROM Balance WHERE ID in ("john", "Club");
 | 
			
		||||
INSERT INTO Transfer (receiptId, fromCredit) VALUES ("TWX2016/123", 1);
 | 
			
		||||
SELECT "Balance of " || ID || "'s Account:", credit, debit * -1 FROM Balance WHERE ID in ("Club", "alex");
 | 
			
		||||
UPDATE Debit SET paid = 20000 WHERE receiptId="TWX2016/123";
 | 
			
		||||
UPDATE Debit SET value = 20000 WHERE receiptId="TWX2016/123";
 | 
			
		||||
DELETE FROM Debit WHERE receiptId="TWX2016/123"; -- *SHOULD NOT* work
 | 
			
		||||
BEGIN TRANSACTION;
 | 
			
		||||
DELETE FROM Transfer WHERE receiptId="TWX2016/123";
 | 
			
		||||
UPDATE Debit SET value = 20000 WHERE receiptId="TWX2016/123";
 | 
			
		||||
DELETE FROM Debit WHERE receiptId="TWX2016/123"; -- *SHOULD* work
 | 
			
		||||
SELECT "Balance of " || ID || "'s Account:", credit, debit * -1 FROM Balance WHERE ID in ("Club", "alex");
 | 
			
		||||
ROLLBACK TRANSACTION;
 | 
			
		||||
SELECT "Balance of " || ID || "'s Account:", credit, debit * -1 FROM Balance WHERE ID in ("Club", "alex");
 | 
			
		||||
		Loading…
	
	
			
			x
			
			
		
	
		Reference in New Issue
	
	Block a user