129 lines
3.1 KiB
SQL
129 lines
3.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buy_getSplit`(vSelf INT, vDated DATE)
|
|
BEGIN
|
|
/**
|
|
* Devuelve tantos registros como etiquetas se necesitan para cada uno de los cubos o cajas de
|
|
* las ventas correspondientes a la compra que se pasa como parámetro, en los almacenes que tienen
|
|
* habilitada la venta de productos con stock virtual, aunque los productos pueden ser de cualquier tipo.
|
|
*
|
|
* @param vSelf Identificador de vn.buy
|
|
* @param vDated Fecha de preparación de las ventas que queremos etiquetar
|
|
*/
|
|
DECLARE vItemFk INT;
|
|
DECLARE vPacking INT;
|
|
DECLARE vRemaining INT;
|
|
DECLARE vLabels INT;
|
|
DECLARE vSaleFk INT;
|
|
DECLARE vAmount INT;
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vCounter INT DEFAULT 1;
|
|
|
|
DECLARE cur CURSOR FOR
|
|
SELECT s.id, s.quantity - IFNULL(l.stem, 0)
|
|
FROM vn.sale s
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
JOIN vn.warehouse w ON w.id = t.warehouseFk
|
|
LEFT JOIN vn.saleLabel l ON l.saleFk = s.id
|
|
WHERE s.itemFk = vItemFk
|
|
AND t.shipped >= vDated
|
|
AND w.isLogiflora
|
|
AND IFNULL(l.stem, 0) < s.quantity
|
|
ORDER BY s.quantity = vRemaining DESC
|
|
LOCK IN SHARE MODE;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
|
SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
START TRANSACTION;
|
|
|
|
-- Obtiene los datos de la compra
|
|
|
|
SELECT itemFk, packing, quantity
|
|
INTO vItemFk, vPacking, vRemaining
|
|
FROM vn.buy WHERE id = vSelf;
|
|
|
|
-- Crea splits de los tickets
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.split
|
|
(
|
|
id INT,
|
|
labels INT DEFAULT 0,
|
|
counter INT DEFAULT 0
|
|
)
|
|
ENGINE = MEMORY;
|
|
|
|
OPEN cur;
|
|
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
|
|
FETCH cur INTO vSaleFk, vAmount;
|
|
|
|
IF vDone OR vRemaining = 0 THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
SET vAmount = LEAST(vAmount, vRemaining);
|
|
|
|
SET vRemaining = vRemaining - vAmount;
|
|
|
|
SET vLabels = vAmount DIV vPacking;
|
|
|
|
-- Se inserta una linea por cada etiqueta
|
|
SET vCounter = 1;
|
|
|
|
WHILE vLabels >= vCounter DO
|
|
INSERT INTO tmp.split
|
|
SET
|
|
id = vSaleFk,
|
|
labels = vLabels,
|
|
counter = vCounter;
|
|
|
|
SET vCounter = vCounter + 1;
|
|
END WHILE;
|
|
|
|
INSERT INTO vn.saleLabel
|
|
SET
|
|
saleFk = vSaleFk,
|
|
stem = vAmount,
|
|
label = vLabels
|
|
ON DUPLICATE KEY UPDATE
|
|
stem = stem + VALUES(stem),
|
|
label = label + VALUES(label);
|
|
END LOOP;
|
|
|
|
CLOSE cur;
|
|
|
|
-- Devuelve los splits creados
|
|
SELECT CONCAT(sp.counter,'/',sp.labels) labels,
|
|
COALESCE(sfc.nickname, sfa.nickname, a.nickname) destination,
|
|
s.itemFk,
|
|
i.longName,
|
|
i.`size`,
|
|
vn.ticketSplitCounter(t.id) counter,
|
|
IF(sfa.id OR sfc.id,
|
|
a.nickname,
|
|
CONCAT(a.id, ' ', p.`name`,' (', c.`code`,')')) destination2
|
|
FROM tmp.split sp
|
|
JOIN vn.sale s ON sp.id = s.id
|
|
JOIN vn.item i ON i.id = s.itemFk
|
|
JOIN vn.ticket t ON t.id = s.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
|
|
LEFT JOIN vn.splitFilter sfa ON sfa.autonomyFk = p.autonomyFk
|
|
LEFT JOIN vn.splitFilter sfc ON sfc.clientFk = t.clientFk;
|
|
|
|
-- Limpia y confirma cambios
|
|
DROP TEMPORARY TABLE
|
|
tmp.split;
|
|
|
|
COMMIT;
|
|
END$$
|
|
DELIMITER ;
|