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

234 lines
8.5 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblems`(
2024-08-07 08:32:47 +00:00
vIsTodayRelative tinyint(1)
)
BEGIN
/**
* Calcula los problemas de cada venta para un conjunto de tickets.
*
* @param vIsTodayRelative Indica si se calcula el disponible como si todo saliera hoy
2024-08-07 08:32:47 +00:00
* @table tmp.sale_getProblems(ticketFk, clientFk, warehouseFk, shipped) Tickets a calcular
* @return tmp.sale_problems
*/
2024-08-07 08:32:47 +00:00
DECLARE vWarehouseFk INT;
DECLARE vDate DATE;
2024-08-07 08:32:47 +00:00
DECLARE vAvailableCache INT;
DECLARE vVisibleCache INT;
DECLARE vDone BOOL;
2024-08-07 08:32:47 +00:00
DECLARE vCursor CURSOR FOR
SELECT DISTINCT warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(shipped))
FROM tmp.sale_getProblems
WHERE shipped BETWEEN util.VN_CURDATE()
AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY);
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_problems (
ticketFk INT(11),
saleFk INT(11),
isFreezed INTEGER(1) DEFAULT 0,
2024-04-29 07:58:58 +00:00
risk DECIMAL(10,1) DEFAULT 0,
2024-09-04 11:37:13 +00:00
hasRisk TINYINT(1) DEFAULT 0,
hasHighRisk TINYINT(1) DEFAULT 0,
hasTicketRequest INTEGER(1) DEFAULT 0,
itemShortage VARCHAR(255),
isTaxDataChecked INTEGER(1) DEFAULT 1,
itemDelay VARCHAR(255),
itemLost VARCHAR(255),
hasComponentLack INTEGER(1),
hasRounding VARCHAR(255),
isTooLittle BOOL DEFAULT FALSE,
2024-05-14 07:07:43 +00:00
isVip BOOL DEFAULT FALSE,
PRIMARY KEY (ticketFk, saleFk)
2024-10-07 04:39:41 +00:00
); -- No memory
2024-09-04 11:37:13 +00:00
INSERT INTO tmp.sale_problems(ticketFk,
saleFk,
isFreezed,
risk,
hasRisk,
hasHighRisk,
hasTicketRequest,
isTaxDataChecked,
hasComponentLack,
isTooLittle)
2024-08-07 08:32:47 +00:00
SELECT sgp.ticketFk,
s.id,
2024-08-07 11:51:00 +00:00
IF(FIND_IN_SET('isFreezed', t.problem), TRUE, FALSE) isFreezed,
t.risk,
IF(FIND_IN_SET('hasRisk', t.problem), TRUE, FALSE) hasRisk,
2024-08-07 11:51:00 +00:00
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,
2024-08-07 08:32:47 +00:00
IF(FIND_IN_SET('hasComponentLack', s.problem), TRUE, FALSE) hasComponentLack,
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
2024-08-07 08:32:47 +00:00
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
2024-08-07 11:51:00 +00:00
LEFT JOIN sale s ON s.ticketFk = t.id
LEFT JOIN item i ON i.id = s.itemFk
LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk
AND zc.dated = util.VN_CURDATE()
2024-08-07 11:51:00 +00:00
WHERE s.problem <> '' OR t.problem <> '' OR t.risk
GROUP BY t.id, s.id;
2024-05-14 07:07:43 +00:00
INSERT INTO tmp.sale_problems(ticketFk, isVip)
2024-08-07 11:51:00 +00:00
SELECT sgp.ticketFk, TRUE
FROM tmp.sale_getProblems sgp
JOIN client c ON c.id = sgp.clientFk
2024-05-09 09:52:25 +00:00
WHERE c.businessTypeFk = 'VIP'
2024-08-07 11:51:00 +00:00
ON DUPLICATE KEY UPDATE isVIP = TRUE;
CREATE OR REPLACE TEMPORARY TABLE tItemShelvingStock_byWarehouse
(INDEX (itemFk, warehouseFk))
ENGINE = MEMORY
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
2024-08-07 08:32:47 +00:00
GROUP BY ish.itemFk, s.warehouseFk;
2024-08-07 08:32:47 +00:00
-- 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.sale_problems(ticketFk, itemShortage, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
2024-08-07 08:32:47 +00:00
SELECT sgp.ticketFk,
LEFT(CONCAT('F: ', GROUP_CONCAT(i.id, ' ', i.longName, ' ')), 250) problem,
s.id saleFk
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
2024-08-07 08:32:47 +00:00
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 tItemShelvingStock_byWarehouse issw ON issw.itemFk = i.id
AND issw.warehouseFk = t.warehouseFk
2024-08-07 08:32:47 +00:00
WHERE IFNULL(v.visible, 0) < s.quantity
AND IFNULL(av.available, 0) < s.quantity
AND IFNULL(issw.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
2024-08-07 08:32:47 +00:00
GROUP BY sgp.ticketFk) sub
ON DUPLICATE KEY UPDATE itemShortage = sub.problem, saleFk = sub.saleFk;
-- Inventario: Visible suficiente, pero ubicado menor a la cantidad vendida
INSERT INTO tmp.sale_problems(ticketFk, itemLost, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
2024-08-07 08:32:47 +00:00
SELECT sgp.ticketFk,
LEFT(GROUP_CONCAT('I: ', i.id, ' ', i.longName, ' '), 250) problem,
s.id saleFk
2024-08-07 08:32:47 +00:00
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
2024-08-07 08:32:47 +00:00
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 tItemShelvingStock_byWarehouse issw ON issw.itemFk = i.id
AND issw.warehouseFk = t.warehouseFk
2024-08-07 08:32:47 +00:00
WHERE IFNULL(v.visible, 0) >= s.quantity
AND IFNULL(issw.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
2024-08-07 08:32:47 +00:00
GROUP BY sgp.ticketFk
) sub
2024-08-07 08:32:47 +00:00
ON DUPLICATE KEY UPDATE itemLost = sub.problem, saleFk = sub.saleFk;
-- Retraso: Disponible suficiente, pero no visible ni ubicado
INSERT INTO tmp.sale_problems(ticketFk, itemDelay, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
2024-08-07 08:32:47 +00:00
SELECT sgp.ticketFk,
LEFT(GROUP_CONCAT('R: ', i.id, ' ', i.longName, ' '), 250) problem,
s.id saleFk
2024-08-07 08:32:47 +00:00
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
2024-08-07 08:32:47 +00:00
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 tItemShelvingStock_byWarehouse issw ON issw.itemFk = i.id
AND issw.warehouseFk = t.warehouseFk
WHERE IFNULL(v.visible, 0) < s.quantity
AND IFNULL(av.available, 0) >= s.quantity
AND IFNULL(issw.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
2024-08-07 08:32:47 +00:00
GROUP BY sgp.ticketFk
) sub
ON DUPLICATE KEY UPDATE itemDelay = sub.problem, saleFk = sub.saleFk;
-- Redondeo: cantidad incorrecta con respecto al grouping
2024-09-11 10:31:16 +00:00
CALL buy_getUltimate(NULL, vWarehouseFk, vDate);
INSERT INTO tmp.sale_problems(ticketFk, hasRounding, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
SELECT sgp.ticketFk,
s.id saleFk,
LEFT(GROUP_CONCAT('RE: ',i.id, ' ', IFNULL(i.longName,'') SEPARATOR ', '), 250) problem
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
AND t.warehouseFk = vWarehouseFk
JOIN sale s ON s.ticketFk = sgp.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 sgp.ticketFk
)sub
ON DUPLICATE KEY UPDATE hasRounding = sub.problem, saleFk = sub.saleFk;
DROP TEMPORARY TABLE tmp.buyUltimate;
END LOOP;
CLOSE vCursor;
2024-08-07 08:40:10 +00:00
DROP TEMPORARY TABLE tItemShelvingStock_byWarehouse;
END$$
DELIMITER ;