Skip to content

Commit

Permalink
feat(db): administrative utilities
Browse files Browse the repository at this point in the history
This commit creates administrative utilities for the database that are
useful in correcting database issues.  It includes the ability to repost
every single transaction type as well as recalculate the entity maps.
  • Loading branch information
Jonathan Niles authored and sfount committed Feb 10, 2017
1 parent 03ea06c commit cda9ea0
Show file tree
Hide file tree
Showing 4 changed files with 111 additions and 61 deletions.
27 changes: 5 additions & 22 deletions server/controllers/finance/trialBalance/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,6 @@
* posting journal to the general ledger.
* It also submit errors back to the client.
*/

const q = require('q');
const uuid = require('node-uuid');
const _ = require('lodash');
Expand Down Expand Up @@ -58,23 +57,6 @@ function checkDescriptionExists(transactions) {
});
}

// make sure that a entity_uuid exists for each deb_cred_type
function checkEntityExists(transactions) {
let sql =
`SELECT COUNT(pj.uuid) AS count, pj.trans_id, pj.entity_uuid FROM posting_journal AS pj
WHERE pj.trans_id IN (?) AND (pj.entity_type = 'D' OR pj.entity_type = 'C')
GROUP BY trans_id HAVING pj.entity_uuid IS NULL;`;

return db.exec(sql, [transactions])
.then(function (rows) {
// if nothing is returned, skip error report
if (!rows.length) { return; }

// returns a error report
return createErrorReport('POSTING_JOURNAL.ERRORS.MISSING_ENTITY', true, rows);
});
}

// make sure that the record Id exist in each line of the transaction
function checkRecordUuidExists(transactions) {
let sql =
Expand Down Expand Up @@ -168,11 +150,12 @@ function checkAccountsLocked(transactions) {

// make sure the debit_equiv, credit_equiv are balanced
function checkTransactionsBalanced(transactions) {
let sql =
`SELECT COUNT(pj.uuid) AS count, pj.trans_id, SUM(pj.debit_equiv - pj.credit_equiv) AS balance
let sql = `
SELECT COUNT(pj.uuid) AS count, pj.trans_id, SUM(pj.debit_equiv - pj.credit_equiv) AS balance
FROM posting_journal AS pj
WHERE pj.trans_id IN (?)
GROUP BY trans_id HAVING balance <> 0;`;
GROUP BY trans_id HAVING balance <> 0;
`;

return db.exec(sql, [transactions])
.then(function (rows) {
Expand Down Expand Up @@ -270,7 +253,7 @@ exports.checkTransactions = function (req, res, next) {
return q.all([
checkSingleLineTransaction(transactions), checkTransactionsBalanced(transactions), checkAccountsLocked(transactions),
checkMissingAccounts(transactions), checkPeriodAndFiscalYearExists(transactions), checkDateInPeriod(transactions),
checkRecordUuidExists(transactions), checkEntityExists(transactions), checkEntityIsAlwaysDefined(transactions),
checkRecordUuidExists(transactions), checkEntityIsAlwaysDefined(transactions),
checkDescriptionExists(transactions)
])
.then(function (errorReports){
Expand Down
105 changes: 105 additions & 0 deletions server/models/admin.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
DELIMITER $$

/*
zRecomputeEntityMap
Abolishes and recomputes the entity_map from the base tables in the system. This is
useful in case of database corruption in which references get out of sync.
*/
CREATE PROCEDURE zRecomputeEntityMap()
BEGIN
DELETE FROM entity_map;

-- employee
INSERT INTO entity_map
SELECT employee.debtor_uuid, CONCAT_WS('.', 'EM', employee.id) FROM employee;

-- patient
INSERT INTO entity_map
SELECT patient.uuid, CONCAT_WS('.', 'PA', project.abbr, patient.reference)
FROM patient JOIN project ON patient.project_id = project.id;

-- patient debtor
INSERT INTO entity_map
SELECT patient.debtor_uuid, CONCAT_WS('.', 'PA', project.abbr, patient.reference)
FROM patient JOIN project ON patient.project_id = project.id;

-- supplier
INSERT INTO entity_map
SELECT supplier.creditor_uuid, CONCAT_WS('.', 'FO', supplier.reference) FROM supplier;
END $$

/*
zRecomputDocumentMap
Abolishes and recomputes the document_map entries from the base tables in the
database. This is useful in case of data corruption.
*/
CREATE PROCEDURE zRecomputeDocumentMap()
BEGIN
DELETE FROM document_map;

-- cash payments
INSERT INTO document_map
SELECT cash.uuid, CONCAT_WS('.', 'CP', project.abbr, cash.reference)
FROM cash JOIN project where project.id = cash.project_id;

-- invoices
INSERT INTO document_map
SELECT invoice.uuid, CONCAT_WS('.', 'IV', project.abbr, invoice.reference)
FROM invoice JOIN project where project.id = invoice.project_id;

-- purchases
INSERT INTO document_map
SELECT purchase.uuid, CONCAT_WS('.', 'PO', project.abbr, purchase.reference)
FROM purchase JOIN project where project.id = purchase.project_id;

-- vouchers
INSERT INTO document_map
SELECT voucher.uuid, CONCAT_WS('.', 'VO', project.abbr, voucher.reference)
FROM voucher JOIN project where project.id = voucher.project_id;
END $$

/*
zRepostVoucher
Removes the voucher record from the posting_journal and calls the PostVoucher() method on
the record in the voucher table to re-post it to the journal.
*/
CREATE PROCEDURE zRepostVoucher(
IN vUuid BINARY(16)
)
BEGIN
DELETE FROM posting_journal WHERE posting_journal.record_uuid = vUuid;
CALL PostVoucher(vUuid);
END $$

/*
zRepostInvoice
Removes the invoice record from the posting_journal and calls the PostInvoice() method on
the record in the invoice table to re-post it to the journal.
*/
CREATE PROCEDURE zRepostInvoice(
IN iUuid BINARY(16)
)
BEGIN
DELETE FROM posting_journal WHERE posting_journal.record_uuid = iUuid;
CALL PostInvoice(iUuid);
END $$

/*
zRepostCash
Removes the cash record from the posting_journal and calls the PostCash() method on
the record in the cash table to re-post it to the journal.
*/
CREATE PROCEDURE zRepostCash(
IN cUuid BINARY(16)
)
BEGIN
DELETE FROM posting_journal WHERE posting_journal.record_uuid = cUuid;
CALL PostCash(cUuid);
END $$

DELIMITER ;
24 changes: 0 additions & 24 deletions server/models/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -410,30 +410,6 @@ CREATE TABLE `country` (
) ENGINE=InnoDB DEFAULT CHARSET=utf8;


DROP TABLE IF EXISTS `credit_note`;
CREATE TABLE `credit_note` (
`uuid` BINARY(16) NOT NULL,
`project_id` SMALLINT(5) UNSIGNED NOT NULL,
`reference` INT(10) UNSIGNED NOT NULL DEFAULT 0,
`cost` DECIMAL(19,4) UNSIGNED NOT NULL,
`debtor_uuid` BINARY(16) NOT NULL,
`seller_id` SMALLINT(5) UNSIGNED NOT NULL DEFAULT 0,
`invoice_uuid` BINARY(36) NOT NULL,
`note_date` DATE NOT NULL,
`description` text NOT NULL,
`posted` tinyint(1) NOT NULL DEFAULT 0,
PRIMARY KEY (`uuid`),
UNIQUE KEY `credit_note_1` (`invoice_uuid`),
UNIQUE KEY `credit_note_2` (`project_id`, `reference`),
KEY `reference` (`reference`),
KEY `project_id` (`project_id`),
KEY `debtor_uuid` (`debtor_uuid`),
KEY `invoice_uuid` (`invoice_uuid`),
FOREIGN KEY (`project_id`) REFERENCES `project` (`id`),
FOREIGN KEY (`debtor_uuid`) REFERENCES `debtor` (`uuid`),
FOREIGN KEY (`invoice_uuid`) REFERENCES `invoice` (`uuid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

DROP TABLE IF EXISTS `creditor`;

CREATE TABLE `creditor` (
Expand Down
16 changes: 1 addition & 15 deletions server/models/triggers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ FOR EACH ROW BEGIN
SELECT new.uuid, CONCAT_WS('.', 'PA', project.abbr, new.reference) FROM project where project.id = new.project_id;

-- this writes a debtor entity into the entity_map table
-- NOTE: the debtor actually points to the patient entity for convienence
-- NOTE: the debtor actually points to the patient entity for convenience
INSERT INTO entity_map
SELECT new.debtor_uuid, CONCAT_WS('.', 'PA', project.abbr, new.reference) FROM project where project.id = new.project_id;
END$$
Expand Down Expand Up @@ -57,20 +57,6 @@ FOR EACH ROW BEGIN
SELECT new.uuid, CONCAT_WS('.', 'CP', project.abbr, new.reference) FROM project where project.id = new.project_id;
END$$


-- Credit Note Triggers
-- @FIXME - why are we still using a credit note table?
CREATE TRIGGER credit_note_before_insert BEFORE INSERT ON credit_note
FOR EACH ROW
SET NEW.reference = (SELECT IF(NEW.reference, NEW.reference, IFNULL(MAX(credit_note.reference) + 1, 1)) FROM credit_note WHERE credit_note.project_id = new.project_id);$$

CREATE TRIGGER credit_note_document_map AFTER INSERT ON credit_note
FOR EACH ROW BEGIN
INSERT INTO document_map
SELECT new.uuid, CONCAT_WS('.', 'CN', project.abbr, new.reference) FROM project where project.id = new.project_id;
END$$


-- Voucher Triggers

CREATE TRIGGER voucher_before_insert BEFORE INSERT ON voucher
Expand Down

0 comments on commit cda9ea0

Please sign in to comment.