195 lines
6.1 KiB
MySQL
195 lines
6.1 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`multipleInventory`(
|
||
|
vDate DATE,
|
||
|
vWarehouseFk TINYINT,
|
||
|
vMaxDays TINYINT
|
||
|
)
|
||
|
proc: BEGIN
|
||
|
DECLARE vDateTomorrow DATE DEFAULT vDate + INTERVAL 1 DAY;
|
||
|
DECLARE vDateFrom DATE DEFAULT vDate;
|
||
|
DECLARE vDateTo DATETIME;
|
||
|
DECLARE vDateToTomorrow DATETIME;
|
||
|
DECLARE vDefaultDayRange INT;
|
||
|
|
||
|
IF vDate < util.VN_CURDATE() THEN
|
||
|
LEAVE proc;
|
||
|
END IF;
|
||
|
|
||
|
IF vDate = util.VN_CURDATE() THEN
|
||
|
SELECT inventoried INTO vDateFrom
|
||
|
FROM config;
|
||
|
END IF;
|
||
|
|
||
|
SELECT defaultDayRange INTO vDefaultDayRange
|
||
|
FROM comparativeConfig;
|
||
|
|
||
|
SET vDateTo = vDate + INTERVAL IFNULL(vMaxDays, vDefaultDayRange) DAY;
|
||
|
SET vDateToTomorrow = vDateTo + INTERVAL 1 DAY;
|
||
|
|
||
|
ALTER TABLE tmp.itemInventory
|
||
|
ADD `avalaible` INT NOT NULL,
|
||
|
ADD `sd` INT NOT NULL,
|
||
|
ADD `rest` INT NOT NULL,
|
||
|
ADD `expected` INT NOT NULL,
|
||
|
ADD `inventory` INT NOT NULL,
|
||
|
ADD `visible` INT NOT NULL,
|
||
|
ADD `life` TINYINT NOT NULL DEFAULT '0';
|
||
|
|
||
|
-- Calculo del inventario
|
||
|
UPDATE tmp.itemInventory ai
|
||
|
JOIN (
|
||
|
SELECT itemFk Id_Article, SUM(quantity) Subtotal
|
||
|
FROM (
|
||
|
SELECT s.itemFk, - s.quantity quantity
|
||
|
FROM sale s
|
||
|
JOIN ticket t ON t.id = s.ticketFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseFk
|
||
|
WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDate)
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseFk) = t.warehouseFk
|
||
|
AND w.isComparative
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseInFk
|
||
|
WHERE t.landed BETWEEN vDateFrom AND util.dayEnd(vDate)
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseInFk) = t.warehouseInFk
|
||
|
AND w.isComparative
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, - b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseOutFk
|
||
|
WHERE t.shipped BETWEEN vDateFrom AND util.dayEnd(vDate)
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseOutFk) = t.warehouseOutFk
|
||
|
AND w.isComparative
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
) sub2
|
||
|
GROUP BY itemFk
|
||
|
) sub ON ai.id = sub.Id_Article
|
||
|
SET ai.inventory = sub.Subtotal,
|
||
|
ai.visible = sub.Subtotal,
|
||
|
ai.avalaible = sub.Subtotal,
|
||
|
ai.sd = sub.Subtotal;
|
||
|
|
||
|
-- Cálculo del visible
|
||
|
UPDATE tmp.itemInventory ai
|
||
|
JOIN (
|
||
|
SELECT itemFk Id_Article, SUM(quantity) Subtotal
|
||
|
FROM (
|
||
|
SELECT s.itemFk, s.quantity
|
||
|
FROM sale s
|
||
|
JOIN ticket t ON t.id = s.ticketFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseFk
|
||
|
WHERE t.shipped >= vDate
|
||
|
AND t.shipped < vDateTomorrow
|
||
|
AND (NOT isPicked AND NOT t.isLabeled AND t.refFk IS NULL)
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseFk) = t.warehouseFk
|
||
|
AND w.isComparative
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, - b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseInFk
|
||
|
WHERE t.landed = vDate
|
||
|
AND NOT t.isReceived
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseInFk) = t.warehouseInFk
|
||
|
AND w.isComparative
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseOutFk
|
||
|
WHERE t.shipped = vDate
|
||
|
AND NOT t.isReceived
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseOutFk) = t.warehouseOutFk
|
||
|
AND w.isComparative
|
||
|
) sub2
|
||
|
GROUP BY itemFk
|
||
|
) sub ON ai.id = sub.Id_Article
|
||
|
SET ai.visible = ai.visible + sub.Subtotal;
|
||
|
|
||
|
-- Calculo del disponible
|
||
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
|
||
|
(INDEX (itemFk, warehouseFk))
|
||
|
ENGINE = MEMORY
|
||
|
SELECT sub.itemFk,
|
||
|
vWarehouseFk warehouseFk,
|
||
|
sub.dated,
|
||
|
SUM(sub.quantity) quantity
|
||
|
FROM (
|
||
|
SELECT s.itemFk,
|
||
|
DATE(t.shipped) dated,
|
||
|
- s.quantity quantity
|
||
|
FROM sale s
|
||
|
JOIN ticket t ON t.id = s.ticketFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseFk
|
||
|
WHERE t.shipped BETWEEN vDateTomorrow AND vDateTo
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseFk) = t.warehouseFk
|
||
|
AND w.isComparative
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, t.landed, b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseInFk
|
||
|
WHERE t.landed BETWEEN vDateTomorrow AND vDateTo
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseInFk) = t.warehouseInFk
|
||
|
AND w.isComparative
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
UNION ALL
|
||
|
SELECT b.itemFk, t.shipped, - b.quantity
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseOutFk
|
||
|
WHERE t.shipped BETWEEN vDateTomorrow AND vDateTo
|
||
|
AND IFNULL(vWarehouseFk, t.warehouseOutFk) = t.warehouseOutFk
|
||
|
AND w.isComparative
|
||
|
AND NOT e.isExcludedFromAvailable
|
||
|
AND NOT e.isRaid
|
||
|
) sub
|
||
|
GROUP BY sub.itemFk, sub.dated;
|
||
|
|
||
|
CALL item_getAtp(vDate);
|
||
|
CALL travel_upcomingArrivals(vWarehouseFk, vDate);
|
||
|
|
||
|
UPDATE tmp.itemInventory ai
|
||
|
JOIN (
|
||
|
SELECT it.itemFk,
|
||
|
SUM(it.quantity) quantity,
|
||
|
im.quantity minQuantity
|
||
|
FROM tmp.itemCalc it
|
||
|
JOIN tmp.itemAtp im ON im.itemFk = it.itemFk
|
||
|
JOIN item i ON i.id = it.itemFk
|
||
|
LEFT JOIN origin o ON o.id = i.originFk
|
||
|
LEFT JOIN tmp.itemTravel t ON t.wh = o.warehouseFk
|
||
|
WHERE it.dated < IF(vMaxDays < 0 AND t.landing IS NOT NULL,
|
||
|
t.landing,
|
||
|
vDateToTomorrow)
|
||
|
GROUP BY it.itemFk
|
||
|
) sub ON sub.itemFk = ai.id
|
||
|
SET ai.avalaible = IF(sub.minQuantity > 0,
|
||
|
ai.avalaible,
|
||
|
ai.avalaible + sub.minQuantity),
|
||
|
ai.sd = ai.inventory + sub.quantity;
|
||
|
|
||
|
DROP TEMPORARY TABLE
|
||
|
tmp.itemTravel,
|
||
|
tmp.itemCalc,
|
||
|
tmp.itemAtp;
|
||
|
END$$
|
||
|
DELIMITER ;
|