forked from brmlab/brmbar-github
127 lines
5.2 KiB
Text
127 lines
5.2 KiB
Text
CREATE SEQUENCE currencies_id_seq START WITH 2 INCREMENT BY 1;
|
|
CREATE TABLE currencies (
|
|
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('currencies_id_seq'::regclass),
|
|
name VARCHAR(128) NOT NULL,
|
|
UNIQUE(name)
|
|
);
|
|
-- Some code depends on the primary physical currency to have id 1.
|
|
INSERT INTO currencies (id, name) VALUES (1, 'Kč');
|
|
|
|
CREATE TYPE exchange_rate_direction AS ENUM ('source_to_target', 'target_to_source');
|
|
CREATE TABLE exchange_rates (
|
|
valid_since TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW() NOT NULL,
|
|
|
|
target INTEGER NOT NULL,
|
|
FOREIGN KEY (target) REFERENCES currencies (id),
|
|
|
|
source INTEGER NOT NULL,
|
|
FOREIGN KEY (source) REFERENCES currencies (id),
|
|
|
|
rate DECIMAL(12,2) NOT NULL,
|
|
rate_dir exchange_rate_direction NOT NULL
|
|
);
|
|
|
|
|
|
-- brmbar users have 'debt' accounts; a negative balance means that
|
|
-- we have debt to the users, i.e. they are positive relative to the brmbar.
|
|
-- Positive balance means that the users have debt in brmbar.
|
|
-- Therefore, user's balance must always be shown negated.
|
|
CREATE SEQUENCE accounts_id_seq START WITH 1 INCREMENT BY 1;
|
|
CREATE TYPE account_type AS ENUM ('cash', 'debt', 'inventory', 'income', 'expense', 'starting_balance', 'ending_balance');
|
|
CREATE TABLE accounts (
|
|
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('accounts_id_seq'::regclass),
|
|
|
|
name VARCHAR(128) NOT NULL,
|
|
UNIQUE (name),
|
|
|
|
currency INTEGER NOT NULL,
|
|
FOREIGN KEY (currency) REFERENCES currencies (id),
|
|
|
|
acctype account_type NOT NULL,
|
|
|
|
active BOOLEAN NOT NULL DEFAULT TRUE
|
|
);
|
|
INSERT INTO accounts (name, currency, acctype) VALUES ('BrmBar Cash', (SELECT id FROM currencies WHERE name='Kč'), 'cash');
|
|
INSERT INTO accounts (name, currency, acctype) VALUES ('BrmBar Profits', (SELECT id FROM currencies WHERE name='Kč'), 'income');
|
|
INSERT INTO accounts (name, currency, acctype) VALUES ('BrmBar Excess', (SELECT id FROM currencies WHERE name='Kč'), 'income');
|
|
INSERT INTO accounts (name, currency, acctype) VALUES ('BrmBar Deficit', (SELECT id FROM currencies WHERE name='Kč'), 'expense');
|
|
|
|
|
|
CREATE SEQUENCE barcodes_id_seq START WITH 1 INCREMENT BY 1;
|
|
CREATE TABLE barcodes (
|
|
barcode VARCHAR(128) PRIMARY KEY NOT NULL,
|
|
|
|
account INTEGER NOT NULL,
|
|
FOREIGN KEY (account) REFERENCES accounts (id)
|
|
);
|
|
-- Barcode for cash
|
|
-- XXX Silently assume there is only one.
|
|
INSERT INTO barcodes (barcode, account) VALUES ('_cash_', (SELECT id FROM accounts WHERE acctype = 'cash'));
|
|
|
|
|
|
CREATE SEQUENCE transactions_id_seq START WITH 1 INCREMENT BY 1;
|
|
CREATE TABLE transactions (
|
|
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('transactions_id_seq'::regclass),
|
|
time TIMESTAMP DEFAULT NOW() NOT NULL,
|
|
|
|
responsible INTEGER,
|
|
FOREIGN KEY (responsible) REFERENCES accounts (id),
|
|
-- FIXME: imperfect constraint to assure this is a user
|
|
|
|
description TEXT
|
|
);
|
|
|
|
CREATE SEQUENCE transaction_splits_id_seq START WITH 1 INCREMENT BY 1;
|
|
CREATE TYPE transaction_split_side AS ENUM ('credit', 'debit');
|
|
CREATE TABLE transaction_splits (
|
|
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('transaction_splits_id_seq'::regclass),
|
|
|
|
transaction INTEGER NOT NULL,
|
|
FOREIGN KEY (transaction) REFERENCES transactions (id),
|
|
|
|
side transaction_split_side NOT NULL,
|
|
|
|
account INTEGER NOT NULL,
|
|
FOREIGN KEY (account) REFERENCES accounts (id),
|
|
amount DECIMAL(12,2) NOT NULL,
|
|
|
|
memo TEXT
|
|
);
|
|
|
|
-- List balances of accounts computed based on transactions
|
|
-- Note that currency information is currently not supplied; inventory items
|
|
-- have balances in stock amounts.
|
|
CREATE VIEW account_balances AS
|
|
SELECT ts.account AS id, accounts.name AS name, accounts.acctype AS acctype,
|
|
-SUM(CASE WHEN ts.side = 'credit' THEN -ts.amount ELSE ts.amount END) AS crbalance
|
|
FROM transaction_splits AS ts
|
|
LEFT JOIN accounts ON accounts.id = ts.account
|
|
GROUP BY ts.account, accounts.name, accounts.acctype
|
|
ORDER BY crbalance ASC;
|
|
|
|
-- Transaction splits in a form that's nicer to query during manual inspection
|
|
CREATE VIEW transaction_nicesplits AS
|
|
SELECT ts.id AS id, ts.transaction AS transaction, ts.account AS account,
|
|
(CASE WHEN ts.side = 'credit' THEN -ts.amount ELSE ts.amount END) AS amount,
|
|
a.currency AS currency, ts.memo AS memo
|
|
FROM transaction_splits AS ts LEFT JOIN accounts AS a ON a.id = ts.account
|
|
ORDER BY ts.id;
|
|
|
|
-- List transactions with summary information regarding their cash element.
|
|
CREATE VIEW transaction_cashsums AS
|
|
SELECT t.id AS id, t.time AS time, SUM(credit_cash) AS cash_credit, SUM(debit_cash) AS cash_debit, a.name AS responsible, t.description AS description
|
|
FROM transactions AS t
|
|
LEFT JOIN (SELECT cts.amount AS credit_cash, cts.transaction AS cts_t
|
|
FROM transaction_nicesplits AS cts
|
|
LEFT JOIN accounts AS a ON a.id = cts.account OR a.id = cts.account
|
|
WHERE a.currency = (SELECT currency FROM accounts WHERE name = 'BrmBar Cash')
|
|
AND a.acctype IN ('cash', 'debt')
|
|
AND cts.amount < 0) credit ON cts_t = t.id
|
|
LEFT JOIN (SELECT dts.amount AS debit_cash, dts.transaction AS dts_t
|
|
FROM transaction_nicesplits AS dts
|
|
LEFT JOIN accounts AS a ON a.id = dts.account OR a.id = dts.account
|
|
WHERE a.currency = (SELECT currency FROM accounts WHERE name = 'BrmBar Cash')
|
|
AND a.acctype IN ('cash', 'debt')
|
|
AND dts.amount > 0) debit ON dts_t = t.id
|
|
LEFT JOIN accounts AS a ON a.id = t.responsible
|
|
GROUP BY t.id, a.name ORDER BY t.id DESC;
|