Skip to content

Commit

Permalink
feat: implemented skeletal journal/cash.js
Browse files Browse the repository at this point in the history
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
Jonathan Niles authored and jniles committed Apr 20, 2016
1 parent da28b58 commit f89255f
Show file tree
Hide file tree
Showing 8 changed files with 121 additions and 53 deletions.
10 changes: 6 additions & 4 deletions server/controllers/finance/cash.js
Original file line number Diff line number Diff line change
Expand Up @@ -12,15 +12,17 @@
* currencies. The API accepts a cashbox ID during cash payment creation and
* looks up the correct account based on the cashbox_id + currency.
*
* @requires lib/db
* @requires node-uuid
* @requires lib/db
* @requires lib/errors/NotFound
* @requires lib/errors/BadRequest
* @requires journal/cash
*/
const db = require('../../lib/db');
const uuid = require('node-uuid');
var NotFound = require('../../lib/errors/NotFound');
var BadRequest = require('../../lib/errors/BadRequest');
const db = require('../../lib/db');
const NotFound = require('../../lib/errors/NotFound');
const BadRequest = require('../../lib/errors/BadRequest');
const journal = require('./journal/cash');

/** retrieves the details of a cash payment */
exports.detail = detail;
Expand Down
64 changes: 64 additions & 0 deletions server/controllers/finance/journal/cash.js
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);
};
15 changes: 12 additions & 3 deletions server/controllers/finance/journal/core.js
Original file line number Diff line number Diff line change
Expand Up @@ -81,12 +81,21 @@ exports.setup = function setup(transaction) {

// if the currency is the enterprise currency, we will set @exchange to 1,
// otherwise it is 1/@rate
.addQuery(
`SET @exchange = (SELECT IF(@currencyId = @enterpriseCurrencyId, 1, 1/@rate));`
)
.addQuery(`
SET @exchange = (SELECT IF(@currencyId = @enterpriseCurrencyId, 1, 1/@rate));
`)

// determine the gain/loss account ids
.addQuery(`
SELECT gain_account_id, loss_account_id
INTO @gainAccountId, @lossAccountId
FROM enterprise WHERE id = @enterpriseId
`)

// error handling query - uses stored procedure PostingJournalErrorHandler
// to make sure we have all the SQL variables properly set (not NULL);
// If any variables are not properly defined, this will SIGNAL an SQL error
// resulting in a transaction ROLLBACK.
.addQuery(`
CALL PostingJournalErrorHandler(
@enterpriseId, @projectId, @fiscalId, @periodId, @exchange, @date
Expand Down
2 changes: 0 additions & 2 deletions server/controllers/finance/journal/index.js
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
Expand Down
34 changes: 9 additions & 25 deletions server/controllers/finance/journal/voucher.js
Original file line number Diff line number Diff line change
@@ -1,7 +1,6 @@
'use strict';

const core = require('./core');
const q = require('q');

/**
* This function is responsible for posting new records from the `voucher` table
Expand All @@ -20,30 +19,15 @@ module.exports = function post(transaction, uuid) {

transaction

// set up the @date SQL variable
.addQuery(`SET @date = (SELECT date FROM voucher WHERE uuid = ?);`, [uuid])

// set up the @enterpriseId SQL variable
.addQuery(
`SET @enterpriseId = (
SELECT e.id FROM enterprise AS e JOIN project AS p JOIN voucher AS v
ON e.id = p.enterprise_id AND p.id = v.project_id
WHERE v.uuid = ?);`, [uuid]
)

// set the @projectId SQL variable
.addQuery(
`SET @projectId = (
SELECT project_id FROM voucher WHERE voucher.uuid = ?
);`, [uuid]
)

// set up the @currencyId SQL variable
.addQuery(
`SET @currencyId = (
SELECT currency_id FROM voucher WHERE voucher.uuid = ?
);`, [uuid]
);
// set up the SQL variables for core.js to consume
.addQuery(`
SELECT voucher.date, enterprise.id, project.id, voucher.currency_id
INTO @date, @enterpriseId, @projectId, @currencyId
FROM voucher JOIN project JOIN enterprise ON
voucher.project_id = project.id AND
project.enterprise_id = enterprise.id
WHERE voucher.uuid = ?;
`, [uuid]);


// this function sets up the dates, fiscal year, and exchange rate for this
Expand Down
26 changes: 16 additions & 10 deletions server/models/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -734,20 +734,26 @@ CREATE TABLE `employee_invoice_item` (

DROP TABLE IF EXISTS `enterprise`;
CREATE TABLE `enterprise` (
`id` smallint(5) unsigned NOT NULL AUTO_INCREMENT,
`name` text NOT NULL,
`abbr` varchar(50) DEFAULT NULL,
`phone` varchar(20) DEFAULT NULL,
`email` varchar(70) DEFAULT NULL,
`location_id` BINARY(16) DEFAULT NULL,
`logo` varchar(70) DEFAULT NULL,
`currency_id` tinyint(3) unsigned NOT NULL,
`po_box` varchar(30) DEFAULT NULL,
`id` SMALLINT(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`name` TEXT NOT NULL,
`abbr` VARCHAR(50) DEFAULT NULL,
`phone` VARCHAR(20) DEFAULT NULL,
`email` VARCHAR(100) DEFAULT NULL,
`location_id` BINARY(16) DEFAULT NULL,
`logo` VARCHAR(100) DEFAULT NULL,
`currency_id` TINYINT(3) UNSIGNED NOT NULL,
`po_box` VARCHAR(30) DEFAULT NULL,
`gain_account_id` INT UNSIGNED NULL,
`loss_account_id` INT UNSIGNED NULL,
PRIMARY KEY (`id`),
KEY `location_id` (`location_id`),
KEY `currency_id` (`currency_id`),
KEY `gain_account_id` (`gain_account_id`),
KEY `loss_account_id` (`loss_account_id`),
FOREIGN KEY (`currency_id`) REFERENCES `currency` (`id`),
FOREIGN KEY (`location_id`) REFERENCES `village` (`uuid`)
FOREIGN KEY (`location_id`) REFERENCES `village` (`uuid`),
FOREIGN KEY (`gain_account_id`) REFERENCES `account` (`id`),
FOREIGN KEY (`loss_account_id`) REFERENCES `account` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


Expand Down
13 changes: 11 additions & 2 deletions server/models/test/data.sql

Large diffs are not rendered by default.

10 changes: 3 additions & 7 deletions server/test/api/accounts.js
Original file line number Diff line number Diff line change
Expand Up @@ -48,20 +48,16 @@ describe('(/accounts) The account API', function () {
it('GET /accounts?full=1 returns the full list of account', function () {
return agent.get('/accounts?full=1')
.then(function (res) {
helpers.api.listed(res, 10);
helpers.api.listed(res, 14);
})
.catch(helpers.handler);
});

it('GET /accounts returns a simple list of account', function () {
return agent.get('/accounts')
.then(function (res) {
helpers.api.listed(res, 10);
expect(res).to.have.status(200);
expect(res).to.be.json;
expect(res.body).to.not.be.empty;
expect(res.body).to.have.length(10);
})
helpers.api.listed(res, 14);
})
.catch(helpers.handler);
});

Expand Down

0 comments on commit f89255f

Please sign in to comment.