From 0cae825c86f23bf889f5c67c7e54b3e62538088a Mon Sep 17 00:00:00 2001 From: Jonathan Niles Date: Wed, 23 Mar 2022 07:26:13 +0100 Subject: [PATCH] feat(invoice): add invoice balance function This commit adds a MySQL function for computing the balance of an invoice. It is for analysis purposes currently. --- server/models/admin.sql | 43 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 43 insertions(+) diff --git a/server/models/admin.sql b/server/models/admin.sql index ea437fb473..07de5be23d 100644 --- a/server/models/admin.sql +++ b/server/models/admin.sql @@ -296,4 +296,47 @@ BEGIN UPDATE lot SET barcode = CONCAT('LT', LEFT(HEX(lot.uuid), 8)); END $$ +/** + zGetInvoiceBalance() + + Gets the balance on an invoice due to a debtor. +*/ +CREATE FUNCTION zGetInvoiceBalance(invoiceUuid BINARY(16)) +RETURNS DOUBLE DETERMINISTIC +BEGIN + DECLARE entityUuid BINARY(16); + + -- get the debtorUuid + SELECT debtor_uuid INTO entityUuid FROM invoice WHERE invoice.uuid = invoiceUuid; + + -- return the balance + RETURN ( + SELECT SUM(debit - credit) AS balance + FROM ( + SELECT record_uuid AS uuid, debit_equiv as debit, credit_equiv as credit, entity_uuid + FROM posting_journal + WHERE posting_journal.record_uuid = invoiceUuid AND entity_uuid = entityUuid + + UNION ALL + + SELECT record_uuid AS uuid, debit_equiv as debit, credit_equiv as credit, entity_uuid + FROM general_ledger + WHERE general_ledger.record_uuid = invoiceUuid AND entity_uuid = entityUuid + + UNION ALL + + SELECT reference_uuid AS uuid, debit_equiv as debit, credit_equiv as credit, entity_uuid + FROM posting_journal + WHERE posting_journal.reference_uuid = invoiceUuid AND entity_uuid = entityUuid + + UNION ALL + + SELECT reference_uuid AS uuid, debit_equiv as debit, credit_equiv as credit, entity_uuid + FROM general_ledger + WHERE general_ledger.reference_uuid = invoiceUuid AND entity_uuid = entityUuid + ) AS ledger + GROUP BY ledger.uuid + ); +END $$ + DELIMITER ;