salix/db/routines/cache/procedures/available_refresh.sql

128 lines
4.0 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `cache`.`available_refresh`(OUT `vCalc` INT, IN `vRefresh` INT, IN `vWarehouse` INT, IN `vDated` DATE)
proc: BEGIN
DECLARE vStartDate DATE;
DECLARE vReserveDate DATETIME;
DECLARE vParams CHAR(100);
DECLARE vInventoryDate DATE;
DECLARE vLifeScope DATE;
DECLARE vWarehouseFkInventory INT;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
CALL cache_calc_unlock (vCalc);
RESIGNAL;
END;
IF vDated < util.VN_CURDATE() THEN
LEAVE proc;
END IF;
CALL vn.item_getStock(vWarehouse, vDated, NULL);
SET vParams = CONCAT_WS('/', vWarehouse, vDated);
CALL cache_calc_start (vCalc, vRefresh, 'available', vParams);
IF !vRefresh THEN
LEAVE proc;
END IF;
-- Calcula algunos parámetros necesarios
SET vStartDate = TIMESTAMP(vDated, '00:00:00');
SELECT inventoried INTO vInventoryDate FROM vn.config;
SELECT DATE_SUB(vStartDate, INTERVAL MAX(life) DAY) INTO vLifeScope FROM vn.itemType;
SELECT SUBTIME(util.VN_NOW(), reserveTime) INTO vReserveDate
FROM hedera.orderConfig;
SELECT w.id INTO vWarehouseFkInventory
FROM vn.warehouse w
WHERE w.code = 'inv';
-- Calcula el ultimo dia de vida para cada producto
DROP TEMPORARY TABLE IF EXISTS itemRange;
CREATE TEMPORARY TABLE itemRange
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
SELECT i.id itemFk,
util.dayEnd(DATE_ADD(c.maxLanded, INTERVAL it.life DAY)) ended, it.life
FROM vn.item i
LEFT JOIN (
SELECT b.itemFk, MAX(t.landed) maxLanded
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.item i ON i.id = b.itemFk
JOIN vn.itemType it ON it.id = i.typeFk
WHERE t.landed BETWEEN vLifeScope AND vStartDate
AND t.warehouseInFk = vWarehouse
AND t.warehouseOutFk <> vWarehouseFkInventory
AND it.life
AND NOT e.isExcludedFromAvailable
GROUP BY b.itemFk
) c ON i.id = c.itemFk
JOIN vn.itemType it ON it.id = i.typeFk
HAVING ended >= vStartDate OR life IS NULL;
-- Calcula el ATP
DELETE FROM available WHERE calc_id = vCalc;
DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc;
CREATE TEMPORARY TABLE tmp.itemCalc
(INDEX (itemFk,warehouseFk))
ENGINE = MEMORY
SELECT itemFk, vWarehouse warehouseFk, DATE(dated) dated, SUM(quantity) quantity
FROM (SELECT i.itemFk, i.shipped dated, i.quantity
FROM vn.itemTicketOut i
JOIN itemRange 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 itemRange ir ON ir.itemFk = i.itemFk
LEFT JOIN edi.warehouseFloramondo wf ON wf.entryFk = i.entryFk
WHERE i.landed >= vStartDate
AND (ir.ended IS NULL OR i.landed <= ir.ended)
AND i.warehouseInFk = vWarehouse
AND ISNULL(wf.entryFk)
UNION ALL
SELECT i.itemFk, i.shipped, i.quantity
FROM vn.itemEntryOut i
JOIN itemRange 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 itemRange 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 available (calc_id, item_id, available)
SELECT vCalc, sub.itemFk, SUM(sub.quantity)
FROM (
SELECT ir.itemFk, stock quantity
FROM tmp.itemList il
JOIN itemRange ir ON ir.itemFk = il.itemFk
UNION ALL
SELECT itemFk, quantity
FROM tmp.itemAtp
)sub
GROUP BY sub.itemFk;
DROP TEMPORARY TABLE tmp.itemCalc, itemRange;
CALL cache_calc_end (vCalc);
END$$
DELIMITER ;