diff --git a/brmbar3/SQL b/brmbar3/SQL index a61dba8..04667f4 100644 --- a/brmbar3/SQL +++ b/brmbar3/SQL @@ -1,11 +1,11 @@ -CREATE SEQUENCE currencies_id_seq START WITH 1 INCREMENT BY 1; +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 (name) VALUES ('Kč'); +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 ( diff --git a/brmbar3/SQL-for-RO-access.sql b/brmbar3/SQL-for-RO-access.sql new file mode 100644 index 0000000..b8c7291 --- /dev/null +++ b/brmbar3/SQL-for-RO-access.sql @@ -0,0 +1,57 @@ +CREATE OR REPLACE FUNCTION accounts_id_seq_value() +RETURNS bigint +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + result bigint; +BEGIN + SELECT last_value FROM accounts_id_seq + INTO result; + RETURN result; +END; +$$; + +CREATE OR REPLACE FUNCTION transactions_id_seq_value() +RETURNS bigint +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + result bigint; +BEGIN + SELECT last_value FROM transactions_id_seq + INTO result; + RETURN result; +END; +$$; + +CREATE OR REPLACE FUNCTION transaction_splits_id_seq_value() +RETURNS bigint +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + result bigint; +BEGIN + SELECT last_value FROM transaction_splits_id_seq + INTO result; + RETURN result; +END; +$$; + +CREATE OR REPLACE FUNCTION currencies_id_seq_value() +RETURNS bigint +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + result bigint; +BEGIN + SELECT last_value FROM currencies_id_seq + INTO result; + RETURN result; +END; +$$; + + diff --git a/brmbar3/SQL-schema-v001.sql b/brmbar3/SQL-schema-v001.sql new file mode 100644 index 0000000..44b9693 --- /dev/null +++ b/brmbar3/SQL-schema-v001.sql @@ -0,0 +1,59 @@ +--RESET search_path; +SELECT pg_catalog.set_config('search_path', '', false); +-- intoduce implementation schema +CREATE SCHEMA IF NOT EXISTS brmbar_implementation; +-- version table (with initialization) +CREATE TABLE IF NOT EXISTS brmbar_implementation.brmbar_schema ( + ver INTEGER NOT NULL +); +DO $$ +DECLARE v INTEGER; +BEGIN + SELECT ver FROM brmbar_implementation.brmbar_schema INTO v; + IF v IS NULL THEN + INSERT INTO brmbar_implementation.brmbar_schema (ver) VALUES (1); + END IF; +END; +$$; + +CREATE OR REPLACE FUNCTION brmbar_implementation.has_exact_schema_version( + IN i_ver INTEGER NOT NULL +) RETURNS INTEGER +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $$ +DECLARE + v_ver INTEGER; +BEGIN + SELECT ver INTO STRICT v_ver FROM brmbar_implementation.brmbar_schema; + IF v_ver IS NULL or v_ver <> i_ver THEN + RAISE EXCEPTION 'Invalid brmbar schema version'; + END IF; + RETURN v_ver; +/* +EXCEPTION + WHEN NO_DATA_FOUND THEN + RAISE EXCEPTION 'PID % not found'; + WHEN TOO_MANY_ROWS THEN + RAISE EXCEPTION 'PID % not unique'; +*/ +END; +$$; + +CREATE OR REPLACE FUNCTION brmbar_implementation.upgrade_schema_version_to( + IN i_ver INTEGER NOT NULL +) RETURNS INTEGER +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $$ +DECLARE + v_ver INTEGER; +BEGIN + SELECT brmbar_implementation.has_exact_schema_version(i_ver) INTO v_ver; + IF v_ver + 1 = i_ver THEN + UPDATE brmbar_implementation.brmbar_schema SET ver = i_ver; + ELSE + RAISE EXCEPTION 'Invalid brmbar schema version'; + END IF; + RETURN i_ver; +END; +$$; + +-- vim: set ft=plsql : + diff --git a/brmbar3/SQL-schema-v002.sql b/brmbar3/SQL-schema-v002.sql new file mode 100644 index 0000000..bfb63fa --- /dev/null +++ b/brmbar3/SQL-schema-v002.sql @@ -0,0 +1,61 @@ +--RESET search_path +SELECT pg_catalog.set_config('search_path', '', false); + +--- upgrade schema +DO $upgrade_block$ +DECLARE +current_ver INTEGER; +BEGIN + +-- confirm that we are upgrading from version 1 +SELECT brmbar_implementation.has_exact_schema_version(1) INTO current_ver; +IF current_ver <> 1 THEN + RAISE EXCEPTION 'BrmBar schema version % cannot be upgraded to version 2.', current_ver; +END IF; + +-- structural changes + +-- TRADING ACCOUNTS +--START TRANSACTION ISOLATION LEVEL SERIALIZABLE; + +-- currency trading accounts - account type +ALTER TYPE public.account_type ADD VALUE IF NOT EXISTS 'trading'; + +-- constraint needed for foreign key in currencies table +ALTER TABLE public.accounts ADD CONSTRAINT accounts_id_acctype_key UNIQUE(id, acctype); + +-- add columns to currencies to record the trading account associated with the currency +ALTER TABLE public.currencies + ADD COLUMN IF NOT EXISTS trading_account integer, + ADD COLUMN IF NOT EXISTS trading_account_type account_type GENERATED ALWAYS AS ('trading'::public.account_type) STORED; + +-- make trading accounts (without making duplicates) +INSERT INTO public.accounts ("name", "currency", acctype) +SELECT + 'Currency Trading Account: ' || c."name", + c.id, + 'trading'::public.account_type +FROM public.currencies AS c +WHERE NOT EXISTS ( + SELECT 1 + FROM public.accounts a + WHERE a.currency = c.id AND a.acctype = 'trading'::public.account_type +); + + +-- record the trading account IDs in currencies table +UPDATE public.currencies AS c SET (trading_account) = (SELECT a.id FROM public.accounts AS a WHERE a.currency = c.id AND c.acctype = 'trading'::public.account_type); + +-- foreign key to check the validity of currency trading account reference +ALTER TABLE public.currencies + ADD CONSTRAINT currencies_trading_fkey FOREIGN KEY (trading_account, trading_account_type) + REFERENCES xaccounts(id,acctype) DEFERRABLE INITIALLY DEFERRED; + +--COMMIT AND CHAIN; + +SELECT brmbar_implementation.upgrade_schema_version_to(2) INTO current_ver; +-- end of upgrade do block +end +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 29dd79e..215df11 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -40,16 +40,22 @@ class Account: @classmethod def create(cls, db, name, currency, acctype): """ Constructor for new account """ - id = db.execute_and_fetch("INSERT INTO accounts (name, currency, acctype) VALUES (%s, %s, %s) RETURNING id", [name, currency.id, acctype]) - id = id[0] + # id = db.execute_and_fetch("INSERT INTO accounts (name, currency, acctype) VALUES (%s, %s, %s) RETURNING id", [name, currency.id, acctype]) + id = db.execute_and_fetch("SELECT public.create_account(%s, %s, %s)", [name, currency.id, acctype]) + # id = id[0] return cls(db, name = name, id = id, currency = currency, acctype = acctype) def balance(self): - debit = self.db.execute_and_fetch("SELECT SUM(amount) FROM transaction_splits WHERE account = %s AND side = %s", [self.id, 'debit']) - debit = debit[0] or 0 - credit = self.db.execute_and_fetch("SELECT SUM(amount) FROM transaction_splits WHERE account = %s AND side = %s", [self.id, 'credit']) - credit = credit[0] or 0 - return debit - credit + bal = self.db.execute_and_fetch( + "SELECT public.compute_account_balance(%s)", + [self.id] + )[0] + return bal + #debit = self.db.execute_and_fetch("SELECT SUM(amount) FROM transaction_splits WHERE account = %s AND side = %s", [self.id, 'debit']) + #debit = debit[0] or 0 + #credit = self.db.execute_and_fetch("SELECT SUM(amount) FROM transaction_splits WHERE account = %s AND side = %s", [self.id, 'credit']) + #credit = credit[0] or 0 + #return debit - credit def balance_str(self): return self.currency.str(self.balance()) @@ -68,9 +74,11 @@ class Account: self.db.execute("INSERT INTO transaction_splits (transaction, side, account, amount, memo) VALUES (%s, %s, %s, %s, %s)", [transaction, side, self.id, amount, memo]) def add_barcode(self, barcode): - self.db.execute("INSERT INTO barcodes (account, barcode) VALUES (%s, %s)", [self.id, barcode]) + # self.db.execute("INSERT INTO barcodes (account, barcode) VALUES (%s, %s)", [self.id, barcode]) + self.db.execute("SELECT public.add_barcode_to_account(%s, %s)", [self.id, barcode]) self.db.commit() def rename(self, name): - self.db.execute("UPDATE accounts SET name = %s WHERE id = %s", [name, self.id]) + # self.db.execute("UPDATE accounts SET name = %s WHERE id = %s", [name, self.id]) + self.db.execute("SELECT public.rename_account(%s, %s)", [self.id, name]) self.name = name diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index d2216ca..29da4a3 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -31,15 +31,34 @@ class Currency: @classmethod def create(cls, db, name): """ Constructor for new currency """ - id = db.execute_and_fetch("INSERT INTO currencies (name) VALUES (%s) RETURNING id", [name]) - id = id[0] + # id = db.execute_and_fetch("INSERT INTO currencies (name) VALUES (%s) RETURNING id", [name]) + id = db.execute_and_fetch("SELECT public.create_currency(%s)", [name]) + # id = id[0] return cls(db, name = name, id = id) def rates(self, other): """ Return tuple ($buy, $sell) of rates of $self in relation to $other (brmbar.Currency): $buy is the price of $self in means of $other when buying it (into brmbar) $sell is the price of $self in means of $other when selling it (from brmbar) """ + # buy rate + res = self.db.execute_and_fetch("SELECT public.find_buy_rate(%s, %s)",[self.id, other.id]) + if res is None: + raise NameError("Something fishy in find_buy_rate."); + buy = res[0] + if buy < 0: + raise NameError("Currency.rate(): Unknown conversion " + other.name() + " to " + self.name()) + # sell rate + res = self.db.execute_and_fetch("SELECT public.find_sell_rate(%s, %s)",[self.id, other.id]) + if res is None: + raise NameError("Something fishy in find_sell_rate."); + sell = res[0] + if sell < 0: + raise NameError("Currency.rate(): Unknown conversion " + self.name() + " to " + other.name()) + return (buy, sell) + + def rates2(self, other): + # the original code for compare testing res = self.db.execute_and_fetch("SELECT rate, rate_dir FROM exchange_rates WHERE target = %s AND source = %s AND valid_since <= NOW() ORDER BY valid_since DESC LIMIT 1", [self.id, other.id]) if res is None: raise NameError("Currency.rate(): Unknown conversion " + other.name() + " to " + self.name()) @@ -54,6 +73,7 @@ class Currency: return (buy, sell) + def convert(self, amount, target): res = self.db.execute_and_fetch("SELECT rate, rate_dir FROM exchange_rates WHERE target = %s AND source = %s AND valid_since <= NOW() ORDER BY valid_since DESC LIMIT 1", [target.id, self.id]) if res is None: @@ -69,6 +89,10 @@ class Currency: return "{:.2f} {}".format(amount, self.name) def update_sell_rate(self, target, rate): - self.db.execute("INSERT INTO exchange_rates (source, target, rate, rate_dir) VALUES (%s, %s, %s, %s)", [self.id, target.id, rate, "source_to_target"]) + # self.db.execute("INSERT INTO exchange_rates (source, target, rate, rate_dir) VALUES (%s, %s, %s, %s)", [self.id, target.id, rate, "source_to_target"]) + self.db.execute("SELECT public.update_currency_sell_rate(%s, %s, %s)", + [self.id, target.id, rate]) def update_buy_rate(self, source, rate): - self.db.execute("INSERT INTO exchange_rates (source, target, rate, rate_dir) VALUES (%s, %s, %s, %s)", [source.id, self.id, rate, "target_to_source"]) + # self.db.execute("INSERT INTO exchange_rates (source, target, rate, rate_dir) VALUES (%s, %s, %s, %s)", [source.id, self.id, rate, "target_to_source"]) + self.db.execute("SELECT public.update_currency_buy_rate(%s, %s, %s)", + [source.id, self.id, rate]) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 6027084..e7dbc6c 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -25,79 +25,123 @@ class Shop: deficit = Account.load(db, name = "BrmBar Deficit")) def sell(self, item, user, amount = 1): - # Sale: Currency conversion from item currency to shop currency - (buy, sell) = item.currency.rates(self.currency) - cost = amount * sell - profit = amount * (sell - buy) + # Call the stored procedure for the sale + cost = self.db.execute_and_fetch( + "SELECT public.sell_item(%s, %s, %s, %s, %s)", + [item.id, amount, user.id, self.currency.id, f"BrmBar sale of {amount}x {item.name} to {user.name}"] + )[0]#[0] - transaction = self._transaction(responsible = user, description = "BrmBar sale of {}x {} to {}".format(amount, item.name, user.name)) - item.credit(transaction, amount, user.name) - user.debit(transaction, cost, item.name) # debit (increase) on a _debt_ account - self.profits.debit(transaction, profit, "Margin on " + item.name) self.db.commit() - return cost + # Sale: Currency conversion from item currency to shop currency + #(buy, sell) = item.currency.rates(self.currency) + #cost = amount * sell + #profit = amount * (sell - buy) + + #transaction = self._transaction(responsible = user, description = "BrmBar sale of {}x {} to {}".format(amount, item.name, user.name)) + #item.credit(transaction, amount, user.name) + #user.debit(transaction, cost, item.name) # debit (increase) on a _debt_ account + #self.profits.debit(transaction, profit, "Margin on " + item.name) + #self.db.commit() + #return cost def sell_for_cash(self, item, amount = 1): - # Sale: Currency conversion from item currency to shop currency - (buy, sell) = item.currency.rates(self.currency) - cost = amount * sell - profit = amount * (sell - buy) + cost = self.db.execute_and_fetch( + "SELECT public.sell_item_for_cash(%s, %s, %s, %s, %s)", + [item.id, amount, user.id, self.currency.id, f"BrmBar sale of {amount}x {item.name} for cash"] + )[0]#[0] - transaction = self._transaction(description = "BrmBar sale of {}x {} for cash".format(amount, item.name)) - item.credit(transaction, amount, "Cash") - self.cash.debit(transaction, cost, item.name) - self.profits.debit(transaction, profit, "Margin on " + item.name) self.db.commit() - return cost + ## Sale: Currency conversion from item currency to shop currency + #(buy, sell) = item.currency.rates(self.currency) + #cost = amount * sell + #profit = amount * (sell - buy) + + #transaction = self._transaction(description = "BrmBar sale of {}x {} for cash".format(amount, item.name)) + #item.credit(transaction, amount, "Cash") + #self.cash.debit(transaction, cost, item.name) + #self.profits.debit(transaction, profit, "Margin on " + item.name) + #self.db.commit() + + #return cost def undo_sale(self, item, user, amount = 1): # Undo sale; rarely needed - (buy, sell) = item.currency.rates(self.currency) - cost = amount * sell - profit = amount * (sell - buy) + #(buy, sell) = item.currency.rates(self.currency) + #cost = amount * sell + #profit = amount * (sell - buy) + + #transaction = self._transaction(responsible = user, description = "BrmBar sale UNDO of {}x {} to {}".format(amount, item.name, user.name)) + #item.debit(transaction, amount, user.name + " (sale undo)") + #user.credit(transaction, cost, item.name + " (sale undo)") + #self.profits.credit(transaction, profit, "Margin repaid on " + item.name) + # Call the stored procedure for undoing a sale + cost = self.db.execute_and_fetch( + "SELECT public.undo_sale_of_item(%s, %s, %s, %s)", + [item.id, amount, user.id, user.currency.id, f"BrmBar sale UNDO of {amount}x {item.name} to {user.name}"] + )[0]#[0] - transaction = self._transaction(responsible = user, description = "BrmBar sale UNDO of {}x {} to {}".format(amount, item.name, user.name)) - item.debit(transaction, amount, user.name + " (sale undo)") - user.credit(transaction, cost, item.name + " (sale undo)") - self.profits.credit(transaction, profit, "Margin repaid on " + item.name) self.db.commit() return cost def add_credit(self, credit, user): - transaction = self._transaction(responsible = user, description = "BrmBar credit replenishment for " + user.name) - self.cash.debit(transaction, credit, user.name) - user.credit(transaction, credit, "Credit replenishment") + self.db.execute_and_fetch( + "SELECT public.add_credit(%s, %s, %s, %s)", + [self.cash.id, credit, user.id, user.name] + ) self.db.commit() + #transaction = self._transaction(responsible = user, description = "BrmBar credit replenishment for " + user.name) + #self.cash.debit(transaction, credit, user.name) + #user.credit(transaction, credit, "Credit replenishment") + #self.db.commit() + def withdraw_credit(self, credit, user): - transaction = self._transaction(responsible = user, description = "BrmBar credit withdrawal for " + user.name) - self.cash.credit(transaction, credit, user.name) - user.debit(transaction, credit, "Credit withdrawal") + self.db.execute_and_fetch( + "SELECT public.withdraw_credit(%s, %s, %s, %s)", + [self.cash.id, credit, user.id, user.name] + ) self.db.commit() + #transaction = self._transaction(responsible = user, description = "BrmBar credit withdrawal for " + user.name) + #self.cash.credit(transaction, credit, user.name) + #user.debit(transaction, credit, "Credit withdrawal") + #self.db.commit() def transfer_credit(self, userfrom, userto, amount): - self.add_credit(amount, userto) - self.withdraw_credit(amount, userfrom) + self.db.execute_and_fetch( + "SELECT public.transfer_credit(%s, %s, %s, %s)", + [self.cash.id, credit, user.id, user.name] + ) + self.db.commit() + #self.add_credit(amount, userto) + #self.withdraw_credit(amount, userfrom) def buy_for_cash(self, item, amount = 1): + cost = self.db.execute_and_fetch( + "SELECT public.buy_for_cash(%s, %s, %s, %s, %s)", + [self.cash.id, item.id, amount, self.currency.id, item.name] + )[0] # Buy: Currency conversion from item currency to shop currency - (buy, sell) = item.currency.rates(self.currency) - cost = amount * buy + #(buy, sell) = item.currency.rates(self.currency) + #cost = amount * buy - transaction = self._transaction(description = "BrmBar stock replenishment of {}x {} for cash".format(amount, item.name)) - item.debit(transaction, amount, "Cash") - self.cash.credit(transaction, cost, item.name) + #transaction = self._transaction(description = "BrmBar stock replenishment of {}x {} for cash".format(amount, item.name)) + #item.debit(transaction, amount, "Cash") + #self.cash.credit(transaction, cost, item.name) self.db.commit() return cost def receipt_to_credit(self, user, credit, description): - transaction = self._transaction(responsible = user, description = "Receipt: " + description) - self.profits.credit(transaction, credit, user.name) - user.credit(transaction, credit, "Credit from receipt: " + description) + #transaction = self._transaction(responsible = user, description = "Receipt: " + description) + #self.profits.credit(transaction, credit, user.name) + #user.credit(transaction, credit, "Credit from receipt: " + description) + self.db.execute_and_fetch( + "SELECT public.buy_for_cash(%s, %s, %s, %s, %s)", + [self.profits.id, user.id, user.name, credit, description] + )[0] self.db.commit() def _transaction(self, responsible = None, description = None): @@ -158,75 +202,95 @@ class Shop: return accts def fix_inventory(self, item, amount): - amount_in_reality = amount - amount_in_system = item.balance() - (buy, sell) = item.currency.rates(self.currency) + rv = self.db.execute_and_fetch( + "SELECT public.fix_inventory(%s, %s, %s, %s, %s, %s)", + [item.id, item.currency.id, self.excess.id, self.deficit.id, self.currency.id, amount] + )[0] - diff = abs(amount_in_reality - amount_in_system) - buy_total = buy * diff - if amount_in_reality > amount_in_system: - transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) - item.debit(transaction, diff, "Inventory fix excess") - self.excess.credit(transaction, buy_total, "Inventory fix excess " + item.name) - self.db.commit() - return True - elif amount_in_reality < amount_in_system: - transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) - item.credit(transaction, diff, "Inventory fix deficit") - self.deficit.debit(transaction, buy_total, "Inventory fix deficit " + item.name) - self.db.commit() - return True - else: - transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) - item.debit(transaction, 0, "Inventory fix - amount was correct") - item.credit(transaction, 0, "Inventory fix - amount was correct") - self.db.commit() - return False + self.db.commit() + return rv + #amount_in_reality = amount + #amount_in_system = item.balance() + #(buy, sell) = item.currency.rates(self.currency) + + #diff = abs(amount_in_reality - amount_in_system) + #buy_total = buy * diff + #if amount_in_reality > amount_in_system: + # transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) + # item.debit(transaction, diff, "Inventory fix excess") + # self.excess.credit(transaction, buy_total, "Inventory fix excess " + item.name) + # self.db.commit() + # return True + #elif amount_in_reality < amount_in_system: + # transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) + # item.credit(transaction, diff, "Inventory fix deficit") + # self.deficit.debit(transaction, buy_total, "Inventory fix deficit " + item.name) + # self.db.commit() + # return True + #else: + # transaction = self._transaction(description = "BrmBar inventory fix of {}pcs {} in system to {}pcs in reality".format(amount_in_system, item.name,amount_in_reality)) + # item.debit(transaction, 0, "Inventory fix - amount was correct") + # item.credit(transaction, 0, "Inventory fix - amount was correct") + # self.db.commit() + # return False def fix_cash(self, amount): - amount_in_reality = amount - amount_in_system = self.cash.balance() + rv = self.db.execute_and_fetch( + "SELECT public.fix_cash(%s, %s, %s, %s)", + [self.excess.id, self.deficit.id, self.currency.id, amount] + )[0] - diff = abs(amount_in_reality - amount_in_system) - if amount_in_reality > amount_in_system: - transaction = self._transaction(description = "BrmBar cash inventory fix of {} in system to {} in reality".format(amount_in_system, amount_in_reality)) - self.cash.debit(transaction, diff, "Inventory fix excess") - self.excess.credit(transaction, diff, "Inventory cash fix excess.") - self.db.commit() - return True - elif amount_in_reality < amount_in_system: - transaction = self._transaction(description = "BrmBar cash inventory fix of {} in system to {} in reality".format(amount_in_system, amount_in_reality)) - self.cash.credit(transaction, diff, "Inventory fix deficit") - self.deficit.debit(transaction, diff, "Inventory fix deficit.") - self.db.commit() - return True - else: - return False + self.db.commit() + return rv + #amount_in_reality = amount + #amount_in_system = self.cash.balance() + + #diff = abs(amount_in_reality - amount_in_system) + #if amount_in_reality > amount_in_system: + # transaction = self._transaction(description = "BrmBar cash inventory fix of {} in system to {} in reality".format(amount_in_system, amount_in_reality)) + # self.cash.debit(transaction, diff, "Inventory fix excess") + # self.excess.credit(transaction, diff, "Inventory cash fix excess.") + # self.db.commit() + # return True + #elif amount_in_reality < amount_in_system: + # transaction = self._transaction(description = "BrmBar cash inventory fix of {} in system to {} in reality".format(amount_in_system, amount_in_reality)) + # self.cash.credit(transaction, diff, "Inventory fix deficit") + # self.deficit.debit(transaction, diff, "Inventory fix deficit.") + # self.db.commit() + # return True + #else: + # return False def consolidate(self): - transaction = self._transaction(description = "BrmBar inventory consolidation") - - excess_balance = self.excess.balance() - if excess_balance != 0: - print("Excess balance {} debited to profit".format(-excess_balance)) - self.excess.debit(transaction, -excess_balance, "Excess balance added to profit.") - self.profits.debit(transaction, -excess_balance, "Excess balance added to profit.") - deficit_balance = self.deficit.balance() - if deficit_balance != 0: - print("Deficit balance {} credited to profit".format(deficit_balance)) - self.deficit.credit(transaction, deficit_balance, "Deficit balance removed from profit.") - self.profits.credit(transaction, deficit_balance, "Deficit balance removed from profit.") + msg = self.db.execute_and_fetch( + "SELECT public.make_consolidate_transaction(%s, %s, %s)", + [self.excess.id, self.deficit.id, self.profits.id] + )[0] + #transaction = self._transaction(description = "BrmBar inventory consolidation") + #excess_balance = self.excess.balance() + #if excess_balance != 0: + # print("Excess balance {} debited to profit".format(-excess_balance)) + # self.excess.debit(transaction, -excess_balance, "Excess balance added to profit.") + # self.profits.debit(transaction, -excess_balance, "Excess balance added to profit.") + #deficit_balance = self.deficit.balance() + #if deficit_balance != 0: + # print("Deficit balance {} credited to profit".format(deficit_balance)) + # self.deficit.credit(transaction, deficit_balance, "Deficit balance removed from profit.") + # self.profits.credit(transaction, deficit_balance, "Deficit balance removed from profit.") + if msg != None: + print(msg) self.db.commit() def undo(self, oldtid): - description = self.db.execute_and_fetch("SELECT description FROM transactions WHERE id = %s", [oldtid])[0] - description = 'undo %d (%s)' % (oldtid, description) + #description = self.db.execute_and_fetch("SELECT description FROM transactions WHERE id = %s", [oldtid])[0] + #description = 'undo %d (%s)' % (oldtid, description) - transaction = self._transaction(description=description) - for split in self.db.execute_and_fetchall("SELECT id, side, account, amount, memo FROM transaction_splits WHERE transaction = %s", [oldtid]): - splitid, side, account, amount, memo = split - memo = 'undo %d (%s)' % (splitid, memo) - amount = -amount - self.db.execute("INSERT INTO transaction_splits (transaction, side, account, amount, memo) VALUES (%s, %s, %s, %s, %s)", [transaction, side, account, amount, memo]) + #transaction = self._transaction(description=description) + #for split in self.db.execute_and_fetchall("SELECT id, side, account, amount, memo FROM transaction_splits WHERE transaction = %s", [oldtid]): + # splitid, side, account, amount, memo = split + # memo = 'undo %d (%s)' % (splitid, memo) + # amount = -amount + # self.db.execute("INSERT INTO transaction_splits (transaction, side, account, amount, memo) VALUES (%s, %s, %s, %s, %s)", [transaction, side, account, amount, memo]) + transaction = self.db.execute_and_fetch("SELECT public.undo_transaction(%s)",[oldtid])[0] self.db.commit() return transaction diff --git a/brmbar3/schema/0001-init.sql b/brmbar3/schema/0001-init.sql new file mode 100644 index 0000000..8e7f8db --- /dev/null +++ b/brmbar3/schema/0001-init.sql @@ -0,0 +1,313 @@ +-- +-- 0001-init.sql +-- +-- Initial SQL schema construction as of 2025-04-20 (or so) +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +-- Privileged schema with protected data +CREATE SCHEMA IF NOT EXISTS brmbar_privileged; + +-- Initial versioning +CREATE TABLE IF NOT EXISTS brmbar_privileged.brmbar_schema( + ver INTEGER NOT NULL +); + +-- ---------------------------------------------------------------- +-- Legacy Schema Initialization +-- ---------------------------------------------------------------- + +DO $$ +DECLARE v INTEGER; +BEGIN + SELECT ver FROM brmbar_privileged.brmbar_schema INTO v; + IF v IS NULL THEN + -- -------------------------------- + -- Legacy Types + + SELECT COUNT(*) INTO v + FROM pg_catalog.pg_type typ + INNER JOIN pg_catalog.pg_namespace nsp + ON nsp.oid = typ.typnamespace + WHERE nsp.nspname = 'public' + AND typ.typname='exchange_rate_direction'; + IF v=0 THEN + RAISE NOTICE 'Creating type exchange_rate_direction'; + CREATE TYPE public.exchange_rate_direction + AS ENUM ('source_to_target', 'target_to_source'); + ELSE + RAISE NOTICE 'Type exchange_rate_direction already exists'; + END IF; + + SELECT COUNT(*) INTO v + FROM pg_catalog.pg_type typ + INNER JOIN pg_catalog.pg_namespace nsp + ON nsp.oid = typ.typnamespace + WHERE nsp.nspname = 'public' + AND typ.typname='account_type'; + IF v=0 THEN + RAISE NOTICE 'Creating type account_type'; + CREATE TYPE public.account_type + AS ENUM ('cash', 'debt', 'inventory', 'income', 'expense', + 'starting_balance', 'ending_balance'); + ELSE + RAISE NOTICE 'Type account_type already exists'; + END IF; + + SELECT COUNT(*) INTO v + FROM pg_catalog.pg_type typ + INNER JOIN pg_catalog.pg_namespace nsp + ON nsp.oid = typ.typnamespace + WHERE nsp.nspname = 'public' + AND typ.typname='transaction_split_side'; + IF v=0 THEN + RAISE NOTICE 'Creating type transaction_split_side'; + CREATE TYPE public.transaction_split_side + AS ENUM ('credit', 'debit'); + ELSE + RAISE NOTICE 'Type transaction_split_side already exists'; + END IF; + + -- -------------------------------- + -- Currencies sequence, table and potential initial data + + CREATE SEQUENCE IF NOT EXISTS public.currencies_id_seq + START WITH 2 INCREMENT BY 1; + CREATE TABLE IF NOT EXISTS public.currencies ( + id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('public.currencies_id_seq'::regclass), + name VARCHAR(128) NOT NULL, + UNIQUE(name) + ); + INSERT INTO public.currencies (id, name) VALUES (1, 'Kč') + ON CONFLICT DO NOTHING; + + -- -------------------------------- + -- Exchange rates table - no initial data required + + CREATE TABLE IF NOT EXISTS public.exchange_rates ( + valid_since TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW() NOT NULL, + + target INTEGER NOT NULL, + FOREIGN KEY (target) REFERENCES public.currencies (id), + + source INTEGER NOT NULL, + FOREIGN KEY (source) REFERENCES public.currencies (id), + + rate DECIMAL(12,2) NOT NULL, + rate_dir public.exchange_rate_direction NOT NULL + ); + + -- -------------------------------- + -- Accounts sequence and table and 4 initial accounts + + CREATE SEQUENCE IF NOT EXISTS public.accounts_id_seq + START WITH 2 INCREMENT BY 1; + CREATE TABLE IF NOT EXISTS public.accounts ( + id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('public.accounts_id_seq'::regclass), + + name VARCHAR(128) NOT NULL, + UNIQUE (name), + + currency INTEGER NOT NULL, + FOREIGN KEY (currency) REFERENCES public.currencies (id), + + acctype public.account_type NOT NULL, + + active BOOLEAN NOT NULL DEFAULT TRUE + ); + INSERT INTO public.accounts (id, name, currency, acctype) + VALUES (1, 'BrmBar Cash', (SELECT id FROM public.currencies WHERE name='Kč'), 'cash') + ON CONFLICT DO NOTHING; + INSERT INTO public.accounts (name, currency, acctype) + VALUES ('BrmBar Profits', (SELECT id FROM public.currencies WHERE name='Kč'), 'income') + ON CONFLICT DO NOTHING; + INSERT INTO public.accounts (name, currency, acctype) + VALUES ('BrmBar Excess', (SELECT id FROM public.currencies WHERE name='Kč'), 'income') + ON CONFLICT DO NOTHING; + INSERT INTO public.accounts (name, currency, acctype) + VALUES ('BrmBar Deficit', (SELECT id FROM public.currencies WHERE name='Kč'), 'expense') + ON CONFLICT DO NOTHING; + + -- -------------------------------- + -- Barcodes + + CREATE TABLE IF NOT EXISTS public.barcodes ( + barcode VARCHAR(128) PRIMARY KEY NOT NULL, + + account INTEGER NOT NULL, + FOREIGN KEY (account) REFERENCES public.accounts (id) + ); + INSERT INTO public.barcodes (barcode, account) + VALUES ('_cash_', (SELECT id FROM public.accounts WHERE acctype = 'cash')) + ON CONFLICT DO NOTHING; + + -- -------------------------------- + -- Transactions + + CREATE SEQUENCE IF NOT EXISTS public.transactions_id_seq + START WITH 1 INCREMENT BY 1; + CREATE TABLE IF NOT EXISTS public.transactions ( + id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('public.transactions_id_seq'::regclass), + time TIMESTAMP DEFAULT NOW() NOT NULL, + + responsible INTEGER, + FOREIGN KEY (responsible) REFERENCES public.accounts (id), + + description TEXT + ); + + -- -------------------------------- + -- Transaction splits + + CREATE SEQUENCE IF NOT EXISTS public.transaction_splits_id_seq + START WITH 1 INCREMENT BY 1; + CREATE TABLE IF NOT EXISTS public.transaction_splits ( + id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('public.transaction_splits_id_seq'::regclass), + + transaction INTEGER NOT NULL, + FOREIGN KEY (transaction) REFERENCES public.transactions (id), + + side public.transaction_split_side NOT NULL, + + account INTEGER NOT NULL, + FOREIGN KEY (account) REFERENCES public.accounts (id), + amount DECIMAL(12,2) NOT NULL, + + memo TEXT + ); + + -- -------------------------------- + -- Account balances view + + CREATE OR REPLACE VIEW public.account_balances AS + SELECT ts.account AS id, + accounts.name, + accounts.acctype, + - sum( + CASE + WHEN ts.side = 'credit'::public.transaction_split_side THEN - ts.amount + ELSE ts.amount + END) AS crbalance + FROM public.transaction_splits ts + LEFT JOIN public.accounts ON accounts.id = ts.account + GROUP BY ts.account, accounts.name, accounts.acctype + ORDER BY (- sum( + CASE + WHEN ts.side = 'credit'::public.transaction_split_side THEN - ts.amount + ELSE ts.amount + END)); + + -- -------------------------------- + -- Transaction nice splits view + + CREATE OR REPLACE VIEW public.transaction_nicesplits AS + SELECT ts.id, + ts.transaction, + ts.account, + CASE + WHEN ts.side = 'credit'::public.transaction_split_side THEN - ts.amount + ELSE ts.amount + END AS amount, + a.currency, + ts.memo + FROM public.transaction_splits ts + LEFT JOIN public.accounts a ON a.id = ts.account + ORDER BY ts.id; + + -- -------------------------------- + -- Transaction cash sums view + + CREATE OR REPLACE VIEW public.transaction_cashsums AS + SELECT t.id, + t."time", + sum(credit.credit_cash) AS cash_credit, + sum(debit.debit_cash) AS cash_debit, + a.name AS responsible, + t.description + FROM public.transactions t + LEFT JOIN ( SELECT cts.amount AS credit_cash, + cts.transaction AS cts_t + FROM public.transaction_nicesplits cts + LEFT JOIN public.accounts a_1 ON a_1.id = cts.account OR a_1.id = cts.account + WHERE a_1.currency = (( SELECT accounts.currency + FROM public.accounts + WHERE accounts.name::text = 'BrmBar Cash'::text)) + AND (a_1.acctype = ANY (ARRAY['cash'::public.account_type, 'debt'::public.account_type])) + AND cts.amount < 0::numeric) credit ON credit.cts_t = t.id + LEFT JOIN ( SELECT dts.amount AS debit_cash, + dts.transaction AS dts_t + FROM public.transaction_nicesplits dts + LEFT JOIN public.accounts a_1 ON a_1.id = dts.account OR a_1.id = dts.account + WHERE a_1.currency = (( SELECT accounts.currency + FROM public.accounts + WHERE accounts.name::text = 'BrmBar Cash'::text)) + AND (a_1.acctype = ANY (ARRAY['cash'::public.account_type, 'debt'::public.account_type])) + AND dts.amount > 0::numeric) debit ON debit.dts_t = t.id + LEFT JOIN public.accounts a ON a.id = t.responsible + GROUP BY t.id, a.name + ORDER BY t.id DESC; + + -- -------------------------------- + -- Function to check schema version (used in migrations) + + CREATE OR REPLACE FUNCTION brmbar_privileged.has_exact_schema_version( + IN i_ver INTEGER + ) RETURNS BOOLEAN + VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $x$ + DECLARE + v_ver INTEGER; + BEGIN + SELECT ver INTO v_ver FROM brmbar_privileged.brmbar_schema; + IF v_ver is NULL THEN + RETURN false; + ELSE + RETURN v_ver = i_ver; + END IF; + END; + $x$; + + -- -------------------------------- + -- + + CREATE OR REPLACE FUNCTION brmbar_privileged.upgrade_schema_version_to( + IN i_ver INTEGER + ) RETURNS VOID + VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $x$ + DECLARE + v_ver INTEGER; + BEGIN + SELECT ver FROM brmbar_privileged.brmbar_schema INTO v_ver; + IF v_ver=(i_ver-1) THEN + UPDATE brmbar_privileged.brmbar_schema SET ver = i_ver; + ELSE + RAISE EXCEPTION 'Invalid brmbar schema version transition (% -> %)', v_ver, i_ver; + END IF; + END; + $x$; + + -- Initialize version 1 + INSERT INTO brmbar_privileged.brmbar_schema(ver) VALUES(1); + END IF; +END; +$$; diff --git a/brmbar3/schema/0002-trading-accounts.sql b/brmbar3/schema/0002-trading-accounts.sql new file mode 100644 index 0000000..021df3d --- /dev/null +++ b/brmbar3/schema/0002-trading-accounts.sql @@ -0,0 +1,40 @@ +-- +-- 0002-trading-accounts.sql +-- +-- #2 - add trading accounts to account type type +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(1) THEN + + ALTER TYPE public.account_type ADD VALUE 'trading'; + + PERFORM brmbar_privileged.upgrade_schema_version_to(2); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0003-new-account.sql b/brmbar3/schema/0003-new-account.sql new file mode 100644 index 0000000..9ac02b5 --- /dev/null +++ b/brmbar3/schema/0003-new-account.sql @@ -0,0 +1,52 @@ +-- +-- 0003-new-account.sql +-- +-- #3 - stored procedure for creating new account +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(2) THEN + + CREATE OR REPLACE FUNCTION public.create_account( + IN i_name public.accounts.name%TYPE, + IN i_currency public.accounts.currency%TYPE, + IN i_acctype public.accounts.acctype%TYPE + ) RETURNS INTEGER LANGUAGE plpgsql AS $$ + DECLARE + r_id INTEGER; + BEGIN + INSERT INTO public.accounts (name, currency, acctype) + VALUES (i_name, i_currency, i_acctype) RETURNING id INTO r_id; + RETURN r_id; + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(3); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0004-add-account-barcode.sql b/brmbar3/schema/0004-add-account-barcode.sql new file mode 100644 index 0000000..dbdba9a --- /dev/null +++ b/brmbar3/schema/0004-add-account-barcode.sql @@ -0,0 +1,50 @@ +-- +-- 0004-add-account-barcode.sql +-- +-- #4 - stored procedure for adding barcode to account +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(3) THEN + + CREATE OR REPLACE FUNCTION public.add_barcode_to_account( + IN i_account public.barcodes.account%TYPE, + IN i_barcode public.barcodes.barcode%TYPE + ) RETURNS VOID LANGUAGE plpgsql AS $$ + DECLARE + r_id INTEGER; + BEGIN + INSERT INTO public.barcodes (account, barcode) + VALUES (i_account, i_barcode); + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(4); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0005-rename-account.sql b/brmbar3/schema/0005-rename-account.sql new file mode 100644 index 0000000..a957029 --- /dev/null +++ b/brmbar3/schema/0005-rename-account.sql @@ -0,0 +1,51 @@ +-- +-- 0005-rename-account.sql +-- +-- #5 - stored procedure for renaming account +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(4) THEN + + CREATE OR REPLACE FUNCTION public.rename_account( + IN i_account public.accounts.id%TYPE, + IN i_name public.accounts.name%TYPE + ) RETURNS VOID LANGUAGE plpgsql AS $$ + DECLARE + r_id INTEGER; + BEGIN + UPDATE public.accounts + SET name = i_name + WHERE id = i_account; + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(5); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0006-new-currency.sql b/brmbar3/schema/0006-new-currency.sql new file mode 100644 index 0000000..0ed9a94 --- /dev/null +++ b/brmbar3/schema/0006-new-currency.sql @@ -0,0 +1,50 @@ +-- +-- 0006-new-currency.sql +-- +-- #6 - stored procedure for creating new currency +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(5) THEN + + CREATE OR REPLACE FUNCTION public.create_currency( + IN i_name public.currencies.name%TYPE + ) RETURNS INTEGER LANGUAGE plpgsql AS $$ + DECLARE + r_id INTEGER; + BEGIN + INSERT INTO public.currencies (name) + VALUES (i_name) RETURNING id INTO r_id; + RETURN r_id; + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(6); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0007-update-currency-sell-rate.sql b/brmbar3/schema/0007-update-currency-sell-rate.sql new file mode 100644 index 0000000..f627897 --- /dev/null +++ b/brmbar3/schema/0007-update-currency-sell-rate.sql @@ -0,0 +1,49 @@ +-- +-- 0007-update-currency-sell-rate.sql +-- +-- #7 - stored procedure for updating sell rate +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(6) THEN + + CREATE OR REPLACE FUNCTION public.update_currency_sell_rate( + IN i_currency public.exchange_rates.source%TYPE, + IN i_target public.exchange_rates.target%TYPE, + IN i_rate public.exchange_rates.rate%TYPE + ) RETURNS VOID LANGUAGE plpgsql AS $$ + BEGIN + INSERT INTO public.exchange_rates(source, target, rate, rate_dir) + VALUES (i_currency, i_target, i_rate, 'source_to_target'); + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(7); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0008-update-currency-buy-rate.sql b/brmbar3/schema/0008-update-currency-buy-rate.sql new file mode 100644 index 0000000..cbab11b --- /dev/null +++ b/brmbar3/schema/0008-update-currency-buy-rate.sql @@ -0,0 +1,49 @@ +-- +-- 0008-update-currency-buy-rate.sql +-- +-- #8 - stored procedure for updating buy rate +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- Dominik Pantůček +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- Require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(7) THEN + + CREATE OR REPLACE FUNCTION public.update_currency_buy_rate( + IN i_currency public.exchange_rates.target%TYPE, + IN i_source public.exchange_rates.source%TYPE, + IN i_rate public.exchange_rates.rate%TYPE + ) RETURNS VOID LANGUAGE plpgsql AS $$ + BEGIN + INSERT INTO public.exchange_rates(source, target, rate, rate_dir) + VALUES (i_source, i_currency, i_rate, 'target_to_source'); + END + $$; + + PERFORM brmbar_privileged.upgrade_schema_version_to(8); +END IF; + +END; +$upgrade_block$; diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql new file mode 100644 index 0000000..811a5f5 --- /dev/null +++ b/brmbar3/schema/0009-shop-sell.sql @@ -0,0 +1,149 @@ +-- +-- 0009-shop-sell.sql +-- +-- #9 - stored function for sell transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(8) THEN + +-- return negative number on rate not found +CREATE OR REPLACE FUNCTION public.find_buy_rate( + IN i_item_id public.accounts.id%TYPE; + IN i_other_id public.accounts.id%TYPE; +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_rate public.exchange_rates.rate%TYPE; + v_rate_dir public.exchange_rates.rate_dir%TYPE; +BEGIN + SELECT rate INTO STRICT v_rate, rate_dir INTO STRICT v_rate_dir FROM public.exchange_rates WHERE target = i_item_id AND source = i_other_id AND valid_since <= NOW() ORDER BY valid_since DESC LIMIT 1; + IF v_rate_dir = 'target_to_source'::public.exchange_rate_direction THEN + RETURN v_rate; + ELSE + RETURN 1/v_rate; + END IF; +EXCEPTION + WHEN NO_DATA_FOUND THEN + RETURN -1; +END; +$$ + + +-- return negative number on rate not found +CREATE OR REPLACE FUNCTION public.find_sell_rate( + IN i_item_id public.accounts.id%TYPE; + IN i_other_id public.accounts.id%TYPE; +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_rate public.exchange_rates.rate%TYPE; + v_rate_dir public.exchange_rates.rate_dir%TYPE; +BEGIN + SELECT rate INTO STRICT v_rate, rate_dir INTO STRICT v_rate_dir FROM public.exchange_rates WHERE target = i_other_id AND source = i_item_id AND valid_since <= NOW() ORDER BY valid_since DESC LIMIT 1; + IF v_rate_dir = 'source_to_target'::public.exchange_rate_direction THEN + RETURN v_rate; + ELSE + RETURN 1/v_rate; + END IF; +EXCEPTION + WHEN NO_DATA_FOUND THEN + RETURN -1; +END; +$$ + +CREATE OR REPLACE FUNCTION public.create_transaction( + i_responsible_id public.accounts.id%TYPE, + i_description public.transactions.description%TYPE +) RETURNS public.transactions.id%TYPE AS $$ +DECLARE + new_transaction_id public.transactions%TYPE; +BEGIN + -- Create a new transaction + INSERT INTO public.transactions (responsible, description) + VALUES (i_responsible_id, i_description) + RETURNING id INTO new_transaction_id; + -- Return the new transaction ID + RETURN new_transaction_id; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION public.sell_item( + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_user_id public.accounts.id%TYPE, + i_target_currency_id public.currencies.id%TYPE, + i_description TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_buy_rate NUMERIC; + v_sell_rate NUMERIC; + v_cost NUMERIC; + v_profit NUMERIC; + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Get the buy and sell rates from the stored functions + v_buy_rate := public.find_buy_rate(i_item_id, i_target_currency_id); + v_sell_rate := public.find_sell_rate(i_item_id, i_target_currency_id); + + -- Calculate cost and profit + v_cost := i_amount * v_sell_rate; + v_profit := i_amount * (v_sell_rate - v_buy_rate); + + -- Create a new transaction + v_transaction_id := public.create_transaction(i_user_id, i_description); + + -- the item (decrease stock) + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_item_id, i_amount, + (SELECT "name" FROM public.accounts WHERE id = i_user_id)); + + -- the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_user_id, v_cost, + (SELECT "name" FROM public.accounts WHERE id = i_item_id)); + + -- the profit + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', (SELECT account_id FROM accounts WHERE name = 'BrmBar Profits'), v_profit, (SELECT 'Margin on ' || "name" FROM public.accounts WHERE id = i_item_id)); + + -- Return the cost + RETURN v_cost; +END; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(9); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql new file mode 100644 index 0000000..23ad131 --- /dev/null +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -0,0 +1,143 @@ +-- +-- 0010-shop-sell-for-cash.sql +-- +-- #10 - stored function for cash sell transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(9) THEN + +CREATE OR REPLACE FUNCTION brmbar_privileged.create_transaction( + i_responsible_id public.accounts.id%TYPE, + i_description public.transactions.description%TYPE +) RETURNS public.transactions.id%TYPE AS $$ +DECLARE + new_transaction_id public.transactions%TYPE; +BEGIN + -- Create a new transaction + INSERT INTO public.transactions (responsible, description) + VALUES (i_responsible_id, i_description) + RETURNING id INTO new_transaction_id; + -- Return the new transaction ID + RETURN new_transaction_id; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION brmbar_privileged.sell_item_internal( + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_user_id public.accounts.id%TYPE, + i_target_currency_id public.currencies.id%TYPE, + i_other_memo TEXT, + i_description TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_buy_rate NUMERIC; + v_sell_rate NUMERIC; + v_cost NUMERIC; + v_profit NUMERIC; + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Get the buy and sell rates from the stored functions + v_buy_rate := public.find_buy_rate(i_item_id, i_target_currency_id); + v_sell_rate := public.find_sell_rate(i_item_id, i_target_currency_id); + + -- Calculate cost and profit + v_cost := i_amount * v_sell_rate; + v_profit := i_amount * (v_sell_rate - v_buy_rate); + + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(i_user_id, i_description); + + -- the item (decrease stock) + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_item_id, i_amount, + i_other_memo); + + -- the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_user_id, v_cost, + (SELECT "name" FROM public.accounts WHERE id = i_item_id)); + + -- the profit + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', (SELECT account_id FROM accounts WHERE name = 'BrmBar Profits'), v_profit, (SELECT 'Margin on ' || "name" FROM public.accounts WHERE id = i_item_id)); + + -- Return the cost + RETURN v_cost; +END; +$$; + +CREATE OR REPLACE FUNCTION public.sell_item( + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_user_id public.accounts.id%TYPE, + i_target_currency_id public.currencies.id%TYPE, + i_description TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN brmbar_privileged.sell_item_internal(i_item_id, + i_amount, + i_other_id, + i_target_currency_id, + (SELECT "name" FROM public.accounts WHERE id = i_user_id), + i_description); +END; +$$; + +CREATE OR REPLACE FUNCTION public.sell_item_for_cash( + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_user_id public.accounts.id%TYPE, + i_target_currency_id public.currencies.id%TYPE, + i_description TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN brmbar_privileged.sell_item_internal(i_item_id, + i_amount, + i_other_id, + i_target_currency_id, + 'Cash', + i_description); +END; +$$; + +DROP FUNCTION public.create_transaction; + +PERFORM brmbar_privileged.upgrade_schema_version_to(10); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0011-shop-undo-sale.sql b/brmbar3/schema/0011-shop-undo-sale.sql new file mode 100644 index 0000000..67d47cc --- /dev/null +++ b/brmbar3/schema/0011-shop-undo-sale.sql @@ -0,0 +1,102 @@ +-- +-- 0011-shop-undo-sale.sql +-- +-- #11 - stored function for sale undo transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(10) THEN + +CREATE OR REPLACE FUNCTION brmbar_privileged.create_transaction( + i_responsible_id public.accounts.id%TYPE, + i_description public.transactions.description%TYPE +) RETURNS public.transactions.id%TYPE AS $$ +DECLARE + new_transaction_id public.transactions%TYPE; +BEGIN + -- Create a new transaction + INSERT INTO public.transactions (responsible, description) + VALUES (i_responsible_id, i_description) + RETURNING id INTO new_transaction_id; + -- Return the new transaction ID + RETURN new_transaction_id; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION public.undo_sale_of_item( + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_user_id public.accounts.id%TYPE, + i_target_currency_id public.currencies.id%TYPE, + i_description TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_buy_rate NUMERIC; + v_sell_rate NUMERIC; + v_cost NUMERIC; + v_profit NUMERIC; + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Get the buy and sell rates from the stored functions + v_buy_rate := public.find_buy_rate(i_item_id, i_target_currency_id); + v_sell_rate := public.find_sell_rate(i_item_id, i_target_currency_id); + + -- Calculate cost and profit + v_cost := i_amount * v_sell_rate; + v_profit := i_amount * (v_sell_rate - v_buy_rate); + + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(i_user_id, i_description); + + -- the item (decrease stock) + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_item_id, i_amount, + (SELECT "name" || ' (sale undo)' FROM public.accounts WHERE id = i_user_id)); + + -- the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_user_id, v_cost, + (SELECT "name" || ' (sale undo)' FROM public.accounts WHERE id = i_item_id)); + + -- the profit + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', (SELECT account_id FROM accounts WHERE name = 'BrmBar Profits'), v_profit, (SELECT 'Margin repaid on ' || "name" FROM public.accounts WHERE id = i_item_id)); + + -- Return the cost + RETURN v_cost; +END; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(11); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0012-shop-add-credit.sql b/brmbar3/schema/0012-shop-add-credit.sql new file mode 100644 index 0000000..00318ae --- /dev/null +++ b/brmbar3/schema/0012-shop-add-credit.sql @@ -0,0 +1,64 @@ +-- +-- 0012-shop-add-credit.sql +-- +-- #12 - stored function for cash deposit transactions +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(11) THEN + +CREATE OR REPLACE FUNCTION public.add_credit( + i_cash_account_id public.accounts.id%TYPE, + i_credit NUMERIC, + i_user_id public.accounts.id%TYPE, + i_user_name TEXT +) RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(i_user_id, 'BrmBar credit replenishment for ' || i_user_name); + -- Debit cash (credit replenishment) + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (v_transaction_id, 'debit', i_cash_account_id, i_credit, i_user_name); + -- Credit the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (v_transaction_id, 'credit', i_user_id, i_credit, 'Credit replenishment'); +END; +$$; + + + +PERFORM brmbar_privileged.upgrade_schema_version_to(12); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0013-shop-withdraw-credit.sql b/brmbar3/schema/0013-shop-withdraw-credit.sql new file mode 100644 index 0000000..d379186 --- /dev/null +++ b/brmbar3/schema/0013-shop-withdraw-credit.sql @@ -0,0 +1,64 @@ +-- +-- 0013-shop-withdraw-credit.sql +-- +-- #13 - stored function for cash withdrawal transactions +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(12) THEN + +CREATE OR REPLACE FUNCTION public.withdraw_credit( + i_cash_account_id public.accounts.id%TYPE, + i_credit NUMERIC, + i_user_id public.accounts.id%TYPE, + i_user_name TEXT +) RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(i_user_id, 'BrmBar credit withdrawal for ' || i_user_name); + -- Debit cash (credit replenishment) + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (v_transaction_id, 'credit', i_cash_account_id, i_credit, i_user_name); + -- Credit the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (v_transaction_id, 'debit', i_user_id, i_credit, 'Credit withdrawal'); +END; +$$; + + + +PERFORM brmbar_privileged.upgrade_schema_version_to(13); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0014-shop-transfer-credit.sql b/brmbar3/schema/0014-shop-transfer-credit.sql new file mode 100644 index 0000000..7e13c03 --- /dev/null +++ b/brmbar3/schema/0014-shop-transfer-credit.sql @@ -0,0 +1,58 @@ +-- +-- 0014-shop-transfer-credit.sql +-- +-- #14 - stored function for "credit" transfer transactions +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(13) THEN + +CREATE OR REPLACE FUNCTION public.transfer_credit( + i_cash_account_id public.accounts.id%TYPE, + i_credit NUMERIC, + i_userfrom_id public.accounts.id%TYPE, + i_userfrom_name TEXT, + i_userto_id public.accounts.id%TYPE, + i_userto_name TEXT +) RETURNS VOID +LANGUAGE plpgsql +AS $$ +BEGIN + PERFORM public.add_credit(i_cash_account_id, i_credit, i_userto_id, i_userto_name); + PERFORM public.withdraw_credit(i_cash_account_id, i_credit, i_userfrom_id, i_userfrom_name); +END; +$$; + + + +PERFORM brmbar_privileged.upgrade_schema_version_to(14); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0015-shop-buy-for-cash.sql b/brmbar3/schema/0015-shop-buy-for-cash.sql new file mode 100644 index 0000000..5cf12bb --- /dev/null +++ b/brmbar3/schema/0015-shop-buy-for-cash.sql @@ -0,0 +1,82 @@ +-- +-- 0015-shop-buy-for-cash.sql +-- +-- #15 - stored function for cash-based stock replenishment transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(14) THEN + +CREATE OR REPLACE FUNCTION public.buy_for_cash( + i_cash_account_id public.accounts.id%TYPE, + i_item_id public.accounts.id%TYPE, + i_amount INTEGER, + i_target_currency_id public.currencies.id%TYPE, + i_item_name TEXT +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_buy_rate NUMERIC; + v_cost NUMERIC; + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- this could fail and it would generate exception in python + -- FIXME: convert v_buy_rate < 0 into python exception + v_buy_rate := public.find_buy_rate(i_item_id, i_target_currency_id); + -- this could fail and it would generate exception in python, even though it is not used + --v_sell_rate := public.find_sell_rate(i_item_id, i_target_currency_id); + + -- Calculate cost and profit + v_cost := i_amount * v_buy_rate; + + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(NULL, + 'BrmBar stock replenishment of ' || i_amount || 'x ' || i_item_name || ' for cash'); + + -- the item + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_item_id, i_amount, + 'Cash'); + + -- the cash + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_cash_account_id, v_cost, + i_item_name); + + -- Return the cost + RETURN v_cost; +END; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(15); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0016-shop-receipt-to-credit.sql b/brmbar3/schema/0016-shop-receipt-to-credit.sql new file mode 100644 index 0000000..21af8b1 --- /dev/null +++ b/brmbar3/schema/0016-shop-receipt-to-credit.sql @@ -0,0 +1,64 @@ +-- +-- 0016-shop-buy-for-cash.sql +-- +-- #16 - stored function for receipt reimbursement transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(15) THEN + +CREATE OR REPLACE FUNCTION public.receipt_reimbursement( + i_profits_id public.accounts.id%TYPE, + i_user_id public.accounts.id%TYPE, + i_user_name public.accounts.name%TYPE, + i_amount NUMERIC, + i_description TEXT +) RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + v_transaction_id public.transactions.id%TYPE; +BEGIN + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(i_user_id, + 'Receipt: ' || i_description); + -- the "profit" + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_profits_id, i_amount, i_user_name); + -- the user + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_user_id, i_amount, 'Credit from receipt: ' || i_description); +END; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(16); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0017-shop-fix-inventory.sql b/brmbar3/schema/0017-shop-fix-inventory.sql new file mode 100644 index 0000000..3bacd8d --- /dev/null +++ b/brmbar3/schema/0017-shop-fix-inventory.sql @@ -0,0 +1,157 @@ +-- +-- 0017-shop-fix-inventory.sql +-- +-- #17 - stored function for "fixing" inventory transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(16) THEN + +CREATE OR REPLACE FUNCTION public.compute_account_balance( + i_account_id public.accounts.id%TYPE +) RETURNS NUMERIC +LANGUAGE plpgsql +AS $$ +DECLARE + v_crsum NUMERIC; + v_dbsum NUMERIC; +BEGIN + SELECT COALESCE(SUM(CASE WHEN side='credit' THEN amount ELSE 0 END),0) crsum INTO v_crsum, + COALESCE(SUM(CASE WHEN side='debit' THEN amount ELSE 0 END),0) dbsum into v_dbsum + FROM public.transaction_splits ts WHERE ts.account=4 + RETURN v_dbsum - v_crsum; +END; $$; + +CREATE OR REPLACE FUNCTION brmbar_privileged.fix_account_balance( + IN i_account_id public.acounts.id%TYPE, + IN i_account_currency_id public.currencies.id%TYPE, + IN i_excess_id public.acounts.id%TYPE, + IN i_deficit_id public.acounts.id%TYPE, + IN i_shop_currency_id public.currencies.id%TYPE, + IN i_amount_in_reality NUMERIC +) RETURNS BOOLEAN +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $fn$ +DECLARE + v_amount_in_system NUMERIC; + v_buy_rate NUMERIC; + v_currency_id public.currencies.id%TYPE; + v_diff NUMERIC; + v_buy_total NUMERIC; + v_ntrn_id public.transactions.id%TYPE; + v_transaction_memo TEXT; + v_item_name TEXT; + v_excess_memo TEXT; + v_deficit_memo TEXT; + + v_old_trn public.transactions%ROWTYPE; + v_old_split public.transaction_splits%ROWTYPE; +BEGIN + v_amount_in_system := public.compute_account_balance(i_account_id); + IF i_account_currency_id <> i_shop_currency_id THEN + v_buy_rate := public.find_buy_rate(i_item_id, i_shop_currency_id); + ELSE + v_buy_rate := 1; + END IF; + + v_diff := ABS(i_amount_in_reality - v_amount_in_system); + v_buy_total := v_buy_rate * v_diff; + -- compute memo strings + IF i_item_id = 1 THEN -- cash account recognized by magic id + -- fixing cash + v_transaction_memo := + 'BrmBar cash inventory fix of ' || v_amount_in_system + || ' in system to ' || i_amount_in_reality || ' in reality'; + v_excess_memo := 'Inventory cash fix excess.'; + v_deficit_memo := 'Inventory fix deficit.'; + ELSE + -- fixing other account + SELECT "name" INTO v_item_name FROM public.accounts WHERE id = i_account_id; + v_transaction_memo := + 'BrmBar inventory fix of ' || v_amount_in_system || 'pcs ' + || v_item_name + || ' in system to ' || i_amount_in_reality || 'pcs in reality'; + v_excess_memo := 'Inventory fix excess ' || v_item_name; + v_deficit_memo := 'Inventory fix deficit ' || v_item_name; + END IF; + -- create transaction based on the relation between counting and accounting + IF i_amount_in_reality > v_amount_in_system THEN + v_ntrn_id := brmbar_privileged.create_transaction(NULL, v_transaction_memo); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'debit', i_item_id, v_diff, 'Inventory fix excess'); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'credit', i_excess_id, v_buy_total, v_excess_memo); + RETURN TRUE; + ELSIF i_amount_in_reality < v_amount_in_system THEN + v_ntrn_id := brmbar_privileged.create_transaction(NULL, v_transaction_memo); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'credit', i_item_id, v_diff, 'Inventory fix deficit'); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'debit', i_deficit_id, v_buy_total, v_deficit_memo); + RETURN TRUE; + ELSIF i_account_id <> 1 THEN -- cash account recognized by magic id + -- record that everything is going on swimmingly only for noncash accounts (WTF) + v_ntrn_id := brmbar_privileged.create_transaction(NULL, v_transaction_memo); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'debit', i_item_id, 0, 'Inventory fix - amount was correct'); + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, 'credit', i_item_id, 0, 'Inventory fix - amount was correct'); + RETURN FALSE; + END IF; + RETURN FALSE; +END; +$fn$; + + +CREATE OR REPLACE FUNCTION public.fix_inventory( + IN i_account_id public.acounts.id%TYPE, + IN i_account_currency_id public.currencies.id%TYPE, + IN i_excess_id public.acounts.id%TYPE, + IN i_deficit_id public.acounts.id%TYPE, + IN i_shop_currency_id public.currencies.id%TYPE, + IN i_amount_in_reality NUMERIC +) RETURNS BOOLEAN +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $fn$ +BEGIN + RETURN brmbar_privileged.fix_account_balance( + i_account_id, + i_account_currency_id, + i_excess_id, + i_deficit_id, + i_shop_currency_id, + i_amount_in_reality + ); +END; +$fn$; + + +PERFORM brmbar_privileged.upgrade_schema_version_to(17); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0018-shop-fix-cash.sql b/brmbar3/schema/0018-shop-fix-cash.sql new file mode 100644 index 0000000..2af5d72 --- /dev/null +++ b/brmbar3/schema/0018-shop-fix-cash.sql @@ -0,0 +1,60 @@ +-- +-- 0018-shop-fix-cash.sql +-- +-- #18 - stored function for "fixing cash" transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(17) THEN + +CREATE OR REPLACE FUNCTION public.fix_cash( + IN i_excess_id public.acounts.id%TYPE, + IN i_deficit_id public.acounts.id%TYPE, + IN i_shop_currency_id public.currencies.id%TYPE, + IN i_amount_in_reality NUMERIC +) RETURNS BOOLEAN +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $fn$ +BEGIN + RETURN brmbar_privileged.fix_account_balance( + 1, + 1, + i_excess_id, + i_deficit_id, + i_shop_currency_id, + i_amount_in_reality + ); +END; +$fn$; + + +PERFORM brmbar_privileged.upgrade_schema_version_to(18); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0019-shop-consolidate.sql b/brmbar3/schema/0019-shop-consolidate.sql new file mode 100644 index 0000000..db06685 --- /dev/null +++ b/brmbar3/schema/0019-shop-consolidate.sql @@ -0,0 +1,82 @@ +-- +-- 0019-shop-consolidate.sql +-- +-- #19 - stored function for "consolidation" transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(18) THEN + +CREATE OR REPLACE FUNCTION public.make_consolidate_transaction( + i_excess_id public.accounts.id%TYPE, + i_deficit_id public.accounts.id%TYPE, + i_profits_id public.accounts.id%TYPE +) RETURNS TEXT +LANGUAGE plpgsql +AS $$ +DECLARE + v_transaction_id public.transactions.id%TYPE; + v_excess_balance NUMERIC; + v_deficit_balance NUMERIC; + v_ret TEXT; +BEGIN + v_ret := NULL; + -- Create a new transaction + v_transaction_id := brmbar_privileged.create_transaction(NULL, + 'BrmBar inventory consolidation'); + v_excess_balance := public.compute_account_balance(i_excess_id); + v_deficit_balance := public.compute_account_balance(i_deficit_id); + IF v_excess_balance <> 0 THEN + v_ret := 'Excess balance ' || -v_excess_balance || ' debited to profit'; + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_excess_id, -v_excess_balance, + 'Excess balance added to profit.'); + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'debit', i_profits_id, -v_excess_balance, + 'Excess balance added to profit.'); + END IF; + IF v_deficit_balance <> 0 THEN + v_ret := COALESCE(v_ret, ''); + v_ret := v_ret || 'Deficit balance ' || v_deficit_balance || ' credited to profit'; + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_deficit_id, v_deficit_balance, + 'Deficit balance removed from profit.'); + INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) + VALUES (i_transaction_id, 'credit', i_profits_id, v_deficit_balance, + 'Deficit balance removed from profit.'); + END IF; + RETURN v_ret; +END; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(19); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/schema/0020-shop-undo.sql b/brmbar3/schema/0020-shop-undo.sql new file mode 100644 index 0000000..a279580 --- /dev/null +++ b/brmbar3/schema/0020-shop-undo.sql @@ -0,0 +1,64 @@ +-- +-- 0020-shop-undo.sql +-- +-- #20 - stored function for undo transaction +-- +-- ISC License +-- +-- Copyright 2023-2025 Brmlab, z.s. +-- TMA +-- +-- Permission to use, copy, modify, and/or distribute this software +-- for any purpose with or without fee is hereby granted, provided +-- that the above copyright notice and this permission notice appear +-- in all copies. +-- +-- THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL +-- WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED +-- WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE +-- AUTHOR BE LIABLE FOR ANY SPECIAL, DIRECT, INDIRECT, OR +-- CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM LOSS +-- OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, +-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN +-- CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. +-- + +-- To require fully-qualified names +SELECT pg_catalog.set_config('search_path', '', false); + +DO $upgrade_block$ +BEGIN + +IF brmbar_privileged.has_exact_schema_version(19) THEN + +CREATE OR REPLACE FUNCTION public.undo_transaction( + IN i_id public.transactions.id%TYPE) +RETURNS public.transactions.id%TYPE +VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $fn$ +DECLARE + v_ntrn_id public.transactions.id%TYPE; + v_old_trn public.transactions%ROWTYPE; + v_old_split public.transaction_splits%ROWTYPE; +BEGIN + SELECT * INTO v_old_trn FROM public.transactions WHERE id = i_id; + INSERT INTO transactions ("description") VALUES ('undo '||o_id||' ('||v_old_trn.description||')') RETURNING id into v_ntrn_id; + FOR v_old_split IN + SELECT * FROM transaction_splits WHERE "transaction" = i_id + LOOP + INSERT INTO transaction_splits ("transaction", "side", "account", "amount", "memo") + VALUES (v_ntrn_id, v_old_split.side, v_old_split.account, -v_old_split.amount, + 'undo ' || v_old_split.id || ' (' || v_old_split.memo || ')' ); + END LOOP; + RETURN v_ntrn_id; +END; +$fn$; + + + +PERFORM brmbar_privileged.upgrade_schema_version_to(20); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : diff --git a/brmbar3/test--currency-rates.py b/brmbar3/test--currency-rates.py new file mode 100644 index 0000000..9ef93bb --- /dev/null +++ b/brmbar3/test--currency-rates.py @@ -0,0 +1,73 @@ +#!/usr/bin/python3 + +import sys +import subprocess + +#from brmbar import Database +#from brmbar import Currency + +from contextlib import closing +import psycopg2 +from brmbar.Database import Database +from brmbar.Currency import Currency +import math + +#import brmbar + + + +def approx_equal(a, b, tol=1e-6): + """Check if two (buy, sell) rate tuples are approximately equal.""" + return ( + isinstance(a, tuple) and isinstance(b, tuple) and + math.isclose(a[0], b[0], abs_tol=tol) and + math.isclose(a[1], b[1], abs_tol=tol) + ) + +def compare_exceptions(e1, e2): + """Compare exception types and messages.""" + return type(e1) == type(e2) and str(e1) == str(e2) + +def main(): + db = Database("dbname=brmbar") + + # Get all currencies + with closing(db.db_conn.cursor()) as cur: + cur.execute("SELECT id, name FROM currencies") + currencies = cur.fetchall() + + # Build Currency objects + currency_objs = [Currency(db, id, name) for id, name in currencies] + + # Test all currency pairs + for c1 in currency_objs: + for c2 in currency_objs: + #if c1.id == c2.id: + # continue + + try: + rates1 = c1.rates(c2) + exc1 = None + except (RuntimeError, NameError) as e1: + rates1 = None + exc1 = e1 + + try: + rates2 = c1.rates2(c2) + exc2 = None + except (RuntimeError, NameError) as e2: + rates2 = None + exc2 = e2 + + if exc1 or exc2: + if not compare_exceptions(exc1, exc2): + print(f"[EXCEPTION DIFFERENCE] {c1.name} -> {c2.name}") + print(f" rates() exception: {type(exc1).__name__}: {exc1}") + print(f" rates2() exception: {type(exc2).__name__}: {exc2}") + elif not approx_equal(rates1, rates2): + print(f"[VALUE DIFFERENCE] {c1.name} -> {c2.name}") + print(f" rates(): {rates1}") + print(f" rates2(): {rates2}") + +if __name__ == "__main__": + main()