148 lines
4.4 KiB
MySQL
148 lines
4.4 KiB
MySQL
|
DROP procedure IF EXISTS `cache`.`available_refresh`;
|
||
|
|
||
|
DELIMITER $$
|
||
|
CREATE DEFINER=`root`@`%` PROCEDURE `cache`.`available_refresh`(OUT `vCalc` INT, IN `vRefresh` INT, IN `vWarehouse` INT, IN `vDate` 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 vDate < CURDATE() THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
CALL vn2008.item_stock (vWarehouse, vDate, NULL);
|
||
|
|
||
|
SET vParams = CONCAT_WS('/', vWarehouse, vDate);
|
||
|
CALL cache_calc_start (vCalc, vRefresh, 'available', vParams);
|
||
|
|
||
|
IF !vRefresh THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
-- Calcula algunos parámetros necesarios
|
||
|
|
||
|
SET vStartDate = TIMESTAMP(vDate, '00:00:00');
|
||
|
SET vEndDate = TIMESTAMP(TIMESTAMPADD(DAY, 4, vDate), '23:59:59');
|
||
|
|
||
|
SELECT FechaInventario INTO vInventoryDate FROM vn2008.tblContadores;
|
||
|
|
||
|
SELECT SUBTIME(NOW(), reserveTime) INTO vReserveDate
|
||
|
FROM hedera.orderConfig;
|
||
|
|
||
|
-- Calcula el ultimo dia de vida para cada producto
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS item_range;
|
||
|
CREATE TEMPORARY TABLE item_range
|
||
|
(PRIMARY KEY (item_id))
|
||
|
ENGINE = MEMORY
|
||
|
SELECT c.item_id, IF(t.life IS NULL, NULL,
|
||
|
TIMESTAMP(TIMESTAMPADD(DAY, t.life, c.landing), '23:59:59')) AS date_end
|
||
|
FROM (
|
||
|
SELECT c.Id_Article item_id, MAX(landing) landing
|
||
|
FROM vn2008.Compres c
|
||
|
JOIN vn2008.Entradas e ON c.Id_Entrada = e.Id_Entrada
|
||
|
JOIN vn2008.travel t ON t.id = e.travel_id
|
||
|
JOIN vn2008.warehouse w ON w.id = t.warehouse_id
|
||
|
WHERE t.landing BETWEEN vInventoryDate AND vStartDate
|
||
|
AND t.warehouse_id = vWarehouse
|
||
|
AND NOT e.Inventario
|
||
|
AND NOT e.Redada
|
||
|
GROUP BY Id_Article
|
||
|
) c
|
||
|
JOIN vn2008.Articles a ON a.Id_Article = c.item_id
|
||
|
JOIN vn2008.Tipos t ON t.tipo_id = a.tipo_id
|
||
|
HAVING date_end >= vStartDate OR date_end IS NULL;
|
||
|
|
||
|
-- Replica la tabla item_range para poder usarla varias veces en la misma consulta
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS item_range_copy1;
|
||
|
CREATE TEMPORARY TABLE item_range_copy1 LIKE item_range;
|
||
|
INSERT INTO item_range_copy1
|
||
|
SELECT * FROM item_range;
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS item_range_copy2;
|
||
|
CREATE TEMPORARY TABLE item_range_copy2 LIKE item_range;
|
||
|
INSERT INTO item_range_copy2
|
||
|
SELECT * FROM item_range;
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS item_range_copy3;
|
||
|
CREATE TEMPORARY TABLE item_range_copy3 LIKE item_range;
|
||
|
INSERT INTO item_range_copy3
|
||
|
SELECT * FROM item_range;
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS item_range_copy4;
|
||
|
CREATE TEMPORARY TABLE item_range_copy4 LIKE item_range;
|
||
|
INSERT INTO item_range_copy4
|
||
|
SELECT * FROM item_range;
|
||
|
|
||
|
-- Calcula el ATP
|
||
|
|
||
|
DELETE FROM available WHERE calc_id = vCalc;
|
||
|
|
||
|
INSERT INTO available (calc_id, item_id, available)
|
||
|
SELECT vCalc, t.item_id, SUM(stock) amount FROM (
|
||
|
SELECT ti.item_id, stock
|
||
|
FROM vn2008.tmp_item ti
|
||
|
JOIN item_range ir ON ir.item_id = ti.item_id
|
||
|
UNION ALL
|
||
|
SELECT t.item_id, minacum(dt, amount, vDate) AS available FROM (
|
||
|
SELECT item_id, DATE(dat) dt, SUM(amount) amount FROM (
|
||
|
SELECT i.item_id, i.dat, i.amount
|
||
|
FROM vn2008.item_out i
|
||
|
JOIN item_range_copy1 ir ON ir.item_id = i.item_id
|
||
|
WHERE i.dat >= vStartDate
|
||
|
AND (ir.date_end IS NULL OR i.dat <= ir.date_end)
|
||
|
AND i.warehouse_id = vWarehouse
|
||
|
UNION ALL
|
||
|
SELECT i.item_id, i.dat, i.amount
|
||
|
FROM vn2008.item_entry_in i
|
||
|
JOIN item_range_copy2 ir ON ir.item_id = i.item_id
|
||
|
WHERE i.dat >= vStartDate
|
||
|
AND (ir.date_end IS NULL OR i.dat <= ir.date_end)
|
||
|
AND i.warehouse_id = vWarehouse
|
||
|
UNION ALL
|
||
|
SELECT i.item_id, i.dat, i.amount
|
||
|
FROM vn2008.item_entry_out i
|
||
|
JOIN item_range_copy3 ir ON ir.item_id = i.item_id
|
||
|
WHERE i.dat >= vStartDate
|
||
|
AND (ir.date_end IS NULL OR i.dat <= ir.date_end)
|
||
|
AND i.warehouse_id = 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 item_range_copy4 ir ON ir.item_id = r.item_id
|
||
|
WHERE r.shipment >= vStartDate
|
||
|
AND (ir.date_end IS NULL OR r.shipment <= ir.date_end)
|
||
|
AND r.warehouse_id = vWarehouse
|
||
|
AND r.created >= vReserveDate
|
||
|
AND NOT o.confirmed
|
||
|
) t
|
||
|
GROUP BY item_id, dt
|
||
|
) t
|
||
|
GROUP BY t.item_id
|
||
|
) t GROUP BY t.item_id;
|
||
|
|
||
|
DROP TEMPORARY TABLE
|
||
|
vn2008.tmp_item
|
||
|
,item_range
|
||
|
,item_range_copy1
|
||
|
,item_range_copy2
|
||
|
,item_range_copy3
|
||
|
,item_range_copy4;
|
||
|
|
||
|
CALL cache_calc_end (vCalc);
|
||
|
END$$
|
||
|
|
||
|
DELIMITER ;
|
||
|
|