DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_getProblems`(IN 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) Identificadores de los tickets a calcular * @return tmp.sale_problems */ DECLARE vWarehouseFk INT; DECLARE vDate DATE; DECLARE vAvailableCache INT; DECLARE vVisibleCache INT; DECLARE vDone BOOL; DECLARE vComponentCount INT; DECLARE vCursor CURSOR FOR SELECT DISTINCT tt.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(tt.shipped)) FROM tmp.sale_getProblems tt WHERE DATE(tt.shipped) BETWEEN util.VN_CURDATE() AND util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; DELETE tt.* FROM tmp.sale_getProblems tt JOIN ticketObservation tto ON tto.ticketFk = tt.ticketFk JOIN observationType ot ON ot.id = tto.observationTypeFk WHERE ot.code = 'administrative' AND tto.description = 'Miriam'; 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, 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; CREATE OR REPLACE TEMPORARY TABLE tmp.ticket_list (PRIMARY KEY (ticketFk)) ENGINE = MEMORY SELECT ticketFk, clientFk FROM tmp.sale_getProblems; SELECT COUNT(*) INTO vComponentCount FROM component WHERE isRequired; -- Too Little INSERT INTO tmp.sale_problems(ticketFk, isTooLittle) SELECT tp.ticketFk, TRUE FROM tmp.sale_getProblems tp JOIN ticket t ON t.id = tp.ticketFk JOIN ( SELECT t.addressFk, SUM(ROUND(`ic`.`cm3delivery` * `s`.`quantity` / 1000, 0)) litros, t.totalWithoutVat FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.ticketFk JOIN sale s ON s.ticketFk = t.id AND s.quantity > 0 JOIN itemCost ic ON ic.itemFk = s.itemFk AND ic.warehouseFk = t.warehouseFk JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk AND zc.dated = util.VN_CURDATE() JOIN agencyMode am ON am.id = t.agencyModeFk JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk WHERE util.VN_NOW() < (util.VN_CURDATE() + INTERVAL HOUR(zc.`hour`) HOUR) + INTERVAL MINUTE(zc.`hour`) MINUTE AND dm.code IN ('AGENCY','DELIVERY','PICKUP') AND t.shipped BETWEEN util.VN_CURDATE() AND util.midnight() GROUP BY t.addressFk ) sub ON sub.addressFk = t.addressFk JOIN volumeConfig vc WHERE sub.litros < vc.minTicketVolume AND sub.totalWithoutVat < vc.minTicketValue; -- VIP INSERT INTO tmp.sale_problems(ticketFk, isVip) SELECT DISTINCT tl.ticketFk, TRUE FROM tmp.ticket_list tl JOIN client c ON c.id = tl.clientFk WHERE c.businessTypeFk = 'VIP' ON DUPLICATE KEY UPDATE isVip = TRUE; -- Faltan componentes INSERT INTO tmp.sale_problems(ticketFk, hasComponentLack, saleFk) SELECT ticketFk, (vComponentCount > nComp) hasComponentLack, saleFk FROM ( SELECT COUNT(s.id) nComp, tl.ticketFk, s.id saleFk FROM tmp.ticket_list tl JOIN sale s ON s.ticketFk = tl.ticketFk LEFT JOIN saleComponent sc ON sc.saleFk = s.id LEFT JOIN component c ON c.id = sc.componentFk AND c.isRequired JOIN ticket t ON t.id = tl.ticketFk JOIN agencyMode am ON am.id = t.agencyModeFk JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk WHERE dm.code IN ('AGENCY','DELIVERY','PICKUP') AND s.quantity > 0 GROUP BY s.id ) sub HAVING hasComponentLack; -- Cliente congelado INSERT INTO tmp.sale_problems(ticketFk, isFreezed) SELECT DISTINCT tl.ticketFk, TRUE FROM tmp.ticket_list tl JOIN client c ON c.id = tl.clientFk WHERE c.isFreezed ON DUPLICATE KEY UPDATE isFreezed = c.isFreezed; -- Credit exceeded CREATE OR REPLACE TEMPORARY TABLE tmp.clientGetDebt (PRIMARY KEY (clientFk)) ENGINE = MEMORY SELECT DISTINCT clientFk FROM tmp.ticket_list; CALL client_getDebt(util.VN_CURDATE()); INSERT INTO tmp.sale_problems(ticketFk, risk, hasHighRisk) SELECT DISTINCT tl.ticketFk, r.risk, ((r.risk - cc.riskTolerance) > c.credit + 10) FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.ticketFk JOIN agencyMode a ON t.agencyModeFk = a.id JOIN tmp.risk r ON r.clientFk = t.clientFk JOIN client c ON c.id = t.clientFk JOIN clientConfig cc WHERE r.risk > c.credit + 10 AND NOT a.isRiskFree ON DUPLICATE KEY UPDATE risk = r.risk, hasHighRisk = ((r.risk - cc.riskTolerance) > c.credit + 10); -- Antiguo COD 100, son peticiones de compra sin terminar INSERT INTO tmp.sale_problems(ticketFk, hasTicketRequest) SELECT DISTINCT tl.ticketFk, TRUE FROM tmp.ticket_list tl JOIN ticketRequest tr ON tr.ticketFk = tl.ticketFk WHERE tr.isOK IS NULL ON DUPLICATE KEY UPDATE hasTicketRequest = 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 tl.ticketFk, LEFT(CONCAT('F: ',GROUP_CONCAT(i.id, ' ', i.longName, ' ')),250) problem, s.id AS saleFk FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.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 tl.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 tl.ticketFk, LEFT(GROUP_CONCAT('I: ', i.id, ' ', i.longName, ' '), 250) problem, s.id saleFk FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.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 tl.ticketFk ) sub ON DUPLICATE KEY UPDATE itemDelay = 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 tl.ticketFk, LEFT(GROUP_CONCAT('R: ', i.id, ' ', i.longName, ' '), 250) problem, s.id saleFk FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.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 tl.ticketFk ) sub ON DUPLICATE KEY UPDATE itemDelay = sub.problem, saleFk = sub.saleFk; -- Redondeo: Cantidad pedida incorrecta en al grouping de la Ășltima compra CALL buyUltimate(vWarehouseFk, vDate); INSERT INTO tmp.sale_problems(ticketFk, hasRounding, saleFk) SELECT ticketFk, problem, saleFk FROM ( SELECT tl.ticketFk, s.id saleFk , LEFT(GROUP_CONCAT('RE: ',i.id, ' ', IFNULL(i.longName,''), ' '), 250) problem, MOD(s.quantity, b.`grouping`) hasRounding FROM tmp.ticket_list tl JOIN ticket t ON t.id = tl.ticketFk AND t.warehouseFk = vWarehouseFk JOIN sale s ON s.ticketFk = tl.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 GROUP BY tl.ticketFk HAVING hasRounding ) sub ON DUPLICATE KEY UPDATE hasRounding = sub.problem, saleFk = sub.saleFk; END LOOP; CLOSE vCursor; INSERT INTO tmp.sale_problems(ticketFk, isTaxDataChecked) SELECT DISTINCT tl.ticketFk, FALSE FROM tmp.ticket_list tl JOIN client c ON c.id = tl.clientFk WHERE NOT c.isTaxDataChecked ON DUPLICATE KEY UPDATE isTaxDataChecked = FALSE; DROP TEMPORARY TABLE tmp.clientGetDebt, tmp.ticket_list, tItemShelvingStock_byWarehouse; END$$ DELIMITER ;