DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`inventario_valorado`(IN vDated DATE, IN vIsDetailed BOOLEAN) BEGIN /** * DEPRECATED usar item_ValuateInventory */ DECLARE vInventoried DATE; DECLARE vHasNotInventory BOOLEAN DEFAULT 0; DECLARE vInventoried2 DATE; DECLARE vDateDayEnd DATETIME; SET vDateDayEnd = util.dayEnd(vDated); SELECT landing INTO vInventoried FROM travel tr JOIN Entradas E ON E.travel_id = tr.id WHERE landing <= vDateDayEnd AND E.Id_Proveedor = 4 ORDER BY landing DESC LIMIT 1; SET vHasNotInventory = IF (vInventoried is null, TRUE, FALSE); IF vHasNotInventory THEN SELECT landing INTO vInventoried2 FROM travel tr JOIN Entradas E ON E.travel_id = tr.id WHERE landing >= vDated AND E.Id_Proveedor = 4 ORDER BY landing ASC LIMIT 1; SET vInventoried = TIMESTAMPADD(DAY,1,vDated); SET vDateDayEnd = vInventoried2; END IF; DROP TEMPORARY TABLE IF EXISTS inv; CREATE TEMPORARY TABLE inv (warehouseFk SMALLINT, Id_Article BIGINT, cantidad INT, coste DOUBLE DEFAULT 0, total DOUBLE DEFAULT 0, Almacen VARCHAR(20), PRIMARY KEY (Almacen, Id_Article) USING HASH) ENGINE = MEMORY; IF vHasNotInventory = TRUE THEN INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT tr.warehouse_id, C.Id_Article, SUM(C.Cantidad), w.`name` FROM Compres C JOIN Articles A USING(Id_Article) JOIN Entradas E USING (Id_Entrada) JOIN travel tr ON tr.id = E.travel_id JOIN Tipos t USING(tipo_id) JOIN warehouse w ON w.id = warehouse_id WHERE landing = vDateDayEnd AND E.Id_Proveedor = 4 AND w.valuatedInventory AND t.inventory GROUP BY tr.warehouse_id, C.Id_Article; END IF; INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT tr.warehouse_id, C.Id_Article, C.Cantidad * IF(vHasNotInventory,-1,1), w.`name` FROM Compres C JOIN Articles A USING(Id_Article) JOIN Entradas E USING (Id_Entrada) JOIN travel tr ON tr.id = E.travel_id JOIN Tipos t USING(tipo_id) JOIN warehouse w ON w.id = tr.warehouse_id WHERE landing BETWEEN vInventoried AND vDateDayEnd AND IF(landing = util.VN_CURDATE(), tr.received, trUE) AND NOT redada AND w.valuatedInventory AND t.inventory ON DUPLICATE KEY UPDATE inv.cantidad = inv.cantidad + (C.Cantidad * IF(vHasNotInventory,-1,1)); INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT tr.warehouse_id_out, C.Id_Article, C.Cantidad * IF(vHasNotInventory,1,-1), w.`name` FROM Compres C JOIN Articles A USING(Id_Article) JOIN Entradas E USING (Id_Entrada) JOIN travel tr ON tr.id = E.travel_id JOIN Tipos t USING(tipo_id) JOIN warehouse w ON w.id = warehouse_id_out WHERE shipment BETWEEN vInventoried AND vDateDayEnd AND NOT redada AND w.valuatedInventory AND t.inventory ON DUPLICATE KEY UPDATE inv.cantidad = inv.cantidad + (C.Cantidad * IF(vHasNotInventory,1,-1)); INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT w.id, M.Id_Article, M.Cantidad * IF(vHasNotInventory,1,-1), w.`name` FROM Movimientos M JOIN Tickets T USING (Id_Ticket) JOIN Clientes C USING(Id_Cliente) JOIN Articles A USING(Id_Article) JOIN Tipos t USING(tipo_id) JOIN warehouse w ON w.id = warehouse_id WHERE T.Fecha BETWEEN vInventoried AND vDateDayEnd AND w.valuatedInventory AND t.inventory ON DUPLICATE KEY UPDATE inv.cantidad = inv.cantidad + M.Cantidad * IF(vHasNotInventory,1,-1); IF vDated = util.VN_CURDATE() THEN -- volver a poner lo que esta aun en las estanterias INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT w.id, M.Id_Article, M.Cantidad * IF(vHasNotInventory,0,1), w.`name` FROM Movimientos M JOIN Tickets T USING (Id_Ticket) JOIN Clientes C USING(Id_Cliente) JOIN Articles A USING(Id_Article) JOIN Tipos t USING(tipo_id) JOIN warehouse w ON w.id = warehouse_id WHERE T.Fecha BETWEEN vDated AND vDateDayEnd AND (M.OK <> 0 or T.Etiquetasemitidas <> 0 ) AND w.valuatedInventory AND t.inventory ON DUPLICATE KEY UPDATE inv.cantidad = inv.cantidad + M.Cantidad * IF(vHasNotInventory,0,1); END IF; -- Mercancia en transito INSERT INTO inv(warehouseFk, Id_Article, cantidad, Almacen) SELECT tr.warehouse_id, C.Id_Article, C.Cantidad, CONCAT(wOut.`name`,' - ', wIn.`name`) FROM Compres C JOIN Articles A USING(Id_Article) JOIN Entradas E USING (Id_Entrada) JOIN travel tr ON tr.id = E.travel_id JOIN Tipos t USING(tipo_id) JOIN warehouse wIn ON wIn.id = tr.warehouse_id JOIN warehouse wOut ON wOut.id = tr.warehouse_id_out WHERE vDated >= shipment AND vDated < landing AND NOT redada AND wIn.valuatedInventory AND t.inventory AND E.Confirmada ON DUPLICATE KEY UPDATE inv.cantidad = inv.cantidad + (C.Cantidad); CALL vn.buyUltimate(NULL,vDateDayEnd); UPDATE inv i JOIN tmp.buyUltimate bu ON i.warehouseFk = bu.warehouseFk AND i.Id_Article = bu.itemFk JOIN Compres C ON C.Id_Compra = bu.buyFk SET total = i.cantidad * (ifnull(C.Costefijo,0) + IFNULL(C.Embalajefijo,0) + IFNULL(C.Portefijo,0) + IFNULL(C.Comisionfija,0)), coste = ifnull(C.Costefijo,0) + IFNULL(C.Embalajefijo,0) + IFNULL(C.Portefijo,0) + IFNULL(C.Comisionfija,0) WHERE i.cantidad <> 0; DELETE FROM inv WHERE Cantidad IS NULL or Cantidad = 0; IF vIsDetailed THEN SELECT inv.warehouseFk, a.Id_Article, a.Article, a.Medida, inv.Cantidad, tp.Id_Tipo, tp.reino_id, inv.coste, cast(inv.total as decimal(10,2)) total, Almacen FROM inv JOIN warehouse w on w.id = warehouseFk JOIN Articles a ON a.Id_Article = inv.Id_Article JOIN Tipos tp ON tp.tipo_id = a.tipo_id WHERE w.valuatedInventory and inv.total > 0 order by inv.total desc; ELSE SELECT i.Almacen, r.reino as Reino, cast(i.total as decimal(10,2)) as Euros, tr.Codigotrabajador as Comprador,A.Id_Article FROM inv i JOIN warehouse w on w.id = warehouseFk JOIN Articles A USING(Id_Article) JOIN Tipos t USING(tipo_id) LEFT JOIN Trabajadores tr ON tr.Id_trabajador = t.Id_trabajador JOIN reinos r ON r.id = t.reino_id WHERE w.valuatedInventory AND i.total > 0; END IF; DROP TEMPORARY TABLE tmp.buyUltimate; DROP TEMPORARY TABLE inv; end$$ DELIMITER ;