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

217 lines
8.0 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_getProblems`(
2024-09-16 16:21:12 +00:00
vIsTodayRelative TINYINT(1)
2024-08-07 08:32:47 +00:00
)
BEGIN
/**
* Calcula los problemas para un conjunto de tickets.
* Agrupados por ticket
*
2024-09-16 16:21:12 +00:00
* @table tmp.tmp.ticket(ticketFk) Identificadores de los tickets a calcular
* @return tmp.ticketProblems
*/
2024-09-16 16:21:12 +00:00
DECLARE vWarehouseFk INT;
DECLARE vDate DATE;
DECLARE vAvailableCache INT;
DECLARE vVisibleCache INT;
DECLARE vDone BOOL;
DECLARE vCursor CURSOR FOR
SELECT DISTINCT t.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(t.shipped))
FROM tmp.ticket t
JOIN ticket t ON t.id = t.ticketFk
WHERE t.shipped BETWEEN util.VN_CURDATE()
AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY);
2024-09-16 16:21:12 +00:00
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
CREATE OR REPLACE TEMPORARY TABLE tmp.saleProblems(
ticketFk INT(11),
saleFk INT(11),
hasItemShortage BOOL DEFAULT FALSE,
hasItemLost BOOL DEFAULT FALSE,
hasItemDelay BOOL DEFAULT FALSE,
hasRounding BOOL DEFAULT FALSE,
PRIMARY KEY (ticketFk, saleFk)
) ENGINE = MEMORY;
CREATE OR REPLACE TEMPORARY TABLE tItemShelving
(INDEX (itemFk, warehouseFk))
ENGINE = MEMORY
2024-09-16 16:21:12 +00:00
SELECT ish.itemFk itemFk,
SUM(ish.visible) visible,
s.warehouseFk warehouseFk
FROM itemShelving ish
JOIN shelving sh ON sh.code = ish.shelvingFk
JOIN parking p ON p.id = sh.parkingFk
JOIN sector s ON s.id = p.sectorFk
GROUP BY ish.itemFk, s.warehouseFk;
-- Disponible, faltas, inventario y retrasos
OPEN vCursor;
l: LOOP
SET vDone = FALSE;
FETCH vCursor INTO vWarehouseFk, vDate;
IF vDone THEN
LEAVE l;
END IF;
-- Disponible: no va a haber suficiente producto para preparar todos los pedidos
CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouseFk, vDate);
-- Faltas: visible, disponible y ubicado son menores que la cantidad vendida
CALL cache.visible_refresh(vVisibleCache, FALSE, vWarehouseFk);
INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemShortage)
SELECT tt.ticketFk, s.id, TRUE
FROM tmp.ticket tt
JOIN ticket t ON t.id = tt.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN itemCategory ic ON ic.id = it.categoryFk
LEFT JOIN cache.visible v ON v.item_id = i.id
AND v.calc_id = vVisibleCache
LEFT JOIN cache.available av ON av.item_id = i.id
AND av.calc_id = vAvailableCache
LEFT JOIN tItemShelving tis ON tis.itemFk = i.id
AND tis.warehouseFk = t.warehouseFk
WHERE IFNULL(v.visible, 0) < s.quantity
AND IFNULL(av.available, 0) < s.quantity
AND IFNULL(tis.visible, 0) < s.quantity
AND NOT s.isPicked
AND NOT s.reserved
AND ic.merchandise
AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate)
AND NOT i.generic
AND util.VN_CURDATE() = vDate
AND t.warehouseFk = vWarehouseFk
GROUP BY s.id;
-- Inventario: Visible suficiente, pero ubicado menor a la cantidad vendida
INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemLost)
SELECT tt.ticketFk, s.id, TRUE
FROM tmp.ticket tt
JOIN ticket t ON t.id = tt.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN itemCategory ic ON ic.id = it.categoryFk
LEFT JOIN cache.visible v ON v.item_id = s.itemFk
AND v.calc_id = vVisibleCache
LEFT JOIN tItemShelving tis ON tis.itemFk = i.id
AND tis.warehouseFk = t.warehouseFk
WHERE IFNULL(v.visible, 0) >= s.quantity
AND IFNULL(tis.visible, 0) < s.quantity
AND s.quantity > 0
AND NOT s.isPicked
AND NOT s.reserved
AND ic.merchandise
AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate)
AND NOT i.generic
AND util.VN_CURDATE() = vDate
AND t.warehouseFk = vWarehouseFk
GROUP BY s.id
ON DUPLICATE KEY UPDATE hasItemLost = TRUE;
-- Retraso: Disponible suficiente, pero no visible ni ubicado
INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemDelay)
SELECT tt.ticketFk, s.id, TRUE
FROM tmp.ticket tt
JOIN ticket t ON t.id = tt.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN itemCategory ic ON ic.id = it.categoryFk
LEFT JOIN cache.visible v ON v.item_id = s.itemFk
AND v.calc_id = vVisibleCache
LEFT JOIN cache.available av ON av.item_id = i.id
AND av.calc_id = vAvailableCache
LEFT JOIN tItemShelving tis ON tis.itemFk = i.id
AND tis.warehouseFk = t.warehouseFk
WHERE IFNULL(v.visible, 0) < s.quantity
AND IFNULL(av.available, 0) >= s.quantity
AND IFNULL(tis.visible, 0) < s.quantity
AND s.quantity > 0
AND NOT s.isPicked
AND NOT s.reserved
AND ic.merchandise
AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate)
AND NOT i.generic
AND util.VN_CURDATE() = vDate
AND t.warehouseFk = vWarehouseFk
GROUP BY s.id
ON DUPLICATE KEY UPDATE hasItemDelay = TRUE;
-- Redondeo: cantidad incorrecta con respecto al grouping
CALL buy_getUltimate(NULL, vWarehouseFk, vDate);
INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasRounding)
SELECT tt.ticketFk, s.id, TRUE
FROM tmp.ticket tt
JOIN ticket t ON t.id = tt.ticketFk
AND t.warehouseFk = vWarehouseFk
JOIN sale s ON s.ticketFk = tt.ticketFk
JOIN item i ON i.id = s.itemFk
JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
JOIN buy b ON b.id = bu.buyFk
WHERE MOD(s.quantity, b.`grouping`)
GROUP BY s.id
ON DUPLICATE KEY UPDATE hasRounding = TRUE;
DROP TEMPORARY TABLE tmp.buyUltimate;
END LOOP;
CLOSE vCursor;
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketProblem (
ticketFk INT(11),
isFreezed BOOL DEFAULT FALSE,
risk DECIMAL(10,1) DEFAULT 0,
hasRisk BOOL DEFAULT FALSE,
hasHighRisk BOOL DEFAULT FALSE,
hasTicketRequest BOOL DEFAULT FALSE,
isTaxDataChecked BOOL DEFAULT FALSE,
isTooLittle BOOL DEFAULT FALSE,
isVip BOOL DEFAULT FALSE,
hasItemShortage BOOL DEFAULT FALSE,
hasItemDelay BOOL DEFAULT FALSE,
hasItemLost BOOL DEFAULT FALSE,
hasComponentLack BOOL DEFAULT FALSE,
hasRounding BOOL DEFAULT FALSE,
PRIMARY KEY (ticketFk)
) ENGINE = MEMORY
SELECT tt.ticketFk,
IF(FIND_IN_SET('isFreezed', t.problem), TRUE, FALSE) isFreezed,
t.risk,
IF(FIND_IN_SET('hasRisk', t.problem), TRUE, FALSE) hasRisk,
IF(FIND_IN_SET('hasHighRisk', t.problem), TRUE, FALSE) hasHighRisk,
IF(FIND_IN_SET('hasTicketRequest', t.problem), TRUE, FALSE) hasTicketRequest,
IF(FIND_IN_SET('isTaxDataChecked', t.problem), FALSE, TRUE) isTaxDataChecked,
IF(FIND_IN_SET('isTooLittle', t.problem)
AND util.VN_NOW() < (util.VN_CURDATE() + INTERVAL HOUR(zc.`hour`) HOUR) + INTERVAL MINUTE(zc.`hour`) MINUTE,
TRUE, FALSE) isTooLittle,
IF(c.businessTypeFk = 'VIP', TRUE, FALSE) isVip,
SUM(IFNULL(ts.hasItemShortage,0)) hasItemShortage,
SUM(IFNULL(ts.hasItemDelay,0)) hasItemDelay,
SUM(IFNULL(ts.hasItemLost,0)) hasItemLost,
IF(FIND_IN_SET('hasComponentLack', s.problem), TRUE, FALSE) hasComponentLack,
SUM(IFNULL(ts.hasRounding,0)) hasRounding,
LEFT(CONCAT('F: ',GROUP_CONCAT(CONCAT(i.id, ' ', i.longName) SEPARATOR ', ')), 250) itemShortage,
LEFT(CONCAT('R: ',GROUP_CONCAT(CONCAT(i2.id, ' ', i2.longName) SEPARATOR ', ')), 250) itemDelay,
LEFT(CONCAT('I: ',GROUP_CONCAT(CONCAT(i3.id, ' ', i3.longName) SEPARATOR ', ')), 250) itemLost,
LEFT(CONCAT('RE: ',GROUP_CONCAT(CONCAT(i4.id, ' ', i4.longName) SEPARATOR ', ')), 250) componentLack,
LEFT(CONCAT('RE: ',GROUP_CONCAT(CONCAT(i5.id, ' ', i5.longName) SEPARATOR ', ')), 250) rounding
FROM tmp.ticket tt
JOIN ticket t ON t.id = tt.ticketFk
JOIN client c ON c.id = t.clientFk
LEFT JOIN sale s ON s.ticketFk = t.id
LEFT JOIN tmp.saleProblems ts ON ts.saleFk = s.id
LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk
AND zc.dated = util.VN_CURDATE()
WHERE s.problem <> '' OR t.problem <> '' OR t.risk
GROUP BY t.id;
DROP TEMPORARY TABLE tItemShelving;
END$$
DELIMITER ;