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

80 lines
2.4 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getMinacum`(IN vWarehouseFk TINYINT, IN vDatedFrom DATETIME, IN vRange INT, IN vItemFk INT)
BEGIN
/**
* Cálculo del mínimo acumulado, para un item/almacén especificado, en caso de
* NULL para todo.
*
* @param vWarehouseFk -> warehouseFk
* @param vDatedFrom -> fecha inicio
* @param vRange -> número de días a considerar
* @param vItemFk -> Identificador de item
* @return tmp.itemMinacum
*/
DECLARE vDatedTo DATETIME;
SET vDatedFrom = TIMESTAMP(DATE(vDatedFrom), '00:00:00');
SET vDatedTo = TIMESTAMP(TIMESTAMPADD(DAY, vRange, vDatedFrom), '23:59:59');
DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc;
CREATE TEMPORARY TABLE tmp.itemCalc
(INDEX (itemFk, warehouseFk))
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 vDatedFrom AND vDatedTo
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
LEFT JOIN travel t ON t.id = e.travelFk
WHERE t.landed BETWEEN vDatedFrom AND vDatedTo
AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk)
AND !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
LEFT JOIN travel t ON t.id = e.travelFk
WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo
AND (vWarehouseFk IS NULL OR t.warehouseOutFk = vWarehouseFk)
AND !e.isExcludedFromAvailable
AND b.quantity != 0
AND (vItemFk IS NULL OR b.itemFk = vItemFk)
AND !e.isRaid
) sub
GROUP BY sub.itemFk, sub.warehouseFk, sub.dated;
CALL item_getAtp(vDatedFrom);
DROP TEMPORARY TABLE tmp.itemCalc;
DROP TEMPORARY TABLE IF EXISTS tmp.itemMinacum;
CREATE TEMPORARY TABLE tmp.itemMinacum
(INDEX(itemFk))
ENGINE = MEMORY
SELECT i.itemFk,
i.warehouseFk,
i.quantity amount
FROM tmp.itemAtp i
HAVING amount != 0;
END$$
DELIMITER ;