103 lines
2.8 KiB
SQL
103 lines
2.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getMinacum`(
|
|
vWarehouseFk TINYINT,
|
|
vDated DATE,
|
|
vRange INT,
|
|
vItemFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Cálculo del mínimo acumulado, para un item/almacén
|
|
* especificado, en caso de NULL para todos.
|
|
*
|
|
* @param vWarehouseFk Id warehouse
|
|
* @param vDated Fecha inicio
|
|
* @param vRange Número de días a considerar
|
|
* @param vItemFk Id de artículo
|
|
* @return tmp.itemMinacum
|
|
*/
|
|
DECLARE vDatedTo DATETIME DEFAULT util.dayEnd(vDated + INTERVAL vRange DAY);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
|
|
(INDEX (itemFk, warehouseFk))
|
|
ENGINE = MEMORY
|
|
SELECT sub.itemFk,
|
|
sub.dated,
|
|
CAST(SUM(sub.quantity) AS SIGNED) quantity,
|
|
sub.warehouseFk
|
|
FROM (
|
|
SELECT s.itemFk,
|
|
DATE(t.shipped) dated,
|
|
-s.quantity quantity,
|
|
t.warehouseFk
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
WHERE t.shipped BETWEEN vDated AND vDatedTo
|
|
AND t.warehouseFk
|
|
AND s.quantity <> 0
|
|
AND (vItemFk IS NULL OR s.itemFk = vItemFk)
|
|
AND (vWarehouseFk IS NULL OR t.warehouseFk = vWarehouseFk)
|
|
UNION ALL
|
|
SELECT b.itemFk,
|
|
t.landed,
|
|
b.quantity,
|
|
t.warehouseInFk
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel t ON t.id = e.travelFk
|
|
WHERE t.landed BETWEEN vDated AND vDatedTo
|
|
AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk)
|
|
AND NOT e.isExcludedFromAvailable
|
|
AND b.quantity <> 0
|
|
AND (vItemFk IS NULL OR b.itemFk = vItemFk)
|
|
UNION ALL
|
|
SELECT b.itemFk,
|
|
t.shipped,
|
|
-b.quantity,
|
|
t.warehouseOutFk
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel t ON t.id = e.travelFk
|
|
WHERE t.shipped BETWEEN vDated AND vDatedTo
|
|
AND (vWarehouseFk IS NULL OR t.warehouseOutFk = vWarehouseFk)
|
|
AND NOT e.isExcludedFromAvailable
|
|
AND b.quantity <> 0
|
|
AND (vItemFk IS NULL OR b.itemFk = vItemFk)
|
|
AND NOT t.daysInForward
|
|
UNION ALL
|
|
SELECT r.itemFk,
|
|
r.shipment,
|
|
-r.amount,
|
|
r.warehouseFk
|
|
FROM hedera.orderRow r
|
|
JOIN hedera.`order` o ON o.id = r.orderFk
|
|
JOIN client c ON c.id = o.customer_id
|
|
WHERE r.shipment BETWEEN vDated AND vDatedTo
|
|
AND (vWarehouseFk IS NULL OR r.warehouseFk = vWarehouseFk)
|
|
AND r.created >= (
|
|
SELECT util.VN_NOW() - INTERVAL TIME_TO_SEC(reserveTime) SECOND
|
|
FROM hedera.orderConfig
|
|
)
|
|
AND NOT o.confirmed
|
|
AND (vItemFk IS NULL OR r.itemFk = vItemFk)
|
|
AND r.amount <> 0
|
|
) sub
|
|
GROUP BY sub.itemFk, sub.warehouseFk, sub.dated;
|
|
|
|
CALL item_getAtp(vDated);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemMinacum
|
|
(INDEX(itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT itemFk,
|
|
warehouseFk,
|
|
quantity amount
|
|
FROM tmp.itemAtp
|
|
WHERE quantity <> 0;
|
|
|
|
DROP TEMPORARY TABLE
|
|
tmp.itemAtp,
|
|
tmp.itemCalc;
|
|
END$$
|
|
DELIMITER ;
|