Skip to content

Commit

Permalink
feat(cash): Posting Caution Payments
Browse files Browse the repository at this point in the history
This commit allows the cash module to post caution payments to the
Posting Journal with the proper conversion of currencies and all other
features.

With this commit, the posting procedure is ready to be thoroughly
tested by the application.
  • Loading branch information
Jonathan Niles committed Sep 5, 2016
1 parent 469a60f commit 6699a07
Show file tree
Hide file tree
Showing 4 changed files with 146 additions and 133 deletions.
5 changes: 1 addition & 4 deletions server/controllers/finance/cash.create.js
Original file line number Diff line number Diff line change
Expand Up @@ -118,10 +118,7 @@ function create(req, res, next) {
}

transaction.addQuery('CALL WriteCash(?)', [cashUuid]);

if (!isCaution) {
transaction.addQuery('CALL PostCash(?)', [cashUuid]);
}
transaction.addQuery('CALL PostCash(?)', [cashUuid]);

transaction.execute()
.then(() => {
Expand Down
250 changes: 133 additions & 117 deletions server/models/procedures.sql
Original file line number Diff line number Diff line change
Expand Up @@ -517,6 +517,7 @@ BEGIN
DECLARE cashCurrencyId TINYINT(3) UNSIGNED;
DECLARE cashAmount DECIMAL;
DECLARE enterpriseCurrencyId INT;
DECLARE isCaution BOOLEAN;

-- variables to store core set-up results
DECLARE cashProjectId SMALLINT(5);
Expand All @@ -533,11 +534,9 @@ BEGIN
DECLARE remainder DECIMAL;
DECLARE lastInvoiceUuid BINARY(16);

CALL DebugLog('Calling PostCash()');

-- copy cash payment values into working variables
SELECT cash.amount, cash.date, cash.currency_id, enterprise.id, cash.project_id, enterprise.currency_id
INTO cashAmount, cashDate, cashCurrencyId, cashEnterpriseId, cashProjectId, enterpriseCurrencyId
SELECT cash.amount, cash.date, cash.currency_id, enterprise.id, cash.project_id, enterprise.currency_id, cash.is_caution
INTO cashAmount, cashDate, cashCurrencyId, cashEnterpriseId, cashProjectId, enterpriseCurrencyId, isCaution
FROM cash
JOIN project ON cash.project_id = project.id
JOIN enterprise ON project.enterprise_id = enterprise.id
Expand All @@ -552,10 +551,6 @@ BEGIN
SET currentExchangeRate = GetExchangeRate(cashEnterpriseId, cashCurrencyId, cashDate);
SET currentExchangeRate = (SELECT IF(cashCurrencyId = enterpriseCurrencyId, 1, currentExchangeRate));

CALL DebugLog(CONCAT_WS(' ', 'currentExchangeRate:', CAST(currentExchangeRate AS char)));
CALL DebugLog(CONCAT_WS(' ', 'cashCurrencyId:', CAST(cashCurrencyId AS char)));
CALL DebugLog(CONCAT_WS(' ', 'enterpriseCurrencyId:', CAST(enterpriseCurrencyId AS char)));

/*
Begin the posting process. We will first write the total value as moving into the cashbox
(a debit to the cashbox's cash account). Then, we will loop through each cash_item and credit
Expand All @@ -578,127 +573,151 @@ BEGIN
JOIN cash_box_account_currency AS cb ON cb.currency_id = c.currency_id AND cb.cash_box_id = c.cashbox_id
WHERE c.uuid = cashUuid;

-- write each cash_item into the posting_journal
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
dg.account_id, 0, ci.amount, 0, (ci.amount / currentExchangeRate), c.currency_id,
c.debtor_uuid, 'D', c.user_id, ci.invoice_uuid
FROM cash AS c
JOIN cash_item AS ci ON c.uuid = ci.cash_uuid
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

/*
Finally, we have to see if there is any rounding to do. If the absolute value of the balance
due minus the balance paid is less than the minMonentaryUnit, it means we should just round that
amount away.
If this is a caution payment, all we need to do is convert and write a single
line to the posting_journal.
*/
IF isCaution THEN

INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid,
c.description, dg.account_id, 0, c.amount, 0, (c.amount / currentExchangeRate), c.currency_id,
c.debtor_uuid, 'D', c.user_id
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

If (cashAmount - previousInvoiceBalances) > 0 then the debtor overpaid and we should debit them and
credit the rounding account. If the (cashAmount - previousInvoiceBalances) is negative, then the debtor
underpaid and we should credit them and debit the rounding account the remainder
/*
In this block, we are paying cash items. We have to look through each cash item, recording the
amount paid as a new line in the posting_journal. The `reference_uuid` is assigned to the
`invoice_uuid` of the cash_item table.
*/
ELSE

/* populates the table stage_cash_invoice_balances */
CALL CalculateCashInvoiceBalances(cashUuid);
-- write each cash_item into the posting_journal
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid,
c.description, dg.account_id, 0, ci.amount, 0, (ci.amount / currentExchangeRate), c.currency_id,
c.debtor_uuid, 'D', c.user_id, ci.invoice_uuid
FROM cash AS c
JOIN cash_item AS ci ON c.uuid = ci.cash_uuid
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

/* These values are in the original currency amount */
SET previousInvoiceBalances = (
SELECT SUM(invoice.balance) AS balance FROM stage_cash_invoice_balances AS invoice
);
/*
Finally, we have to see if there is any rounding to do. If the absolute value of the balance
due minus the balance paid is less than the minMonentaryUnit, it means we should just round that
amount away.
-- this is date ASC to get the most recent invoice
SET lastInvoiceUuid = (
SELECT invoice.uuid FROM stage_cash_invoice_balances AS invoice ORDER BY invoice.date LIMIT 1
);
If (cashAmount - previousInvoiceBalances) > 0 then the debtor overpaid and we should debit them and
credit the rounding account. If the (cashAmount - previousInvoiceBalances) is negative, then the debtor
underpaid and we should credit them and debit the rounding account the remainder
*/

SET minMonentaryUnit = (
SELECT currency.min_monentary_unit FROM currency WHERE currency.id = cashCurrencyId
);
/* populates the table stage_cash_invoice_balances */
CALL CalculateCashInvoiceBalances(cashUuid);

/* These values are in the original currency amount */
SET previousInvoiceBalances = (
SELECT SUM(invoice.balance) AS balance FROM stage_cash_invoice_balances AS invoice
);

SET remainder = cashAmount - previousInvoiceBalances;
-- this is date ASC to get the most recent invoice
SET lastInvoiceUuid = (
SELECT invoice.uuid FROM stage_cash_invoice_balances AS invoice ORDER BY invoice.date LIMIT 1
);

-- check if we should round or not
IF (minMonentaryUnit > ABS(remainder)) THEN
SET minMonentaryUnit = (
SELECT currency.min_monentary_unit FROM currency WHERE currency.id = cashCurrencyId
);

CALL DebugLog(CONCAT_WS(' ', 'We have a remainder of:', CAST(remainder AS char)));
SET remainder = cashAmount - previousInvoiceBalances;

/*
A positive remainder means that the debtor overpaid slightly and we should debit
the difference to the debtor and credit the difference as a gain to the gain_account
*/
IF (remainder > 0) THEN

-- debit the debtor
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
dg.account_id, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id,
c.debtor_uuid, 'D', c.user_id, lastInvoiceUuid
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

-- credit the rounding account
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, user_id
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
gain_account_id, 0, remainder, 0, (remainder / currentExchangeRate), c.currency_id, c.user_id
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;
-- check if we should round or not
IF (minMonentaryUnit > ABS(remainder)) THEN

/*
A negative remainder means that the debtor underpaid slightly and we should credit
the difference to the debtor and debit the difference as a loss to the loss_account
*/
ELSE
/*
A positive remainder means that the debtor overpaid slightly and we should debit
the difference to the debtor and credit the difference as a gain to the gain_account
*/
IF (remainder > 0) THEN

-- debit the debtor
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
dg.account_id, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id,
c.debtor_uuid, 'D', c.user_id, lastInvoiceUuid
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

-- credit the rounding account
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, user_id
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
gain_account_id, 0, remainder, 0, (remainder / currentExchangeRate), c.currency_id, c.user_id
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

/*
A negative remainder means that the debtor underpaid slightly and we should credit
the difference to the debtor and debit the difference as a loss to the loss_account
*/
ELSE

-- convert the remainder into the enterprise currency
SET remainder = (-1 * remainder);

-- credit the debtor
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
dg.account_id, 0, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id,
c.debtor_uuid, 'D', c.user_id, lastInvoiceUuid
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

-- debit the rounding account
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, user_id
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
loss_account_id, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id, c.user_id
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;
-- convert the remainder into the enterprise currency
SET remainder = (-1 * remainder);

-- credit the debtor
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, entity_type, user_id, reference_uuid
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
dg.account_id, 0, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id,
c.debtor_uuid, 'D', c.user_id, lastInvoiceUuid
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;

-- debit the rounding account
INSERT INTO posting_journal (
uuid, project_id, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, user_id
) SELECT
HUID(UUID()), cashProjectId, currentFiscalYearId, currentPeriodId, transactionId, c.date, c.uuid, c.description,
loss_account_id, remainder, 0, (remainder / currentExchangeRate), 0, c.currency_id, c.user_id
FROM cash AS c
JOIN debtor AS d ON c.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
WHERE c.uuid = cashUuid;
END IF;
END IF;
END IF;

CALL FlushLog('Finished PostCash()');
END IF;
END $$

CREATE PROCEDURE StageCash(
Expand Down Expand Up @@ -835,8 +854,6 @@ BEGIN
CALL CalculateCashInvoiceBalances(cashUuid);
SET totalInvoiceCost = (SELECT IFNULL(SUM(invoice.balance), 0) FROM stage_cash_invoice_balances AS invoice);

CALL DebugLog(CONCAT_WS(' ', 'minMonentaryUnit:', CAST(minMonentaryUnit AS char)));

/*
If the difference between the paid amount and the totalInvoiceCost is greater than the
minMonentaryUnit, the client has overpaid.
Expand Down Expand Up @@ -922,7 +939,6 @@ BEGIN

CALL WriteCashItems(cashUuid, cashAmount, currentExchangeRate);
END IF;

END $$

DELIMITER ;
20 changes: 10 additions & 10 deletions server/models/test/data.sql
Original file line number Diff line number Diff line change
Expand Up @@ -425,17 +425,17 @@ INSERT INTO cash (uuid, project_id, reference, date, debtor_uuid, currency_id, a
(@cash_payment, 1, 1, '2016-01-09 14:33:13', HUID('3be232f9-a4b9-4af6-984c-5d3f87d5c107'), 1, 100, 1, 2, "Some cool description", 1);

INSERT INTO `posting_journal` VALUES
(HUID(UUID()),1,1,1,'TRANS1','2016-01-09 14:35:55',@first_invoice, 'description x',3631,75.0000,0.0000,75.0000,0.0000,2,HUID('3be232f9-a4b9-4af6-984c-5d3f87d5c107'),'D',NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS1','2016-01-09 14:35:55',@first_invoice,'description x',3638,0.0000,75.0000,0.0000,75.0000,2,NULL,NULL,NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS2','2016-01-09 17:04:27',@second_invoice,'description x',3631,25.0000,0.0000,25.0000,0.0000,2,HUID('3be232f9-a4b9-4af6-984c-5d3f87d5c107'),'D',NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS2','2016-01-09 17:04:27',@second_invoice,'description x',3638,0.0000,25.0000,0.0000,25.0000,2,NULL,NULL,NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA1','2016-01-09 14:35:55',@first_invoice, 'description x',3631,75.0000,0.0000,75.0000,0.0000,2,HUID('3be232f9-a4b9-4af6-984c-5d3f87d5c107'),'D',NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA1','2016-01-09 14:35:55',@first_invoice,'description x',3638,0.0000,75.0000,0.0000,75.0000,2,NULL,NULL,NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA2','2016-01-09 17:04:27',@second_invoice,'description x',3631,25.0000,0.0000,25.0000,0.0000,2,HUID('3be232f9-a4b9-4af6-984c-5d3f87d5c107'),'D',NULL,NULL,1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA2','2016-01-09 17:04:27',@second_invoice,'description x',3638,0.0000,25.0000,0.0000,25.0000,2,NULL,NULL,NULL,NULL,1,2,1,NULL),
-- vouchers data
(HUID(UUID()),1,1,1,'TRANS3','2016-01-09 17:04:27',@first_voucher,'description x',3627,100.0000,0.0000,100.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data one',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS3','2016-01-09 17:04:27',@first_voucher,'description x',3628,0.0000,100.0000,0.0000,100.0000,2,NULL,NULL,NULL,'Sample voucher data one',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS4','2016-01-09 17:04:27',@second_voucher,'description x',3627,200.0000,0.0000,200.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data two',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS4','2016-01-09 17:04:27',@second_voucher,'description x',3628,0.0000,200.0000,0.0000,200.0000,2,NULL,NULL,NULL,'Sample voucher data two',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS5','2016-01-09 17:04:27',@third_voucher,'description x',3627,300.0000,0.0000,300.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data three',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TRANS5','2016-02-09 17:04:27',@third_voucher,'description x',3628,0.0000,300.0000,0.0000,300.0000,2,NULL,NULL,NULL,'Sample voucher data three',1,2,1,NULL);
(HUID(UUID()),1,1,1,'TPA3','2016-01-09 17:04:27',@first_voucher,'description x',3627,100.0000,0.0000,100.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data one',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA3','2016-01-09 17:04:27',@first_voucher,'description x',3628,0.0000,100.0000,0.0000,100.0000,2,NULL,NULL,NULL,'Sample voucher data one',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA4','2016-01-09 17:04:27',@second_voucher,'description x',3627,200.0000,0.0000,200.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data two',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA4','2016-01-09 17:04:27',@second_voucher,'description x',3628,0.0000,200.0000,0.0000,200.0000,2,NULL,NULL,NULL,'Sample voucher data two',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA5','2016-01-09 17:04:27',@third_voucher,'description x',3627,300.0000,0.0000,300.0000,0.0000,2,NULL,NULL,NULL,'Sample voucher data three',1,2,1,NULL),
(HUID(UUID()),1,1,1,'TPA5','2016-02-09 17:04:27',@third_voucher,'description x',3628,0.0000,300.0000,0.0000,300.0000,2,NULL,NULL,NULL,'Sample voucher data three',1,2,1,NULL);

-- zones des santes SNIS
INSERT INTO `mod_snis_zs` VALUES
Expand Down
4 changes: 2 additions & 2 deletions test/integration/cash.js
Original file line number Diff line number Diff line change
Expand Up @@ -39,7 +39,7 @@ describe.only('(/cash) Cash Payments', function () {
cashbox_id: CASHBOX_ID,
debtor_uuid: DEBTOR_UUID,
project_id: PROJECT_ID,
date: new Date('2015-01-01'),
date: new Date(),
user_id: USER_ID,
is_caution: 1,
description : 'A caution payment'
Expand Down Expand Up @@ -200,7 +200,7 @@ describe.only('(/cash) Cash Payments', function () {
debtor_uuid: DEBTOR_UUID,
items: INVOICES,
project_id: PROJECT_ID,
date: new Date('2015-05-01'),
date: new Date(),
user_id: USER_ID,
is_caution: 1,
description : 'This is a confused payment'
Expand Down

0 comments on commit 6699a07

Please sign in to comment.