266 lines
6.8 KiB
MySQL
266 lines
6.8 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`inventoryMake`(vDate DATE, vWh INT)
|
||
|
proc: BEGIN
|
||
|
/**
|
||
|
* Recalcula los inventarios de todos los almacenes, si vWh = 0
|
||
|
*
|
||
|
* @param vDate Fecha de los nuevos inventarios
|
||
|
* @param vWh almacen al cual hacer el inventario
|
||
|
*/
|
||
|
|
||
|
DECLARE vDone BOOL;
|
||
|
DECLARE vEntryFk INT;
|
||
|
DECLARE vTravelFk INT;
|
||
|
DECLARE vDateLastInventory DATE;
|
||
|
DECLARE vDateYesterday DATETIME DEFAULT vDate - INTERVAL 1 SECOND;
|
||
|
DECLARE vWarehouseOutFkInventory INT;
|
||
|
DECLARE vInventorySupplierFk INT;
|
||
|
DECLARE vAgencyModeFkInventory INT;
|
||
|
|
||
|
DECLARE cWarehouses CURSOR FOR
|
||
|
SELECT id
|
||
|
FROM warehouse
|
||
|
WHERE isInventory
|
||
|
AND vWh IN (0,id);
|
||
|
|
||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||
|
|
||
|
OPEN cWarehouses;
|
||
|
SET @isModeInventory := TRUE;
|
||
|
l: LOOP
|
||
|
|
||
|
SET vDone = FALSE;
|
||
|
FETCH cWarehouses INTO vWh;
|
||
|
|
||
|
IF vDone THEN
|
||
|
LEAVE l;
|
||
|
END IF;
|
||
|
|
||
|
SELECT w.id INTO vWarehouseOutFkInventory
|
||
|
FROM warehouse w
|
||
|
WHERE w.code = 'inv';
|
||
|
|
||
|
SELECT inventorySupplierFk INTO vInventorySupplierFk
|
||
|
FROM entryConfig;
|
||
|
|
||
|
SELECT am.id INTO vAgencyModeFkInventory
|
||
|
FROM agencyMode am
|
||
|
where code = 'inv';
|
||
|
|
||
|
SELECT MAX(landed) INTO vDateLastInventory
|
||
|
FROM travel tr
|
||
|
JOIN entry e ON e.travelFk = tr.id
|
||
|
JOIN buy b ON b.entryFk = e.id
|
||
|
WHERE warehouseOutFk = vWarehouseOutFkInventory
|
||
|
AND landed < vDate
|
||
|
AND e.supplierFk = vInventorySupplierFk
|
||
|
AND warehouseInFk = vWh
|
||
|
AND NOT isRaid;
|
||
|
|
||
|
IF vDateLastInventory IS NULL THEN
|
||
|
SELECT inventoried INTO vDateLastInventory FROM config;
|
||
|
END IF;
|
||
|
|
||
|
-- Generamos travel, si no existe.
|
||
|
SET vTravelFK = 0;
|
||
|
|
||
|
SELECT id INTO vTravelFk
|
||
|
FROM travel
|
||
|
WHERE warehouseOutFk = vWarehouseOutFkInventory
|
||
|
AND warehouseInFk = vWh
|
||
|
AND landed = vDate
|
||
|
AND agencyModeFk = vAgencyModeFkInventory
|
||
|
AND ref = 'inventario'
|
||
|
LIMIT 1;
|
||
|
|
||
|
IF NOT vTravelFK THEN
|
||
|
|
||
|
INSERT INTO travel SET
|
||
|
warehouseOutFk = vWarehouseOutFkInventory,
|
||
|
warehouseInFk = vWh,
|
||
|
shipped = vDate,
|
||
|
landed = vDate,
|
||
|
agencyModeFk = vAgencyModeFkInventory,
|
||
|
ref = 'inventario',
|
||
|
isDelivered = TRUE,
|
||
|
isReceived = TRUE;
|
||
|
|
||
|
SELECT LAST_INSERT_ID() INTO vTravelFk;
|
||
|
|
||
|
END IF;
|
||
|
|
||
|
-- Generamos entrada si no existe, o la vaciamos.
|
||
|
SET vEntryFk = 0;
|
||
|
|
||
|
SELECT id INTO vEntryFk
|
||
|
FROM entry
|
||
|
WHERE supplierFk = vInventorySupplierFk
|
||
|
AND travelFk = vTravelFk;
|
||
|
|
||
|
IF NOT vEntryFk THEN
|
||
|
|
||
|
INSERT INTO entry SET
|
||
|
supplierFk = vInventorySupplierFk,
|
||
|
isConfirmed = TRUE,
|
||
|
isOrdered = TRUE,
|
||
|
travelFk = vTravelFk;
|
||
|
|
||
|
SELECT LAST_INSERT_ID() INTO vEntryFk;
|
||
|
|
||
|
ELSE
|
||
|
|
||
|
DELETE FROM buy WHERE entryFk = vEntryFk;
|
||
|
|
||
|
END IF;
|
||
|
|
||
|
-- Preparamos tabla auxilar
|
||
|
CREATE OR REPLACE TEMPORARY TABLE tmp.inventory (
|
||
|
itemFk INT(11) NOT NULL PRIMARY KEY,
|
||
|
quantity int(11) DEFAULT '0',
|
||
|
buyingValue decimal(10,4) DEFAULT '0.0000',
|
||
|
freightValue decimal(10,3) DEFAULT '0.000',
|
||
|
packing int(11) DEFAULT '0',
|
||
|
`grouping` smallint(5) unsigned NOT NULL DEFAULT '1',
|
||
|
groupingMode tinyint(4) NOT NULL DEFAULT 0 ,
|
||
|
comissionValue decimal(10,3) DEFAULT '0.000',
|
||
|
packageValue decimal(10,3) DEFAULT '0.000',
|
||
|
packageFk varchar(10) COLLATE utf8_unicode_ci DEFAULT '--',
|
||
|
price1 decimal(10,2) DEFAULT '0.00',
|
||
|
price2 decimal(10,2) DEFAULT '0.00',
|
||
|
price3 decimal(10,2) DEFAULT '0.00',
|
||
|
minPrice decimal(10,2) DEFAULT '0.00',
|
||
|
producer varchar(50) COLLATE utf8_unicode_ci DEFAULT NULL,
|
||
|
INDEX (itemFK)) ENGINE = MEMORY;
|
||
|
|
||
|
-- Compras
|
||
|
INSERT INTO tmp.inventory(itemFk,quantity)
|
||
|
SELECT b.itemFk, SUM(b.quantity)
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel tr ON tr.id = e.travelFk
|
||
|
WHERE tr.warehouseInFk = vWh
|
||
|
AND tr.landed BETWEEN vDateLastInventory
|
||
|
AND vDateYesterday
|
||
|
AND NOT isRaid
|
||
|
GROUP BY b.itemFk;
|
||
|
SELECT vDateLastInventory , vDateYesterday;
|
||
|
|
||
|
-- Traslados
|
||
|
INSERT INTO tmp.inventory(itemFk, quantity)
|
||
|
SELECT itemFk, quantityOut
|
||
|
FROM (
|
||
|
SELECT b.itemFk,- SUM(b.quantity) quantityOut
|
||
|
FROM buy b
|
||
|
JOIN entry e ON e.id = b.entryFk
|
||
|
JOIN travel tr ON tr.id = e.travelFk
|
||
|
WHERE tr.warehouseOutFk = vWh
|
||
|
AND tr.shipped BETWEEN vDateLastInventory
|
||
|
AND vDateYesterday
|
||
|
AND NOT isRaid
|
||
|
GROUP BY b.itemFk
|
||
|
) sub
|
||
|
ON DUPLICATE KEY UPDATE quantity = IFNULL(quantity, 0) + sub.quantityOut;
|
||
|
|
||
|
-- Ventas
|
||
|
INSERT INTO tmp.inventory(itemFk,quantity)
|
||
|
SELECT itemFk, saleOut
|
||
|
FROM (
|
||
|
SELECT s.itemFk, - SUM(s.quantity) saleOut
|
||
|
FROM sale s
|
||
|
JOIN ticket t ON t.id = s.ticketFk
|
||
|
WHERE t.warehouseFk = vWh
|
||
|
AND t.shipped BETWEEN vDateLastInventory AND vDateYesterday
|
||
|
GROUP BY s.itemFk
|
||
|
) sub
|
||
|
ON DUPLICATE KEY UPDATE quantity = IFNULL(quantity,0) + sub.saleOut;
|
||
|
|
||
|
-- Actualiza valores de la ultima compra
|
||
|
UPDATE tmp.inventory inv
|
||
|
JOIN cache.last_buy lb ON lb.item_id = inv.itemFk AND lb.warehouse_id = vWh
|
||
|
JOIN buy b ON b.id = lb.buy_id
|
||
|
JOIN item i ON i.id = b.itemFk
|
||
|
LEFT JOIN producer p ON p.id = i.producerFk
|
||
|
SET inv.buyingValue = b.buyingValue,
|
||
|
inv.freightValue = b.freightValue,
|
||
|
inv.packing = b.packing,
|
||
|
inv.`grouping`= b.`grouping`,
|
||
|
inv.groupingMode = b.groupingMode,
|
||
|
inv.comissionValue = b.comissionValue,
|
||
|
inv.packageValue = b.packageValue,
|
||
|
inv.packageFk = b.packagingFk,
|
||
|
inv.price1 = b.price1,
|
||
|
inv.price2 = b.price2,
|
||
|
inv.price3 = b.price3,
|
||
|
inv.minPrice = b.minPrice,
|
||
|
inv.producer = p.name;
|
||
|
|
||
|
INSERT INTO buy( itemFk,
|
||
|
quantity,
|
||
|
buyingValue,
|
||
|
freightValue,
|
||
|
packing,
|
||
|
`grouping`,
|
||
|
groupingMode,
|
||
|
comissionValue,
|
||
|
packageValue,
|
||
|
packagingFk,
|
||
|
price1,
|
||
|
price2,
|
||
|
price3,
|
||
|
minPrice,
|
||
|
entryFk)
|
||
|
SELECT itemFk,
|
||
|
GREATEST(quantity, 0),
|
||
|
buyingValue,
|
||
|
freightValue,
|
||
|
packing,
|
||
|
`grouping`,
|
||
|
groupingMode,
|
||
|
comissionValue,
|
||
|
packageValue,
|
||
|
packageFk,
|
||
|
price1,
|
||
|
price2,
|
||
|
price3,
|
||
|
minPrice,
|
||
|
vEntryFk
|
||
|
FROM tmp.inventory;
|
||
|
|
||
|
SELECT vWh, COUNT(*), util.VN_NOW() FROM tmp.inventory;
|
||
|
|
||
|
-- Actualizamos el campo lastUsed de item
|
||
|
UPDATE item i
|
||
|
JOIN tmp.inventory i2 ON i2.itemFk = i.id
|
||
|
SET i.lastUsed = NOW()
|
||
|
WHERE i2.quantity;
|
||
|
|
||
|
-- DROP TEMPORARY TABLE tmp.inventory;
|
||
|
|
||
|
END LOOP;
|
||
|
|
||
|
CLOSE cWarehouses;
|
||
|
|
||
|
UPDATE config SET inventoried = vDate;
|
||
|
SET @isModeInventory := FALSE;
|
||
|
|
||
|
DROP TEMPORARY TABLE IF EXISTS tmp.entryToDelete;
|
||
|
CREATE TEMPORARY TABLE tmp.entryToDelete
|
||
|
(INDEX(entryId) USING BTREE) ENGINE = MEMORY
|
||
|
SELECT e.id as entryId,
|
||
|
t.id as travelId
|
||
|
FROM travel t
|
||
|
JOIN `entry` e ON e.travelFk = t.id
|
||
|
WHERE e.supplierFk = vInventorySupplierFk
|
||
|
AND t.shipped <= util.VN_CURDATE() - INTERVAL 12 DAY
|
||
|
AND (DAY(t.shipped) <> 1 OR shipped < util.VN_CURDATE() - INTERVAL 12 DAY);
|
||
|
|
||
|
DELETE e
|
||
|
FROM `entry` e
|
||
|
JOIN tmp.entryToDelete tmp ON tmp.entryId = e.id;
|
||
|
|
||
|
DELETE IGNORE t
|
||
|
FROM travel t
|
||
|
JOIN tmp.entryToDelete tmp ON tmp.travelId = t.id;
|
||
|
END$$
|
||
|
DELIMITER ;
|