-
Notifications
You must be signed in to change notification settings - Fork 105
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat: implemented skeletal journal/cash.js
This commit implements the initial cash posting journal route by porting journal/voucher.js to the journal/cash.js. It also implements the following optimizations/cleanups: 1) The @Date, @currencyId, @enterpriseId, and @projectid are all performed in a single SQL `SELECT ... INTO` statement for both the cash and voucher posting. This improves readability and performance. 2) `gain_account_id` and `loss_account_id` are implemented as an enterprise setting, as required by #327 and requested in #324. In a future commit, the gain/loss accounts should be removed from the cashboxes. Closes #327.
- Loading branch information
Showing
8 changed files
with
121 additions
and
53 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,64 @@ | ||
'use strict'; | ||
|
||
const core = require('./core'); | ||
|
||
/** | ||
* This module is responsible for posting new records from the `cash` table into | ||
* the posting journal. It expects to receive a transaction object, and (binary) | ||
* cash uuid to post into the `posting_journal` table. | ||
* | ||
* Importantly, this file handles not only the posting procedure, but also error | ||
* cases that may arise from lack of fiscal years, exchange rates, and the like. | ||
* These are handled at the transaction level, within a MySQL function, and | ||
* bubbled up through journal/core.js. | ||
* | ||
* @todo - introduce code to perform generic gain/loss on rounding using the SQL | ||
* variables @gainAccountId and @lossAccountId. | ||
*/ | ||
module.exports = function post(transaction, uuid) { | ||
|
||
transaction | ||
|
||
// set up SQL variables for the posting journal | ||
.addQuery(` | ||
SELECT cash.date, enterprise.id, project.id, cash.currency_id | ||
INTO @date, @enterpriseId, @projectId, @currencyId | ||
FROM cash JOIN project JOIN enterprise ON | ||
cash.project_id = project.id AND | ||
project.enterprise_id = enterprise.id | ||
WHERE cash.uuid = ?; | ||
`, [uuid]); | ||
|
||
// this function sets up the dates, fiscal year, and exchange rate for this | ||
// posting session and ensures they all exist before attempting to write to | ||
// the posting journal. | ||
core.setup(transaction); | ||
|
||
/** | ||
* @todo - this templates in 'D' as the debtor/creditor type | ||
* @todo - this adds origin_id = 1. Should we keep origin around? | ||
* @todo - rounding?! | ||
* @todo - method calls the internal UUID() function of MySQL, which is not a | ||
* version 4 UUID. How will this affect the uuid parsing of reads? | ||
* @todo - should we be inserting to the posting journal in record_uuid sorted | ||
* order? Will that speed up reads? With an INDEX on record_uuid? | ||
*/ | ||
transaction | ||
|
||
.addQuery( | ||
`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, reference_uuid, comment, origin_id, user_id, cc_id, pc_id) | ||
SELECT | ||
HUID(UUID()), c.project_id, @fiscalId, @periodId, @transId, c.date, | ||
c.uuid, c.description, ci.account_id, ci.debit, ci.credit, | ||
ci.debit * @exchange, ci.credit * @exchange, c.currency_id, | ||
ci.entity_uuid, 'D', ci.document_uuid, NULL, 1, c.user_id, NULL, NULL | ||
FROM cash AS c JOIN cash_item AS ci ON c.uuid = ci.voucher_uuid | ||
WHERE c.uuid = ?;`, [uuid] | ||
); | ||
|
||
return transaction.execute() | ||
.catch(core.handler); | ||
}; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,5 +1,3 @@ | ||
|
||
|
||
/** | ||
* temporary noop() function to not break other module's imports | ||
* @todo - remove this | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Large diffs are not rendered by default.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters