salix/db/changes/10503-november/00-ticket_canbePostponed.sql

80 lines
2.6 KiB
SQL

DROP PROCEDURE IF EXISTS `vn`.`ticket_canbePostponed`;
DELIMITER $$
$$
CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_canbePostponed`(vOriginDated DATE, vFutureDated DATE, vLitersMax INT, vLinesMax INT, vWarehouseFk INT)
BEGIN
/**
* Devuelve un listado de tickets susceptibles de fusionarse con otros tickets en el futuro
*
* @param vOriginDated Fecha en cuestión
* @param vFutureDated Fecha en el futuro a sondear
* @param vLitersMax Volumen máximo de los tickets a catapultar
* @param vLinesMax Número máximo de lineas de los tickets a catapultar
* @param vWarehouseFk Identificador de vn.warehouse
*/
DROP TEMPORARY TABLE IF EXISTS tmp.filter;
CREATE TEMPORARY TABLE tmp.filter
(INDEX (id))
SELECT sv.ticketFk id,
GROUP_CONCAT(DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk) ipt,
CAST(sum(litros) AS DECIMAL(10,0)) liters,
CAST(count(*) AS DECIMAL(10,0)) `lines`,
st.name state,
sub2.id ticketFuture,
t.landed originETD,
sub2.landed destETD,
sub2.iptd tfIpt,
sub2.state tfState,
t.clientFk,
t.warehouseFk,
ts.alertLevel,
t.shipped,
sub2.shipped tfShipped,
t.workerFk,
st.code code,
sub2.code tfCode
FROM vn.saleVolume sv
JOIN vn.sale s ON s.id = sv.saleFk
JOIN vn.item i ON i.id = s.itemFk
JOIN vn.ticket t ON t.id = sv.ticketFk
JOIN vn.address a ON a.id = t.addressFk
JOIN vn.province p ON p.id = a.provinceFk
JOIN vn.country c ON c.id = p.countryFk
JOIN vn.ticketState ts ON ts.ticketFk = t.id
JOIN vn.state st ON st.id = ts.stateFk
JOIN vn.alertLevel al ON al.id = ts.alertLevel
LEFT JOIN vn.ticketParking tp ON tp.ticketFk = t.id
LEFT JOIN (
SELECT *
FROM (
SELECT
t.addressFk ,
t.id,
t.landed,
t.shipped,
st.name state,
st.code code,
GROUP_CONCAT(DISTINCT i.itemPackingTypeFk ORDER BY i.itemPackingTypeFk) iptd
FROM vn.ticket t
JOIN vn.ticketState ts ON ts.ticketFk = t.id
JOIN vn.state st ON st.id = ts.stateFk
JOIN vn.sale s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = s.itemFk
WHERE t.shipped BETWEEN vFutureDated
AND util.dayend(vFutureDated)
AND t.warehouseFk = vWarehouseFk
GROUP BY t.id
) sub
GROUP BY sub.addressFk
) sub2 ON sub2.addressFk = t.addressFk AND t.id != sub2.id
WHERE t.shipped BETWEEN vOriginDated AND util.dayend(vOriginDated)
AND t.warehouseFk = vWarehouseFk
AND al.code = 'FREE'
AND tp.ticketFk IS NULL
GROUP BY sv.ticketFk
HAVING liters <= IFNULL(vLitersMax, 9999) AND `lines` <= IFNULL(vLinesMax, 9999) AND ticketFuture;
END$$
DELIMITER ;