Skip to content

Commit

Permalink
perf(stock): improve createMovement speed
Browse files Browse the repository at this point in the history
This improves the performance of createMovement speed by using the
updated "getLotsForDate" function.
  • Loading branch information
jniles committed Mar 4, 2022
1 parent cfc2f56 commit 22a3cf1
Show file tree
Hide file tree
Showing 4 changed files with 137 additions and 87 deletions.
31 changes: 21 additions & 10 deletions server/controllers/inventory/depots/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@ exports.detail = detail;
exports.create = create;
exports.update = update;
exports.remove = remove;
exports.getLotsInStockForDate = getLotsInStockForDate;
exports.searchByName = searchByName;

// router base is /depots
Expand All @@ -44,7 +45,7 @@ router.put('/:uuid', update);
router.post('/', create);
router.delete('/:uuid', remove);
router.get('/:depotUuid/inventories', getQuantitiesInStock);
router.get('/:depotUuid/stock', getLotsInStockForDate);
router.get('/:depotUuid/stock', getLotsInStockForDateHttp);
router.get('/:depotUuid/flags/stock_out', getStockOuts);

// special route for searching depot by name
Expand Down Expand Up @@ -105,15 +106,17 @@ async function getQuantitiesInStock(req, res, next) {
}
}

async function getLotsInStockForDate(req, res, next) {
const { depotUuid } = req.params;
const { date } = req.query;

try {
/**
* @function getLotsInStockForDate
*
* @description
* A higher-performance query to figure out the lots in a given depot.
*/
function getLotsInStockForDate(depotUuid, date) {

// NOTE(@jniles) - doing the filtering on depot before the JOIN speeds
// this query up by 3X.
const sql = `
// NOTE(@jniles) - doing the filtering on depot before the JOIN speeds
// this query up by 3X.
const sql = `
SELECT
BUID(inventory.uuid) AS inventory_uuid,
BUID(lot.uuid) AS lot_uuid,
Expand Down Expand Up @@ -143,7 +146,15 @@ async function getLotsInStockForDate(req, res, next) {
ORDER BY inventory.text, lot.expiration_date, lot.label;
`;

const rows = await db.exec(sql, [date, db.bid(depotUuid)]);
return db.exec(sql, [date, db.bid(depotUuid)]);
}

async function getLotsInStockForDateHttp(req, res, next) {
const { depotUuid } = req.params;
const { date } = req.query;

try {
const rows = await getLotsInStockForDate(depotUuid, date);
res.status(200).json(rows);
} catch (e) {
next(e);
Expand Down
89 changes: 42 additions & 47 deletions server/controllers/stock/index.js
Original file line number Diff line number Diff line change
@@ -1,3 +1,5 @@
/* eslint-disable camelcase */

/**
* @module stock
*
Expand Down Expand Up @@ -27,6 +29,7 @@ const requisition = require('./requisition/requisition');
const requestorType = require('./requisition/requestor_type');
const Fiscal = require('../finance/fiscal');
const vouchers = require('../finance/vouchers');
const depots = require('../inventory/depots');

// expose to the API
exports.createStock = createStock;
Expand Down Expand Up @@ -146,12 +149,19 @@ async function createStock(req, res, next) {
transaction.addQuery('CALL PostStockMovement(?)', [postingParams]);
}

// gather unique inventory uuids for use later recomputing the stock quantities
const inventoryUuids = params.lots
.map(lot => lot.inventory_uuid)
.filter((uid, index, array) => array.lastIndexOf(uid) === index);

// if we are adding stock, we must update the weighted average cost
if (!isExit && params.flux_id !== core.flux.FROM_OTHER_DEPOT) {
transaction.addQuery('CALL RecomputeStockValue(NULL);');
}
inventoryUuids.forEach(uid => {
transaction.addQuery('CALL StageInventoryForStockValue(?);', [db.bid(uid)]);
});

// gather inventory uuids for use later recomputing the stock quantities
const inventoryUuids = params.lots.map(lot => lot.inventory_uuid);
transaction.addQuery('CALL RecomputeStockValueForStagedInventory(NULL);');
}

// execute all operations as one transaction
await transaction.execute();
Expand All @@ -177,12 +187,8 @@ async function createStock(req, res, next) {
function updateQuantityInStockAfterMovement(inventoryUuids, mvmtDate, depotUuid) {
const txn = db.transaction();

// makes a unique array of inventory uuids so we don't do extra calls
const uniqueInventoryUuids = inventoryUuids
.filter((uid, index, array) => array.lastIndexOf(uid) === index);

// loop through the inventory uuids, queuing up them to rerun
uniqueInventoryUuids.forEach(uid => {
inventoryUuids.forEach(uid => {
txn.addQuery(`CALL StageInventoryForAMC(?)`, [db.bid(uid)]);
});

Expand Down Expand Up @@ -414,8 +420,6 @@ async function createInventoryAdjustment(req, res, next) {
*/
async function createMovement(req, res, next) {
const params = req.body;
let stockAvailable = [];
let filteredInvalidData = [];

const document = {
uuid : params.document_uuid || uuid(),
Expand All @@ -430,43 +434,31 @@ async function createMovement(req, res, next) {
};

try {
params.month_average_consumption = req.session.stock_settings.month_average_consumption;
params.average_consumption_algo = req.session.stock_settings.average_consumption_algo;

const paramsStock = {
dateTo : new Date(),
depot_uuid : params.depot_uuid,
includeEmptyLot : 0,
month_average_consumption : params.month_average_consumption,
average_consumption_algo : params.average_consumption_algo,
};

// FIXME(@jniles) - do we really look up the entire inventory of the depot a second time?
// when exit, we need to check that we are not accidentally over-consuming items
if (params.is_exit) {
stockAvailable = await core.getLotsDepot(null, paramsStock);

params.lots.forEach(lot => {
lot.quantityAvailable = 0;
if (stockAvailable) {
stockAvailable.forEach(stock => {
if (stock.uuid === lot.uuid) {
lot.quantityAvailable = stock.quantity;
lot.unit_cost = stock.wac;
}
});
}
// NOTE(@jniles) - we use _today's_ date because we want to know if this movement will
// cause a negative value at any point in the future.
const stockInDepot = await depots.getLotsInStockForDate(params.depot_uuid, new Date());

// get a list of the lots that are being overconsumed
// if the lot is in the depot, that means it was totally consumed at some point
const overconsumed = params.lots.filter(lot => {
const lotInDepot = stockInDepot.find(l => l.lot_uuid === lot.uuid);
if (!lotInDepot) { return true; }
return lot.quantity > lotInDepot.quantity;
});

filteredInvalidData = params.lots.filter(l => l.quantity > l.quantityAvailable);
}

if (filteredInvalidData.length) {
throw new BadRequest(
`This stock exit will overconsume the quantity in stock and generate negative quantity in stock`,
`ERRORS.ER_PREVENT_NEGATIVE_QUANTITY_IN_EXIT_STOCK`,
);
// show a nicer error if the quantity in stock is overconsumed
if (overconsumed.length) {
const labels = overconsumed.map(l => l.label).join(', ').trim();
throw new BadRequest(
`This stock exit will overconsume the lots in stock and create negative quantity in stock for ${labels}.`,
`ERRORS.ER_PREVENT_NEGATIVE_QUANTITY_IN_EXIT_STOCK`,
);
}
}

// NOTE(@jniles) - the id here is the period id, not the fiscal year id.
const periodId = (await Fiscal.lookupFiscalYearByDate(params.date)).id;
params.period_id = periodId;

Expand Down Expand Up @@ -662,12 +654,15 @@ async function depotMovement(document, params) {
// gather inventory uuids for later quantity in stock calculation updates
const inventoryUuids = parameters.lots.map(lot => lot.inventory_uuid);

transaction.addQuery('CALL RecomputeStockValue(NULL);');
// TODO(@jniles) - we don't need to recompute stock value for depot movements
// the value to the enterprise has not changed.
// transaction.addQuery('CALL RecomputeStockValue(NULL);');

const result = await transaction.execute();

// update the quantity in stock as needed
await updateQuantityInStockAfterMovement(inventoryUuids, document.date, depotUuid);

return result;
}

Expand Down Expand Up @@ -743,10 +738,10 @@ function dashboard(req, res, next) {
ORDER BY d.text ASC`;

db.exec(getDepotsByUser, [req.session.user.id])
.then((depots) => {
depotsByUser = depots;
.then((_depots) => {
depotsByUser = _depots;

depots.forEach(depot => {
_depots.forEach(depot => {
if (status === 'expired') {
const paramsFilter = {
dateTo : new Date(),
Expand Down
90 changes: 68 additions & 22 deletions server/models/procedures/stock.sql
Original file line number Diff line number Diff line change
Expand Up @@ -330,7 +330,7 @@ END $$
CALL StageInventoryForAMC(inventoryUuid)
DESCRIPTION
This procedure adds an inventory uuid to a temporary table for latter use in the
This procedure adds an inventory uuid to a temporary table for later use in the
ComputeStockStatus() stored procedure. The idea is to allow the database to use a
JOIN to group the calculation upon the stock_movement table.
Expand Down Expand Up @@ -674,7 +674,23 @@ CREATE PROCEDURE GetAMC(
_initial_quantity AS quantity_at_beginning;
END $$

/*

/*
CALL StageInventoryForStockValue(inventoryUuid)
DESCRIPTION
This procedure adds an inventory uuid to a temporary table for later use in the
RecomputeStockValueForStagedInventory() stored procedure.
*/
DROP PROCEDURE IF EXISTS StageInventoryForStockValue$$
CREATE PROCEDURE StageInventoryForStockValue(
IN _inventory_uuid BINARY(16)
) BEGIN
CREATE TEMPORARY TABLE IF NOT EXISTS stage_inventory_for_stock_value(inventory_uuid BINARY(16) NOT NULL);
INSERT INTO stage_inventory_for_stock_value SET stage_inventory_for_stock_value.inventory_uuid = _inventory_uuid;
END $$

/*
* ComputeInventoryStockValue
* This procedure computes the stock value for a given inventory
* and update value in the database, the value is computed
Expand All @@ -685,9 +701,9 @@ CREATE PROCEDURE ComputeInventoryStockValue(
IN _inventory_uuid BINARY(16),
IN _date DATE
)
BEGIN
BEGIN
DECLARE v_cursor_all_movements_finished INTEGER DEFAULT 0;

DECLARE v_quantity_in_stock INT(11) DEFAULT 0;
DECLARE v_wac DECIMAL(19, 4) DEFAULT 0;
DECLARE v_is_exit TINYINT(1) DEFAULT 0;
Expand All @@ -704,7 +720,7 @@ BEGIN
WHERE
l.inventory_uuid = _inventory_uuid AND DATE(sm.date) <= DATE(_date)
ORDER BY DATE(sm.date), sm.created_at ASC;

DECLARE CONTINUE HANDLER FOR NOT FOUND SET v_cursor_all_movements_finished = 1;

OPEN cursor_all_movements;
Expand All @@ -716,9 +732,9 @@ BEGIN
LEAVE loop_cursor_all_movements;
END IF;

IF v_line_is_exit <> 0 THEN
IF v_line_is_exit <> 0 THEN
SET v_is_exit = -1;
ELSE
ELSE
SET v_is_exit = 1;
END IF;

Expand All @@ -735,7 +751,7 @@ BEGIN
conversion here, so the wac is based on movement unit_cost * 1
(in other word wac is based on movement cost which is in the enterprise currency)
*/
IF v_line_is_exit = 0 AND v_quantity_in_stock > 0 THEN
IF v_line_is_exit = 0 AND v_quantity_in_stock > 0 THEN
SET v_wac = ((v_quantity_in_stock * v_wac) + (v_line_quantity * v_line_unit_cost)) / (v_line_quantity + v_quantity_in_stock);
ELSEIF v_line_is_exit = 0 AND v_quantity_in_stock = 0 THEN
SET v_wac = (v_line_unit_cost * 1);
Expand All @@ -759,47 +775,79 @@ CREATE PROCEDURE RecomputeInventoryStockValue(
IN _inventory_uuid BINARY(16),
IN _date DATE
)
BEGIN
BEGIN

IF _date IS NOT NULL THEN
IF _date IS NOT NULL THEN
CALL ComputeInventoryStockValue(_inventory_uuid, _date);
ELSE
ELSE
CALL ComputeInventoryStockValue(_inventory_uuid, CURRENT_DATE());
END IF;

END $$

DROP PROCEDURE IF EXISTS RecomputeStockValueForStagedInventory$$
CREATE PROCEDURE RecomputeStockValueForStagedInventory(
IN _date DATE
)
BEGIN
DECLARE v_cursor_finished INTEGER DEFAULT 0;
DECLARE v_inventory_uuid BINARY(16);

DECLARE cursor_all_inventories CURSOR FOR
SELECT inv.inventory_uuid AS inventory_uuid
FROM stock_movement AS sm
JOIN lot AS l ON l.uuid = sm.lot_uuid
JOIN stage_inventory_for_stock_value AS inv ON inv.inventory_uuid = l.inventory_uuid
WHERE DATE(sm.date) <= DATE(_date)
GROUP BY inv.inventory_uuid;

DECLARE CONTINUE HANDLER FOR NOT FOUND SET v_cursor_finished = 1;

OPEN cursor_all_inventories;

loop_cursor_all_inventories : LOOP
FETCH cursor_all_inventories INTO v_inventory_uuid;

IF v_cursor_finished = 1 THEN
LEAVE loop_cursor_all_inventories;
END IF;

CALL RecomputeInventoryStockValue(v_inventory_uuid, _date);
END LOOP;

CLOSE cursor_all_inventories;

DROP TEMPORARY TABLE stage_inventory_for_stock_value;
END $$

DROP PROCEDURE IF EXISTS RecomputeAllInventoriesValue$$
CREATE PROCEDURE RecomputeAllInventoriesValue(
IN _date DATE
)
BEGIN
DECLARE v_cursor_finished INTEGER DEFAULT 0;

DECLARE v_inventory_uuid BINARY(16);

DECLARE cursor_all_inventories CURSOR FOR
SELECT inv.uuid AS inventory_uuid
FROM stock_movement AS sm
JOIN lot AS l ON l.uuid = sm.lot_uuid
JOIN inventory AS inv ON inv.uuid = l.inventory_uuid
JOIN document_map AS map ON map.uuid = sm.document_uuid
JOIN lot AS l ON l.uuid = sm.lot_uuid
JOIN inventory AS inv ON inv.uuid = l.inventory_uuid
WHERE DATE(sm.date) <= DATE(_date)
GROUP BY inv.uuid;

DECLARE CONTINUE HANDLER FOR NOT FOUND SET v_cursor_finished = 1;

OPEN cursor_all_inventories;

loop_cursor_all_inventories : LOOP
loop_cursor_all_inventories : LOOP
FETCH cursor_all_inventories INTO v_inventory_uuid;

IF v_cursor_finished = 1 THEN
LEAVE loop_cursor_all_inventories;
END IF;

CALL RecomputeInventoryStockValue(v_inventory_uuid, _date);

END LOOP;

CLOSE cursor_all_inventories;
Expand All @@ -809,14 +857,12 @@ DROP PROCEDURE IF EXISTS RecomputeStockValue$$
CREATE PROCEDURE RecomputeStockValue(
IN _date DATE
)
BEGIN

IF _date IS NOT NULL THEN
BEGIN
IF _date IS NOT NULL THEN
CALL RecomputeAllInventoriesValue(_date);
ELSE
ELSE
CALL RecomputeAllInventoriesValue(CURRENT_DATE());
END IF;

END $$

DELIMITER ;
Loading

0 comments on commit 22a3cf1

Please sign in to comment.