221 lines
7.0 KiB
SQL
221 lines
7.0 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_valuateInventory`(
|
|
vDated DATE
|
|
)
|
|
BEGIN
|
|
DECLARE vInventoried DATE;
|
|
DECLARE vHasNotInventory BOOLEAN DEFAULT FALSE;
|
|
DECLARE vInventoryClone DATE;
|
|
DECLARE vDateDayEnd DATETIME;
|
|
DECLARE vInventorySupplierFk INT;
|
|
|
|
SELECT inventorySupplierFk INTO vInventorySupplierFk
|
|
FROM entryConfig;
|
|
|
|
SET vDateDayEnd = util.dayEnd(vDated);
|
|
|
|
SELECT tr.landed INTO vInventoried
|
|
FROM travel tr
|
|
JOIN `entry` e ON e.travelFk = tr.id
|
|
WHERE tr.landed <= vDateDayEnd
|
|
AND e.supplierFk = vInventorySupplierFk
|
|
ORDER BY tr.landed DESC
|
|
LIMIT 1;
|
|
|
|
SET vHasNotInventory = (vInventoried IS NULL);
|
|
|
|
IF vHasNotInventory THEN
|
|
SELECT landed INTO vInventoryClone
|
|
FROM travel tr
|
|
JOIN `entry` e ON e.travelFk = tr.id
|
|
WHERE tr.landed >= vDated
|
|
AND e.supplierFk = vInventorySupplierFk
|
|
ORDER BY landed ASC
|
|
LIMIT 1;
|
|
|
|
SET vInventoried = vDated + INTERVAL 1 DAY;
|
|
SET vDateDayEnd = vInventoryClone;
|
|
END IF;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tInventory(
|
|
warehouseFk SMALLINT,
|
|
itemFk BIGINT,
|
|
quantity INT,
|
|
volume DECIMAL(10,2),
|
|
cost DOUBLE DEFAULT 0,
|
|
total DOUBLE DEFAULT 0,
|
|
warehouseInventory VARCHAR(20),
|
|
PRIMARY KEY (warehouseInventory, itemFk) USING HASH
|
|
)
|
|
ENGINE = MEMORY;
|
|
|
|
-- Inventario inicial
|
|
IF vHasNotInventory THEN
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT tr.warehouseInFk,
|
|
b.itemFk,
|
|
SUM(b.quantity),
|
|
w.name
|
|
FROM buy b
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN `entry` e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN itemType t ON t.id = i.typeFk
|
|
JOIN warehouse w ON w.id = tr.warehouseInFk
|
|
WHERE tr.landed = vDateDayEnd
|
|
AND e.supplierFk = vInventorySupplierFk
|
|
AND w.valuatedInventory
|
|
AND t.isInventory
|
|
GROUP BY tr.warehouseInFk, b.itemFk;
|
|
ELSE
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT tr.warehouseInFk,
|
|
b.itemFk,
|
|
SUM(b.quantity),
|
|
w.name
|
|
FROM buy b
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN `entry` e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN itemType t ON t.id = i.typeFk
|
|
JOIN warehouse w ON w.id = tr.warehouseInFk
|
|
WHERE tr.landed = vInventoried
|
|
AND e.supplierFk = vInventorySupplierFk
|
|
AND w.valuatedInventory
|
|
AND t.isInventory
|
|
GROUP BY tr.warehouseInFk, b.itemFk;
|
|
END IF;
|
|
|
|
-- Añadimos las entradas
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT tr.warehouseInFk,
|
|
b.itemFk,
|
|
b.quantity * IF(vHasNotInventory, -1, 1),
|
|
w.name
|
|
FROM buy b
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN `entry` e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN itemType t ON t.id = i.typeFk
|
|
JOIN warehouse w ON w.id = tr.warehouseInFk
|
|
WHERE tr.landed BETWEEN vInventoried AND vDateDayEnd
|
|
AND IF(tr.landed = util.VN_CURDATE(), tr.isReceived, TRUE)
|
|
AND NOT e.isRaid
|
|
AND w.valuatedInventory
|
|
AND t.isInventory
|
|
AND e.supplierFk <> vInventorySupplierFk
|
|
ON DUPLICATE KEY UPDATE tInventory.quantity = tInventory.quantity + (b.quantity * IF(vHasNotInventory, -1, 1));
|
|
|
|
-- Descontamos las salidas
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT tr.warehouseOutFk,
|
|
b.itemFk,
|
|
b.quantity * IF(vHasNotInventory, 1, -1),
|
|
w.name
|
|
FROM buy b
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN `entry` e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN itemType t ON t.id = i.typeFk
|
|
JOIN warehouse w ON w.id = tr.warehouseOutFk
|
|
WHERE tr.shipped BETWEEN vInventoried AND vDateDayEnd
|
|
AND NOT e.isRaid
|
|
AND w.valuatedInventory
|
|
AND t.isInventory
|
|
ON DUPLICATE KEY UPDATE tInventory.quantity = tInventory.quantity + (b.quantity * IF(vHasNotInventory,1,-1));
|
|
|
|
-- Descontamos las lineas de venta
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT w.id,
|
|
s.itemFk,
|
|
s.quantity * IF(vHasNotInventory, 1, -1),
|
|
w.name
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
JOIN `client` c ON c.id = t.clientFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
JOIN itemType it ON it.id = i.typeFk
|
|
JOIN warehouse w ON w.id = t.warehouseFk
|
|
WHERE t.shipped BETWEEN vInventoried AND vDateDayEnd
|
|
AND w.valuatedInventory
|
|
AND it.isInventory
|
|
ON DUPLICATE KEY UPDATE tInventory.quantity = tInventory.quantity + s.quantity * IF(vHasNotInventory, 1, -1);
|
|
|
|
-- Volver a poner lo que esta aun en las estanterias
|
|
IF vDated = util.VN_CURDATE() THEN
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT w.id,
|
|
s.itemFk,
|
|
s.quantity * IF(vHasNotInventory, 0, 1),
|
|
w.name
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
JOIN `client` c ON c.id = t.clientFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
JOIN itemType it ON it.id = i.typeFk
|
|
JOIN warehouse w ON w.id = t.warehouseFk
|
|
WHERE t.shipped BETWEEN vDated AND vDateDayEnd
|
|
AND NOT (s.isPicked OR t.isLabeled)
|
|
AND w.valuatedInventory
|
|
AND it.isInventory
|
|
ON DUPLICATE KEY UPDATE tInventory.quantity = tInventory.quantity + s.quantity * IF(vHasNotInventory, 0, 1);
|
|
END IF;
|
|
|
|
-- Mercancia en transito
|
|
INSERT INTO tInventory(warehouseFk, itemFk, quantity, warehouseInventory)
|
|
SELECT tr.warehouseInFk,
|
|
b.itemFk,
|
|
b.quantity,
|
|
CONCAT(wOut.`name`, ' - ', wIn.`name`)
|
|
FROM buy b
|
|
JOIN item i ON i.id = b.itemFk
|
|
JOIN `entry` e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN itemType t ON t.id = i.typeFk
|
|
JOIN warehouse wIn ON wIn.id = tr.warehouseInFk
|
|
JOIN warehouse wOut ON wOut.id = tr.warehouseOutFk
|
|
WHERE vDated >= tr.shipped AND vDated < tr.landed
|
|
AND NOT isRaid
|
|
AND wIn.valuatedInventory
|
|
AND t.isInventory
|
|
AND e.isConfirmed
|
|
ON DUPLICATE KEY UPDATE tInventory.quantity = tInventory.quantity + (b.quantity);
|
|
|
|
CALL buyUltimate(NULL, vDateDayEnd);
|
|
|
|
DELETE FROM tInventory WHERE quantity IS NULL OR NOT quantity;
|
|
|
|
UPDATE tInventory i
|
|
JOIN tmp.buyUltimate bu ON i.warehouseFk = bu.warehouseFk AND i.itemFk = bu.itemFk
|
|
JOIN buy b ON b.id = bu.buyFk
|
|
LEFT JOIN itemCost ic ON ic.itemFk = i.itemFk
|
|
AND ic.warehouseFk = i.warehouseFk
|
|
SET i.total = i.quantity * (IFNULL(b.buyingValue, 0) + IFNULL(b.packageValue, 0) + IFNULL(b.freightValue, 0) + IFNULL(b.comissionValue, 0)),
|
|
i.cost = IFNULL(b.buyingValue, 0) + IFNULL(b.packageValue, 0) + IFNULL(b.freightValue, 0) + IFNULL(b.comissionValue, 0),
|
|
i.volume = i.quantity * ic.cm3delivery / 1000000;
|
|
|
|
SELECT ti.warehouseFk,
|
|
i.id,
|
|
i.longName,
|
|
i.size,
|
|
ti.quantity,
|
|
ti.volume,
|
|
tp.name itemTypeName,
|
|
ic.name itemCategoryName,
|
|
ti.cost,
|
|
ti.total,
|
|
ti.warehouseInventory
|
|
FROM tInventory ti
|
|
JOIN warehouse w ON w.id = warehouseFk
|
|
JOIN item i ON i.id = ti.itemFk
|
|
JOIN itemType tp ON tp.id = i.typeFk
|
|
JOIN itemCategory ic ON ic.id = tp.categoryFk
|
|
WHERE w.valuatedInventory
|
|
AND ti.total > 0;
|
|
|
|
DROP TEMPORARY TABLE
|
|
tmp.buyUltimate,
|
|
tInventory;
|
|
END$$
|
|
DELIMITER ;
|