salix/db/changes/234801/00-ticket_canAdvance_update...

153 lines
4.6 KiB
MySQL
Raw Normal View History

DELIMITER $$
$$
CREATE OR REPLACE 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 config;
CREATE OR REPLACE 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 itemTicketOut
WHERE shipped >= vDateInventory
AND shipped < vDateFuture
AND warehouseFk = vWarehouseFk
UNION ALL
SELECT itemFk, quantity
FROM itemEntryIn
WHERE landed >= vDateInventory
AND landed <= vDateToAdvance
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
origin.ticketFk futureId,
dest.ticketFk id,
dest.state,
origin.futureState,
origin.futureIpt,
dest.ipt,
origin.workerFk,
origin.futureLiters,
origin.futureLines,
dest.shipped,
origin.shipped futureShipped,
dest.totalWithVat,
origin.totalWithVat futureTotalWithVat,
dest.agency,
dest.agencyModeFk,
origin.futureAgency,
origin.agencyModeFk futureAgencyModeFk,
dest.lines,
dest.liters,
origin.futureLines - origin.hasStock AS notMovableLines,
(origin.futureLines = origin.hasStock) AS isFullMovable,
dest.zoneFk,
origin.futureZoneFk,
origin.futureZoneName,
origin.classColor futureClassColor,
dest.classColor,
origin.clientFk futureClientFk,
origin.addressFk futureAddressFk,
origin.warehouseFk futureWarehouseFk,
origin.companyFk futureCompanyFk,
IFNULL(dest.nickname, origin.nickname) nickname,
dest.landed
FROM (
SELECT
s.ticketFk,
c.salesPersonFk workerFk,
t.shipped,
t.totalWithVat,
st.name futureState,
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(st.amount,0))) hasStock,
z.id futureZoneFk,
z.name futureZoneName,
st.classColor,
t.clientFk,
t.nickname,
t.addressFk,
t.warehouseFk,
t.companyFk,
t.agencyModeFk
FROM ticket t
JOIN client c ON c.id = t.clientFk
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 zone z ON t.zoneFk = z.id
LEFT JOIN itemPackingType ipt ON ipt.code = i.itemPackingTypeFk
LEFT JOIN tmp.stock st ON st.itemFk = i.id
WHERE t.shipped BETWEEN vDateFuture AND util.dayend(vDateFuture)
AND t.warehouseFk = vWarehouseFk
GROUP BY t.id
) origin
LEFT JOIN (
SELECT
t.id ticketFk,
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,
t.clientFk,
t.nickname,
t.addressFk,
t.zoneFk,
t.warehouseFk,
t.companyFk,
t.landed,
t.agencyModeFk
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
WHERE t.shipped BETWEEN vDateToAdvance AND util.dayend(vDateToAdvance)
AND t.warehouseFk = vWarehouseFk
AND st.order <= 5
GROUP BY t.id
) dest ON dest.addressFk = origin.addressFk
WHERE origin.hasStock;
DROP TEMPORARY TABLE tmp.stock;
END$$
DELIMITER ;