salix/db/routines/vn/procedures/item_getAtp.sql

50 lines
1.5 KiB
MySQL
Raw Normal View History

2024-06-14 11:54:43 +00:00
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getAtp`(vDated DATE)
BEGIN
/**
* Calcula el valor mínimo acumulado para cada artículo ordenado por fecha y
* almacén.
*
* @param vDated Si no hay movimientos en la fecha indicada, debe devolver 0
* @table tmp.itemCalc(itemFk, wareHouseFk, dated, quantity)
* @return tmp.itemAtp(itemFk, warehouseFk, quantity)
*/
CREATE OR REPLACE TEMPORARY TABLE tItemOrdered
(UNIQUE(itemFk, warehouseFk, dated))
ENGINE = MEMORY
SELECT itemFk, warehouseFk, dated, SUM(quantity) quantity
FROM (
SELECT itemFk, warehouseFk, dated, quantity
FROM tmp.itemCalc
UNION ALL
SELECT itemFk, warehouseFk, vDated, 0
FROM (SELECT DISTINCT itemFk, warehouseFk FROM tmp.itemCalc) t2
) t1
2024-06-14 12:55:03 +00:00
GROUP BY itemFk, warehouseFk, dated;
2024-06-14 12:55:03 +00:00
SET @lastItemFk = 0;
SET @lastWareHouseFk = 0;
SET @lastQuantity = 0;
CREATE OR REPLACE TEMPORARY TABLE tmp.itemAtp
(INDEX (itemFk, wareHouseFk))
SELECT itemFk, wareHouseFk, MIN(quantityAccumulated) quantity
FROM (
SELECT
itemFk,
2024-06-14 11:54:43 +00:00
IF(itemFk <> @lastItemFk OR wareHouseFk <> @lastWareHouseFk OR wareHouseFk IS NULL,
@lastQuantity := quantity,
@lastQuantity := @lastQuantity + quantity) quantityAccumulated,
wareHouseFk,
@lastItemFk := itemFk,
@lastWareHouseFk := wareHouseFk
FROM tItemOrdered
2024-06-14 12:55:03 +00:00
ORDER BY itemFk, warehouseFk, dated
LIMIT 10000000000000000000
)sub
GROUP BY itemFk, wareHouseFk;
DROP TEMPORARY TABLE tItemOrdered;
2024-06-14 11:54:43 +00:00
END$$
DELIMITER ;