From dbd3835dfb33e017b842552d9d81799dd5b645ce Mon Sep 17 00:00:00 2001 From: niekt0 Date: Tue, 30 Jan 2024 20:18:07 +0100 Subject: [PATCH 01/57] fixed NaN issue in withdraw/charge --- brmbar3/brmbar-gui-qt4/ChargeCredit.qml | 13 +++++++++++-- brmbar3/brmbar-gui-qt4/Withdraw.qml | 13 +++++++++++-- 2 files changed, 22 insertions(+), 4 deletions(-) diff --git a/brmbar3/brmbar-gui-qt4/ChargeCredit.qml b/brmbar3/brmbar-gui-qt4/ChargeCredit.qml index 8eda557..0ff8dc8 100644 --- a/brmbar3/brmbar-gui-qt4/ChargeCredit.qml +++ b/brmbar3/brmbar-gui-qt4/ChargeCredit.qml @@ -100,8 +100,17 @@ Item { } function chargeCredit() { - var balance = shop.chargeCredit(amount, userdbid) - status_text.setStatus("Charged! "+username+"'s credit is "+balance+".", "#ffff7c") + var balance=0 + if (!isNaN(amount)) { + if(amount>=0) { + balance = shop.chargeCredit(amount, userdbid) + status_text.setStatus("Charged "+amount+"! "+username+"'s credit is "+balance+".", "#ffff7c") + } else { + balance = shop.withdrawCredit((amount*(-1)), userdbid) + status_text.setStatus("Withdrawn "+amount+"! "+username+"'s credit is "+balance+".", "#ffff7c") + } + } loadPage("MainPage") + } } diff --git a/brmbar3/brmbar-gui-qt4/Withdraw.qml b/brmbar3/brmbar-gui-qt4/Withdraw.qml index a9e7700..b37b670 100644 --- a/brmbar3/brmbar-gui-qt4/Withdraw.qml +++ b/brmbar3/brmbar-gui-qt4/Withdraw.qml @@ -100,8 +100,17 @@ Item { } function withdrawCredit() { - var balance = shop.withdrawCredit(amount, userdbid) - status_text.setStatus("Withdrawn! "+username+"'s credit is "+balance+".", "#ffff7c") + var balance=0 + if (!isNaN(amount)) { + amount=(amount*1) + if(amount>=0) { + balance = shop.withdrawCredit(amount, userdbid) + status_text.setStatus("Withdrawn "+amount+"! "+username+"'s credit is "+balance+".", "#ffff7c") + } else { + balance = shop.chargeCredit((amount*(-1)),userdbid) + status_text.setStatus("Charged "+amount+"! "+username+"'s credit is "+balance+".", "#ffff7c") + } + } loadPage("MainPage") } } From f6ec2be215bbfbdf99156507b5e53fc0a185c5ac Mon Sep 17 00:00:00 2001 From: TMA Date: Sat, 19 Apr 2025 22:44:01 +0200 Subject: [PATCH 02/57] schema v1 setup script --- brmbar3/SQL-schema-v001.sql | 59 +++++++++++++++++++++++++++++++++++++ 1 file changed, 59 insertions(+) create mode 100644 brmbar3/SQL-schema-v001.sql 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 : + From 900264469a9f925749246477b7803b052b91ae07 Mon Sep 17 00:00:00 2001 From: TMA Date: Sun, 20 Apr 2025 10:13:31 +0200 Subject: [PATCH 03/57] schema v2 setup script --- brmbar3/SQL-schema-v002.sql | 105 +++++++++++++++--------------------- 1 file changed, 43 insertions(+), 62 deletions(-) diff --git a/brmbar3/SQL-schema-v002.sql b/brmbar3/SQL-schema-v002.sql index afe6c80..bfb63fa 100644 --- a/brmbar3/SQL-schema-v002.sql +++ b/brmbar3/SQL-schema-v002.sql @@ -1,80 +1,61 @@ --- 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; -$$; - +--RESET search_path +SELECT pg_catalog.set_config('search_path', '', false); --- upgrade schema -DO $$ +DO $upgrade_block$ DECLARE current_ver INTEGER; BEGIN -SELECT ver FROM brmbar_implementation.brmbar_schema INTO current_ver; +-- 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; -ALTER TYPE public.account_type ADD VALUE 'trading'; +-- structural changes ---drop function if exists public.create_currency; -CREATE OR REPLACE PROCEDURE public.create_currency( - IN i_name public.currencies.name%TYPE, - OUT o_id public.currencies.id%TYPE) -LANGUAGE plpgsql SECURITY DEFINER AS $fn$ -BEGIN - INSERT INTO currencies ("name") VALUES (i_name) RETURNING o_id; -END -$fn$; +-- TRADING ACCOUNTS +--START TRANSACTION ISOLATION LEVEL SERIALIZABLE; -CREATE OR REPLACE PROCEDURE public.undo_transaction( - IN i_id public.transactions.id%TYPE, - OUT o_id public.transactions.id%TYPE) -LANGUAGE plpgsql SECURITY DEFINER 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; - o_id := v_ntrn_id; -END -$fn$; +-- currency trading accounts - account type +ALTER TYPE public.account_type ADD VALUE IF NOT EXISTS 'trading'; --- this is for the case that psycopg2 cannot do output arguments -CREATE OR REPLACE FUNCTION public.undo_transaction_fn( - 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; -BEGIN - CALL public.undo_transaction(i_id, v_ntrn_id); - RETURN v_ntrn_id; -END -$fn$; +-- 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 : From c04f934340929607a88251c66522e66f2ae94a8c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 17:01:05 +0200 Subject: [PATCH 04/57] #1: add initial SQL schema as the database currently in use --- brmbar3/schema/0001-init.sql | 313 +++++++++++++++++++++++++++++++++++ 1 file changed, 313 insertions(+) create mode 100644 brmbar3/schema/0001-init.sql diff --git a/brmbar3/schema/0001-init.sql b/brmbar3/schema/0001-init.sql new file mode 100644 index 0000000..52afd7e --- /dev/null +++ b/brmbar3/schema/0001-init.sql @@ -0,0 +1,313 @@ +-- +-- 0000-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 INTEGER + 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 INTEGER + 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; +$$; From 111a8c9b63138e405f4073fd38787f9e7267d03c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 17:11:49 +0200 Subject: [PATCH 05/57] #2: add trading account type type and fix schema migrations machinery --- brmbar3/schema/0001-init.sql | 6 ++-- brmbar3/schema/0002-trading-accounts.sql | 37 ++++++++++++++++++++++++ 2 files changed, 40 insertions(+), 3 deletions(-) create mode 100644 brmbar3/schema/0002-trading-accounts.sql diff --git a/brmbar3/schema/0001-init.sql b/brmbar3/schema/0001-init.sql index 52afd7e..8e7f8db 100644 --- a/brmbar3/schema/0001-init.sql +++ b/brmbar3/schema/0001-init.sql @@ -1,5 +1,5 @@ -- --- 0000-init.sql +-- 0001-init.sql -- -- Initial SQL schema construction as of 2025-04-20 (or so) -- @@ -273,7 +273,7 @@ BEGIN CREATE OR REPLACE FUNCTION brmbar_privileged.has_exact_schema_version( IN i_ver INTEGER - ) RETURNS INTEGER + ) RETURNS BOOLEAN VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $x$ DECLARE v_ver INTEGER; @@ -292,7 +292,7 @@ BEGIN CREATE OR REPLACE FUNCTION brmbar_privileged.upgrade_schema_version_to( IN i_ver INTEGER - ) RETURNS INTEGER + ) RETURNS VOID VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $x$ DECLARE v_ver INTEGER; diff --git a/brmbar3/schema/0002-trading-accounts.sql b/brmbar3/schema/0002-trading-accounts.sql new file mode 100644 index 0000000..08397cd --- /dev/null +++ b/brmbar3/schema/0002-trading-accounts.sql @@ -0,0 +1,37 @@ +-- +-- 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. +-- + +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$; From c5d1fc3402e9aafbf6de1fd1ae0a7c9d905b4cda Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 17:42:12 +0200 Subject: [PATCH 06/57] #3: create account in SQL not in Python. --- brmbar3/brmbar/Account.py | 3 +- brmbar3/schema/0002-trading-accounts.sql | 3 ++ brmbar3/schema/0003-new-account.sql | 52 ++++++++++++++++++++++++ 3 files changed, 57 insertions(+), 1 deletion(-) create mode 100644 brmbar3/schema/0003-new-account.sql diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 29dd79e..fca6d82 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -40,7 +40,8 @@ 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 = 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) diff --git a/brmbar3/schema/0002-trading-accounts.sql b/brmbar3/schema/0002-trading-accounts.sql index 08397cd..021df3d 100644 --- a/brmbar3/schema/0002-trading-accounts.sql +++ b/brmbar3/schema/0002-trading-accounts.sql @@ -23,6 +23,9 @@ -- 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 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$; From 58ab1d00be2914c9c215c67d81ba02ad86ee78f1 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 17:55:18 +0200 Subject: [PATCH 07/57] #4: add account to barcode stored procedure. --- brmbar3/brmbar/Account.py | 3 +- brmbar3/schema/0004-add-account-barcode.sql | 50 +++++++++++++++++++++ 2 files changed, 52 insertions(+), 1 deletion(-) create mode 100644 brmbar3/schema/0004-add-account-barcode.sql diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index fca6d82..8615dfd 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -69,7 +69,8 @@ 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): 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$; From 8f42145bee0bb6e265d7a1f7e63816c6666d5999 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 18:00:40 +0200 Subject: [PATCH 08/57] #5: rename account stored function --- brmbar3/brmbar/Account.py | 3 +- brmbar3/schema/0005-rename-account.sql | 51 ++++++++++++++++++++++++++ 2 files changed, 53 insertions(+), 1 deletion(-) create mode 100644 brmbar3/schema/0005-rename-account.sql diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 8615dfd..3e3a24d 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -74,5 +74,6 @@ class Account: 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/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$; From 9235607d4cae9f9a262a1aa85b02d4b6c8ca3311 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 19:15:23 +0200 Subject: [PATCH 09/57] #6: new currency stored function --- brmbar3/brmbar/Account.py | 2 +- brmbar3/brmbar/Currency.py | 5 +-- brmbar3/schema/0006-new-currency.sql | 50 ++++++++++++++++++++++++++++ 3 files changed, 54 insertions(+), 3 deletions(-) create mode 100644 brmbar3/schema/0006-new-currency.sql diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 3e3a24d..40e86be 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -42,7 +42,7 @@ class Account: """ 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 = db.execute_and_fetch("SELECT public.create_account(%s, %s, %s)", [name, currency.id, acctype]) - id = id[0] + # id = id[0] return cls(db, name = name, id = id, currency = currency, acctype = acctype) def balance(self): diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index d2216ca..a03a893 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -31,8 +31,9 @@ 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): 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$; From 66870bbc8c943b16919a5659cb229d24c502d2f9 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 19:22:19 +0200 Subject: [PATCH 10/57] #7: migrate to stored function for updating currency sell rate. --- brmbar3/brmbar/Currency.py | 4 +- .../schema/0007-update-currency-sell-rate.sql | 49 +++++++++++++++++++ 2 files changed, 52 insertions(+), 1 deletion(-) create mode 100644 brmbar3/schema/0007-update-currency-sell-rate.sql diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index a03a893..e204ac4 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -70,6 +70,8 @@ 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 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"]) 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$; From aded7a5769570f63c4e62e88e762c65ada4d77ee Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sun, 20 Apr 2025 19:27:02 +0200 Subject: [PATCH 11/57] #8: stored function to update currency buy rate --- brmbar3/brmbar/Currency.py | 6 ++- .../schema/0008-update-currency-buy-rate.sql | 49 +++++++++++++++++++ 2 files changed, 53 insertions(+), 2 deletions(-) create mode 100644 brmbar3/schema/0008-update-currency-buy-rate.sql diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index e204ac4..294d9f4 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -71,7 +71,9 @@ class Currency: 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("SELECT update_currency_sell_rate(%s, %s, %s)", + 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/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$; From cef95c43136a642f660bd1f3f59176d6fe5fd705 Mon Sep 17 00:00:00 2001 From: TMA Date: Sun, 20 Apr 2025 23:43:52 +0200 Subject: [PATCH 12/57] #9: stored function for sell transaction --- brmbar3/brmbar/Currency.py | 18 ++-- brmbar3/brmbar/Shop.py | 25 +++-- brmbar3/schema/0009-shop-sell.sql | 149 ++++++++++++++++++++++++++++++ 3 files changed, 175 insertions(+), 17 deletions(-) create mode 100644 brmbar3/schema/0009-shop-sell.sql diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index 294d9f4..7c56984 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -40,18 +40,20 @@ class Currency: """ 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) """ - - 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]) + # 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()) - buy_rate, buy_rate_dir = res - buy = buy_rate if buy_rate_dir == "target_to_source" else 1/buy_rate - - 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", [other.id, self.id]) + # 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()) - sell_rate, sell_rate_dir = res - sell = sell_rate if sell_rate_dir == "source_to_target" else 1/sell_rate return (buy, sell) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 5049fcc..f005d7b 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -25,18 +25,25 @@ 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 diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql new file mode 100644 index 0000000..64d4353 --- /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 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 := find_buy_rate(i_item_id, i_target_currency_id); + v_sell_rate := 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 := create_transaction(i_user_id, i_description); + + -- the item (decrease stock) + INSERT INTO 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 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 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 : From 4c7012c517b3933468a844c78ded98b0c83e9f5f Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 12:22:22 +0200 Subject: [PATCH 13/57] #10: stored function for cash sell transaction --- brmbar3/brmbar/Shop.py | 25 ++-- brmbar3/schema/0010-shop-sell-for-cash.sql | 141 +++++++++++++++++++++ 2 files changed, 157 insertions(+), 9 deletions(-) create mode 100644 brmbar3/schema/0010-shop-sell-for-cash.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index f005d7b..0e9b3b2 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -46,18 +46,25 @@ class Shop: #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 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..03dabda --- /dev/null +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -0,0 +1,141 @@ +-- +-- 0009-shop-sell.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; +$$; + +PERFORM brmbar_privileged.upgrade_schema_version_to(10); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : From deb3faa71707811dafa84303cca39f7bda482fba Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 12:27:29 +0200 Subject: [PATCH 14/57] minor fixes in schemata 0009 and 0010 --- brmbar3/schema/0009-shop-sell.sql | 14 +++++++------- brmbar3/schema/0010-shop-sell-for-cash.sql | 2 ++ 2 files changed, 9 insertions(+), 7 deletions(-) diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql index 64d4353..811a5f5 100644 --- a/brmbar3/schema/0009-shop-sell.sql +++ b/brmbar3/schema/0009-shop-sell.sql @@ -86,7 +86,7 @@ DECLARE new_transaction_id public.transactions%TYPE; BEGIN -- Create a new transaction - INSERT INTO transactions (responsible, description) + INSERT INTO public.transactions (responsible, description) VALUES (i_responsible_id, i_description) RETURNING id INTO new_transaction_id; -- Return the new transaction ID @@ -111,28 +111,28 @@ DECLARE v_transaction_id public.transactions.id%TYPE; BEGIN -- Get the buy and sell rates from the stored functions - v_buy_rate := find_buy_rate(i_item_id, i_target_currency_id); - v_sell_rate := find_sell_rate(i_item_id, i_target_currency_id); + 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 := create_transaction(i_user_id, i_description); + v_transaction_id := public.create_transaction(i_user_id, i_description); -- the item (decrease stock) - INSERT INTO transaction_splits (transaction, side, account, amount, memo) + 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 transaction_splits (transaction, side, account, amount, memo) + 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 transaction_splits (transaction, side, account, amount, memo) + 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 diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index 03dabda..ea30445 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -132,6 +132,8 @@ BEGIN END; $$; +DROP FUNCTION public.create_transaction; + PERFORM brmbar_privileged.upgrade_schema_version_to(10); END IF; From 028d4d98dbe7dfcdd5352d9cc885be9038a73828 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:06:21 +0200 Subject: [PATCH 15/57] #11: stored function for sale undo transaction --- brmbar3/brmbar/Shop.py | 20 +++-- brmbar3/schema/0011-shop-undo-sale.sql | 102 +++++++++++++++++++++++++ 2 files changed, 115 insertions(+), 7 deletions(-) create mode 100644 brmbar3/schema/0011-shop-undo-sale.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 0e9b3b2..eb57d1a 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -68,14 +68,20 @@ class Shop: 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 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 : From 7ed7417492464d1e7a2e7168b4a42a84812a8ca5 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:06:42 +0200 Subject: [PATCH 16/57] schema 0010: fix header id --- brmbar3/schema/0010-shop-sell-for-cash.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index ea30445..23ad131 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -1,5 +1,5 @@ -- --- 0009-shop-sell.sql +-- 0010-shop-sell-for-cash.sql -- -- #10 - stored function for cash sell transaction -- From f0cd8361d1fd1f5831e70e42d47db9c53d87c098 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:23:24 +0200 Subject: [PATCH 17/57] #12 - stored function for cash deposit transactions --- brmbar3/brmbar/Shop.py | 13 ++- brmbar3/schema/0012-shop-add-credit.sql | 110 ++++++++++++++++++++++++ 2 files changed, 120 insertions(+), 3 deletions(-) create mode 100644 brmbar3/schema/0012-shop-add-credit.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index eb57d1a..0f672c2 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -87,10 +87,17 @@ class Shop: 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") + trn = self.db.execute_and_fetch( + "SELECT public.add_credit(%s, %s, %s, %s)", + [self.cash.id, credit, user.id, user.name] + )[0] self.db.commit() + return trn # unused + + #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) diff --git a/brmbar3/schema/0012-shop-add-credit.sql b/brmbar3/schema/0012-shop-add-credit.sql new file mode 100644 index 0000000..48f2da6 --- /dev/null +++ b/brmbar3/schema/0012-shop-add-credit.sql @@ -0,0 +1,110 @@ +-- +-- 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; +$$; + + + +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(12); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : From 7b11a8c954c71f52d64f0b0c180ffbe7f1372b19 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:30:57 +0200 Subject: [PATCH 18/57] #12 - stored function for cash deposit transactions - remove duplicate fn --- brmbar3/schema/0012-shop-add-credit.sql | 46 ------------------------- 1 file changed, 46 deletions(-) diff --git a/brmbar3/schema/0012-shop-add-credit.sql b/brmbar3/schema/0012-shop-add-credit.sql index 48f2da6..00318ae 100644 --- a/brmbar3/schema/0012-shop-add-credit.sql +++ b/brmbar3/schema/0012-shop-add-credit.sql @@ -55,52 +55,6 @@ $$; -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(12); END IF; From e15f1646ce460c288a17067905bd95889ad32e8a Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:35:03 +0200 Subject: [PATCH 19/57] #13: stored function for cash withdrawal transactions --- brmbar3/brmbar/Shop.py | 12 +++- brmbar3/schema/0013-shop-withdraw-credit.sql | 64 ++++++++++++++++++++ 2 files changed, 73 insertions(+), 3 deletions(-) create mode 100644 brmbar3/schema/0013-shop-withdraw-credit.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 0f672c2..85251de 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -100,10 +100,16 @@ class Shop: #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") + trn = self.db.execute_and_fetch( + "SELECT public.withdraw_credit(%s, %s, %s, %s)", + [self.cash.id, credit, user.id, user.name] + )[0] self.db.commit() + return trn # unused + #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) 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 : From ad832fc71ba7a0dfcc45ee6f2d6f851c8c453481 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 17:45:40 +0200 Subject: [PATCH 20/57] #14: stored function for "credit" transfer transactions --- brmbar3/brmbar/Shop.py | 19 ++++--- brmbar3/schema/0014-shop-transfer-credit.sql | 58 ++++++++++++++++++++ 2 files changed, 69 insertions(+), 8 deletions(-) create mode 100644 brmbar3/schema/0014-shop-transfer-credit.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 85251de..df29c18 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -87,12 +87,11 @@ class Shop: return cost def add_credit(self, credit, user): - trn = self.db.execute_and_fetch( + self.db.execute_and_fetch( "SELECT public.add_credit(%s, %s, %s, %s)", [self.cash.id, credit, user.id, user.name] - )[0] + ) self.db.commit() - return trn # unused #transaction = self._transaction(responsible = user, description = "BrmBar credit replenishment for " + user.name) #self.cash.debit(transaction, credit, user.name) @@ -100,20 +99,24 @@ class Shop: #self.db.commit() def withdraw_credit(self, credit, user): - trn = self.db.execute_and_fetch( + self.db.execute_and_fetch( "SELECT public.withdraw_credit(%s, %s, %s, %s)", [self.cash.id, credit, user.id, user.name] - )[0] + ) self.db.commit() - return trn # unused #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): # Buy: Currency conversion from item currency to shop currency diff --git a/brmbar3/schema/0014-shop-transfer-credit.sql b/brmbar3/schema/0014-shop-transfer-credit.sql new file mode 100644 index 0000000..48dc644 --- /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(12) 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(13); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : From 629b35655dd6fd97f506fc5598ab34a4d399589d Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 18:23:11 +0200 Subject: [PATCH 21/57] #15: stored function for cash-based stock replenishment transaction --- brmbar3/brmbar/Shop.py | 14 ++-- brmbar3/schema/0015-shop-buy-for-cash.sql | 82 +++++++++++++++++++++++ 2 files changed, 91 insertions(+), 5 deletions(-) create mode 100644 brmbar3/schema/0015-shop-buy-for-cash.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index df29c18..f669c75 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -119,13 +119,17 @@ class Shop: #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 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..9736d2e --- /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(9) 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(10); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : From 1df7db93e71dd00db7e556f724879e3c1cc4528b Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 18:36:50 +0200 Subject: [PATCH 22/57] #16: stored function for receipt reimbursement transaction --- brmbar3/brmbar/Shop.py | 10 ++- .../schema/0016-shop-receipt-to-credit.sql | 64 +++++++++++++++++++ 2 files changed, 71 insertions(+), 3 deletions(-) create mode 100644 brmbar3/schema/0016-shop-receipt-to-credit.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index f669c75..1bdd4c2 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -135,9 +135,13 @@ class Shop: 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): 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..1b91e20 --- /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(9) 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(10); +END IF; + +END; +$upgrade_block$; + +-- vim: set ft=plsql : From aad79dafa6a75ec60e1d6b129f0099489d22c796 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 18:45:00 +0200 Subject: [PATCH 23/57] fix bugs in schema version checking --- brmbar3/schema/0014-shop-transfer-credit.sql | 4 ++-- brmbar3/schema/0015-shop-buy-for-cash.sql | 4 ++-- brmbar3/schema/0016-shop-receipt-to-credit.sql | 4 ++-- 3 files changed, 6 insertions(+), 6 deletions(-) diff --git a/brmbar3/schema/0014-shop-transfer-credit.sql b/brmbar3/schema/0014-shop-transfer-credit.sql index 48dc644..7e13c03 100644 --- a/brmbar3/schema/0014-shop-transfer-credit.sql +++ b/brmbar3/schema/0014-shop-transfer-credit.sql @@ -29,7 +29,7 @@ SELECT pg_catalog.set_config('search_path', '', false); DO $upgrade_block$ BEGIN -IF brmbar_privileged.has_exact_schema_version(12) THEN +IF brmbar_privileged.has_exact_schema_version(13) THEN CREATE OR REPLACE FUNCTION public.transfer_credit( i_cash_account_id public.accounts.id%TYPE, @@ -49,7 +49,7 @@ $$; -PERFORM brmbar_privileged.upgrade_schema_version_to(13); +PERFORM brmbar_privileged.upgrade_schema_version_to(14); END IF; END; diff --git a/brmbar3/schema/0015-shop-buy-for-cash.sql b/brmbar3/schema/0015-shop-buy-for-cash.sql index 9736d2e..5cf12bb 100644 --- a/brmbar3/schema/0015-shop-buy-for-cash.sql +++ b/brmbar3/schema/0015-shop-buy-for-cash.sql @@ -29,7 +29,7 @@ SELECT pg_catalog.set_config('search_path', '', false); DO $upgrade_block$ BEGIN -IF brmbar_privileged.has_exact_schema_version(9) THEN +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, @@ -73,7 +73,7 @@ BEGIN END; $$; -PERFORM brmbar_privileged.upgrade_schema_version_to(10); +PERFORM brmbar_privileged.upgrade_schema_version_to(15); END IF; END; diff --git a/brmbar3/schema/0016-shop-receipt-to-credit.sql b/brmbar3/schema/0016-shop-receipt-to-credit.sql index 1b91e20..21af8b1 100644 --- a/brmbar3/schema/0016-shop-receipt-to-credit.sql +++ b/brmbar3/schema/0016-shop-receipt-to-credit.sql @@ -29,7 +29,7 @@ SELECT pg_catalog.set_config('search_path', '', false); DO $upgrade_block$ BEGIN -IF brmbar_privileged.has_exact_schema_version(9) THEN +IF brmbar_privileged.has_exact_schema_version(15) THEN CREATE OR REPLACE FUNCTION public.receipt_reimbursement( i_profits_id public.accounts.id%TYPE, @@ -55,7 +55,7 @@ BEGIN END; $$; -PERFORM brmbar_privileged.upgrade_schema_version_to(10); +PERFORM brmbar_privileged.upgrade_schema_version_to(16); END IF; END; From 96027ca66ae65c14287b6ead3ac2a3ef49eb9791 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 19:49:07 +0200 Subject: [PATCH 24/57] #19: stored function for "consolidation" transaction --- brmbar3/brmbar/Account.py | 15 ++-- brmbar3/brmbar/Shop.py | 29 ++++--- brmbar3/schema/0019-shop-consolidate.sql | 97 ++++++++++++++++++++++++ 3 files changed, 124 insertions(+), 17 deletions(-) create mode 100644 brmbar3/schema/0019-shop-consolidate.sql diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 40e86be..215df11 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -46,11 +46,16 @@ class Account: 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()) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 1bdd4c2..e0084f5 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -248,18 +248,23 @@ class Shop: 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): diff --git a/brmbar3/schema/0019-shop-consolidate.sql b/brmbar3/schema/0019-shop-consolidate.sql new file mode 100644 index 0000000..29e767b --- /dev/null +++ b/brmbar3/schema/0019-shop-consolidate.sql @@ -0,0 +1,97 @@ +-- +-- 0019-shop-buy-for-cash.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.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 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 : From c8892f825cf34956c2b7593790136fce45d7078b Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 19:56:15 +0200 Subject: [PATCH 25/57] cosmetic --- brmbar3/schema/0019-shop-consolidate.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0019-shop-consolidate.sql b/brmbar3/schema/0019-shop-consolidate.sql index 29e767b..1290cf4 100644 --- a/brmbar3/schema/0019-shop-consolidate.sql +++ b/brmbar3/schema/0019-shop-consolidate.sql @@ -1,5 +1,5 @@ -- --- 0019-shop-buy-for-cash.sql +-- 0019-shop-consolidate.sql -- -- #19 - stored function for "consolidation" transaction -- From 69c405f7151a5cc048261745af316546e42367e5 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 19:56:39 +0200 Subject: [PATCH 26/57] #20: stored function for undo transaction --- brmbar3/brmbar/Shop.py | 2 +- brmbar3/schema/0020-shop-undo.sql | 64 +++++++++++++++++++++++++++++++ 2 files changed, 65 insertions(+), 1 deletion(-) create mode 100644 brmbar3/schema/0020-shop-undo.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index e0084f5..c8f4a36 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -277,6 +277,6 @@ class Shop: # 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("CALL undo_transaction(%s)",[oldtid])[0] + transaction = self.db.execute_and_fetch("SELECT public.undo_transaction(%s)",[oldtid])[0] self.db.commit() return transaction 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 : From c21b394b429c449f32995228623ead792b4e1953 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 21:14:18 +0200 Subject: [PATCH 27/57] #17: stored function for "fixing" inventory transaction --- brmbar3/brmbar/Shop.py | 53 ++++--- brmbar3/schema/0017-shop-fix-inventory.sql | 157 +++++++++++++++++++++ brmbar3/schema/0019-shop-consolidate.sql | 15 -- 3 files changed, 187 insertions(+), 38 deletions(-) create mode 100644 brmbar3/schema/0017-shop-fix-inventory.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index c8f4a36..2d96fce 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -202,30 +202,37 @@ 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 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/0019-shop-consolidate.sql b/brmbar3/schema/0019-shop-consolidate.sql index 1290cf4..db06685 100644 --- a/brmbar3/schema/0019-shop-consolidate.sql +++ b/brmbar3/schema/0019-shop-consolidate.sql @@ -31,21 +31,6 @@ BEGIN IF brmbar_privileged.has_exact_schema_version(18) 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 public.make_consolidate_transaction( i_excess_id public.accounts.id%TYPE, i_deficit_id public.accounts.id%TYPE, From f0058aad682da46f051486f0eeb4618f9e9b7b00 Mon Sep 17 00:00:00 2001 From: TMA Date: Mon, 21 Apr 2025 21:14:34 +0200 Subject: [PATCH 28/57] #18: stored function for "fixing cash" transaction --- brmbar3/brmbar/Shop.py | 41 ++++++++++-------- brmbar3/schema/0018-shop-fix-cash.sql | 60 +++++++++++++++++++++++++++ 2 files changed, 84 insertions(+), 17 deletions(-) create mode 100644 brmbar3/schema/0018-shop-fix-cash.sql diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 2d96fce..e7dbc6c 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -235,24 +235,31 @@ class Shop: # 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): msg = self.db.execute_and_fetch( 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 : From 0bff27da29bd51e613b65b8b0a7c6992a1917105 Mon Sep 17 00:00:00 2001 From: TMA Date: Tue, 22 Apr 2025 00:00:38 +0200 Subject: [PATCH 29/57] test reimplementation of brmbar.Currency.rates method --- brmbar3/brmbar/Currency.py | 17 ++++++++ brmbar3/test--currency-rates.py | 73 +++++++++++++++++++++++++++++++++ 2 files changed, 90 insertions(+) create mode 100644 brmbar3/test--currency-rates.py diff --git a/brmbar3/brmbar/Currency.py b/brmbar3/brmbar/Currency.py index 7c56984..29da4a3 100644 --- a/brmbar3/brmbar/Currency.py +++ b/brmbar3/brmbar/Currency.py @@ -57,6 +57,23 @@ class Currency: 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()) + buy_rate, buy_rate_dir = res + buy = buy_rate if buy_rate_dir == "target_to_source" else 1/buy_rate + + 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", [other.id, self.id]) + if res is None: + raise NameError("Currency.rate(): Unknown conversion " + self.name() + " to " + other.name()) + sell_rate, sell_rate_dir = res + sell = sell_rate if sell_rate_dir == "source_to_target" else 1/sell_rate + + 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: 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() From a8a124835c8fd8655a23974fd98797c0632e9c80 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:00:28 +0200 Subject: [PATCH 30/57] Schema 0009: fix find_buy_rate arguments syntax --- brmbar3/schema/0009-shop-sell.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql index 811a5f5..7f411dc 100644 --- a/brmbar3/schema/0009-shop-sell.sql +++ b/brmbar3/schema/0009-shop-sell.sql @@ -33,8 +33,8 @@ 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; + IN i_item_id public.accounts.id%TYPE, + IN i_other_id public.accounts.id%TYPE ) RETURNS NUMERIC LANGUAGE plpgsql AS $$ From 8d2c9cb20f245476c73d6c5d3e229107013843f1 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:05:19 +0200 Subject: [PATCH 31/57] Schema 0009: fix DDL statements ends, fix argument delimiters in second procedure as well --- brmbar3/schema/0009-shop-sell.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql index 7f411dc..4be346c 100644 --- a/brmbar3/schema/0009-shop-sell.sql +++ b/brmbar3/schema/0009-shop-sell.sql @@ -52,13 +52,13 @@ 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; + IN i_item_id public.accounts.id%TYPE, + IN i_other_id public.accounts.id%TYPE ) RETURNS NUMERIC LANGUAGE plpgsql AS $$ @@ -76,7 +76,7 @@ EXCEPTION WHEN NO_DATA_FOUND THEN RETURN -1; END; -$$ +$$; CREATE OR REPLACE FUNCTION public.create_transaction( i_responsible_id public.accounts.id%TYPE, From 903cc8f4d70f6c3fbf42bd1035913d3a156ccfa7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:15:19 +0200 Subject: [PATCH 32/57] Schema 0009: fix select into --- brmbar3/schema/0009-shop-sell.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql index 4be346c..da3af48 100644 --- a/brmbar3/schema/0009-shop-sell.sql +++ b/brmbar3/schema/0009-shop-sell.sql @@ -42,7 +42,7 @@ 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; + SELECT rate, rate_dir INTO STRICT v_rate, 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 @@ -66,7 +66,7 @@ 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; + SELECT rate, rate_dir INTO STRICT v_rate, 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 From ae16ebc51f4b4966ff9f2c1261741bab4956d4a3 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:17:34 +0200 Subject: [PATCH 33/57] Schema 0009: fix type inference for id --- brmbar3/schema/0009-shop-sell.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0009-shop-sell.sql b/brmbar3/schema/0009-shop-sell.sql index da3af48..6468bdb 100644 --- a/brmbar3/schema/0009-shop-sell.sql +++ b/brmbar3/schema/0009-shop-sell.sql @@ -83,7 +83,7 @@ CREATE OR REPLACE FUNCTION public.create_transaction( i_description public.transactions.description%TYPE ) RETURNS public.transactions.id%TYPE AS $$ DECLARE - new_transaction_id public.transactions%TYPE; + new_transaction_id public.transactions.id%TYPE; BEGIN -- Create a new transaction INSERT INTO public.transactions (responsible, description) From fba614de785167f7e081d66037a2fa5b8deff320 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:18:39 +0200 Subject: [PATCH 34/57] Schema 0010: fix type inference for id --- brmbar3/schema/0010-shop-sell-for-cash.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index 23ad131..de93d62 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -36,7 +36,7 @@ CREATE OR REPLACE FUNCTION brmbar_privileged.create_transaction( i_description public.transactions.description%TYPE ) RETURNS public.transactions.id%TYPE AS $$ DECLARE - new_transaction_id public.transactions%TYPE; + new_transaction_id public.transactions.id%TYPE; BEGIN -- Create a new transaction INSERT INTO public.transactions (responsible, description) From 3b0cb6472d341463abc15daf34947240327feb7b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:19:25 +0200 Subject: [PATCH 35/57] Schema 0011: fix type inference for id --- brmbar3/schema/0011-shop-undo-sale.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0011-shop-undo-sale.sql b/brmbar3/schema/0011-shop-undo-sale.sql index 67d47cc..4427070 100644 --- a/brmbar3/schema/0011-shop-undo-sale.sql +++ b/brmbar3/schema/0011-shop-undo-sale.sql @@ -36,7 +36,7 @@ CREATE OR REPLACE FUNCTION brmbar_privileged.create_transaction( i_description public.transactions.description%TYPE ) RETURNS public.transactions.id%TYPE AS $$ DECLARE - new_transaction_id public.transactions%TYPE; + new_transaction_id public.transactions.id%TYPE; BEGIN -- Create a new transaction INSERT INTO public.transactions (responsible, description) From f7f137821b00f3efb468d96555b255b689f983ca Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:21:22 +0200 Subject: [PATCH 36/57] Schema 0017: fix into syntax --- brmbar3/schema/0017-shop-fix-inventory.sql | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0017-shop-fix-inventory.sql b/brmbar3/schema/0017-shop-fix-inventory.sql index 3bacd8d..64c1843 100644 --- a/brmbar3/schema/0017-shop-fix-inventory.sql +++ b/brmbar3/schema/0017-shop-fix-inventory.sql @@ -40,8 +40,10 @@ 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 + SELECT + COALESCE(SUM(CASE WHEN side='credit' THEN amount ELSE 0 END),0) crsum, + COALESCE(SUM(CASE WHEN side='debit' THEN amount ELSE 0 END),0) dbsum + INTO v_crsum, v_dbsum FROM public.transaction_splits ts WHERE ts.account=4 RETURN v_dbsum - v_crsum; END; $$; From 1eff329496501087e80bda028bb2cb603cecc627 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:22:13 +0200 Subject: [PATCH 37/57] Schema 0017: fix semicolon before return --- brmbar3/schema/0017-shop-fix-inventory.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0017-shop-fix-inventory.sql b/brmbar3/schema/0017-shop-fix-inventory.sql index 64c1843..fafad73 100644 --- a/brmbar3/schema/0017-shop-fix-inventory.sql +++ b/brmbar3/schema/0017-shop-fix-inventory.sql @@ -44,7 +44,7 @@ BEGIN COALESCE(SUM(CASE WHEN side='credit' THEN amount ELSE 0 END),0) crsum, COALESCE(SUM(CASE WHEN side='debit' THEN amount ELSE 0 END),0) dbsum INTO v_crsum, v_dbsum - FROM public.transaction_splits ts WHERE ts.account=4 + FROM public.transaction_splits ts WHERE ts.account=4; RETURN v_dbsum - v_crsum; END; $$; From 5e348b2463ca273a742f74aa9f6bee33c17405dc Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:23:25 +0200 Subject: [PATCH 38/57] Schema 0017: fix ac-c-ounts --- brmbar3/schema/0017-shop-fix-inventory.sql | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/brmbar3/schema/0017-shop-fix-inventory.sql b/brmbar3/schema/0017-shop-fix-inventory.sql index fafad73..7c04aa4 100644 --- a/brmbar3/schema/0017-shop-fix-inventory.sql +++ b/brmbar3/schema/0017-shop-fix-inventory.sql @@ -49,10 +49,10 @@ BEGIN END; $$; CREATE OR REPLACE FUNCTION brmbar_privileged.fix_account_balance( - IN i_account_id public.acounts.id%TYPE, + IN i_account_id public.accounts.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_excess_id public.accounts.id%TYPE, + IN i_deficit_id public.accounts.id%TYPE, IN i_shop_currency_id public.currencies.id%TYPE, IN i_amount_in_reality NUMERIC ) RETURNS BOOLEAN @@ -129,10 +129,10 @@ $fn$; CREATE OR REPLACE FUNCTION public.fix_inventory( - IN i_account_id public.acounts.id%TYPE, + IN i_account_id public.accounts.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_excess_id public.accounts.id%TYPE, + IN i_deficit_id public.accounts.id%TYPE, IN i_shop_currency_id public.currencies.id%TYPE, IN i_amount_in_reality NUMERIC ) RETURNS BOOLEAN From 597bca87b5de7f019a7251600753a89d1ac46a0a Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:24:31 +0200 Subject: [PATCH 39/57] Schema 0018: fix ac-c-ounts --- brmbar3/schema/0018-shop-fix-cash.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0018-shop-fix-cash.sql b/brmbar3/schema/0018-shop-fix-cash.sql index 2af5d72..5ced17d 100644 --- a/brmbar3/schema/0018-shop-fix-cash.sql +++ b/brmbar3/schema/0018-shop-fix-cash.sql @@ -32,8 +32,8 @@ 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_excess_id public.accounts.id%TYPE, + IN i_deficit_id public.accounts.id%TYPE, IN i_shop_currency_id public.currencies.id%TYPE, IN i_amount_in_reality NUMERIC ) RETURNS BOOLEAN From cd9b4484c86a0be062a68fce8e92ebde13bff5cf Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Thu, 10 Jul 2025 16:54:45 +0200 Subject: [PATCH 40/57] Shop.py: python <3.6 compatibility --- brmbar3/brmbar/Shop.py | 8 +++++--- 1 file changed, 5 insertions(+), 3 deletions(-) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index e7dbc6c..dd762c1 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -28,7 +28,8 @@ class Shop: # 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}"] + [item.id, amount, user.id, self.currency.id, + "BrmBar sale of {0}x {1} to {2}".format(amount, item.name, user.name)] )[0]#[0] self.db.commit() @@ -48,7 +49,8 @@ class Shop: def sell_for_cash(self, item, amount = 1): 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"] + [item.id, amount, user.id, self.currency.id, + "BrmBar sale of {0}x {1} for cash".format(amount, item.name)] )[0]#[0] self.db.commit() @@ -79,7 +81,7 @@ class Shop: # 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}"] + [item.id, amount, user.id, user.currency.id, "BrmBar sale UNDO of {0}x {1} to {2}".format(amount, item.name, user.name)] )[0]#[0] self.db.commit() From 3a4aaa74cecd847a27ecbb4302ab63ffc6c3204b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 15:15:21 +0200 Subject: [PATCH 41/57] 0017: use proper account id argument - not a constant --- brmbar3/schema/0017-shop-fix-inventory.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0017-shop-fix-inventory.sql b/brmbar3/schema/0017-shop-fix-inventory.sql index 7c04aa4..a011892 100644 --- a/brmbar3/schema/0017-shop-fix-inventory.sql +++ b/brmbar3/schema/0017-shop-fix-inventory.sql @@ -44,7 +44,7 @@ BEGIN COALESCE(SUM(CASE WHEN side='credit' THEN amount ELSE 0 END),0) crsum, COALESCE(SUM(CASE WHEN side='debit' THEN amount ELSE 0 END),0) dbsum INTO v_crsum, v_dbsum - FROM public.transaction_splits ts WHERE ts.account=4; + FROM public.transaction_splits ts WHERE ts.account=i_account_id; RETURN v_dbsum - v_crsum; END; $$; From 5355eca6f5c7c063d0dfc2bb07934726c3ac5c6a Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 15:55:06 +0200 Subject: [PATCH 42/57] gui: pass database configuration as command-line options --- brmbar3/brmbar-gui-qt4.py | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index 9ca11d0..fca7f03 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -9,6 +9,8 @@ from brmbar import Database import brmbar +import argparse + # User credit balance limit; sale will fail when balance is below this limit. LIMIT_BALANCE = -200 # When below this credit balance, an alert hook script (see below) is run. @@ -224,6 +226,23 @@ class ShopAdapter(QtCore.QObject): db.commit() return balance +parser = argparse.ArgumentParser() +parser.add_argument("--dbname", help="Database name", type=str) +parser.add_argument("--dbuser", help="Database user", type=str) +parser.add_argument("--dbhost", help="Database host", type=str) +parser.add_argument("--dbpass", help="Database user password", type=str) +args = parser.parse_args() +argdbname = args.dbname +argdbuser = args.dbuser +argdbhost = args.dbhost +argdbpass = args.dbpass + +db = Database.Database( + "dbname={0} user={1} host={2} password={3}".format( + argdbname,argdbuser,argdbhost,argdbpass + ) +) + db = Database.Database("dbname=brmbar") shop = brmbar.Shop.new_with_defaults(db) currency = shop.currency From 15dfd0be0445aaf5b2f0f56b35b28659b33d7de5 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 15:57:41 +0200 Subject: [PATCH 43/57] gui: remove old db initialization --- brmbar3/brmbar-gui-qt4.py | 1 - 1 file changed, 1 deletion(-) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index fca7f03..f6027dc 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -243,7 +243,6 @@ db = Database.Database( ) ) -db = Database.Database("dbname=brmbar") shop = brmbar.Shop.new_with_defaults(db) currency = shop.currency db.commit() From 3ab537f7d9cfed7a3f1c9628aed7dc6aa70349c4 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:15:22 +0200 Subject: [PATCH 44/57] Try logging. --- brmbar3/brmbar-gui-qt4.py | 11 +++++++++++ brmbar3/brmbar/Account.py | 3 +++ 2 files changed, 14 insertions(+) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index f6027dc..75e77c4 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -11,6 +11,17 @@ import brmbar import argparse +import logging + +root = logging.getLogger() +root.setLevel(logging.DEBUG) + +handler = logging.StreamHandler(sys.stdout) +handler.setLevel(logging.DEBUG) +formatter = logging.Formatter('%(asctime)s - %(name)s - %(levelname)s - %(message)s') +handler.setFormatter(formatter) +root.addHandler(handler) + # User credit balance limit; sale will fail when balance is below this limit. LIMIT_BALANCE = -200 # When below this credit balance, an alert hook script (see below) is run. diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 215df11..5344301 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -1,4 +1,6 @@ from .Currency import Currency +import logging +logger = logging.getLogger(__name__) class Account: """ BrmBar Account @@ -14,6 +16,7 @@ class Account: @classmethod def load_by_barcode(cls, db, barcode): + logger.debug("load_by_barcode: %s", barcode) res = db.execute_and_fetch("SELECT account FROM barcodes WHERE barcode = %s", [barcode]) if res is None: return None From 93f9b336b6a446ce4c53b35eff46aa28b77d657c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:25:27 +0200 Subject: [PATCH 45/57] Shop.py: logging to sell --- brmbar3/brmbar/Shop.py | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index dd762c1..2c878b2 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -1,6 +1,8 @@ import brmbar from .Currency import Currency from .Account import Account +import logging +logger = logging.getLogger(__name__) class Shop: """ BrmBar Shop @@ -26,6 +28,8 @@ class Shop: def sell(self, item, user, amount = 1): # Call the stored procedure for the sale + logger.debug("sell: item.id=%s amount=%s user.id=%s self.currency.id=%s", + item.id, amount, user.id, self.currency.id) cost = self.db.execute_and_fetch( "SELECT public.sell_item(%s, %s, %s, %s, %s)", [item.id, amount, user.id, self.currency.id, From f9230ed5bfbe2130632034ec7dc6e7b8f4b42e94 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:29:08 +0200 Subject: [PATCH 46/57] gui: try logging acct in acct_map --- brmbar3/brmbar-gui-qt4.py | 1 + brmbar3/brmbar/Account.py | 2 +- 2 files changed, 2 insertions(+), 1 deletion(-) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index 75e77c4..dea0807 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -65,6 +65,7 @@ class ShopAdapter(QtCore.QObject): return map def acct_map(self, acct): + logger.debug("acct_map: acct=%s", acct) if acct is None: return None if acct.acctype == 'debt': diff --git a/brmbar3/brmbar/Account.py b/brmbar3/brmbar/Account.py index 5344301..ef7a494 100644 --- a/brmbar3/brmbar/Account.py +++ b/brmbar3/brmbar/Account.py @@ -16,7 +16,7 @@ class Account: @classmethod def load_by_barcode(cls, db, barcode): - logger.debug("load_by_barcode: %s", barcode) + logger.debug("load_by_barcode: '%s'", barcode) res = db.execute_and_fetch("SELECT account FROM barcodes WHERE barcode = %s", [barcode]) if res is None: return None From c3abceac5d57e5bc4fba3e0e66bcb480dac427f5 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:33:28 +0200 Subject: [PATCH 47/57] gui: try logging acct in acct_map better --- brmbar3/brmbar-gui-qt4.py | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index dea0807..8f06882 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -65,9 +65,10 @@ class ShopAdapter(QtCore.QObject): return map def acct_map(self, acct): - logger.debug("acct_map: acct=%s", acct) if acct is None: + logger.debug("acct_map: acct is None") return None + logger.debug("acct_map: acct.acctype=%s", acct.acctype) if acct.acctype == 'debt': return self.acct_debt_map(acct) elif acct.acctype == "inventory": From 829bab66b400c8f9b47727bf87b78d54f1257131 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:35:38 +0200 Subject: [PATCH 48/57] gui: fine-grained logging --- brmbar3/brmbar-gui-qt4.py | 2 ++ 1 file changed, 2 insertions(+) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index 8f06882..4bb9e48 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -87,12 +87,14 @@ class ShopAdapter(QtCore.QObject): Therefore, we construct a map that we can pass around easily. We return None on unrecognized barcode. """ barcode = str(barcode) + logger.debug("barcodeInput: barcode='%s'", barcode) if barcode and barcode[0] == "$": credits = {'$02': 20, '$05': 50, '$10': 100, '$20': 200, '$50': 500, '$1k': 1000} credit = credits[barcode] if credit is None: return None return { "acctype": "recharge", "amount": str(credit)+".00" } + logger.debug("barcodeInput: before load_by_barcode") acct = self.acct_map(brmbar.Account.load_by_barcode(db, barcode)) db.commit() return acct From 0a8e2b727b918302e8fc242c02b488f7fb55b6fc Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:37:17 +0200 Subject: [PATCH 49/57] gui: logger --- brmbar3/brmbar-gui-qt4.py | 1 + 1 file changed, 1 insertion(+) diff --git a/brmbar3/brmbar-gui-qt4.py b/brmbar3/brmbar-gui-qt4.py index 4bb9e48..62e4c4a 100755 --- a/brmbar3/brmbar-gui-qt4.py +++ b/brmbar3/brmbar-gui-qt4.py @@ -21,6 +21,7 @@ handler.setLevel(logging.DEBUG) formatter = logging.Formatter('%(asctime)s - %(name)s - %(levelname)s - %(message)s') handler.setFormatter(formatter) root.addHandler(handler) +logger = logging.getLogger(__name__) # User credit balance limit; sale will fail when balance is below this limit. LIMIT_BALANCE = -200 From 343df879fb5e95e0c2465c0435d5b1aaedcfafb1 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:40:16 +0200 Subject: [PATCH 50/57] Shop: sell log res --- brmbar3/brmbar/Shop.py | 7 ++++--- 1 file changed, 4 insertions(+), 3 deletions(-) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index 2c878b2..c6f7c1c 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -30,12 +30,13 @@ class Shop: # Call the stored procedure for the sale logger.debug("sell: item.id=%s amount=%s user.id=%s self.currency.id=%s", item.id, amount, user.id, self.currency.id) - cost = self.db.execute_and_fetch( + res = self.db.execute_and_fetch( "SELECT public.sell_item(%s, %s, %s, %s, %s)", [item.id, amount, user.id, self.currency.id, "BrmBar sale of {0}x {1} to {2}".format(amount, item.name, user.name)] - )[0]#[0] - + )#[0] + logger.debug("sell: res=%s", res) + cost = res[0] self.db.commit() return cost # Sale: Currency conversion from item currency to shop currency From 557d36cac313e8700e257f740d5e99104cb23f64 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:42:32 +0200 Subject: [PATCH 51/57] Shop: not array --- brmbar3/brmbar/Shop.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/brmbar/Shop.py b/brmbar3/brmbar/Shop.py index c6f7c1c..7a64274 100644 --- a/brmbar3/brmbar/Shop.py +++ b/brmbar3/brmbar/Shop.py @@ -35,7 +35,7 @@ class Shop: [item.id, amount, user.id, self.currency.id, "BrmBar sale of {0}x {1} to {2}".format(amount, item.name, user.name)] )#[0] - logger.debug("sell: res=%s", res) + logger.debug("sell: res[0]=%s", res[0]) cost = res[0] self.db.commit() return cost From 38838692c63f50bf68ecba7f89caa60385100f1b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:45:06 +0200 Subject: [PATCH 52/57] Database: other exceptions --- brmbar3/brmbar/Database.py | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/brmbar3/brmbar/Database.py b/brmbar3/brmbar/Database.py index d0202d4..6b985eb 100644 --- a/brmbar3/brmbar/Database.py +++ b/brmbar3/brmbar/Database.py @@ -3,6 +3,8 @@ import psycopg2 from contextlib import closing import time +import logging +logger = logging.getLogger(__name__) class Database: """self-reconnecting database object""" @@ -55,6 +57,8 @@ class Database: time.sleep(1) cur = self.db_conn.cursor() #how ugly is this? return self._execute(cur, query, attrs, level+1) + except Exception as ex: + logger.debug("_execute exception: %s", ex) def commit(self): """passes commit to db""" From ee2b9452998e592400189986ed2d22ec761bac1c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 17:53:33 +0200 Subject: [PATCH 53/57] 0010: fix other to user --- brmbar3/schema/0010-shop-sell-for-cash.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index de93d62..4881b27 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -106,7 +106,7 @@ AS $$ BEGIN RETURN brmbar_privileged.sell_item_internal(i_item_id, i_amount, - i_other_id, + i_user_id, i_target_currency_id, (SELECT "name" FROM public.accounts WHERE id = i_user_id), i_description); @@ -125,7 +125,7 @@ AS $$ BEGIN RETURN brmbar_privileged.sell_item_internal(i_item_id, i_amount, - i_other_id, + i_user_id, i_target_currency_id, 'Cash', i_description); From 81366fd2bbeb4585d1da269e8b413a1a572c2477 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 18:04:56 +0200 Subject: [PATCH 54/57] 0010: fix v_transaction_id --- brmbar3/schema/0010-shop-sell-for-cash.sql | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index 4881b27..c29b0f8 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -77,17 +77,17 @@ BEGIN -- the item (decrease stock) INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) - VALUES (i_transaction_id, 'credit', i_item_id, i_amount, + VALUES (v_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, + VALUES (v_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)); + VALUES (v_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; From 8ee51a23d9165620f1b5b0400bab4e4e6773d021 Mon Sep 17 00:00:00 2001 From: TMA Date: Sat, 12 Jul 2025 18:25:24 +0200 Subject: [PATCH 55/57] account_id -> id --- brmbar3/schema/0010-shop-sell-for-cash.sql | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index c29b0f8..12e0b9d 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -87,7 +87,11 @@ BEGIN -- the profit INSERT INTO public.transaction_splits (transaction, side, account, amount, memo) - VALUES (v_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)); + VALUES (v_transaction_id, + 'debit', + (SELECT id FROM public.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; From 9d8827ccbdbb9a7ef4cfe3e761bc706bd97faba7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dominik=20Pant=C5=AF=C4=8Dek?= Date: Sat, 12 Jul 2025 18:52:21 +0200 Subject: [PATCH 56/57] 0010: lookup item currency id --- brmbar3/schema/0010-shop-sell-for-cash.sql | 11 +++++++++-- 1 file changed, 9 insertions(+), 2 deletions(-) diff --git a/brmbar3/schema/0010-shop-sell-for-cash.sql b/brmbar3/schema/0010-shop-sell-for-cash.sql index 12e0b9d..86fcf9c 100644 --- a/brmbar3/schema/0010-shop-sell-for-cash.sql +++ b/brmbar3/schema/0010-shop-sell-for-cash.sql @@ -63,10 +63,17 @@ DECLARE v_cost NUMERIC; v_profit NUMERIC; v_transaction_id public.transactions.id%TYPE; + v_item_currency_id public.accounts.currency%TYPE; BEGIN + -- Get item's currency + SELECT currency + INTO v_item_currency_id + FROM public.accounts + WHERE id=i_item_id; + -- 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); + v_buy_rate := public.find_buy_rate(v_item_currency_id, i_target_currency_id); + v_sell_rate := public.find_sell_rate(v_item_currency_id, i_target_currency_id); -- Calculate cost and profit v_cost := i_amount * v_sell_rate; From afb5476c2d4f3a6bff1c26c5295a2ba819310219 Mon Sep 17 00:00:00 2001 From: TMA Date: Sat, 12 Jul 2025 19:11:25 +0200 Subject: [PATCH 57/57] o_id -> i_id --- brmbar3/schema/0020-shop-undo.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/brmbar3/schema/0020-shop-undo.sql b/brmbar3/schema/0020-shop-undo.sql index a279580..d2d12b3 100644 --- a/brmbar3/schema/0020-shop-undo.sql +++ b/brmbar3/schema/0020-shop-undo.sql @@ -41,7 +41,7 @@ DECLARE 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; + INSERT INTO transactions ("description") VALUES ('undo '||i_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