salix/db/changes/230401/00-ticket_canAdvance.sql

102 lines
3.3 KiB
SQL

DROP PROCEDURE IF EXISTS vn.ticket_canAdvance;
DELIMITER $$
$$
CREATE DEFINER=`root`@`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 vn.config;
DROP TEMPORARY TABLE IF EXISTS tmp.stock;
CREATE TEMPORARY TABLE tmp.stock
(itemFk INT PRIMARY KEY,
amount INT)
ENGINE = MEMORY;
INSERT INTO tmp.stock(itemFk, amount)
SELECT itemFk, SUM(quantity) amount FROM
(
SELECT itemFk, quantity
FROM vn.itemTicketOut
WHERE shipped >= vDateInventory
AND shipped < vDateFuture
AND warehouseFk = vWarehouseFk
UNION ALL
SELECT itemFk, quantity
FROM vn.itemEntryIn
WHERE landed >= vDateInventory
AND landed < vDateFuture
AND isVirtualStock = FALSE
AND warehouseInFk = vWarehouseFk
UNION ALL
SELECT itemFk, quantity
FROM vn.itemEntryOut
WHERE shipped >= vDateInventory
AND shipped < vDateFuture
AND warehouseOutFk = vWarehouseFk
) t
GROUP BY itemFk HAVING amount != 0;
DROP TEMPORARY TABLE IF EXISTS tmp.filter;
CREATE TEMPORARY TABLE tmp.filter
(INDEX (id))
SELECT s.ticketFk futureId,
t2.ticketFk id,
count(DISTINCT s.id) saleCount,
t2.state,
t2.isNotValidated,
st.name futureState,
st.isNotValidated futureIsNotValidated,
GROUP_CONCAT(DISTINCT ipt.code ORDER BY ipt.code) futureIpt,
t2.ipt,
t.workerFk,
CAST(sum(litros) AS DECIMAL(10,0)) liters,
CAST(count(*) AS DECIMAL(10,0)) `lines`,
t2.shipped,
t.shipped futureShipped,
t2.totalWithVat,
t.totalWithVat futureTotalWithVat,
t2.hasStock
FROM vn.ticket t
JOIN vn.ticketState ts ON ts.ticketFk = t.id
JOIN vn.state st ON st.id = ts.stateFk
JOIN vn.saleVolume sv ON t.id = sv.ticketFk
JOIN (SELECT
t2.id ticketFk,
t2.addressFk,
st.isNotValidated,
st.name state,
GROUP_CONCAT(DISTINCT ipt.code ORDER BY ipt.code) ipt,
t2.shipped,
t2.totalWithVat,
sum((s.quantity <= IFNULL(st.amount,0))) hasStock
FROM vn.ticket t2
JOIN vn.sale s ON s.ticketFk = t2.id
JOIN vn.item i ON i.id = s.itemFk
JOIN vn.ticketState ts ON ts.ticketFk = t2.id
JOIN vn.state st ON st.id = ts.stateFk
LEFT JOIN vn.itemPackingType ipt ON ipt.code = i.itemPackingTypeFk
LEFT JOIN tmp.stock st ON st.itemFk = s.itemFk
WHERE t2.shipped BETWEEN vDateToAdvance AND util.dayend(vDateToAdvance)
AND t2.warehouseFk = vWarehouseFk
GROUP BY t2.id) t2 ON t2.addressFk = t.addressFk
JOIN vn.sale s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = s.itemFk
LEFT JOIN vn.itemPackingType ipt ON ipt.code = i.itemPackingTypeFk
WHERE t.shipped BETWEEN vDateFuture AND util.dayend(vDateFuture)
AND t.warehouseFk = vWarehouseFk
GROUP BY t.id;
DROP TEMPORARY TABLE tmp.stock;
END$$
DELIMITER ;