salix/services/db/install/changes/1.0.10/05-ticketGetProblems.sql

147 lines
4.7 KiB
SQL

USE `vn`;
DROP procedure IF EXISTS `ticketGetProblems`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketGetProblems`()
BEGIN
/*
* Necesita la tabla tmp.ticket
*
*/
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.ticket 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),
problem VARCHAR(50),
INDEX (ticketFk)
)
ENGINE = MEMORY;
-- CONGELADO
INSERT INTO tmp.ticketProblems(ticketFk, problem)
SELECT DISTINCT tt.ticketFk, 'Freezed'
FROM tmp.ticket tt
JOIN vn.client c ON c.id = tt.clientFk
WHERE c.isFreezed;
-- eliminamos tickets con problemas para no volverlos a mirar
DROP TEMPORARY TABLE IF EXISTS tmp.ticketListFiltered;
CREATE TEMPORARY TABLE tmp.ticketListFiltered
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT tt.ticketFk, c.id
FROM tmp.ticket tt
JOIN vn.client c ON c.id = tt.clientFk
WHERE c.isFreezed = 0;
DROP TEMPORARY TABLE IF EXISTS tmp.client_list;
CREATE TEMPORARY TABLE tmp.client_list
(PRIMARY KEY (Id_Cliente))
ENGINE = MEMORY
SELECT DISTINCT tt.clientFk AS Id_Cliente
FROM tmp.ticket tt;
-- RIESGO
CALL vn2008.risk_vs_client_list(CURDATE());
INSERT INTO tmp.ticketProblems(ticketFk, problem)
SELECT DISTINCT tt.ticketFk, 'Risk'
FROM tmp.ticketListFiltered tt
JOIN vn.ticket t ON t.id = tt.ticketFk
JOIN vn.agencyMode a ON t.agencyModeFk = a.id
JOIN tmp.risk r ON r.Id_Cliente = t.clientFk
JOIN vn.client c ON c.id = t.clientFk
WHERE r.risk > c.credit + 10
AND a.deliveryMethodFk != 3; -- para que las recogidas se preparen
-- eliminamos tickets con problemas para no volverlos a mirar
DELETE tlf FROM tmp.ticketListFiltered tlf
JOIN tmp.ticketProblems tp ON tlf.ticketFk = tp.ticketFk;
-- CODIGO 100
INSERT INTO tmp.ticketProblems(ticketFk, problem)
SELECT DISTINCT tt.ticketFk, 'Code 100'
FROM tmp.ticket tt
JOIN sale s ON s.ticketFk = tt.ticketFk
WHERE s.itemFk = 100;
-- eliminamos tickets con problemas para no volverlos a mirar
DELETE tlf FROM tmp.ticketListFiltered tlf
JOIN tmp.ticketProblems tp ON tlf.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);
-- El disponible es menor que 0
INSERT INTO tmp.ticketProblems(ticketFk, problem)
SELECT tt.ticketFk, i.name
FROM tmp.ticket tt
JOIN vn.ticket t ON t.id = tt.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;
-- eliminamos tickets con problemas para no volverlos a mirar
DELETE tlf FROM tmp.ticketListFiltered tlf
JOIN tmp.ticketProblems tp ON tlf.ticketFk = tp.ticketFk;
-- Amarillo: El disponible es mayor que cero y la cantidad supera el visible, estando aun sin preparar
INSERT INTO tmp.ticketProblems(ticketFk, problem)
SELECT tt.ticketFk, CONCAT('Delay', i.name)
FROM tmp.ticket tt
JOIN vn.ticket t ON t.id = tt.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;
END WHILE;
CLOSE vCursor;
DROP TEMPORARY TABLE tmp.ticketListFiltered;
END$$
DELIMITER ;