0023: stored function for total inventory balance

This commit is contained in:
TMA 2025-07-21 16:49:29 +02:00
parent 4f9611727b
commit 2e328e4fb3

View file

@ -0,0 +1,94 @@
--
-- 0023-inventory-balance.sql
--
-- #23 - stored function for total inventory balance
--
-- ISC License
--
-- Copyright 2023-2025 Brmlab, z.s.
-- TMA <tma+hs@jikos.cz>
--
-- 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(22) THEN
CREATE OR REPLACE VIEW brmbar_privileged.debit_balances AS
SELECT
ts.account AS debit_account,
SUM(ts.amount) AS debit_sum
FROM public.transaction_splits ts
WHERE (ts.side = 'debit'::public.transaction_split_side)
GROUP BY ts.account;
CREATE OR REPLACE VIEW brmbar_privileged.credit_balances AS
SELECT
ts.account AS credit_account,
SUM(ts.amount) AS credit_sum
FROM public.transaction_splits ts
WHERE (ts.side = 'credit'::public.transaction_split_side)
GROUP BY 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;
*/
CREATE OR REPLACE FUNCTION public.inventory_balance()
RETURNS DECIMAL(12,2)
VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $fn$
DECLARE
rv DECIMAL(12,2);
BEGIN
WITH inventory_balances AS (
SELECT COALESCE(credit_sum, 0) * public.find_buy_rate(a.currency, 1) as credit_sum,
COALESCE(debit_sum, 0) * public.find_buy_rate(a.currency, 1) as debit_sum,
COALESCE(credit_account, debit_account) as cd_account
FROM brmbar_privileged.credit_balances cb
FULL OUTER JOIN brmbar_privileged.debit_balances db
ON (debit_account = credit_account)
LEFT JOIN public.accounts a
ON (a.id = COALESCE(credit_account, debit_account))
WHERE a.acctype = 'inventory'::public.account_type
)
SELECT SUM(debit_sum) - SUM(credit_sum) INTO rv
FROM inventory_balances;
RETURN rv;
END;
$fn$;
PERFORM brmbar_privileged.upgrade_schema_version_to(23);
END IF;
END;
$upgrade_block$;
-- vim: set ft=plsql :