151 lines
4.1 KiB
SQL
151 lines
4.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_split`(IN `v_buy` INT, IN `v_entry` INT)
|
|
BEGIN
|
|
|
|
-- DEPRECATED use vn.buySplit
|
|
|
|
DECLARE v_item INT;
|
|
DECLARE v_packing INT;
|
|
DECLARE v_remaining INT;
|
|
DECLARE v_labels INT;
|
|
DECLARE v_remainder INT;
|
|
DECLARE v_is_buy INT;
|
|
DECLARE v_id INT;
|
|
DECLARE v_amount INT;
|
|
DECLARE v_done BOOL DEFAULT FALSE;
|
|
DECLARE vNameCharMax INT DEFAULT 16;
|
|
|
|
DECLARE cur CURSOR FOR
|
|
SELECT TRUE, c.Id_Compra, c.Cantidad - IFNULL((c.Vida * c.Packing), 0)
|
|
FROM Compres c
|
|
JOIN Entradas e ON e.Id_Entrada = c.Id_Entrada
|
|
JOIN travel t ON t.id = e.travel_id
|
|
WHERE c.Id_Article = v_item
|
|
AND DATE(t.shipment) = util.VN_CURDATE() AND t.warehouse_id_out IN (7, 40)
|
|
AND t.warehouse_id NOT IN (60)
|
|
AND NOT e.redada AND NOT e.Inventario
|
|
AND IFNULL(c.Vida, 0) < c.Etiquetas
|
|
UNION ALL
|
|
SELECT FALSE, m.Id_Movimiento, m.Cantidad - IFNULL(l.stem, 0)
|
|
FROM Movimientos m
|
|
JOIN Tickets t ON t.Id_Ticket = m.Id_Ticket
|
|
LEFT JOIN movement_label l ON l.Id_Movimiento = m.Id_Movimiento
|
|
WHERE m.Id_Article = v_item
|
|
AND t.Fecha >= util.VN_CURDATE() AND t.warehouse_id IN (7, 40)
|
|
AND NOT t.Etiquetasemitidas
|
|
AND IFNULL(l.stem, 0) < m.Cantidad
|
|
LOCK IN SHARE MODE;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
|
SET v_done = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
START TRANSACTION;
|
|
|
|
-- Obtiene los datos de la compra
|
|
|
|
SELECT Id_Article, Packing, Cantidad
|
|
INTO v_item, v_packing, v_remaining
|
|
FROM Compres WHERE Id_Compra = v_buy;
|
|
|
|
-- Crea splits de los tickets
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.split;
|
|
CREATE TEMPORARY TABLE tmp.split
|
|
(
|
|
is_buy BOOL,
|
|
id INT,
|
|
labels INT,
|
|
remainder INT
|
|
)
|
|
ENGINE = MEMORY;
|
|
|
|
OPEN cur;
|
|
|
|
l: LOOP
|
|
SET v_done = FALSE;
|
|
FETCH cur INTO v_is_buy, v_id, v_amount;
|
|
|
|
IF v_done OR v_remaining = 0 THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
SET v_amount = LEAST(v_amount, v_remaining);
|
|
SET v_remaining = v_remaining - v_amount;
|
|
SET v_labels = v_amount DIV v_packing;
|
|
|
|
INSERT INTO tmp.split
|
|
VALUES (v_is_buy, v_id, v_labels, v_amount % v_packing);
|
|
|
|
IF v_is_buy
|
|
THEN
|
|
UPDATE Compres
|
|
SET Vida = Vida + v_labels
|
|
WHERE Id_Compra = v_id;
|
|
ELSE
|
|
INSERT INTO movement_label
|
|
SET
|
|
Id_Movimiento = v_id,
|
|
stem = v_amount,
|
|
label = v_labels
|
|
ON DUPLICATE KEY UPDATE
|
|
stem = stem + VALUES(stem),
|
|
label = label + VALUES(label);
|
|
END IF;
|
|
END LOOP;
|
|
|
|
CLOSE cur;
|
|
|
|
-- Crea los movimientos de almacén a silla
|
|
|
|
CALL buy_transfer (v_buy, v_entry);
|
|
|
|
UPDATE Compres SET dispatched = Vida * Packing
|
|
WHERE Id_Compra = v_buy;
|
|
|
|
-- Devuelve los splits creados
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.aux;
|
|
CREATE TEMPORARY TABLE tmp.aux
|
|
ENGINE = MEMORY
|
|
SELECT s.labels, s.remainder, w.`name` destination,
|
|
a.Id_Article, a.Article, a.Medida, ' ' counter, ' ' destination2
|
|
FROM tmp.split s
|
|
JOIN Compres c ON c.Id_Compra = s.id
|
|
JOIN Articles a ON a.Id_Article = c.Id_Article
|
|
JOIN Entradas e ON e.Id_Entrada = c.Id_Entrada
|
|
JOIN travel t ON t.id = e.travel_id
|
|
JOIN warehouse w ON t.warehouse_id = w.id
|
|
WHERE s.is_buy;
|
|
|
|
INSERT INTO tmp.aux
|
|
SELECT s.labels, s.remainder, IF(p.`name` IN ('BARCELONA','TARRAGONA','GIRONA','LLEIDA','LÉRIDA') AND t.Id_Cliente != 93, '<< VILASSAR >>',o.Consignatario),
|
|
a.Id_Article, a.Article, a.Medida,
|
|
vn.ticketSplitCounter(t.Id_Ticket), IF(p.`name` IN ('BARCELONA','TARRAGONA','GIRONA','LLEIDA','LÉRIDA') AND t.Id_Cliente != 93, o.Consignatario,CONCAT(o.id_consigna, ' ', p.`name`,' (', c.`code`,')'))
|
|
/*UCASE(CONCAT(p.`name`,' (', c.`code`, ')'))*/
|
|
FROM tmp.split s
|
|
JOIN Movimientos m ON m.Id_Movimiento = s.id
|
|
JOIN Articles a ON a.Id_Article = m.Id_Article
|
|
JOIN Tickets t ON t.Id_Ticket = m.Id_Ticket
|
|
JOIN Consignatarios o ON o.Id_Consigna = t.Id_Consigna
|
|
JOIN vn.province p ON p.id = o.province_id
|
|
JOIN vn.country c ON c.id = p.countryFk
|
|
WHERE NOT s.is_buy;
|
|
|
|
SELECT * FROM tmp.aux;
|
|
|
|
-- Limpia y confirma cambios
|
|
|
|
DROP TEMPORARY TABLE
|
|
tmp.split,
|
|
tmp.aux;
|
|
|
|
COMMIT;
|
|
END$$
|
|
DELIMITER ;
|