USE `vn`; DROP procedure IF EXISTS `ticketGetProblems`; DELIMITER $$ USE `vn`$$ CREATE DEFINER=`root`@`%` PROCEDURE `ticketGetProblems`() BEGIN /* * Obtiene los problemas de uno o varios tickets * * @table tmp.ticketGetProblems(ticketFk, clientFk, warehouseFk, shipped) * @return tmp.ticketProblems */ DECLARE vWarehouse INT; DECLARE vDate DATE; DECLARE vAvailableCache INT; DECLARE vVisibleCache INT; DECLARE vDone INT DEFAULT 0; DECLARE vCursor CURSOR FOR SELECT DISTINCT tt.warehouseFk, date(tt.shipped) FROM tmp.ticketGetProblems tt WHERE DATE(tt.shipped) BETWEEN CURDATE() AND TIMESTAMPADD(DAY, 1.9, CURDATE()); DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = 1; DROP TEMPORARY TABLE IF EXISTS tmp.ticketProblems; CREATE TEMPORARY TABLE tmp.ticketProblems ( ticketFk INT(11) PRIMARY KEY, isFreezed INTEGER(1) DEFAULT 0, risk DECIMAL(10,2) DEFAULT 0, hasTicketRequest INTEGER(1) DEFAULT 0, isAvailable INTEGER(1) DEFAULT 1 ) ENGINE = MEMORY; DROP TEMPORARY TABLE IF EXISTS tmp.ticketList; CREATE TEMPORARY TABLE tmp.ticketList (PRIMARY KEY (ticketFk)) ENGINE = MEMORY SELECT tp.ticketFk, c.id clientFk FROM tmp.ticketGetProblems tp JOIN vn.client c ON c.id = tp.clientFk; -- Inserta tickets de clientes congelados INSERT INTO tmp.ticketProblems(ticketFk, isFreezed) SELECT DISTINCT tl.ticketFk, 1 FROM tmp.ticketList tl JOIN vn.client c ON c.id = tl.clientFk WHERE c.isFreezed; DELETE tl FROM tmp.ticketList tl JOIN tmp.ticketProblems tp ON tl.ticketFk = tp.ticketFk; DROP TEMPORARY TABLE IF EXISTS tmp.clientGetDebt; CREATE TEMPORARY TABLE tmp.clientGetDebt (PRIMARY KEY (clientFk)) ENGINE = MEMORY SELECT DISTINCT clientFk FROM tmp.ticketList; CALL clientGetDebt(CURDATE()); -- Inserta tickets de clientes con riesgo INSERT INTO tmp.ticketProblems(ticketFk, risk) SELECT DISTINCT tl.ticketFk, r.risk FROM tmp.ticketList tl JOIN vn.ticket t ON t.id = tl.ticketFk JOIN vn.agencyMode a ON t.agencyModeFk = a.id JOIN tmp.risk r ON r.clientFk = t.clientFk JOIN vn.client c ON c.id = t.clientFk WHERE r.risk > c.credit + 10 AND a.deliveryMethodFk != 3 ON DUPLICATE KEY UPDATE risk = r.risk; DELETE tl FROM tmp.ticketList tl JOIN tmp.ticketProblems tp ON tl.ticketFk = tp.ticketFk; -- Inserta tickets que tengan codigos 100 INSERT INTO tmp.ticketProblems(ticketFk, hasTicketRequest) SELECT DISTINCT tl.ticketFk, 'Code 100' FROM tmp.ticketList tl JOIN vn.ticketRequest tr ON tr.ticketFk = tl.ticketFk WHERE tr.isOK IS NULL ON DUPLICATE KEY UPDATE hasTicketRequest = 1; DELETE tl FROM tmp.ticketList tl JOIN tmp.ticketProblems tp ON tl.ticketFk = tp.ticketFk; OPEN vCursor; WHILE NOT vDone DO FETCH vCursor INTO vWarehouse, vDate; CALL cache.visible_refresh(vVisibleCache, FALSE, vWarehouse); CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouse, vDate); -- Inserta tickets con articulos que no tegan disponible INSERT INTO tmp.ticketProblems(ticketFk, isAvailable) SELECT tl.ticketFk, 0 FROM tmp.ticketList tl JOIN vn.ticket t ON t.id = tl.ticketFk LEFT JOIN vn.sale s ON s.ticketFk = t.id JOIN vn.item i ON i.id = s.itemFk JOIN vn.itemType it on it.id = i.typeFk LEFT JOIN cache.visible v ON i.id = v.item_id AND v.calc_id = vVisibleCache LEFT JOIN cache.available av ON av.item_id = i.id AND av.calc_id = vAvailableCache WHERE date(t.shipped) = vDate AND categoryFk != 6 AND s.quantity > IFNULL(v.visible, 0) AND IFNULL(av.available, 0) < 0 AND s.isPicked = FALSE AND NOT i.generic AND vWarehouse = t.warehouseFk GROUP BY tl.ticketFk ON DUPLICATE KEY UPDATE isAvailable = 0; DELETE tl FROM tmp.ticketList tl JOIN tmp.ticketProblems tp ON tl.ticketFk = tp.ticketFk; INSERT INTO tmp.ticketProblems(ticketFk, isAvailable) SELECT tl.ticketFk, 0 FROM tmp.ticketList tl JOIN vn.ticket t ON t.id = tl.ticketFk LEFT JOIN vn.sale s ON s.ticketFk = t.id JOIN vn.item i ON i.id = s.itemFk JOIN vn.itemType it on it.id = i.typeFk LEFT JOIN cache.visible v ON i.id = v.item_id AND v.calc_id = vVisibleCache LEFT JOIN cache.available av ON av.item_id = i.id AND av.calc_id = vAvailableCache WHERE IFNULL(av.available, 0) >= 0 AND s.quantity > IFNULL(v.visible, 0) AND s.isPicked = FALSE AND s.reserved = FALSE AND it.categoryFk != 6 AND date(t.shipped) = vDate AND NOT i.generic AND CURDATE() = vDate AND t.warehouseFk = vWarehouse GROUP BY tl.ticketFk ON DUPLICATE KEY UPDATE isAvailable = 0; DELETE tl FROM tmp.ticketList tl JOIN tmp.ticketProblems tp ON tl.ticketFk = tp.ticketFk; END WHILE; CLOSE vCursor; SELECT * FROM tmp.ticketProblems; DROP TEMPORARY TABLE tmp.clientGetDebt, tmp.ticketList; END$$ DELIMITER ;