183 lines
6.5 KiB
SQL
183 lines
6.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`traslado`(IN i_entrada INTEGER)
|
|
BEGIN
|
|
DECLARE dateShipment DATE;
|
|
DECLARE dateLanding DATE;
|
|
DECLARE warehouseShipment INTEGER;
|
|
DECLARE warehouseLanding INTEGER;
|
|
DECLARE v_calc_visible INTEGER;
|
|
DECLARE vInventoryDate DATE;
|
|
|
|
SET vInventoryDate := vn.getInventoryDate();
|
|
SELECT shipment, landing, warehouse_id_out, warehouse_id
|
|
INTO dateShipment, dateLanding, warehouseShipment, warehouseLanding
|
|
FROM travel t JOIN Entradas e ON t.id = e.travel_id
|
|
WHERE Id_Entrada = i_entrada;
|
|
|
|
CALL vn.rate_getPrices(dateShipment, warehouseLanding);
|
|
|
|
-- Traslado en almacen origen
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS buy_edi_temp;
|
|
CREATE TEMPORARY TABLE buy_edi_temp
|
|
(KEY (Id_Article), INDEX(Id_Compra)) ENGINE = MEMORY
|
|
SELECT *
|
|
FROM (SELECT c.Id_Article, c.Id_Compra
|
|
FROM Compres c INNER JOIN Entradas e USING(Id_Entrada)
|
|
INNER JOIN travel t ON t.id = e.travel_id
|
|
WHERE t.landing BETWEEN vInventoryDate AND dateShipment
|
|
AND c.Novincular = FALSE
|
|
AND c.Tarifa2 >= 0
|
|
ORDER BY (warehouseShipment = t.warehouse_id) DESC, t.landing DESC
|
|
LIMIT 10000000000000000000) t
|
|
GROUP BY Id_Article;
|
|
|
|
IF dateShipment >= util.VN_CURDATE() THEN
|
|
CALL `cache`.visible_refresh(v_calc_visible, TRUE, warehouseShipment);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.item;
|
|
|
|
CREATE TEMPORARY TABLE tmp.item (
|
|
`itemFk` int(10) unsigned NOT NULL,
|
|
`visible` int(11) NOT NULL DEFAULT 0,
|
|
`available` int(11) NOT NULL DEFAULT 0,
|
|
`visibleLanding` int(11) NOT NULL DEFAULT 0,
|
|
`availableLanding` int(11) NOT NULL DEFAULT 0,
|
|
UNIQUE INDEX i USING HASH (itemFk)
|
|
) ENGINE = MEMORY;
|
|
|
|
INSERT INTO tmp.item(itemFk, visible)
|
|
SELECT item_id itemFk, visible
|
|
FROM `cache`.visible
|
|
WHERE calc_id = v_calc_visible
|
|
AND visible;
|
|
|
|
CALL `cache`.visible_refresh(v_calc_visible, TRUE, warehouseLanding);
|
|
|
|
INSERT INTO tmp.item(itemFk, visibleLanding)
|
|
SELECT item_id, `visible`
|
|
FROM `cache`.`visible` v
|
|
WHERE v.calc_id = v_calc_visible
|
|
AND v.`visible`
|
|
ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`;
|
|
|
|
CALL availableTraslate(warehouseShipment, dateShipment, NULL);
|
|
|
|
INSERT INTO tmp.item(itemFk, available)
|
|
SELECT a.item_id, a.available
|
|
FROM availableTraslate a
|
|
WHERE a.available
|
|
ON DUPLICATE KEY UPDATE available = a.available;
|
|
|
|
CALL availableTraslate(warehouseLanding, dateLanding, warehouseShipment);
|
|
|
|
INSERT INTO tmp.item(itemFk, availableLanding)
|
|
SELECT a.item_id, a.available
|
|
FROM availableTraslate a
|
|
WHERE a.available
|
|
ON DUPLICATE KEY UPDATE availableLanding = a.available;
|
|
ELSE
|
|
CALL vn.item_getStock(warehouseShipment, dateShipment, NULL);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.item;
|
|
CREATE TEMPORARY TABLE tmp.item (UNIQUE INDEX i USING HASH (itemFk)) ENGINE = MEMORY
|
|
SELECT itemFk, `visible`, available , 0 visibleLanding, 0 availableLanding
|
|
FROM tmp.itemList;
|
|
|
|
DROP TEMPORARY TABLE tmp.itemList;
|
|
END IF;
|
|
|
|
CALL vn.buyUltimateFromInterval(warehouseLanding,vInventoryDate, dateLanding);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS Traslados;
|
|
CREATE TEMPORARY TABLE Traslados ENGINE = MEMORY
|
|
SELECT tp.Id_Tipo AS Tipo,
|
|
tp.reino_id,
|
|
ar.tipo_id,
|
|
ar.Id_Article AS article_id,
|
|
ar.Article,
|
|
ar.Medida,
|
|
ar.Categoria,
|
|
ar.Color,
|
|
Origen.abreviatura as Origen,
|
|
CE.Cantidad,
|
|
ar.Tallos,
|
|
CAST(AIM.visible AS DECIMAL(10,0)) as vis1,
|
|
CAST(AIM.available AS DECIMAL(10,0)) as dis1,
|
|
CAST(AIM.visibleLanding AS DECIMAL(10,0)) as vis2,
|
|
CAST(AIM.availableLanding AS DECIMAL(10,0)) as dis2,
|
|
COALESCE(CE.`grouping`, C.`grouping`) as `grouping`,
|
|
COALESCE(CE.Packing, C.Packing) as Packing,
|
|
COALESCE(cl.caja, CE.caja, C.caja) as caja,
|
|
IFNULL(p.name, P2.Alias) AS Productor,
|
|
C.Id_Cubo,
|
|
1 Tinta,
|
|
CE.Id_Compra,
|
|
CE.Etiquetas,
|
|
C.buy_edi_id,
|
|
tp.Id_Trabajador,
|
|
CB.Volumen,
|
|
IFNULL(CB.x,0) x,
|
|
IFNULL(CB.y,0) y,
|
|
IFNULL(CB.z,0) z,
|
|
IFNULL(C.Costefijo,0) Costefijo,
|
|
IFNULL(C.Comisionfija,0) Comisionfija,
|
|
IFNULL(C.Portefijo,0) Portefijo,
|
|
A.m3,
|
|
E.comision,
|
|
CB.Retornable,
|
|
IFNULL(CEB.Valor,CB.Valor) Valor,
|
|
r.rate3 t3, r.rate2 t2, tp.promo,
|
|
C.`grouping` groupingOrigin,
|
|
C.Packing PackingOrigin,
|
|
C.Id_Compra CompraOrigin,
|
|
CB.costeRetorno,
|
|
C.weight
|
|
FROM Articles ar
|
|
JOIN tmp.item AIM ON AIM.itemFk = ar.Id_Article
|
|
LEFT JOIN producer p ON p.producer_id = ar.producer_id
|
|
LEFT JOIN Tipos tp ON tp.tipo_id = ar.tipo_id
|
|
JOIN vn.itemCategory ic ON ic.id = tp.reino_id
|
|
LEFT JOIN Origen ON Origen.id = ar.id_origen
|
|
LEFT JOIN buy_edi_temp lb ON lb.Id_Article = ar.Id_Article
|
|
LEFT JOIN Compres C ON C.Id_Compra = lb.Id_Compra
|
|
LEFT JOIN Cubos CB ON CB.Id_Cubo = C.Id_Cubo
|
|
LEFT JOIN Entradas E2 ON E2.Id_Entrada = C.Id_Entrada
|
|
LEFT JOIN Proveedores P2 ON P2.Id_Proveedor = E2.Id_Proveedor
|
|
LEFT JOIN Entradas E ON E.Id_Entrada = i_entrada
|
|
LEFT JOIN travel TR ON TR.id = E.travel_id
|
|
LEFT JOIN Agencias A ON A.Id_Agencia = TR.agency_id
|
|
LEFT JOIN Compres CE ON CE.Id_Article = ar.Id_Article AND CE.Id_Entrada = i_entrada
|
|
LEFT JOIN Cubos CEB ON CEB.Id_Cubo = CE.Id_Cubo
|
|
LEFT JOIN tmp.rate r ON TRUE
|
|
LEFT JOIN tmp.buyUltimateFromInterval bufi ON bufi.itemFk = ar.Id_Article
|
|
LEFT JOIN Compres cl ON cl.Id_Compra = bufi.buyFk
|
|
WHERE ic.display
|
|
AND E.Redada = FALSE
|
|
AND (AIM.visible != 0 OR AIM.available != 0)
|
|
ORDER BY tipo_id, Article, article_id, Medida, Categoria, Origen;
|
|
|
|
CREATE INDEX tindex USING HASH ON Traslados (article_id);
|
|
|
|
SELECT t.*,
|
|
Cantidad - MOD(Cantidad , `grouping`) as Subcantidad,
|
|
MOD(Cantidad , `grouping`) as Soll,
|
|
ROUND((IF(Volumen > 0,Volumen,x * y * IF(z = 0, Medida + 10, z))) / Packing,0) as cm3,
|
|
Costefijo + Comisionfija + Portefijo AS Cost,
|
|
@porte := ROUND((IF(Volumen > 0,Volumen,x * y * IF(z = 0, Medida + 10, z))) * m3 / 1000000 / Packing ,3) AS Porte,
|
|
@comision := ROUND((Costefijo + Comisionfija + Portefijo) * comision / 100 ,3) AS Comision,
|
|
ROUND(@embalaje := (costeRetorno + IF(Retornable != 0, 0, Valor)) / packing ,3) AS Embalaje,
|
|
@coste := IFNULL((Costefijo + Comisionfija + Portefijo),0) + IFNULL(@embalaje,0) + IFNULL(@porte,0) + IFNULL(@comision,0) AS Coste,
|
|
@t3 := ROUND(@coste / ( (100 - t3 - t.promo)/100),2) AS Tarifa3,
|
|
ROUND(@t3 * (1 + ((t2 - t3)/100)),2) AS Tarifa2,
|
|
0 selected
|
|
FROM Traslados t;
|
|
|
|
DROP TEMPORARY TABLE Traslados;
|
|
DROP TEMPORARY TABLE tmp.item;
|
|
DROP TEMPORARY TABLE buy_edi_temp;
|
|
DROP TEMPORARY TABLE tmp.buyUltimateFromInterval;
|
|
DROP TEMPORARY TABLE tmp.rate;
|
|
END$$
|
|
DELIMITER ;
|