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

102 lines
2.6 KiB
MySQL
Raw Normal View History

2024-03-04 07:11:06 +00:00
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`absoluteInventoryHistory`(
2024-03-06 11:44:59 +00:00
vItemFk INT,
vWarehouseFk INT,
vDate DATETIME
)
2024-03-04 07:11:06 +00:00
BEGIN
/**
* Calcula y proporciona un historial de inventario absoluto
* para un artículo específico en un almacén dado
* hasta una fecha determinada.
*
2024-03-05 12:43:03 +00:00
* @param vItemFk Id de artículo
2024-03-06 11:44:59 +00:00
* @param vWarehouseFk Id de almacén
2024-03-04 07:11:06 +00:00
* @param vDate Fecha
*/
DECLARE vCalculatedInventory INT;
2024-03-06 11:44:59 +00:00
DECLARE vToday DATETIME DEFAULT util.VN_CURDATE();
2024-03-06 14:16:55 +00:00
DECLARE vStartDate DATE DEFAULT '2001-01-01';
2024-03-04 07:11:06 +00:00
2024-03-05 12:43:03 +00:00
CREATE OR REPLACE TEMPORARY TABLE tHistoricalPast
ENGINE = MEMORY
2024-03-04 07:11:06 +00:00
SELECT *
FROM (
2024-03-05 12:43:03 +00:00
SELECT tr.landed `date`,
b.quantity input,
NULL `output`,
2024-03-06 11:44:59 +00:00
tr.isReceived ok,
2024-03-05 12:43:03 +00:00
s.name alias,
e.invoiceNumber reference,
2024-03-04 07:11:06 +00:00
e.id id,
2024-03-05 12:43:03 +00:00
tr.isDelivered f5
2024-03-04 07:11:06 +00:00
FROM buy b
2024-03-05 12:43:03 +00:00
JOIN `entry` e ON e.id = b.entryFk
2024-03-04 07:11:06 +00:00
JOIN travel tr ON tr.id = e.travelFk
2024-03-05 12:43:03 +00:00
JOIN supplier s ON s.id = e.supplierFk
2024-03-06 14:16:55 +00:00
WHERE tr.landed >= vStartDate
AND s.id <> (SELECT supplierFk FROM inventoryConfig)
2024-03-06 11:44:59 +00:00
AND vWarehouseFk IN (tr.warehouseInFk, 0)
2024-03-05 12:43:03 +00:00
AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable
AND NOT e.isRaid
2024-03-04 07:11:06 +00:00
UNION ALL
2024-03-06 14:16:55 +00:00
SELECT tr.shipped,
NULL,
b.quantity,
tr.isDelivered,
s.name,
e.invoiceNumber,
e.id,
tr.isDelivered
2024-03-04 07:11:06 +00:00
FROM buy b
2024-03-05 12:43:03 +00:00
JOIN `entry` e ON e.id = b.entryFk
2024-03-04 07:11:06 +00:00
JOIN travel tr ON tr.id = e.travelFk
2024-03-05 12:43:03 +00:00
JOIN supplier s ON s.id = e.supplierFk
2024-03-06 14:16:55 +00:00
WHERE tr.shipped >= vStartDate
2024-03-06 11:44:59 +00:00
AND vWarehouseFk = tr.warehouseOutFk
2024-03-06 14:16:55 +00:00
AND s.id <> (SELECT supplierFk FROM inventoryConfig)
2024-03-05 12:43:03 +00:00
AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable
AND NOT e.isRaid
2024-03-04 07:11:06 +00:00
UNION ALL
2024-03-06 14:16:55 +00:00
SELECT t.shipped,
NULL,
m.quantity,
(m.isPicked OR t.isLabeled OR t.refFk IS NOT NULL),
t.nickname,
t.refFk,
2024-03-04 07:11:06 +00:00
t.id,
t.isPrinted
FROM sale m
2024-03-05 12:43:03 +00:00
JOIN ticket t ON t.id = m.ticketFk
JOIN client c ON c.id = t.clientFk
2024-03-06 14:16:55 +00:00
WHERE t.shipped >= vStartDate
2024-03-05 12:43:03 +00:00
AND m.itemFk = vItemFk
2024-03-06 14:16:55 +00:00
AND vWarehouseFk IN (t.warehouseFk, 0)
2024-03-06 08:00:21 +00:00
) t1
2024-03-05 12:43:03 +00:00
ORDER BY `date`, input DESC, ok DESC;
2024-03-04 07:11:06 +00:00
2024-03-06 11:44:59 +00:00
SELECT SUM(input) - SUM(`output`) INTO vCalculatedInventory
2024-03-05 12:43:03 +00:00
FROM tHistoricalPast
WHERE `date` < vDate;
2024-03-04 07:11:06 +00:00
SELECT p1.*, NULL v_virtual
2024-03-06 11:44:59 +00:00
FROM (
2024-03-05 12:43:03 +00:00
SELECT vDate `date`,
vCalculatedInventory input,
NULL `output`,
1 ok,
'Inventario calculado' alias,
'' reference,
0 id,
1 f5
2024-03-04 07:11:06 +00:00
UNION ALL
2024-03-05 12:43:03 +00:00
SELECT *
FROM tHistoricalPast
WHERE `date` >= vDate
2024-03-04 07:11:06 +00:00
) p1;
2024-03-05 12:43:03 +00:00
DROP TEMPORARY TABLE tHistoricalPast;
2024-03-04 07:11:06 +00:00
END$$
DELIMITER ;