DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemShelvingRadar`( vSectorFk INT ) BEGIN /** * Calcula la informaciĆ³n detallada respecto un sector. * * @param vSectorFk Id de sector */ 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 sector s WHERE s.id = vSectorFk; SELECT COUNT(*) INTO hasFatherSector FROM sector WHERE sonFk = vSectorFk; SELECT warehouseFk, sonFk INTO vWarehouseFk, vSonSectorFk FROM sector WHERE id = vSectorFk; CALL cache.visible_refresh(vCalcVisibleFk, TRUE, vWarehouseFk); CALL cache.available_refresh(vCalcAvailableFk, FALSE, vWarehouseFk, util.VN_CURDATE()); IF hasFatherSector THEN CREATE OR REPLACE TEMPORARY TABLE tItemShelvingRadar (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)) visible, vSectorFk sectorFk, ish.isChecked, sub.isAllChecked FROM itemShelvingStock iss JOIN itemShelving ish ON ish.id = iss.itemShelvingFk LEFT JOIN ( SELECT itemFk, IF( COUNT(*) = SUM(IF(isChecked >= 0, 1, 0)), TRUE, FALSE ) isAllChecked FROM itemShelving is2 GROUP BY itemFk ) sub ON sub.itemFk = ish.itemFk JOIN sector s ON s.id = iss.sectorFk JOIN item i ON i.id = iss.itemFk JOIN itemType it ON it.id = i.typeFk 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, IFNULL(a.available, 0), 0, 0, IF(it.isPackaging, NULL, v.visible), vSectorFk, NULL, NULL FROM cache.visible v JOIN item i ON i.id = v.item_id JOIN itemType it ON it.id = i.typeFk LEFT JOIN 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)) nicho, CAST(downstairs - IFNULL(notPickedYed, 0) AS DECIMAL(10, 0)) pendiente FROM tItemShelvingRadar ishr JOIN item i ON i.id = ishr.itemFk LEFT JOIN ( SELECT s.itemFk, SUM(s.quantity) notPickedYed FROM ticket t JOIN ticketStateToday tst ON tst.ticketFk = t.id JOIN alertLevel al ON al.id = tst.alertLevel JOIN sale s ON s.ticketFk = t.id WHERE t.warehouseFk = vWarehouseFk AND al.code = 'FREE' GROUP BY s.itemFk ) sub ON sub.itemFk = ishr.itemFk ORDER BY i.typeFk, i.longName; ELSE CREATE OR REPLACE TEMPORARY TABLE tItemShelvingRadar (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 itemShelvingStock iss JOIN 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 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) onTheWay FROM itemPlacementSupplyList WHERE saldo > 0 GROUP BY itemFk ) ips ON ips.itemFk = i.id WHERE iss.sectorFk = vSectorFk OR iss.sectorFk IS NULL; CREATE OR REPLACE TEMPORARY TABLE tmp.itemOutTime SELECT *, SUM(amount) quantity FROM ( SELECT io.itemFk, io.quantity amount, IF(HOUR(t.shipped), HOUR(t.shipped), HOUR(z.`hour`)) `hours`, IF(MINUTE(t.shipped), MINUTE(t.shipped), MINUTE(z.`hour`)) `minutes` FROM itemTicketOut `io` JOIN tItemShelvingRadar isr ON isr.itemFk = io.itemFk JOIN ticket t ON t.id= io.ticketFk JOIN ticketState ts ON ts.ticketFk = io.ticketFk JOIN `state` s ON s.id = ts.stateFk LEFT JOIN `zone` z ON z.id = t.zoneFk LEFT JOIN ( SELECT DISTINCT saleFk FROM saleTracking st WHERE st.created > util.VN_CURDATE() AND st.isChecked ) stPrevious ON stPrevious.saleFk = io.saleFk WHERE t.warehouseFk = vWarehouseFk AND NOT s.isPicked AND NOT io.reserved AND stPrevious.saleFk IS NULL AND io.shipped >= util.VN_CURDATE() AND io.shipped < util.VN_CURDATE() + INTERVAL 1 DAY ) sub GROUP BY itemFk, `hours`, `minutes`; INSERT INTO tItemShelvingRadar (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 tItemShelvingRadar isr JOIN ( SELECT s.itemFk, SUM(s.quantity) amount FROM sale s JOIN ticket t ON t.id = s.ticketFk JOIN ticketState ts ON ts.ticketFk = t.id WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE()) AND ts.code = 'COOLER_PREPARATION' GROUP BY s.itemFk ) sub ON sub.itemFk = isr.itemFk SET isr.dayEndVisible = dayEndVisible + sub.amount, firstNegative = firstNegative + sub.amount; SELECT * FROM tItemShelvingRadar; END IF; DROP TEMPORARY TABLE tItemShelvingRadar; END$$ DELIMITER ;