124 lines
3.8 KiB
MySQL
124 lines
3.8 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `cache`.`availableNoRaids_refresh`(OUT `vCalc` INT, IN `vRefresh` INT, IN `vWarehouse` INT, IN `vDated` DATE)
|
||
|
proc: BEGIN
|
||
|
DECLARE vStartDate DATE;
|
||
|
DECLARE vEndDate DATETIME;
|
||
|
DECLARE vReserveDate DATETIME;
|
||
|
DECLARE vParams CHAR(100);
|
||
|
DECLARE vInventoryDate DATE;
|
||
|
|
||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||
|
BEGIN
|
||
|
CALL cache_calc_unlock (vCalc);
|
||
|
RESIGNAL;
|
||
|
END;
|
||
|
|
||
|
IF vDated < util.VN_CURDATE() THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
SET vParams = CONCAT_WS('/', vWarehouse, vDated);
|
||
|
CALL vn.item_getStock (vWarehouse, vDated, NULL);
|
||
|
CALL cache_calc_start (vCalc, vRefresh, 'availableNoRaids', vParams);
|
||
|
|
||
|
IF !vRefresh THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
-- Calcula algunos parametros necesarios
|
||
|
|
||
|
SET vStartDate = TIMESTAMP(vDated, '00:00:00');
|
||
|
SET vEndDate = TIMESTAMP(TIMESTAMPADD(DAY, 4, vDated), '23:59:59');
|
||
|
|
||
|
SELECT inventoried INTO vInventoryDate FROM vn.config;
|
||
|
|
||
|
SELECT SUBTIME(util.VN_NOW(), reserveTime) INTO vReserveDate
|
||
|
FROM hedera.orderConfig;
|
||
|
|
||
|
-- Calcula el ultimo dia de vida para cada producto
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS tItemRange;
|
||
|
CREATE TEMPORARY TABLE tItemRange
|
||
|
(PRIMARY KEY (itemFk))
|
||
|
ENGINE = MEMORY
|
||
|
SELECT c.itemFk, IF(it.life IS NULL, NULL,
|
||
|
TIMESTAMP(TIMESTAMPADD(DAY, it.life, c.landing), '23:59:59')) AS ended
|
||
|
FROM (
|
||
|
SELECT b.itemFk, MAX(t.landed) landing
|
||
|
FROM vn.buy b
|
||
|
JOIN vn.entry e ON b.entryFk = e.id
|
||
|
JOIN vn.travel t ON t.id = e.travelFk
|
||
|
JOIN vn.warehouse w ON w.id = t.warehouseInFk
|
||
|
JOIN vn.supplier s ON s.id = e.supplierFk
|
||
|
WHERE t.landed BETWEEN vInventoryDate AND vStartDate
|
||
|
AND t.warehouseInFk = vWarehouse
|
||
|
AND s.name != 'INVENTARIO'
|
||
|
AND NOT e.isRaid
|
||
|
GROUP BY b.itemFk
|
||
|
) c
|
||
|
JOIN vn.item i ON i.id = c.itemFk
|
||
|
JOIN vn.itemType it ON it.id = i.typeFk
|
||
|
HAVING ended >= vStartDate OR ended IS NULL;
|
||
|
|
||
|
-- Calcula el ATP
|
||
|
|
||
|
DELETE FROM availableNoRaids WHERE calc_id = vCalc;
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc;
|
||
|
CREATE TEMPORARY TABLE tmp.itemCalc
|
||
|
(INDEX (itemFk, warehouseFk))
|
||
|
SELECT itemFk, vWarehouse warehouseFk, DATE(dated) dated, SUM(quantity) quantity
|
||
|
FROM (
|
||
|
SELECT i.itemFk, i.shipped dated, i.quantity
|
||
|
FROM vn.itemTicketOut i
|
||
|
JOIN tItemRange ir ON ir.itemFk = i.itemFk
|
||
|
WHERE i.shipped >= vStartDate
|
||
|
AND (ir.ended IS NULL OR i.shipped <= ir.ended)
|
||
|
AND i.warehouseFk = vWarehouse
|
||
|
UNION ALL
|
||
|
SELECT i.itemFk, i.landed, i.quantity
|
||
|
FROM vn.itemEntryIn i
|
||
|
JOIN tItemRange ir ON ir.itemFk = i.itemFk
|
||
|
WHERE i.landed >= vStartDate
|
||
|
AND (ir.ended IS NULL OR i.landed <= ir.ended)
|
||
|
AND i.warehouseInFk = vWarehouse
|
||
|
AND i.isVirtualStock = FALSE
|
||
|
UNION ALL
|
||
|
SELECT i.itemFk, i.shipped, i.quantity
|
||
|
FROM vn.itemEntryOut i
|
||
|
JOIN tItemRange ir ON ir.itemFk = i.itemFk
|
||
|
WHERE i.shipped >= vStartDate
|
||
|
AND (ir.ended IS NULL OR i.shipped <= ir.ended)
|
||
|
AND i.warehouseOutFk = vWarehouse
|
||
|
UNION ALL
|
||
|
SELECT r.item_id, r.shipment, -r.amount
|
||
|
FROM hedera.order_row r
|
||
|
JOIN hedera.`order` o ON o.id = r.order_id
|
||
|
JOIN tItemRange ir ON ir.itemFk = r.item_id
|
||
|
WHERE r.shipment >= vStartDate
|
||
|
AND (ir.ended IS NULL OR r.shipment <= ir.ended)
|
||
|
AND r.warehouse_id = vWarehouse
|
||
|
AND r.created >= vReserveDate
|
||
|
AND NOT o.confirmed
|
||
|
) t
|
||
|
GROUP BY itemFk, dated;
|
||
|
|
||
|
CALL vn.item_getAtp(vDated);
|
||
|
|
||
|
INSERT INTO availableNoRaids (calc_id, item_id, available)
|
||
|
SELECT vCalc, sub.itemFk, SUM(sub.quantity)
|
||
|
FROM (
|
||
|
SELECT il.itemFk, stock quantity
|
||
|
FROM tmp.itemList il
|
||
|
JOIN tItemRange ir ON ir.itemFk = il.itemFk
|
||
|
UNION ALL
|
||
|
SELECT itemFk, quantity
|
||
|
FROM tmp.itemAtp
|
||
|
)sub
|
||
|
GROUP BY sub.itemFk;
|
||
|
|
||
|
DROP TEMPORARY TABLE tmp.itemCalc, tItemRange;
|
||
|
CALL cache_calc_end (vCalc);
|
||
|
END$$
|
||
|
DELIMITER ;
|