salix/db/routines/vn/procedures/ticket_canAdvance.sql

122 lines
3.9 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_canAdvance`(vDateFuture DATE, vDateToAdvance DATE, vWarehouseFk INT)
BEGIN
/**
* Devuelve los tickets y la cantidad de lineas de venta que se pueden adelantar.
*
* @param vDateFuture Fecha de los tickets que se quieren adelantar.
* @param vDateToAdvance Fecha a cuando se quiere adelantar.
* @param vWarehouseFk Almacén
*/
DECLARE vDateInventory DATE;
SELECT inventoried INTO vDateInventory FROM config;
CREATE OR REPLACE TEMPORARY TABLE tStock
(itemFk INT PRIMARY KEY, amount INT)
ENGINE = MEMORY;
INSERT INTO tStock(itemFk, amount)
SELECT itemFk, SUM(quantity) amount FROM
(
SELECT itemFk, quantity
FROM itemTicketOut
WHERE shipped >= vDateInventory
AND shipped < vDateFuture
AND warehouseFk = vWarehouseFk
UNION ALL
SELECT itemFk, quantity
FROM itemEntryIn
WHERE landed >= vDateInventory
AND landed < vDateFuture
AND isVirtualStock = FALSE
AND warehouseInFk = vWarehouseFk
UNION ALL
SELECT itemFk, quantity
FROM itemEntryOut
WHERE shipped >= vDateInventory
AND shipped < vDateFuture
AND warehouseOutFk = vWarehouseFk
) t
GROUP BY itemFk HAVING amount != 0;
CREATE OR REPLACE TEMPORARY TABLE tmp.filter
(INDEX (id))
SELECT dest.*,
origin.*,
IFNULL(dest.nickname, origin.nickname) nickname,
(origin.futureLines = origin.hasStock) AS isFullMovable,
origin.futureLines - origin.hasStock AS notMovableLines
FROM (
SELECT s.ticketFk futureId,
t.workerFk,
t.shipped futureShipped,
t.totalWithVat futureTotalWithVat,
st.name futureState,
t.addressFk futureAddressFk,
am.name futureAgency,
count(s.id) futureLines,
GROUP_CONCAT(DISTINCT ipt.code ORDER BY ipt.code) futureIpt,
CAST(SUM(litros) AS DECIMAL(10,0)) futureLiters,
SUM((s.quantity <= IFNULL(tst.amount,0))) hasStock,
st.classColor futureClassColor,
(
count(s.id) -
SUM((s.quantity <= IFNULL(tst.amount,0)))
) notMovableLines,
(
count(s.id) =
SUM((s.quantity <= IFNULL(tst.amount,0)))
) isFullMovable
FROM ticket t
JOIN sale s ON s.ticketFk = t.id
JOIN saleVolume sv ON sv.saleFk = s.id
JOIN item i ON i.id = s.itemFk
JOIN ticketState ts ON ts.ticketFk = t.id
JOIN `state` st ON st.id = ts.stateFk
JOIN agencyMode am ON t.agencyModeFk = am.id
LEFT JOIN itemPackingType ipt ON ipt.code = i.itemPackingTypeFk
LEFT JOIN tStock tst ON tst.itemFk = i.id
WHERE t.shipped BETWEEN vDateFuture AND util.dayend(vDateFuture)
AND t.warehouseFk = vWarehouseFk
GROUP BY t.id
) origin
JOIN (
SELECT t.id,
t.addressFk,
st.name state,
GROUP_CONCAT(DISTINCT ipt.code ORDER BY ipt.code) ipt,
t.shipped,
t.totalWithVat,
am.name agency,
CAST(SUM(litros) AS DECIMAL(10,0)) liters,
CAST(COUNT(*) AS DECIMAL(10,0)) `lines`,
st.classColor,
CONCAT_WS(':',
COALESCE(HOUR(t.shipped), HOUR(zc.hour), HOUR(z.hour)),
COALESCE(MINUTE(t.shipped), MINUTE(zc.hour), MINUTE(z.hour))
) preparation
FROM ticket t
JOIN sale s ON s.ticketFk = t.id
JOIN saleVolume sv ON sv.saleFk = s.id
JOIN item i ON i.id = s.itemFk
JOIN ticketState ts ON ts.ticketFk = t.id
JOIN `state` st ON st.id = ts.stateFk
JOIN agencyMode am ON t.agencyModeFk = am.id
JOIN ticketCanAdvanceConfig
LEFT JOIN itemPackingType ipt ON ipt.code = i.itemPackingTypeFk
LEFT JOIN `zone` z ON z.id = t.zoneFk
LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk
WHERE t.shipped BETWEEN vDateToAdvance AND util.dayend(vDateToAdvance)
AND t.warehouseFk = vWarehouseFk
AND st.order <= destinationOrder
GROUP BY t.id
) dest ON dest.addressFk = origin.futureAddressFk
WHERE origin.hasStock;
DROP TEMPORARY TABLE tStock;
END$$
DELIMITER ;