fix: refs #7760 tmp.ticketIPT

This commit is contained in:
Carlos Andrés 2024-09-16 18:21:12 +02:00
parent 956058c10c
commit 91fac11fa0
8 changed files with 250 additions and 327 deletions

View File

@ -1,16 +1,18 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`prepareTicketList`(vStartingDate DATETIME, vEndingDate DATETIME)
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`prepareTicketList`(
vStartingDate DATETIME,
vEndingDate DATETIME
)
BEGIN
DROP TEMPORARY TABLE IF EXISTS tmp.productionTicket;
CREATE TEMPORARY TABLE tmp.productionTicket
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT t.id ticketFk, t.clientFk
SELECT t.id ticketFk
FROM ticket t
JOIN alertLevel al ON al.code = 'DELIVERED'
LEFT JOIN ticketState ts ON ts.ticketFk = t.id
JOIN client c ON c.id = t.clientFk
WHERE c.typeFk IN ('normal','handMaking','internalUse')
AND (
t.shipped BETWEEN util.VN_CURDATE() AND vEndingDate

View File

@ -15,7 +15,7 @@ proc: BEGIN
DECLARE vEndingDate DATETIME;
DECLARE vIsTodayRelative BOOLEAN;
SELECT util.dayEnd(util.VN_CURDATE()) + INTERVAL LEAST(vScopeDays, maxProductionScopeDays) DAY
SELECT util.dayEnd(util.VN_CURDATE() + INTERVAL LEAST(vScopeDays, maxProductionScopeDays) DAY)
INTO vEndingDate
FROM productionConfig;
@ -26,16 +26,10 @@ proc: BEGIN
CALL prepareTicketList(util.yesterday(), vEndingDate);
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
SELECT * FROM tmp.productionTicket;
CALL prepareClientList();
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT tt.ticketFk, tt.clientFk, t.warehouseFk, t.shipped
FROM tmp.productionTicket tt
JOIN ticket t ON t.id = tt.ticketFk;
SELECT ticketFk
FROM tmp.productionTicket;
CALL ticket_getProblems(vIsTodayRelative);
@ -43,7 +37,7 @@ proc: BEGIN
(PRIMARY KEY(ticketFk), previaParking VARCHAR(255))
ENGINE = MEMORY
SELECT tt.ticketFk,
tt.clientFk,
t.clientFk,
t.warehouseFk,
t.nickname,
t.packages,
@ -61,7 +55,17 @@ proc: BEGIN
0 `lines`,
CAST( 0 AS DECIMAL(5,2)) m3,
CAST( 0 AS DECIMAL(5,2)) preparationRate,
"" problem,
TRIM(CAST(CONCAT( IFNULL(tpr.itemShortage, ''),
IFNULL(tpr.itemDelay, ''),
IFNULL(tpr.itemLost, ''),
IF(tpr.isFreezed, ' CONGELADO',''),
IF(tpr.hasHighRisk, ' RIESGO',''),
IF(tpr.hasTicketRequest, ' COD 100',''),
IF(tpr.isTaxDataChecked, '',' FICHA INCOMPLETA'),
IF(tpr.hasComponentLack, ' COMPONENTES', ''),
IF(HOUR(util.VN_NOW()) < IF(HOUR(t.shipped), HOUR(t.shipped), COALESCE(HOUR(zc.hour),HOUR(z.hour)))
AND tpr.isTooLittle, ' PEQUEÑO', '')
) AS char(255))) problem,
IFNULL(tls.state,2) state,
w.code workerCode,
DATE(t.shipped) shipped,
@ -101,6 +105,7 @@ proc: BEGIN
AND DATE(t.shipped) = zc.dated
LEFT JOIN ticketParking tp ON tp.ticketFk = t.id
LEFT JOIN parking pk ON pk.id = tp.parkingFk
LEFT JOIN tmp.ticketProblem tpr ON tpr.ticketFk = tt.ticketFk
WHERE t.warehouseFk = vWarehouseFk
AND dm.code IN ('AGENCY', 'DELIVERY', 'PICKUP');
@ -123,19 +128,6 @@ proc: BEGIN
ADD COLUMN `collectionV` INT,
ADD COLUMN `collectionN` INT;
UPDATE tmp.productionBuffer pb
JOIN tmp.ticket_problems tp ON tp.ticketFk = pb.ticketFk
SET pb.problem = TRIM(CAST(CONCAT( IFNULL(tp.itemShortage, ''),
IFNULL(tp.itemDelay, ''),
IFNULL(tp.itemLost, ''),
IF(tp.isFreezed, ' CONGELADO',''),
IF(tp.hasHighRisk, ' RIESGO',''),
IF(tp.hasTicketRequest, ' COD 100',''),
IF(tp.isTaxDataChecked, '',' FICHA INCOMPLETA'),
IF(tp.hasComponentLack, ' COMPONENTES', ''),
IF(HOUR(util.VN_NOW()) < pb.HH AND tp.isTooLittle, ' PEQUEÑO', '')
) AS char(255)));
-- Clientes Nuevos o Recuperados
UPDATE tmp.productionBuffer pb
LEFT JOIN bs.clientNewBorn cnb ON cnb.clientFk = pb.clientFk
@ -267,8 +259,7 @@ proc: BEGIN
DROP TEMPORARY TABLE
tmp.productionTicket,
tmp.ticket,
tmp.ticket_problems,
tmp.ticketProblems,
tmp.ticketWithPrevia,
tItemShelvingStock,
tItemPackingType;

View File

@ -1,233 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblems`(
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
* @table tmp.sale_getProblems(ticketFk, clientFk, warehouseFk, shipped) Tickets a calcular
* @return tmp.sale_problems
*/
DECLARE vWarehouseFk INT;
DECLARE vDate DATE;
DECLARE vAvailableCache INT;
DECLARE vVisibleCache INT;
DECLARE vDone BOOL;
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,
risk DECIMAL(10,1) DEFAULT 0,
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,
isVip BOOL DEFAULT FALSE,
PRIMARY KEY (ticketFk, saleFk)
) ENGINE = MEMORY;
INSERT INTO tmp.sale_problems(ticketFk,
saleFk,
isFreezed,
risk,
hasRisk,
hasHighRisk,
hasTicketRequest,
isTaxDataChecked,
hasComponentLack,
isTooLittle)
SELECT sgp.ticketFk,
s.id,
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('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
FROM tmp.sale_getProblems sgp
JOIN ticket t ON t.id = sgp.ticketFk
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()
WHERE s.problem <> '' OR t.problem <> '' OR t.risk
GROUP BY t.id, s.id;
INSERT INTO tmp.sale_problems(ticketFk, isVip)
SELECT sgp.ticketFk, TRUE
FROM tmp.sale_getProblems sgp
JOIN client c ON c.id = sgp.clientFk
WHERE c.businessTypeFk = 'VIP'
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
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.sale_problems(ticketFk, itemShortage, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
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
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
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
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 (
SELECT sgp.ticketFk,
LEFT(GROUP_CONCAT('I: ', 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
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
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
GROUP BY sgp.ticketFk
) sub
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 (
SELECT sgp.ticketFk,
LEFT(GROUP_CONCAT('R: ', 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
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
GROUP BY sgp.ticketFk
) sub
ON DUPLICATE KEY UPDATE itemDelay = sub.problem, saleFk = sub.saleFk;
-- Redondeo: cantidad incorrecta con respecto al grouping
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;
DROP TEMPORARY TABLE tItemShelvingStock_byWarehouse;
END$$
DELIMITER ;

View File

@ -1,5 +1,8 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblemsByTicket`(IN vTicketFk INT, IN vIsTodayRelative TINYINT(1))
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblemsByTicket`(
IN vTicketFk INT,
IN vIsTodayRelative TINYINT(1)
)
BEGIN
/**
* Calcula los problemas de cada venta
@ -7,19 +10,17 @@ BEGIN
*
* @return Problems result
*/
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT t.id ticketFk, t.clientFk, t.warehouseFk, t.shipped
FROM ticket t
WHERE t.id = vTicketFk;
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT vTicketFk ticketFk;
CALL sale_getProblems(vIsTodayRelative);
CALL ticket_getProblems(vIsTodayRelative);
SELECT * FROM tmp.sale_problems;
SELECT * FROM tmp.saleProblems;
DROP TEMPORARY TABLE
tmp.sale_getProblems,
tmp.sale_problems;
tmp.ticket,
tmp.ticketProblems;
END$$
DELIMITER ;

View File

@ -1,53 +1,216 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_getProblems`(
vIsTodayRelative tinyint(1)
vIsTodayRelative TINYINT(1)
)
BEGIN
/**
* Calcula los problemas para un conjunto de tickets.
* Agrupados por ticket
*
* @table tmp.sale_getProblems(ticketFk, clientFk, warehouseFk, shipped) Identificadores de los tickets a calcular
* @return tmp.ticket_problems
* @table tmp.tmp.ticket(ticketFk) Identificadores de los tickets a calcular
* @return tmp.ticketProblems
*/
CALL sale_getProblems(vIsTodayRelative);
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);
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket_problems
(PRIMARY KEY (ticketFk))
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
SELECT ticketFk,
MAX(isFreezed) isFreezed,
MAX(risk) risk,
MAX(hasRisk) hasRisk,
MAX(hasHighRisk) hasHighRisk,
MAX(hasTicketRequest) hasTicketRequest,
MAX(itemShortage) itemShortage,
MIN(isTaxDataChecked) isTaxDataChecked,
MAX(hasComponentLack) hasComponentLack,
MAX(isTooLittle) isTooLittle,
MAX(itemDelay) itemDelay,
MAX(hasRounding) hasRounding,
MAX(itemLost) itemLost,
MAX(isVip) isVip,
0 totalProblems
FROM tmp.sale_problems
GROUP BY ticketFk;
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;
UPDATE tmp.ticket_problems
SET totalProblems = (
(isFreezed) +
(hasHighRisk) +
(hasTicketRequest) +
(!isTaxDataChecked) +
(hasComponentLack) +
(itemDelay IS NOT NULL) +
(isTooLittle) +
(itemLost IS NOT NULL) +
(hasRounding IS NOT NULL) +
(itemShortage IS NOT NULL) +
(isVip)
);
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);
DROP TEMPORARY TABLE tmp.sale_problems;
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 ;

View File

@ -239,10 +239,10 @@ module.exports = Self => {
stmts.push(`SET SESSION optimizer_search_depth = @_optimizer_search_depth`);
stmt = new ParameterizedSQL(`
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT f.id ticketFk, f.clientFk, f.warehouseFk, f.shipped
SELECT f.id ticketFk
FROM tmp.filter f
LEFT JOIN alertLevel al ON al.id = f.alertLevel
WHERE (al.code = 'FREE' OR f.alertLevel IS NULL)
@ -263,7 +263,7 @@ module.exports = Self => {
stmts.push('CALL ticket_getWarnings()');
stmt = new ParameterizedSQL(`
UPDATE tmp.ticket_problems
UPDATE tmp.ticketProblems
SET risk = IF(hasRisk, risk, 0)
`);
stmts.push(stmt);
@ -271,7 +271,7 @@ module.exports = Self => {
stmt = new ParameterizedSQL(`
SELECT *
FROM tmp.filter f
LEFT JOIN tmp.ticket_problems tp ON tp.ticketFk = f.id
LEFT JOIN tmp.ticketProblems tp ON tp.ticketFk = f.id
LEFT JOIN tmp.ticket_warnings tw ON tw.ticketFk = f.id
`);
stmts.push(stmt);
@ -376,8 +376,7 @@ module.exports = Self => {
stmts.push(`
DROP TEMPORARY TABLE
tmp.filter,
tmp.ticket_problems,
tmp.sale_getProblems,
tmp.ticketProblem,
tmp.sale_getWarnings,
tmp.ticket_warnings
`);

View File

@ -293,10 +293,10 @@ module.exports = Self => {
stmts.push(stmt);
stmt = new ParameterizedSQL(`
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT f.id ticketFk, f.clientFk, f.warehouseFk, f.shipped
SELECT f.id ticketFk
FROM tmp.filter f
LEFT JOIN alertLevel al ON al.id = f.alertLevel
WHERE (al.code = 'FREE' OR f.alertLevel IS NULL)
@ -307,7 +307,7 @@ module.exports = Self => {
stmts.push('CALL ticket_getProblems(FALSE)');
stmt = new ParameterizedSQL(`
UPDATE tmp.ticket_problems
UPDATE tmp.ticketProblems
SET risk = IF(hasRisk, risk, 0)
`);
stmts.push(stmt);
@ -315,7 +315,7 @@ module.exports = Self => {
stmt = new ParameterizedSQL(`
SELECT f.*, tp.*
FROM tmp.filter f
LEFT JOIN tmp.ticket_problems tp ON tp.ticketFk = f.id
LEFT JOIN tmp.ticketProblems tp ON tp.ticketFk = f.id
`);
if (args.problems != undefined && (!args.from && !args.to))
@ -371,7 +371,7 @@ module.exports = Self => {
stmts.push(
`DROP TEMPORARY TABLE
tmp.filter,
tmp.ticket_problems`);
tmp.ticketProblems`);
const sql = ParameterizedSQL.join(stmts, ';');
const result = await conn.executeStmt(sql, myOptions);

View File

@ -146,10 +146,10 @@ module.exports = Self => {
stmts.push(stmt);
stmt = new ParameterizedSQL(`
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT f.id ticketFk, f.clientFk, f.warehouseFk, f.shipped, f.lines, f.liters
SELECT f.id ticketFk
FROM tmp.filter f
LEFT JOIN alertLevel al ON al.id = f.alertLevel
WHERE (al.code = 'FREE' OR f.alertLevel IS NULL)
@ -159,7 +159,7 @@ module.exports = Self => {
stmts.push('CALL ticket_getProblems(FALSE)');
stmt = new ParameterizedSQL(`
UPDATE tmp.ticket_problems
UPDATE tmp.ticketProblems
SET risk = IF(hasRisk, risk, 0)
`);
stmts.push(stmt);
@ -167,7 +167,7 @@ module.exports = Self => {
stmt = new ParameterizedSQL(`
SELECT f.*, tp.*
FROM tmp.filter f
LEFT JOIN tmp.ticket_problems tp ON tp.ticketFk = f.id
LEFT JOIN tmp.ticketProblems tp ON tp.ticketFk = f.id
`);
if (args.problems != undefined && (!args.originScopeDays && !args.futureScopeDays))
@ -217,7 +217,7 @@ module.exports = Self => {
stmts.push(
`DROP TEMPORARY TABLE
tmp.filter,
tmp.ticket_problems`);
tmp.ticketProblems`);
const sql = ParameterizedSQL.join(stmts, ';');
const result = await conn.executeStmt(sql, myOptions);