Skip to content

Commit

Permalink
fix: miscellaneous fixes for production
Browse files Browse the repository at this point in the history
This commit fixes a few miscellaneous bugs that prevent proper
production deployment.

 1. The inventory list controller used ES2015+.
 2. The interceptors file did not log the full error from a database SQL
 error.
 3. The cashboxes server API hard-coded the name of the test database
 `bhima_test`.  This prevented using any other database.
 4. Added extra migration scripts to update units.
 5. Fixed four instances of Group By rules breaking.  All integration
 tests now pass.
  • Loading branch information
jniles committed Dec 14, 2017
1 parent 2a6b0fe commit 623a910
Show file tree
Hide file tree
Showing 7 changed files with 148 additions and 58 deletions.
6 changes: 3 additions & 3 deletions client/src/modules/inventory/list/list.js
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ InventoryListController.$inject = [
*/
function InventoryListController(
Inventory, Notify, uiGridConstants, Modal, $state, Filters, AppCache, Columns, GridState,
GridExport, Languages, Session,
GridExport, Languages, Session
) {
var vm = this;
vm.download = Inventory.download;
Expand Down Expand Up @@ -107,8 +107,8 @@ function InventoryListController(
showColumnFooter : true,
fastWatch : true,
flatEntityAccess : true,
columnDefs,
onRegisterApi,
columnDefs : columnDefs,
onRegisterApi : onRegisterApi,
};

// configurations
Expand Down
9 changes: 4 additions & 5 deletions server/config/interceptors.js
Original file line number Diff line number Diff line change
Expand Up @@ -64,6 +64,10 @@ exports.handler = function handler(err, req, res, next) {
let key;
let description;

debugDB(`#interceptor(): [SQL-QUERY] ${error.sql}`);
debugDB(`#interceptor(): [SQL-RESPONSE] ${error.code}`);
debugDB(`#interceptor(): [SQL-MESSAGE] ${error.sqlMessage}`);

// todo(jniles) - unify this error handing
if (error.code === 'ER_SIGNAL_EXCEPTION') {
key = SQL_STATES[error.sqlState] || error.sqlState;
Expand All @@ -72,11 +76,6 @@ exports.handler = function handler(err, req, res, next) {
key = `ERRORS.${error.code || error.sqlState}`;
description = map[error.code];
}

debugDB(`#interceptor(): [ERROR-QUERY] ${error.sql}`);
debugDB(`#interceptor(): [ERROR-RESPONSE] ${error.sqlState}`);
debugDB(`#interceptor(): [ERROR-MESSAGE] ${error.sqlMesssage}`);

error = new BadRequest(description, key);
}

Expand Down
2 changes: 1 addition & 1 deletion server/controllers/finance/cashboxes/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -237,7 +237,7 @@ function privileges(req, res, next) {
(
SELECT cash_box.id, cash_box.label, cash_box.project_id, cash_box.is_auxiliary, cashbox_permission.user_id
FROM cash_box
JOIN cashbox_permission ON bhima_test.cashbox_permission.cashbox_id = cash_box.id
JOIN cashbox_permission ON cashbox_permission.cashbox_id = cash_box.id
WHERE cashbox_permission.user_id = ? AND cash_box.is_auxiliary = ?
)
UNION
Expand Down
3 changes: 1 addition & 2 deletions server/models/bhima.sql
Original file line number Diff line number Diff line change
Expand Up @@ -112,8 +112,7 @@ INSERT INTO `report` (`id`, `report_key`, `title_key`) VALUES
-- Supported Languages
INSERT INTO `language` VALUES
(1,'Francais','fr', 'fr-be'),
(2,'English','en', 'en-us'),
(3,'Lingala','lg', 'fr-cd');
(2,'English','en', 'en-us');

-- Currencies
INSERT INTO `currency` (`id`, `name`, `format_key`, `symbol`, `note`, `min_monentary_unit`) VALUES
Expand Down
91 changes: 91 additions & 0 deletions server/models/migrations/v0.5.0-v0.6.0/migrate.sql
Original file line number Diff line number Diff line change
Expand Up @@ -131,3 +131,94 @@ ALTER TABLE `patient_group_invoicing_fee` ADD FOREIGN KEY (`invoicing_fee_id`) R
-- ALTER TABLE `invoice_invoicing_fee` DROP FOREIGN KEY `billing_service_id`;
ALTER TABLE `invoice_invoicing_fee` CHANGE COLUMN `billing_service_id` `invoicing_fee_id` SMALLINT UNSIGNED NOT NULL;
ALTER TABLE `invoice_invoicing_fee` ADD FOREIGN KEY (`invoicing_fee_id`) REFERENCES `invoicing_fee` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;


-- insert missing modules
INSERT IGNORE INTO unit VALUES
(0, 'Root','TREE.ROOT','The unseen root node',NULL,'/modules/index.html','/root'),
(1, 'Admin','TREE.ADMIN','The Administration Super-Category',0,'/modules/admin/index.html','/admin'),
(2, 'Enterprise', 'TREE.ENTERPRISE', 'Manage the registered enterprises from here', 1, '/modules/enterprise/', '/enterprises'),
(3, 'Invoice Registry','TREE.INVOICE_REGISTRY','Invoice Registry',5,'/modules/invoices/registry/','/invoices'),
(4, 'Users & Permissions','TREE.USERS','Manage user privileges and permissions',1,'/modules/users/','/users'),
(5, 'Finance','TREE.FINANCE','The Finance Super-Category',0,'/modules/finance/','/finance'),
(6, 'Account','TREE.ACCOUNT','Chart of Accounts management',5,'/modules/accounts/','/accounts'),
(9, 'Posting Journal','TREE.POSTING_JOURNAL','Daily Log',5,'/modules/journal/','/journal'),
(10, 'General Ledger','TREE.GENERAL_LEDGER','Posted Journal Data', 5,'/modules/general_ledger/','/general_ledger'),
(12, 'Hospital','TREE.HOSPITAL','The Hospital Super-Category',0,'/modules/hospital/index.html','/hospital'),
(13, 'Fiscal Year','TREE.FISCAL_YEAR','Fiscal year configuration page',5,'/modules/fiscal/','/fiscal'),
(14, 'Patient Registration','TREE.PATIENT_REGISTRATION','Register patients',12,'/modules/patient/register/','/patients/register'),
(15, 'Patient Registry','TREE.PATIENT_REGISTRY','Patient Registry',12,'/modules/patients/registry/','/patients'),
(16, 'Patient Invoice','TREE.PATIENT_INVOICE','Create an invoice for a patient',5,'/modules/patient_invoice/','/invoices/patient'),
(18, 'Cash Window','TREE.CASH_WINDOW','Cash payments against past or future invoices',5,'/modules/cash/','/cash'),
(19, 'Register Supplier','TREE.REGISTER_SUPPLIER','',1,'/modules/suppliers/','/suppliers'),
(20, 'Depot Management','TREE.DEPOTS','',1,'/modules/depots/','/depots'),
(21, 'Price List','TREE.PRICE_LIST','Configure price lists!',1,'/modules/prices/','/prices'),
(26, 'Location Manager','TREE.LOCATION','',1,'/modules/locations/locations.html','/locations'),
(29, 'Patient Group','TREE.PATIENT_GRP','',1,'/modules/patients/groups/','/patients/groups'),
(48, 'Service Management','TREE.SERVICE','',1,'modules/services/','/services'),
(57, 'Payroll','TREE.PAYROLL','',0,'modules/payroll/','/payroll/'),
(61, 'Employee','TREE.EMPLOYEE','Employees Registration',57,'modules/employees/register/','/employees/register'),
(62, 'Employee Registry','TREE.EMPLOYEE_REGISTRY','Employee Registry',57,'/modules/payroll/registry/','/employees'),
(82, 'Subsidies','TREE.SUBSIDY','Handles the subsidy situation',1,'/modules/subsidies/','/subsidies'),
(105, 'Cashbox Management','TREE.CASHBOX_MANAGEMENT','',1,'/modules/cash/cashbox/','/cashboxes'),
(107, 'Debtor Groups Management', 'TREE.DEBTOR_GROUP', 'Debtor Groups Management module', 1, '/modules/debtors/groups/', '/debtors/groups'),
(134, 'Simple Journal Vouchers', 'TREE.SIMPLE_VOUCHER', 'Creates a simple transfer slip between two accounts', 5, '/modules/vouchers/simple', '/vouchers/simple'),
(135, 'Invoicing Fee', 'TREE.INVOICING_FEES', 'Configures invoicing Fee for bhima', 1, '/modules/invoicing_fees', '/invoicing_fees'),
(137, 'Complex Journal Vouchers', 'TREE.COMPLEX_JOURNAL_VOUCHER', 'Complex Journal vouchers module', 5, '/modules/vouchers/complex', '/vouchers/complex'),
(138, 'Inventory Module', 'TREE.INVENTORY', 'Inventory management module', 0, '/modules/inventory/index', '/inventory'),
(139, 'Inventory List', 'TREE.INVENTORY_LIST', 'Inventory list module', 138, '/modules/inventory/list', '/inventory/list'),
(140, 'Inventory Configurations', 'TREE.INVENTORY_CONFIGURATION', 'Inventory configuration module', 138, '/modules/inventory/configuration', '/inventory/configuration'),
(141, 'Vouchers Records', 'TREE.VOUCHER_REGISTRY', 'Vouchers registry module', 5, '/modules/vouchers/index', '/vouchers'),
(142, 'Purchase Orders', 'TREE.PURCHASING', 'This module is responsible for creating purchase orders', 138, '/modules/purchases/create', '/purchases/create'),
(143, 'Transaction Type Module', 'TREE.TRANSACTION_TYPE', 'This module is responsible for managing transaction type', 1, '/modules/transaction-type', '/transaction_type'),
(144, 'Reports (Finance)', 'TREE.REPORTS', 'A folder holding all finance reports', 0, '/modules/finance/reports', '/finance/reports'),
(145, 'Cashflow', 'TREE.CASHFLOW', 'The Cashflow Report', 144, '/modules/reports/cashflow', '/reports/cashflow'),
(146, 'Creditor Groups Management', 'TREE.CREDITOR_GROUP', 'Creditor Groups Management module', 1, '/modules/creditor-groups/', '/creditors/groups'),
(147, 'Cash Payment Registry', 'TREE.CASH_PAYMENT_REGISTRY', 'Cash Payment Registry', 5, '/modules/cash/payments/registry', '/payments'),
(149, 'Cash report', 'TREE.CASH_REPORT', 'The Report of cash entry and exit', 144, '/modules/reports/cash_report', '/reports/cash_report'),
(150, 'Balance Report', 'TREE.BALANCE_REPORT', 'Balance report module', 144, '/modules/reports/balance_report', '/reports/balance_report'),
(151, 'Customer Debts', 'TREE.AGED_DEBTORS', 'Aged Debtors', 144, '/modules/reports/aged_debtors', '/reports/aged_debtors'),
(152, 'Account report', 'TREE.REPORT_ACCOUNTS', 'The Report accounts', 144, '/modules/reports/account_report', '/reports/account_report'),
(153, 'Report Cashflow by Service', 'TREE.CASHFLOW_BY_SERVICE', 'CashflowByService', 144, '/partials/reports/cashflowByService', '/reports/cashflowByService'),
(154, 'Purchase Order', 'TREE.PURCHASE_ORDER', 'Purchase order folder', 0, '/partials/purchase_order', '/purchases/'),
(155, 'Purchase', 'TREE.PURCHASE', 'The purchase module', 154, '/partials/purchase_order/purchase', '/purchases/create'),
(156, 'Purchase Registry', 'TREE.PURCHASE_REGISTRY', 'The purchase registry', 154, '/partials/purchase_order/registry', '/purchases'),
(157, 'Open Debtors', 'REPORT.OPEN_DEBTORS.TREE', 'Open Debtors', 144, '/modules/finance/open_debtors', '/reports/open_debtors'),
(159, 'Clients report', 'REPORT.CLIENTS_REPORT.TITLE', 'The Client report', 144, '/modules/reports/clients_report', '/reports/clients_report'),
(160, 'Stock', 'TREE.STOCK', 'The stock management module', 0, '/partials/stock', '/stock'),
(161, 'Stock Lots', 'TREE.STOCK_LOTS', 'The stock lots registry', 160, '/partials/stock/lots', '/stock/lots'),
(162, 'Stock Movements', 'TREE.STOCK_MOVEMENTS', 'The stock lots movements registry', 160, '/partials/stock/movements', '/stock/movements'),
(163, 'Stock Inventory', 'TREE.STOCK_INVENTORY', 'The stock inventory registry', 160, '/partials/stock/inventories', '/stock/inventories'),
(164, 'Stock Exit', 'STOCK.EXIT', 'The stock exit module', 160, '/partials/stock/exit', '/stock/exit'),
(165, 'Stock Entry', 'STOCK.ENTRY', 'The stock entry module', 160, '/partials/stock/entry', '/stock/entry'),
(167, 'Stock Adjustment', 'STOCK.ADJUSTMENT', 'The stock adjustment module', 160, '/partials/stock/adjustment', '/stock/adjustment'),
(168, 'Aged Creditors', 'TREE.AGED_CREDITORS', 'Aged Creditors', 144, '/modules/reports/aged_creditors', '/reports/aged_creditors'),
(170, 'Account Statement', 'TREE.ACCOUNT_STATEMENT', 'Account Statement Module', 5, '/partials/account_statement/', '/account_statement'),
(171, 'Balance Sheet Statement', 'TREE.BALANCE_SHEET', 'Balance Sheet Module', 144, '/modules/reports/balance_sheet_report/', '/reports/balance_sheet_report'),
(180, 'Income Expenses', 'TREE.INCOME_EXPENSE', 'The Report of income and expenses', 144, '/modules/finance/income_expense', '/reports/income_expense'),
(181, 'Stock Report', 'TREE.STOCK_REPORT', 'The Report of inventories in stock', 144, '/modules/reports/inventory_report', '/reports/inventory_report'),
(182, 'Stock File Report', 'TREE.STOCK_INVENTORY_REPORT', 'The Report of an inventory in stock', 144, '/modules/reports/inventory_file', '/reports/inventory_file'),
(183, 'Grade Management','TREE.GRADES','', 1,'/modules/grades/','/grades'),
(184, 'Job Title Management','TREE.PROFESSION','', 1,'/modules/functions/','/functions');


INSERT IGNORE INTO `report` (`id`, `report_key`, `title_key`) VALUES
(1, 'cashflow', 'TREE.CASHFLOW'),
(2, 'accounts_chart', 'REPORT.CHART_OF_ACCOUNTS'),
(3, 'income_expense', 'REPORT.INCOME_EXPENSE'),
(4, 'balance_report', 'REPORT.BALANCE'),
(5, 'aged_debtors', 'TREE.AGED_DEBTORS'),
(6, 'account_report', 'REPORT.REPORT_ACCOUNTS.TITLE'),
(7, 'cashflowByService', 'REPORT.CASHFLOW_BY_SERVICE.TITLE'),
(8, 'open_debtors', 'REPORT.OPEN_DEBTORS.TITLE'),
(9, 'clients_report','REPORT.CLIENTS'),
(10, 'aged_creditors','TREE.AGED_CREDITORS'),
(11, 'balance_sheet_report', 'REPORT.BALANCE_SHEET.TITLE'),
(12, 'cash_report', 'REPORT.CASH_REPORT'),
(13, 'inventory_report', 'REPORT.STOCK.TITLE'),
(14, 'inventory_file', 'REPORT.STOCK.INVENTORY_REPORT');

-- various unit updates

DELETE FROM unit WHERE id IN (135, 158);
INSERT INTO unit values (135, 'Invoicing Fee', 'TREE.INVOICING_FEES', 'Configures invoicing Fee for bhima', 1, '/modules/invoicing_fees', '/invoicing_fees')
42 changes: 3 additions & 39 deletions server/models/procedures/invoicing.sql
Original file line number Diff line number Diff line change
Expand Up @@ -409,8 +409,9 @@ BEGIN
DECLARE cdescription TEXT;

-- cursor for debtor's cautions
-- TODO(@jniles) - remove MAX() call. This violates ONLY_FULL_GROUP_BY.
DECLARE curse CURSOR FOR
SELECT c.id, c.date, c.description, SUM(c.credit - c.debit) AS balance FROM (
SELECT c.id, c.date, MAX(c.description), SUM(c.credit - c.debit) AS balance FROM (

-- get the record_uuids in the posting journal
SELECT debit_equiv as debit, credit_equiv as credit, posting_journal.trans_date as date, posting_journal.description, record_uuid AS id
Expand Down Expand Up @@ -442,7 +443,7 @@ BEGIN
ON cash.uuid = general_ledger.reference_uuid
WHERE entity_uuid = ientityId AND cash.is_caution = 0
) AS c
GROUP BY c.id
GROUP BY c.id, c.date
HAVING balance > 0
ORDER BY c.date;

Expand Down Expand Up @@ -581,40 +582,3 @@ BEGIN
WHERE i.uuid = iuuid;
END
$$

/*
PostToGeneralLedger()
This procedure uses the same staging code as the Trial Balance to stage and then post transactions
from the posting_journal table to the General Ledger table.
*/
CREATE PROCEDURE PostToGeneralLedger()
BEGIN
-- write into the posting journal
INSERT INTO general_ledger (
project_id, uuid, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, reference_uuid, comment, origin_id, user_id,
cc_id, pc_id
) SELECT project_id, uuid, fiscal_year_id, period_id, trans_id, trans_date, posting_journal.record_uuid,
description, account_id, debit, credit, debit_equiv, credit_equiv, currency_id,
entity_uuid, reference_uuid, comment, origin_id, user_id, cc_id, pc_id
FROM posting_journal JOIN stage_trial_balance_transaction AS staged
ON posting_journal.record_uuid = staged.record_uuid;

-- write into period_total
INSERT INTO period_total (
account_id, credit, debit, fiscal_year_id, enterprise_id, period_id
)
SELECT account_id, SUM(credit_equiv) AS credit, SUM(debit_equiv) as debit,
fiscal_year_id, project.enterprise_id, period_id
FROM posting_journal JOIN stage_trial_balance_transaction JOIN project
ON posting_journal.record_uuid = stage_trial_balance_transaction.record_uuid
AND project_id = project.id
GROUP BY period_id, account_id
ON DUPLICATE KEY UPDATE credit = credit + VALUES(credit), debit = debit + VALUES(debit);

-- remove from posting journal
DELETE FROM posting_journal WHERE record_uuid IN (SELECT record_uuid FROM stage_trial_balance_transaction);
END $$
53 changes: 45 additions & 8 deletions server/models/procedures/trial_balance.sql
Original file line number Diff line number Diff line change
Expand Up @@ -98,7 +98,7 @@ BEGIN

-- check if dates are in the correct period
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.DATE_IN_WRONG_PERIOD' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.DATE_IN_WRONG_PERIOD' AS code
FROM posting_journal AS pj
JOIN stage_trial_balance_transaction AS temp ON pj.record_uuid = temp.record_uuid
JOIN period AS p ON pj.period_id = p.id
Expand All @@ -107,7 +107,7 @@ BEGIN

-- check to make sure that the fiscal year is not closed
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.CLOSED_FISCAL_YEAR' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.CLOSED_FISCAL_YEAR' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
JOIN fiscal_year ON pj.fiscal_year_id = fiscal_year.id
Expand All @@ -116,39 +116,39 @@ BEGIN

-- check to make sure that all lines of a transaction have a description
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.MISSING_DESCRIPTION' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.MISSING_DESCRIPTION' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
WHERE pj.description IS NULL
GROUP BY pj.record_uuid;

-- check that all periods are unlocked
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.LOCKED_PERIOD' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.LOCKED_PERIOD' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
JOIN period p ON pj.period_id = p.id
WHERE p.locked = 1 GROUP BY pj.record_uuid;

-- check that all accounts are unlocked
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.LOCKED_ACCOUNT' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.LOCKED_ACCOUNT' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
JOIN account a ON pj.account_id = a.id
WHERE a.locked = 1 GROUP BY pj.record_uuid;

-- check that all transactions are balanced
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.UNBALANCED_TRANSACTIONS' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.UNBALANCED_TRANSACTIONS' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
GROUP BY pj.record_uuid
HAVING SUM(pj.debit_equiv) <> SUM(pj.credit_equiv);

-- check that all transactions have two or more lines
INSERT INTO stage_trial_balance_errors
SELECT pj.record_uuid, pj.trans_id, 'POSTING_JOURNAL.ERRORS.SINGLE_LINE_TRANSACTION' AS code
SELECT pj.record_uuid, MAX(pj.trans_id), 'POSTING_JOURNAL.ERRORS.SINGLE_LINE_TRANSACTION' AS code
FROM posting_journal AS pj JOIN stage_trial_balance_transaction AS temp
ON pj.record_uuid = temp.record_uuid
GROUP BY pj.record_uuid
Expand Down Expand Up @@ -206,7 +206,7 @@ BEGIN
balance_before, debit_equiv, credit_equiv,
balance_before + debit_equiv - credit_equiv AS balance_final
FROM (
SELECT posting_journal.account_id, totals.balance_before, SUM(debit_equiv) AS debit_equiv,
SELECT posting_journal.account_id, SUM(totals.balance_before) AS balance_before, SUM(debit_equiv) AS debit_equiv,
SUM(credit_equiv) AS credit_equiv
FROM posting_journal JOIN before_totals as totals
ON posting_journal.account_id = totals.account_id
Expand All @@ -217,3 +217,40 @@ BEGIN
JOIN account ON account.id = combined.account_id
ORDER BY account.number;
END $$

/*
PostToGeneralLedger()
This procedure uses the same staging code as the Trial Balance to stage and then post transactions
from the posting_journal table to the General Ledger table.
*/
CREATE PROCEDURE PostToGeneralLedger()
BEGIN
-- write into the posting journal
INSERT INTO general_ledger (
project_id, uuid, fiscal_year_id, period_id, trans_id, trans_date,
record_uuid, description, account_id, debit, credit, debit_equiv,
credit_equiv, currency_id, entity_uuid, reference_uuid, comment, origin_id, user_id,
cc_id, pc_id
) SELECT project_id, uuid, fiscal_year_id, period_id, trans_id, trans_date, posting_journal.record_uuid,
description, account_id, debit, credit, debit_equiv, credit_equiv, currency_id,
entity_uuid, reference_uuid, comment, origin_id, user_id, cc_id, pc_id
FROM posting_journal JOIN stage_trial_balance_transaction AS staged
ON posting_journal.record_uuid = staged.record_uuid;

-- write into period_total
INSERT INTO period_total (
account_id, credit, debit, fiscal_year_id, enterprise_id, period_id
)
SELECT account_id, SUM(credit_equiv) AS credit, SUM(debit_equiv) as debit,
fiscal_year_id, project.enterprise_id, period_id
FROM posting_journal JOIN stage_trial_balance_transaction JOIN project
ON posting_journal.record_uuid = stage_trial_balance_transaction.record_uuid
AND project_id = project.id
GROUP BY fiscal_year_id, period_id, account_id
ON DUPLICATE KEY UPDATE credit = credit + VALUES(credit), debit = debit + VALUES(debit);

-- remove from posting journal
DELETE FROM posting_journal WHERE record_uuid IN (SELECT record_uuid FROM stage_trial_balance_transaction);
END $$

0 comments on commit 623a910

Please sign in to comment.