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