salix/db/routines/vn/procedures/inventoryMake.sql

270 lines
7.0 KiB
MySQL
Raw Normal View History

DELIMITER $$
2024-02-15 09:04:15 +00:00
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`inventoryMake`(vInventoryDate DATE)
BEGIN
/**
2024-02-15 09:04:15 +00:00
* Recalculate the inventories
*
2024-02-15 09:04:15 +00:00
* @param vInventoryDate date for the new inventory
*/
DECLARE vDone BOOL;
DECLARE vEntryFk INT;
DECLARE vTravelFk INT;
DECLARE vDateLastInventory DATE;
2024-02-15 09:04:15 +00:00
DECLARE vDateYesterday DATETIME DEFAULT vInventoryDate - INTERVAL 1 SECOND;
DECLARE vWarehouseOutFkInventory INT;
DECLARE vInventorySupplierFk INT;
DECLARE vAgencyModeFkInventory INT;
2024-02-15 09:04:15 +00:00
DECLARE vMaxRecentInventories INT;
DECLARE vWarehouseFk INT;
DECLARE cWarehouses CURSOR FOR
SELECT id
FROM warehouse
2024-02-15 09:04:15 +00:00
WHERE isInventory;
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
2024-02-15 09:04:15 +00:00
SELECT inventorySupplierFk INTO vInventorySupplierFk FROM entryConfig LIMIT 1;
SELECT inventoried INTO vDateLastInventory FROM config LIMIT 1;
SELECT maxRecentInventories,
warehouseOutFk,
agencyModeFk
INTO vMaxRecentInventories,
vWarehouseOutFkInventory,
vAgencyModeFkInventory
FROM inventoryConfig
LIMIT 1;
IF vDateLastInventory IS NULL
OR vInventorySupplierFk IS NULL
OR vMaxRecentInventories IS NULL
OR vInventoryDate IS NULL
OR vWarehouseOutFkInventory IS NULL
OR vAgencyModeFkInventory IS NULL THEN
CALL util.throw('Some config parameters are not set');
END IF;
START TRANSACTION;
OPEN cWarehouses;
2024-02-15 09:04:15 +00:00
-- Environment variable to disable the triggers of the affected tables
SET @isModeInventory := TRUE;
l: LOOP
SET vDone = FALSE;
2024-02-15 09:04:15 +00:00
SET vEntryFk = NULL;
SET vTravelFk = NULL;
FETCH cWarehouses INTO vWarehouseFk;
IF vDone THEN
LEAVE l;
END IF;
2024-02-15 09:04:15 +00:00
-- Generate travel, if it does not exist
SELECT id INTO vTravelFk
FROM travel
WHERE warehouseOutFk = vWarehouseOutFkInventory
2024-02-15 09:04:15 +00:00
AND warehouseInFk = vWarehouseFk
AND landed = vInventoryDate
AND agencyModeFk = vAgencyModeFkInventory
AND ref = 'inventario'
LIMIT 1;
2024-02-15 09:04:15 +00:00
IF vTravelFk IS NULL THEN
INSERT INTO travel
SET warehouseOutFk = vWarehouseOutFkInventory,
warehouseInFk = vWarehouseFk,
shipped = vInventoryDate,
landed = vInventoryDate,
agencyModeFk = vAgencyModeFkInventory,
ref = 'inventario',
isDelivered = TRUE,
isReceived = TRUE;
SELECT LAST_INSERT_ID() INTO vTravelFk;
END IF;
2024-02-15 09:04:15 +00:00
-- Generate an entry if it does not exist, or we empty it
SELECT id INTO vEntryFk
FROM entry
WHERE supplierFk = vInventorySupplierFk
AND travelFk = vTravelFk;
2024-02-15 09:04:15 +00:00
IF vEntryFk IS NULL 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;
2024-02-15 09:04:15 +00:00
-- Prepare the auxiliary table
CREATE OR REPLACE TEMPORARY TABLE tInventory (
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;
-- Buys
INSERT INTO tInventory(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
2024-02-15 09:04:15 +00:00
WHERE tr.warehouseInFk = vWarehouseFk
AND tr.landed BETWEEN vDateLastInventory AND vDateYesterday
AND NOT isRaid
GROUP BY b.itemFk;
2024-02-15 09:04:15 +00:00
-- Transfers
INSERT INTO tInventory(itemFk, quantity)
SELECT itemFk, quantityOut
2024-02-15 09:04:15 +00:00
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
2024-02-15 09:04:15 +00:00
WHERE tr.warehouseOutFk = vWarehouseFk
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;
2024-02-15 09:04:15 +00:00
-- Sales
INSERT INTO tInventory(itemFk, quantity)
SELECT itemFk, saleOut
2024-02-15 09:04:15 +00:00
FROM (
SELECT s.itemFk, - SUM(s.quantity) saleOut
FROM sale s
JOIN ticket t ON t.id = s.ticketFk
2024-02-15 09:04:15 +00:00
WHERE t.warehouseFk = vWarehouseFk
AND t.shipped BETWEEN vDateLastInventory AND vDateYesterday
GROUP BY s.itemFk
) sub
ON DUPLICATE KEY UPDATE quantity = IFNULL(quantity,0) + sub.saleOut;
2024-02-15 09:04:15 +00:00
-- Update values of the last purchase
UPDATE tInventory inv
JOIN cache.last_buy lb ON lb.item_id = inv.itemFk AND lb.warehouse_id = vWarehouseFk
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;
2024-02-15 09:04:15 +00:00
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
2024-02-15 09:04:15 +00:00
FROM tInventory;
2024-02-15 09:04:15 +00:00
-- Update the 'lastUsed' field of the item
UPDATE item i
JOIN tInventory i2 ON i2.itemFk = i.id
SET i.lastUsed = NOW()
WHERE i2.quantity;
DROP TEMPORARY TABLE tInventory;
END LOOP;
2024-02-15 09:04:15 +00:00
CLOSE cWarehouses;
2024-02-15 09:04:15 +00:00
UPDATE config SET inventoried = vInventoryDate;
2024-02-15 09:04:15 +00:00
SET @isModeInventory := FALSE;
CREATE OR REPLACE TEMPORARY TABLE tEntryToDelete
(INDEX(entryId)) ENGINE = MEMORY
SELECT e.id entryId,
t.id travelId
FROM travel t
JOIN `entry` e ON e.travelFk = t.id
2024-02-15 09:04:15 +00:00
JOIN (
SELECT t.shipped
FROM travel t
JOIN `entry` e ON e.travelFk = t.id
WHERE e.supplierFk = vInventorySupplierFk
AND t.shipped <= vInventoryDate
GROUP BY t.shipped
ORDER BY t.shipped DESC
OFFSET vMaxRecentInventories ROWS
) sub
WHERE e.supplierFk = vInventorySupplierFk
2024-02-15 09:04:15 +00:00
AND t.shipped IN (sub.shipped);
2024-02-15 09:04:15 +00:00
DELETE e
FROM `entry` e
2024-02-15 09:04:15 +00:00
JOIN tEntryToDelete tmp ON tmp.entryId = e.id;
DELETE IGNORE t
FROM travel t
2024-02-15 09:04:15 +00:00
JOIN tEntryToDelete tmp ON tmp.travelId = t.id;
DROP TEMPORARY TABLE IF EXISTS tEntryToDelete;
COMMIT;
END$$
DELIMITER ;