2024-01-15 11:31:03 +00:00
|
|
|
DELIMITER $$
|
2024-02-06 07:15:25 +00:00
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingRadar`(
|
|
|
|
vSectorFk INT
|
|
|
|
)
|
2024-01-15 11:31:03 +00:00
|
|
|
proc:BEGIN
|
2024-02-06 07:15:25 +00:00
|
|
|
/**
|
|
|
|
* Calcula la información detallada respecto un sector.
|
|
|
|
*
|
|
|
|
* @param vSectorFk Id de sector
|
|
|
|
*/
|
2024-01-15 11:31:03 +00:00
|
|
|
DECLARE vCalcVisibleFk INT;
|
|
|
|
DECLARE vCalcAvailableFk INT;
|
|
|
|
DECLARE hasFatherSector BOOLEAN;
|
|
|
|
DECLARE vBuyerFk INT DEFAULT 0;
|
|
|
|
DECLARE vWarehouseFk INT DEFAULT 0;
|
|
|
|
DECLARE vSonSectorFk INT;
|
|
|
|
DECLARE vWorkerFk INT;
|
|
|
|
|
|
|
|
SELECT s.workerFk
|
|
|
|
INTO vWorkerFk
|
|
|
|
FROM vn.sector s
|
|
|
|
WHERE s.id = vSectorFk;
|
|
|
|
|
|
|
|
SELECT w.id, s.warehouseFk INTO vBuyerFk, vWarehouseFk
|
|
|
|
FROM vn.worker w
|
|
|
|
JOIN vn.sector s ON s.code = w.code
|
|
|
|
WHERE s.id = vSectorFk;
|
|
|
|
|
|
|
|
SELECT s.id INTO vSectorFk
|
|
|
|
FROM vn.sector s
|
|
|
|
WHERE s.warehouseFk = vWarehouseFk
|
|
|
|
AND s.isMain;
|
|
|
|
|
|
|
|
SELECT COUNT(*) INTO hasFatherSector
|
|
|
|
FROM vn.sector
|
|
|
|
WHERE sonFk = vSectorFk;
|
|
|
|
|
|
|
|
SELECT warehouseFk, sonFk INTO vWarehouseFk, vSonSectorFk
|
|
|
|
FROM vn.sector
|
|
|
|
WHERE id = vSectorFk;
|
|
|
|
|
|
|
|
CALL cache.visible_refresh(vCalcVisibleFk, TRUE, vWarehouseFk);
|
|
|
|
CALL cache.available_refresh(vCalcAvailableFk, FALSE, vWarehouseFk, util.VN_CURDATE());
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemShelvingRadar;
|
|
|
|
|
|
|
|
IF hasFatherSector THEN
|
|
|
|
CREATE TEMPORARY TABLE tmp.itemShelvingRadar
|
|
|
|
(PRIMARY KEY (itemFk))
|
|
|
|
ENGINE = MEMORY
|
|
|
|
SELECT *
|
|
|
|
FROM (
|
|
|
|
SELECT iss.itemFk,
|
|
|
|
i.longName,
|
|
|
|
i.size,
|
|
|
|
i.subName producer,
|
|
|
|
IFNULL(a.available,0) available,
|
|
|
|
SUM(IF(s.sonFk = vSectorFk, IFNULL(iss.visible,0), 0)) upstairs,
|
|
|
|
SUM(IF(iss.sectorFk = vSectorFk, IFNULL(iss.visible,0), 0)) downstairs,
|
|
|
|
IF(it.isPackaging, NULL, IFNULL(v.visible,0)) as visible,
|
|
|
|
vSectorFk sectorFk
|
|
|
|
FROM vn.itemShelvingStock iss
|
|
|
|
JOIN vn.sector s ON s.id = iss.sectorFk
|
|
|
|
JOIN vn.item i on i.id = iss.itemFk
|
|
|
|
JOIN vn.itemType it ON it.id = i.typeFk AND vBuyerFk IN (0,it.workerFk)
|
|
|
|
LEFT JOIN cache.available a ON a.item_id = iss.itemFk AND a.calc_id = vCalcAvailableFk
|
|
|
|
LEFT JOIN cache.visible v ON v.item_id = iss.itemFk AND v.calc_id = vCalcVisibleFk
|
|
|
|
WHERE vSectorFk IN (iss.sectorFk, s.sonFk)
|
|
|
|
GROUP BY iss.itemFk
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
SELECT v.item_id,
|
|
|
|
i.longName,
|
|
|
|
i.size,
|
|
|
|
i.subName producer,
|
|
|
|
IFNULL(a.available,0) as available,
|
|
|
|
0 upstairs,
|
|
|
|
0 downstairs,
|
|
|
|
IF(it.isPackaging, NULL, v.visible) visible,
|
|
|
|
vSectorFk as sectorFk
|
|
|
|
FROM cache.visible v
|
|
|
|
JOIN vn.item i on i.id = v.item_id
|
|
|
|
JOIN vn.itemType it ON it.id = i.typeFk AND vBuyerFk IN (0,it.workerFk)
|
|
|
|
LEFT JOIN vn.itemShelvingStock iss ON iss.itemFk = v.item_id AND iss.warehouseFk = vWarehouseFk
|
|
|
|
LEFT JOIN cache.available a ON a.item_id = v.item_id AND a.calc_id = vCalcAvailableFk
|
|
|
|
WHERE v.calc_id = vCalcVisibleFk
|
|
|
|
AND iss.itemFk IS NULL
|
|
|
|
AND it.isInventory
|
|
|
|
) sub GROUP BY itemFk;
|
|
|
|
|
|
|
|
SELECT ishr.*,
|
|
|
|
CAST(visible - upstairs - downstairs AS DECIMAL(10,0)) AS nicho,
|
|
|
|
CAST(downstairs - IFNULL(notPickedYed,0) AS DECIMAL(10,0)) as pendiente
|
|
|
|
FROM tmp.itemShelvingRadar ishr
|
|
|
|
JOIN vn.item i ON i.id = ishr.itemFk
|
|
|
|
LEFT JOIN (SELECT s.itemFk, sum(s.quantity) as notPickedYed
|
|
|
|
FROM vn.ticket t
|
|
|
|
JOIN vn.ticketStateToday tst ON tst.ticketFk = t.id
|
|
|
|
JOIN vn.sale s ON s.ticketFk = t.id
|
|
|
|
WHERE t.warehouseFk = vWarehouseFk
|
|
|
|
AND tst.alertLevel = 0
|
|
|
|
GROUP BY s.itemFk
|
|
|
|
) sub ON sub.itemFk = ishr.itemFk
|
|
|
|
ORDER BY i.typeFk, i.longName;
|
|
|
|
ELSE
|
|
|
|
CREATE TEMPORARY TABLE tmp.itemShelvingRadar
|
|
|
|
(PRIMARY KEY (itemFk))
|
|
|
|
ENGINE = MEMORY
|
|
|
|
SELECT iss.itemFk,
|
|
|
|
0 `hour`,
|
|
|
|
0 `minute`,
|
|
|
|
'--' itemPlacementCode,
|
|
|
|
i.longName,
|
|
|
|
i.size,
|
|
|
|
i.subName producer,
|
|
|
|
i.upToDown,
|
|
|
|
IFNULL(a.available,0) available,
|
|
|
|
IFNULL(v.visible - iss.visible,0) dayEndVisible,
|
|
|
|
IFNULL(v.visible - iss.visible,0) firstNegative,
|
|
|
|
IFNULL(v.visible - iss.visible,0) itemPlacementVisible,
|
|
|
|
IFNULL(i.minimum * b.packing,0) itemPlacementSize,
|
|
|
|
ips.onTheWay,
|
|
|
|
iss.visible itemShelvingStock,
|
|
|
|
IFNULL(v.visible,0) visible,
|
|
|
|
b.isPickedOff,
|
|
|
|
iss.sectorFk
|
|
|
|
FROM vn.itemShelvingStock iss
|
|
|
|
JOIN vn.item i on i.id = iss.itemFk
|
|
|
|
LEFT JOIN cache.last_buy lb ON lb.item_id = iss.itemFk AND lb.warehouse_id = vWarehouseFk
|
|
|
|
LEFT JOIN vn.buy b ON b.id = lb.buy_id
|
|
|
|
LEFT JOIN cache.available a ON a.item_id = iss.itemFk AND a.calc_id = vCalcAvailableFk
|
|
|
|
LEFT JOIN cache.visible v ON v.item_id = iss.itemFk AND v.calc_id = vCalcVisibleFk
|
|
|
|
LEFT JOIN (SELECT itemFk, sum(saldo) as onTheWay
|
|
|
|
FROM vn.itemPlacementSupplyList
|
|
|
|
WHERE saldo > 0
|
|
|
|
GROUP BY itemFk
|
|
|
|
) ips ON ips.itemFk = i.id
|
|
|
|
WHERE IFNULL(iss.sectorFk,0) IN (0, vSectorFk)
|
|
|
|
OR iss.sectorFk = vSectorFk;
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemOutTime;
|
|
|
|
CREATE TEMPORARY TABLE tmp.itemOutTime
|
|
|
|
SELECT *,SUM(amount) quantity
|
|
|
|
FROM
|
|
|
|
(SELECT item_id itemFk,
|
|
|
|
amount,
|
|
|
|
IF(HOUR(t.shipped), HOUR(t.shipped), HOUR(z.`hour`)) as hours,
|
|
|
|
IF(MINUTE(t.shipped), MINUTE(t.shipped), MINUTE(z.`hour`)) as minutes
|
|
|
|
FROM vn2008.item_out io
|
|
|
|
JOIN tmp.itemShelvingRadar isr ON isr.itemFk = io.item_id
|
|
|
|
JOIN vn.ticket t on t.id= io.ticketFk
|
|
|
|
JOIN vn.ticketState ts on ts.ticketFk = io.ticketFk
|
|
|
|
JOIN vn.state s ON s.id = ts.stateFk
|
|
|
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
|
|
|
LEFT JOIN (SELECT DISTINCT saleFk
|
|
|
|
FROM vn.saleTracking st
|
|
|
|
WHERE st.created > util.VN_CURDATE()
|
|
|
|
AND st.isChecked
|
|
|
|
) stPrevious ON `stPrevious`.`saleFk` = io.saleFk
|
|
|
|
WHERE t.warehouseFk = vWarehouseFk
|
|
|
|
AND s.isPicked = 0
|
|
|
|
AND NOT io.Reservado
|
|
|
|
AND stPrevious.saleFk IS NULL
|
|
|
|
AND io.dat >= util.VN_CURDATE()
|
|
|
|
AND io.dat < util.VN_CURDATE() + INTERVAL 1 DAY
|
|
|
|
) sub
|
|
|
|
GROUP BY itemFk, hours, minutes;
|
|
|
|
|
|
|
|
INSERT INTO tmp.itemShelvingRadar (itemFk)
|
|
|
|
SELECT itemFk FROM tmp.itemOutTime
|
|
|
|
ON DUPLICATE KEY UPDATE dayEndVisible = dayEndVisible + quantity,
|
|
|
|
firstNegative = if (firstNegative < 0, firstNegative, firstNegative + quantity),
|
|
|
|
`hour` = ifnull(if (firstNegative > 0 , `hour`, hours),0),
|
|
|
|
`minute` = ifnull(if (firstNegative > 0, `minute`, minutes),0);
|
|
|
|
|
|
|
|
UPDATE tmp.itemShelvingRadar isr
|
|
|
|
JOIN (SELECT s.itemFk, sum(s.quantity) amount
|
|
|
|
FROM sale s
|
|
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
|
|
JOIN ticketLastState tls ON tls.ticketFk = t.id
|
|
|
|
WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE())
|
|
|
|
AND tls.name = 'Prep Camara'
|
|
|
|
GROUP BY s.itemFk) sub ON sub.itemFk = isr.itemFk
|
|
|
|
SET isr.dayEndVisible = dayEndVisible + sub.amount,
|
|
|
|
firstNegative = firstNegative + sub.amount;
|
|
|
|
|
|
|
|
SELECT * FROM tmp.itemShelvingRadar;
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.itemShelvingRadar;
|
|
|
|
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|