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

174 lines
5.1 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`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;
DECLARE vCalcFk 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
CREATE OR REPLACE TEMPORARY TABLE tItemInventoryCalc
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
SELECT itemFk,
SUM(quantity) quantity
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 t.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 t.isRaid
) sub
GROUP BY itemFk;
-- Cálculo del visible
CALL cache.visible_refresh(vCalcFk, FALSE, vWarehouseFk);
CREATE OR REPLACE TEMPORARY TABLE tItemVisibleCalc
(PRIMARY KEY (item_id))
ENGINE = MEMORY
SELECT item_id, visible
FROM cache.visible
WHERE calc_id = vCalcFk;
UPDATE tmp.itemInventory it
LEFT JOIN tItemInventoryCalc iic ON iic.itemFk = it.id
LEFT JOIN tItemVisibleCalc ivc ON ivc.item_id = it.id
SET it.inventory = iic.quantity,
it.visible = ivc.visible,
it.avalaible = iic.quantity,
it.sd = iic.quantity;
-- 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 t.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 t.isRaid
) sub
GROUP BY sub.itemFk, sub.dated;
CALL item_getAtp(vDate);
CALL travel_upcomingArrivals(vWarehouseFk, vDate);
CREATE OR REPLACE TEMPORARY TABLE tItemAvailableCalc
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
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;
UPDATE tmp.itemInventory it
JOIN tItemAvailableCalc iac ON iac.itemFk = it.id
SET it.avalaible = IF(iac.minQuantity > 0,
it.avalaible,
it.avalaible + iac.minQuantity),
it.sd = it.inventory + iac.quantity;
DROP TEMPORARY TABLE
tmp.itemTravel,
tmp.itemCalc,
tmp.itemAtp,
tItemInventoryCalc,
tItemVisibleCalc,
tItemAvailableCalc;
END$$
DELIMITER ;