Skip to content

Commit

Permalink
feat(stock): algorithm for quantity in stock
Browse files Browse the repository at this point in the history
Adds an algorithm developed by @jeremielodi and formatted by @jniles for
computing the quantity in stock of inventory items.

Closes #4864.
  • Loading branch information
jniles committed Sep 1, 2020
1 parent 9ce5ebc commit 5ac6caf
Show file tree
Hide file tree
Showing 2 changed files with 216 additions and 0 deletions.
32 changes: 32 additions & 0 deletions server/models/admin.sql
Original file line number Diff line number Diff line change
Expand Up @@ -194,4 +194,36 @@ CREATE PROCEDURE zMergeAccounts(
DELETE FROM account WHERE id = from_account_id;
END $$

/*
CALL zComputeAllInventoryStockQuantities(startDate, depotUuid)
DESCRIPTION
Recomputes the quantity in stock for all inventory items for a given depot.
*/
DROP PROCEDURE IF EXISTS zComputeAllInventoryStockQuantities $$
CREATE PROCEDURE zComputeAllInventoryStockQuantities (
IN _start_date DATE,
IN _depot_uuid BINARY(16)
) BEGIN
DECLARE _inventory_uuid BINARY(16);
DECLARE done BOOLEAN;
DECLARE inventory_cursor
CURSOR FOR SELECT inventory.uuid FROM inventory WHERE consumable = 1;

DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;

OPEN inventory_cursor;

read_loop: LOOP
FETCH inventory_cursor INTO _inventory_uuid;
IF done THEN
LEAVE read_loop;
END IF;
CALL computeStockQuantity(_start_date, _inventory_uuid, _depot_uuid);
END LOOP;

CLOSE inventory_cursor;
END$$

DELIMITER ;
184 changes: 184 additions & 0 deletions server/models/procedures/stock.sql
Original file line number Diff line number Diff line change
Expand Up @@ -274,4 +274,188 @@ BEGIN
VALUES (HUID(UUID()), documentUuid, depotUuid, lotUuid, fluxId, CURRENT_DATE(), stockLotQuantity, inventoryUnitCost, 0, userId, periodId);
END $$

-- the main procedure that loops through stock_movement , retrieve and caculate cmm data
/*
CALL computeStockQuantity(startDate, inventoryUuid, depotUuid);
DESCRIPTION
Computes the quantity in stock from the startDate until now for a given inventoryUuid.
Originally written by @jeremielodi
*/
DROP PROCEDURE IF EXISTS `computeStockQuantity`$$
CREATE PROCEDURE `computeStockQuantity` (
IN _start_date DATE,
IN _inventory_uuid BINARY(16),
IN _depot_filter_uuid BINARY(16)
) BEGIN
DECLARE done BOOLEAN;
DECLARE _depot_uuid, _row_uuid BINARY(16);
DECLARE _inventory_name TEXT;
DECLARE _end_date DATE;
DECLARE _qtt, _in_qtt, _out_qtt DECIMAL(19, 4);

-- DROP TEMPORARY TABLE IF EXISTS `stock_movement_status`;
CREATE TEMPORARY TABLE IF NOT EXISTS `stock_movement_status` (
`uuid` BINARY(16),
`start_date` DATE,
`end_date` DATE,
`quantity` DECIMAL(19,4),
`in_quantity` DECIMAL(19,4),
`out_quantity` DECIMAL(19,4),
`inventory_uuid` BINARY(16),
`inventory_name` varchar(100),
`depot_uuid` BINARY(16),
PRIMARY KEY(`uuid`),
KEY `depot_uuid` (`depot_uuid`),
KEY `inventory_uuid` (`inventory_uuid`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;


DROP TEMPORARY TABLE IF EXISTS `temp_stock_movement`;

-- every stock movement for a inventory will be stored here in order to facilitate search
CREATE TEMPORARY TABLE `temp_stock_movement` (
`reference` INT,
`date` DATE,
`depot_uuid` BINARY(16),
`inventory_uuid` BINARY(16),
`quantity` DECIMAL(19,4),
`in_quantity` DECIMAL(19,4),
`out_quantity` DECIMAL(19,4),
`is_exit` TINYINT(2),
KEY `depot_uuid` (`depot_uuid`),
KEY `inventory_uuid` (`inventory_uuid`),
KEY `reference` (`reference`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

-- every stock movement for a inventory will be stored here in order to facilitate search
CREATE TEMPORARY TABLE IF NOT EXISTS `temp_depot` (
`reference` INT,
`uuid` BINARY(16),
`text` varchar(100),
KEY `uuid` (`uuid`),
KEY `reference` (`reference`)
) ENGINE=InnoDB DEFAULT CHARACTER SET = utf8mb4 DEFAULT COLLATE = utf8mb4_unicode_ci;

SET _end_date = NOW();
SET @depot_number = 0;

DELETE FROM `temp_depot`;

SET @filter_by_depot = (_depot_filter_uuid IS NOT NULL);

IF @filter_by_depot = 0 THEN -- will work for each depot
INSERT INTO `temp_depot`
SELECT (@depot_number:=@depot_number + 1)as ref, `uuid`, `text`
FROM depot;
ELSE
INSERT INTO `temp_depot` -- will work just for a specific depot
SELECT (@depot_number := @depot_number + 1) as ref, `uuid`, `text`
FROM depot
WHERE `uuid` = _depot_filter_uuid;
END IF;

SET @depot_counter = 1;
-- let's loop throw all inventories

WHILE (@depot_counter <= @depot_number) DO
SET @depot_uuid = (SELECT `uuid` FROM `temp_depot` WHERE `reference` = @depot_counter);

-- delete all inventory's data for this period

DELETE FROM `stock_movement_status`
WHERE `start_date` >= _start_date AND `end_date` <= _end_date AND `inventory_uuid` = _inventory_uuid AND `depot_uuid` = @depot_uuid;

DELETE FROM `temp_stock_movement` WHERE 1;
INSERT INTO `temp_stock_movement`

SELECT (@row_number:=@row_number + 1) AS `reference`, x.* FROM (
SELECT DATE(m.date) AS `date`, m.depot_uuid, i.uuid,
SUM( IFNULL(m.quantity * IF(m.is_exit = 1, -1, 1), 0)) AS quantity,
SUM(IF(m.is_exit = 0, m.quantity, 0)),
SUM(IF(m.is_exit = 1, m.quantity, 0)), m.is_exit
FROM `stock_movement` m
JOIN lot l ON l.uuid = m.lot_uuid
JOIN inventory i ON i.uuid = l.inventory_uuid
WHERE i.uuid = _inventory_uuid AND m.date <= _end_date AND m.depot_uuid = @depot_uuid
GROUP BY DATE(m.date), m.depot_uuid
ORDER BY `date`
) AS x
ORDER BY x.date;

SET @row_i = 0;
SET _row_uuid = NULL;

SELECT SUM(quantity) AS quantity INTO _qtt
FROM temp_stock_movement m
JOIN inventory i ON i.uuid = m.inventory_uuid
JOIN depot d ON d.uuid = m.depot_uuid
WHERE m.date <=_start_date AND m.depot_uuid = @depot_uuid
LIMIT 1;

SET _qtt = IFNULL(_qtt, 0);

DELETE FROM temp_stock_movement WHERE `date`<=_start_date AND `depot_uuid` = @depot_uuid;

-- check if this date already exist in stock_movement_status for the inventory
SET @date_exists = 0;

SELECT `uuid`, count(`uuid`) as nbr
INTO _row_uuid, @date_exists
FROM `stock_movement_status`
WHERE `depot_uuid` = @depot_uuid AND `inventory_uuid` = _inventory_uuid
AND `start_date` <= _start_date
ORDER BY `start_date` DESC
LIMIT 1;

IF @date_exists = 0 THEN
SET _row_uuid = HUID(uuid());
INSERT INTO `stock_movement_status` VALUES (_row_uuid, _start_date, _start_date, _qtt, 0, 0, _inventory_uuid, _inventory_name, @depot_uuid);
END IF;

SELECT `reference` INTO @row_i
FROM temp_stock_movement
WHERE `date` > _start_date
LIMIT 1;

SET @mvts_number = (SELECT COUNT(*) from temp_stock_movement WHERE `date` > _start_date);
SET @row_number = @row_i + @mvts_number - 1;

SET @row_i = IFNULL(@row_i, 0);

IF @row_i = 0 THEN
UPDATE `stock_movement_status` SET `end_date` = _end_date WHERE `uuid` = _row_uuid;
ELSE
WHILE (@row_i < @row_number + 1) DO
SET _in_qtt = 0;
SET _out_qtt = 0;

SET @current_qtt = 0;
SET @current_date = _start_date;

SELECT m.quantity, m.in_quantity, m.out_quantity, m.date
INTO @current_qtt, _in_qtt, _out_qtt, @current_date
FROM temp_stock_movement m
JOIN inventory i ON i.uuid = m.inventory_uuid
JOIN depot d ON d.uuid = m.depot_uuid
WHERE m.reference = @row_i
GROUP BY m.depot_uuid;
UPDATE `stock_movement_status` SET `end_date` = DATE_SUB(@current_date, INTERVAL 1 DAY) WHERE `uuid` = _row_uuid;
IF @current_qtt <> _qtt THEN
SET _row_uuid = HUID(UUID());
SET _qtt = @current_qtt + _qtt;
INSERT INTO `stock_movement_status` VALUES (_row_uuid, @current_date, @current_date, _qtt, _in_qtt, _out_qtt, _inventory_uuid, _inventory_name, @depot_uuid);
END IF;
SET @row_i= @row_i + 1;
END WHILE;
END IF;

UPDATE `stock_movement_status` SET `end_date` = _end_date WHERE `uuid` = _row_uuid;
SET _qtt = 0;
SET @depot_counter = @depot_counter +1;
SET _row_uuid = NULL;
END WHILE;
END$$

DELIMITER ;

0 comments on commit 5ac6caf

Please sign in to comment.