salix/db/routines/vn2008/procedures/buy_transfer.sql

105 lines
3.0 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_transfer`(IN `v_buy` INT, IN `entryFk` INT)
proc: BEGIN
/**
* Traslada la cantidad restante de una compra de Holanda
* al almacén de Silla.
*/
DECLARE v_wh INT;
DECLARE v_fv INT;
DECLARE v_amount INT;
DECLARE v_item INT;
DECLARE v_holland_wh INT DEFAULT 7;
DECLARE vIsIgnored BOOL DEFAULT FALSE;
DECLARE vDestinationWarehouse INT;
-- Comprueba que es mercancía que llega al almacén de Holanda
SELECT t.warehouse_id, IF(tp.warehouseFk=1,1,0), tp.warehouseFk, c.Id_Article, c.Novincular
INTO v_wh, v_fv, vDestinationWarehouse, v_item, vIsIgnored
FROM Compres c
JOIN Entradas e ON c.Id_Entrada = e.Id_Entrada
JOIN travel t ON t.id = e.travel_id
JOIN Articles a ON a.Id_Article = c.Id_Article
JOIN Tipos tp ON tp.tipo_id = a.tipo_id
WHERE c.Id_Compra = v_buy;
IF v_wh != v_holland_wh THEN
LEAVE proc;
END IF;
IF entryFk IS NULL THEN
LEAVE proc;
END IF;
-- Calcula la cantidad a trasladar
SELECT IFNULL(SUM(amount), 0) INTO v_amount
FROM (
SELECT SUM(c.Cantidad) amount
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 t.landing = util.VN_CURDATE()
AND t.warehouse_id = v_holland_wh
UNION ALL
SELECT -SUM(c.Cantidad)
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 t.shipment = util.VN_CURDATE()
AND t.warehouse_id_out = v_holland_wh
UNION ALL
SELECT -SUM(Cantidad)
FROM Movimientos m
JOIN Tickets t ON t.Id_Ticket = m.Id_Ticket
WHERE m.Id_Article = v_item
AND t.Fecha = util.VN_CURDATE()
AND t.warehouse_id = v_holland_wh
) t;
IF v_amount <= 0 THEN
LEAVE proc;
END IF;
-- Si la linea tiene no vincular hay que buscar la anterior válida
IF vIsIgnored THEN
CALL buyUltimate(vDestinationWarehouse, util.VN_CURDATE());
SELECT buyFk INTO v_buy
FROM tmp.buyUltimate
LIMIT 1;
DROP TEMPORARY TABLE IF EXISTS tmp.buyUltimate;
END IF;
-- Crea la nueva línea de compra con el translado
INSERT INTO Compres (
Id_Article, Etiquetas, Cantidad, Id_Entrada,
Id_Cubo, Packing, `grouping`, caja, Costefijo, Portefijo,
Embalajefijo, Comisionfija, buy_edi_id)
SELECT c.Id_Article,
v_amount DIV c.Packing,
v_amount,
entryFk,
c.Id_Cubo,
c.Packing,
c.`grouping`,
c.caja,
@cost := IFNULL(c.Costefijo, 0) + IFNULL(c.Comisionfija, 0) + IFNULL(c.Portefijo, 0),
@porte := ROUND((@cm3:= vn.item_getVolume(c.Id_Article, c.Id_Cubo)) * a.m3 / 1000000 / c.Packing, 3),
c.EmbalajeFijo,
@comision := ROUND(c.Costefijo * e.comision / 100, 3),
c.buy_edi_id
FROM Compres c
JOIN Cubos cu ON cu.Id_Cubo = c.Id_Cubo
JOIN Entradas e ON e.Id_Entrada = entryFk
JOIN travel t ON t.id = e.travel_id
JOIN Agencias a ON t.agency_id = a.Id_Agencia
WHERE c.Id_Compra = v_buy;
CALL buy_tarifas (LAST_INSERT_ID());
END$$
DELIMITER ;