DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_getProblems`( vIsTodayRelative TINYINT(1) ) BEGIN /** * Calcula los problemas para un conjunto de tickets. * * @table tmp.ticket(ticketFk) Identificadores de los tickets a calcular * @return tmp.ticketProblems, tmp.saleProblems */ CREATE OR REPLACE TEMPORARY TABLE tmp.sale ( saleFk INT(11), PRIMARY KEY (saleFk) ) ENGINE = MEMORY SELECT DISTINCT s.id saleFk FROM tmp.ticket tt JOIN ticket t ON t.id = tt.ticketFk JOIN sale s ON s.ticketFk = t.id WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY) GROUP BY s.id; CALL sale_getProblems(vIsTodayRelative); CREATE OR REPLACE TEMPORARY TABLE tmp.ticketProblems ( 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 WITH hasItemShortage AS( SELECT s.ticketFk FROM tmp.saleProblems sp JOIN vn.sale s ON s.id = sp.saleFk WHERE sp.hasItemShortage GROUP BY s.ticketFk ),hasItemLost AS( SELECT s.ticketFk FROM tmp.saleProblems sp JOIN vn.sale s ON s.id = sp.saleFk WHERE sp.hasItemLost GROUP BY s.ticketFk ),hasRounding AS( SELECT s.ticketFk FROM tmp.saleProblems sp JOIN vn.sale s ON s.id = sp.saleFk WHERE sp.hasRounding GROUP BY s.ticketFk ), hasItemDelay AS( SELECT s.ticketFk FROM tmp.saleProblems sp JOIN vn.sale s ON s.id = sp.saleFk WHERE sp.hasItemDelay GROUP BY s.ticketFk ), hasComponentLack AS( SELECT s.ticketFk FROM tmp.saleProblems sp JOIN vn.sale s ON s.id = sp.saleFk WHERE FIND_IN_SET('hasComponentLack', s.problem) GROUP BY s.ticketFk )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), TRUE, FALSE) 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, IF(his.ticketFk IS NULL, FALSE, TRUE) hasItemShortage, IF(hid.ticketFk IS NULL, FALSE, TRUE) hasItemDelay, IF(hil.ticketFk IS NULL, FALSE, TRUE) hasItemLost, IF(hcl.ticketFk IS NULL, FALSE, TRUE) hasComponentLack, IF(hr.ticketFk IS NULL, FALSE, TRUE) hasRounding, 0 totalProblems FROM tmp.ticket tt JOIN vn.ticket t ON t.id = tt.ticketFk JOIN vn.client c ON c.id = t.clientFk LEFT JOIN hasItemShortage his ON his.ticketFk = t.id LEFT JOIN hasItemLost hil ON hil.ticketFk = t.id LEFT JOIN hasRounding hr ON hr.ticketFk = t.id LEFT JOIN hasItemDelay hid ON hid.ticketFk = t.id LEFT JOIN hasComponentLack hcl ON hcl.ticketFk = t.id LEFT JOIN vn.zoneClosure zc ON zc.zoneFk = t.zoneFk AND zc.dated = util.VN_CURDATE() GROUP BY t.id; UPDATE tmp.ticketProblems SET totalProblems = isFreezed + hasHighRisk + hasTicketRequest + isTaxDataChecked + hasComponentLack + hasItemDelay + isTooLittle + hasItemLost + hasRounding + hasItemShortage + isVip; DROP TEMPORARY TABLE tmp.sale; END$$ DELIMITER ;