Skip to content

Commit

Permalink
feat(journal): add PostingJournalErrorHandler proc
Browse files Browse the repository at this point in the history
This commit adds the PostingJournalErrorHandler stored procedure to the
procedures.sql file.  This ensures that all necessary SQL variables are
defined, and properly sends SQL SIGNAL errors if they are not,
terminating the transaction (and triggering a rollback).

The next step is to make these errors intelligible to the user via
translation keys.
  • Loading branch information
jniles committed Apr 15, 2016
1 parent e059699 commit 6712e58
Show file tree
Hide file tree
Showing 4 changed files with 88 additions and 15 deletions.
42 changes: 30 additions & 12 deletions server/controllers/finance/journal/core.js
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,9 @@
'use strict';

/**
* Set up the SQL transaction with default variables useful for posting records
* to the posting journal.
*
* @param {object} transaction - the transaction object
*
* NOTE - this expects SQL variables "@date" and "@enterpriseId" to be set.
Expand Down Expand Up @@ -56,23 +59,38 @@ exports.setup = function setup(transaction) {
)

// set up the @enterpriseCurrencyId
.addQuery(
`SET @enterpriseCurrencyId = (
.addQuery(`
SET @enterpriseCurrencyId = (
SELECT currency_id FROM enterprise WHERE id = @enterpriseId
);`
)
);
`)

// set up the @exchange SQL variable
// if the currency is the enterprise currency, we will set @exchange to 1
.addQuery(
`SET @exchange = (
SELECT IF(@currencyId=@enterpriseCurrencyId, 1, 1 / rate) FROM exchange_rate
// set up the @rate SQL variable
.addQuery(`
SET @rate = (
SELECT rate FROM exchange_rate
WHERE enterprise_id = @enterpriseId
AND currency_id = @currencyId
AND date <= DATE(@date)
AND date <= @date
ORDER BY date DESC
LIMIT 1);`
);
LIMIT 1);
`)

// 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));`
)

// error handling query - uses stored procedure PostingJournalErrorHandler
// to make sure we have all the SQL variables properly set (not NULL);
.addQuery(`
CALL PostingJournalErrorHandler(
@enterpriseId, @projectId, @fiscalId, @periodId, @exchange, @date
);
`);

return transaction;
};


10 changes: 8 additions & 2 deletions server/controllers/finance/journal/voucher.js
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@
'use strict';

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

/**
* @param {object} transaction - the transaction query object
Expand Down Expand Up @@ -44,7 +45,8 @@ module.exports = function post(transaction, uuid) {


// this function sets up the dates, fiscal year, and exchange rate for this
// posting session
// posting session and ensures they all exist before attempting to write to
// the posting journal.
core.setup(transaction);

/**
Expand All @@ -68,5 +70,9 @@ module.exports = function post(transaction, uuid) {
WHERE v.uuid = ?;`, [uuid]
);

return transaction.execute();
return transaction.execute()
.catch(function (error) {
/** @todo - custom error handling based on SQLSTATE */
return q.reject(error);
});
};
49 changes: 49 additions & 0 deletions server/models/procedures.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,4 +18,53 @@ BEGIN
END
$$


-- detects MySQL Posting Journal Errors
CREATE PROCEDURE PostingJournalErrorHandler(
enterprise INT,
project INT,
fiscal INT,
period INT,
exchange DECIMAL,
date DATETIME
)
BEGIN

-- set up error declarations
DECLARE NoEnterprise CONDITION FOR SQLSTATE '45000';
DECLARE NoProject CONDITION FOR SQLSTATE '45000';
DECLARE NoFiscalYear CONDITION FOR SQLSTATE '45000';
DECLARE NoPeriod CONDITION FOR SQLSTATE '45000';
DECLARE NoExchangeRate CONDITION FOR SQLSTATE '45000';

IF enterprise IS NULL THEN
SIGNAL NoEnterprise
SET MESSAGE_TEXT = 'No enterprise found in the database.';
END IF;

IF project IS NULL THEN
SIGNAL NoProject
SET MESSAGE_TEXT = 'No project provided for that record.';
END IF;

IF fiscal IS NULL THEN
SET @text = CONCAT('No fiscal year found for the provided date: ', CAST(date AS char));
SIGNAL NoFiscalYear
SET MESSAGE_TEXT = @text;
END IF;

IF period IS NULL THEN
SET @text = CONCAT('No period found for the provided date: ', CAST(date AS char));
SIGNAL NoPeriod
SET MESSAGE_TEXT = @text;
END IF;

IF exchange IS NULL THEN
SET @text = CONCAT('No exchange rate found for the provided date: ', CAST(date AS char));
SIGNAL NoExchangeRate
SET MESSAGE_TEXT = @text;
END IF;
END
$$

DELIMITER ;
2 changes: 1 addition & 1 deletion server/models/test/data.sql
Original file line number Diff line number Diff line change
Expand Up @@ -308,7 +308,7 @@ INSERT INTO `primary_cash_module` VALUES (1,'Transfert'),(3,'Convention');

-- exchange rate for the current date
INSERT INTO `exchange_rate` VALUES
(1,1,1,930.0000, CURRENT_DATE());
(1,1,1,930.0000, NOW());

INSERT INTO `employee` VALUES
(1,'E1','Dedrick','Kitamuka','Mvuezolo','M','1980-02-01 00:00:00','2016-02-02 00:00:00',1,3,HUID('71e9f21c-d9b1-11e5-8ab7-78eb2f2a46e0'),500,NULL,NULL,'kinshasa','0896611111','my@email.com',1,3,HUID('bfd8563e-72db-4698-af0f-55bd7849369e'),HUID('42d3756a-7770-4bb8-a899-7953cd859892'),HUID('be0096dd-2929-41d2-912e-fb2259356fb5'),NULL);
Expand Down

0 comments on commit 6712e58

Please sign in to comment.