Skip to content

Commit

Permalink
feat(stored procedure): Add a stored procedure to handle stock integr…
Browse files Browse the repository at this point in the history
…ation
  • Loading branch information
DedrickEnc committed Sep 21, 2017
1 parent 32a0d75 commit b2ed339
Show file tree
Hide file tree
Showing 3 changed files with 122 additions and 5 deletions.
2 changes: 1 addition & 1 deletion client/src/modules/stock/entry/entry.js
Original file line number Diff line number Diff line change
Expand Up @@ -341,7 +341,7 @@ function StockEntryController(
var entry = {
integration : { date : vm.movement.date, description : vm.movement.description },
lots : lots,
movement : movement,
movement : movement
}

Stock.integration.create(entry)
Expand Down
14 changes: 11 additions & 3 deletions server/controllers/stock/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -102,13 +102,14 @@ function createStock(req, res, next) {
transaction.addQuery(createMovementQuery, [createMovementObject]);
});

// An arry of common info, to send to the store procedure in order to insert to the posting journal
// An array of common info, to send to the store procedure in order to insert to the posting journal
const commonInfos = [
db.bid(document.uuid), document.date,
req.session.enterprise.id, req.session.project.id,
req.session.enterprise.currency_id, document.user,
];


// writting all records relative to the movement in the posting journal table
transaction.addQuery('CALL PostPurchase(?)', [commonInfos]);

Expand Down Expand Up @@ -383,10 +384,17 @@ function createIntegration(req, res, next) {
});

// An arry of common info, to send to the store procedure in order to insert to the posting journal
commonInfos = [ db.bid(documentUuid), new Date(params.movement.date), req.session.enterprise.id, req.session.project.id, req.session.enterprise.currency_id, req.session.user.id ];
commonInfos = [
db.bid(documentUuid),
new Date(params.movement.date),
req.session.enterprise.id,
req.session.project.id,
req.session.enterprise.currency_id,
req.session.user.id
];

// writting all records relative to the movement in the posting journal table
transaction.addQuery('CALL PostStockEntry(?)', [commonInfos]);
transaction.addQuery('CALL PostIntegration(?)', [commonInfos]);
});

// execute all operations as one transaction
Expand Down
111 changes: 110 additions & 1 deletion server/models/procedures.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1350,7 +1350,7 @@ BEGIN
END $$

-- This processus inserts records relative to the stock movement in the posting journal
CREATE PROCEDURE PostStockEntry (
CREATE PROCEDURE PostPurchase (
IN document_uuid BINARY(16),
IN date DATETIME,
IN enterprise_id SMALLINT(5) UNSIGNED,
Expand Down Expand Up @@ -1463,4 +1463,113 @@ BEGIN
sm.document_uuid = document_uuid
GROUP BY i.uuid;
END $$

-- This processus inserts records relative to the stock movement integration in the posting journal
CREATE PROCEDURE PostIntegration (
IN document_uuid BINARY(16),
IN date DATETIME,
IN enterprise_id SMALLINT(5) UNSIGNED,
IN project_id SMALLINT(5) UNSIGNED,
IN currency_id TINYINT(3) UNSIGNED,
IN user_id SMALLINT(5) UNSIGNED
)
BEGIN
DECLARE InvalidInventoryAccounts CONDITION FOR SQLSTATE '45006';
DECLARE current_fiscal_year_id MEDIUMINT(8) UNSIGNED;
DECLARE current_period_id MEDIUMINT(8) UNSIGNED;
DECLARE current_exchange_rate DECIMAL(19, 4) UNSIGNED;
DECLARE transaction_id VARCHAR(100);
DECLARE verify_invalid_accounts SMALLINT(5);
DECLARE STOCK_INTEGRATION_TRANSACTION_TYPE TINYINT(3) UNSIGNED;

-- should not be reassigned during the execution, to know why 12 please see the transaction_type table
SET STOCK_INTEGRATION_TRANSACTION_TYPE = 12;


-- getting the curent fiscal year
SET current_fiscal_year_id = (
SELECT id FROM fiscal_year AS fy
WHERE date BETWEEN fy.start_date AND DATE(ADDDATE(fy.start_date, INTERVAL fy.number_of_months MONTH)) AND fy.enterprise_id = enterprise_id
);

-- getting the period id
SET current_period_id = (
SELECT id FROM period AS p
WHERE DATE(date) BETWEEN DATE(p.start_date) AND DATE(p.end_date) AND p.fiscal_year_id = current_fiscal_year_id
);

-- getting the transaction number
SET transaction_id = GenerateTransactionId(project_id);

CALL PostingJournalErrorHandler(enterprise_id, project_id, current_fiscal_year_id, current_period_id, 1, date);

-- Check that all every inventory has a stock account and a variation account - if they do not the transaction will be Unbalanced
SELECT
COUNT(l.uuid) INTO verify_invalid_accounts
FROM
lot AS l
JOIN
stock_movement sm ON sm.lot_uuid = l.uuid
JOIN
inventory i ON i.uuid = l.inventory_uuid
JOIN
inventory_group ig ON ig.uuid = i.group_uuid
WHERE
ig.stock_account IS NULL AND
ig.cogs_account IS NULL AND
sm.document_uuid = document_uuid;

IF verify_invalid_accounts > 0 THEN
SIGNAL InvalidInventoryAccounts
SET MESSAGE_TEXT = 'Every inventory should belong to a group with a cogs account and stock account.';
END IF;

-- Debiting stock account, by inserting a record to the posting journal table
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, origin_id, user_id
)
SELECT
HUID(UUID()), project_id, current_fiscal_year_id, current_period_id, transaction_id,
date, i.uuid, sm.description, ig.stock_account, l.quantity * l.unit_cost, 0, l.quantity * l.unit_cost, 0, currency_id,
STOCK_INTEGRATION_TRANSACTION_TYPE, user_id
FROM
stock_movement As sm
JOIN
lot l ON l.uuid = sm.lot_uuid
JOIN
integration i ON i.uuid = l.origin_uuid
JOIN
inventory inv ON inv.uuid = l.inventory_uuid
JOIN
inventory_group ig ON ig.uuid = inv.group_uuid
WHERE
sm.document_uuid = document_uuid;

-- Crediting cost of good sale account, by inserting a record to the posting journal table
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, origin_id, user_id
)
SELECT
HUID(UUID()), project_id, current_fiscal_year_id, current_period_id, transaction_id,
date, i.uuid, sm.description, ig.cogs_account, 0, l.quantity * l.unit_cost, 0, l.quantity * l.unit_cost, currency_id,
STOCK_INTEGRATION_TRANSACTION_TYPE, user_id
FROM
stock_movement As sm
JOIN
lot l ON l.uuid = sm.lot_uuid
JOIN
integration i ON i.uuid = l.origin_uuid
JOIN
inventory inv ON inv.uuid = l.inventory_uuid
JOIN
inventory_group ig ON ig.uuid = inv.group_uuid
WHERE
sm.document_uuid = document_uuid;
END $$
DELIMITER ;

0 comments on commit b2ed339

Please sign in to comment.