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

282 lines
6.8 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`(
vItemFk INT,
vWarehouseFk INT,
2024-07-04 07:17:22 +00:00
vDated DATETIME
)
BEGIN
/**
2024-07-05 05:06:40 +00:00
* Calcula el balance de un artículo.
2024-07-04 07:17:22 +00:00
*
* @vItemFk Id de artículo
* @vWarehouseFk Id de almacén
2024-07-05 05:06:40 +00:00
* @vDated Fecha a calcular, si es NULL muestra el histórico desde el inventario
*/
2024-07-12 05:18:37 +00:00
DECLARE vDateInventory DATETIME
DEFAULT (
SELECT IF(vDated, uc.mockUtcTime, c.inventoried)
FROM config c
JOIN util.config uc
);
DECLARE vSupplierInventoryFk INT
DEFAULT (SELECT supplierFk FROM inventoryConfig);
2024-07-12 05:18:37 +00:00
IF NOT vSupplierInventoryFk OR NOT vDateInventory THEN
2024-07-04 07:17:22 +00:00
CALL util.throw('Config variables are not set');
END IF;
CREATE OR REPLACE TEMPORARY TABLE tItemDiary
ENGINE = MEMORY
2024-05-10 11:05:44 +00:00
WITH entriesIn AS (
2024-07-05 05:06:40 +00:00
SELECT 'entry' originType,
e.id originId,
tr.landed shipped,
b.quantity `in`,
NULL `out`,
st.alertLevel ,
st.name stateName,
e.invoiceNumber reference,
2024-07-05 05:06:40 +00:00
'supplier' entityType,
s.id entityId,
s.name entityName,
IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked,
FALSE isTicket,
b.id lineFk,
NULL `order`,
NULL clientType,
NULL claimFk,
vSupplierInventoryFk inventorySupplierFk
2024-05-10 11:05:44 +00:00
FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk
JOIN vn.travel tr ON tr.id = e.travelFk
JOIN vn.supplier s ON s.id = e.supplierFk
JOIN vn.state st ON st.`code` = IF(tr.landed < util.VN_CURDATE()
OR (util.VN_CURDATE() AND tr.isReceived),
2024-05-10 11:05:44 +00:00
'DELIVERED',
'FREE')
WHERE tr.landed >= vDateInventory
2024-07-04 07:17:22 +00:00
AND tr.warehouseInFk = vWarehouseFk
AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable
AND NOT e.isRaid
2024-07-04 07:17:22 +00:00
),
entriesOut AS (
SELECT 'entry',
2024-07-05 05:06:40 +00:00
e.id originType,
tr.shipped,
2024-05-10 11:05:44 +00:00
NULL,
b.quantity,
st.alertLevel,
st.name stateName,
e.invoiceNumber,
2024-07-05 05:06:40 +00:00
'supplier' entityType,
s.id entityId,
s.name,
2024-05-10 11:05:44 +00:00
IF(st.`code` = 'DELIVERED' , TRUE, FALSE),
FALSE isTicket,
b.id,
NULL `order`,
NULL clientType,
NULL claimFk,
vSupplierInventoryFk
2024-05-10 11:05:44 +00:00
FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk
JOIN vn.travel tr ON tr.id = e.travelFk
JOIN vn.warehouse w ON w.id = tr.warehouseOutFk
JOIN vn.supplier s ON s.id = e.supplierFk
JOIN vn.state st ON st.`code` = IF(tr.shipped < util.VN_CURDATE()
OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived),
'DELIVERED',
'FREE')
2024-05-10 11:05:44 +00:00
WHERE tr.shipped >= vDateInventory
AND tr.warehouseOutFk = vWarehouseFk
2024-07-04 07:17:22 +00:00
AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
2024-05-10 11:05:44 +00:00
AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable
AND NOT w.isFeedStock
AND NOT e.isRaid
2024-07-04 07:17:22 +00:00
),
sales AS (
WITH itemSales AS (
SELECT DATE(t.shipped) shipped,
s.quantity,
st2.alertLevel,
st2.name,
t.refFk,
t.id ticketFk,
2024-07-05 05:06:40 +00:00
'client' entityType,
t.clientFk entityId,
t.nickname,
2024-07-04 07:17:22 +00:00
s.id saleFk,
st.`order`,
c.typeFk,
cb.claimFk
FROM vn.sale s
JOIN vn.ticket t ON t.id = s.ticketFk
LEFT JOIN vn.ticketLastState tls ON tls.ticketFk = t.id
LEFT JOIN vn.ticketTracking tt ON tt.id = tls.ticketTrackingFk
LEFT JOIN vn.state st ON st.id = tt.stateFk
2024-07-04 07:17:22 +00:00
JOIN vn.client c ON c.id = t.clientFk
JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(),
'DELIVERED',
IF (t.shipped > util.dayEnd(util.VN_CURDATE()),
'FREE',
IFNULL(st.code, 'FREE')))
LEFT JOIN vn.claimBeginning cb ON cb.saleFk = s.id
2024-07-04 07:17:22 +00:00
WHERE t.shipped >= vDateInventory
AND s.itemFk = vItemFk
AND t.warehouseFk = vWarehouseFk
2024-07-04 07:17:22 +00:00
)
SELECT 'ticket',
2024-07-05 05:06:40 +00:00
s.ticketFk,
s.shipped,
NULL `in`,
s.quantity,
s.alertLevel,
s.name,
s.refFk,
2024-07-05 05:06:40 +00:00
s.entityType,
s.entityId,
s.nickname,
2024-07-04 07:17:22 +00:00
IF(stk.saleFk, TRUE, FALSE),
TRUE,
s.saleFk,
s.`order`,
s.typeFk,
s.claimFk,
NULL
2024-07-04 07:17:22 +00:00
FROM itemSales s
2024-05-10 11:05:44 +00:00
LEFT JOIN vn.state stPrep ON stPrep.`code` = 'PREPARED'
LEFT JOIN vn.saleTracking stk ON stk.saleFk = s.saleFk
AND stk.stateFk = stPrep.id
GROUP BY s.saleFk
2024-07-04 07:17:22 +00:00
),
orders AS (
2024-07-05 05:06:40 +00:00
SELECT 'order' originType,
o.id originId,
r.shipment,
2024-07-04 07:17:22 +00:00
NULL 'in',
r.amount,
NULL alertLevel,
NULL stateName,
NULL invoiceNumber,
2024-07-05 05:06:40 +00:00
'client' entityType,
c.id,
c.name,
2024-07-04 07:17:22 +00:00
FALSE,
FALSE isTicket,
NULL buyFk,
NULL 'order',
c.typeFk,
NULL claimFk,
NULL
2024-07-04 07:17:22 +00:00
FROM hedera.orderRow r
JOIN hedera.`order` o ON o.id = r.orderFk
JOIN vn.client c ON c.id = o.customer_id
WHERE r.shipment >= vDateInventory
AND r.warehouseFk = vWarehouseFk
AND r.created >= (
SELECT SUBTIME(util.VN_NOW(), reserveTime)
FROM hedera.orderConfig
)
2024-07-04 07:17:22 +00:00
AND NOT o.confirmed
AND r.itemFk = vItemFk
)
SELECT * FROM entriesIn
2024-05-10 11:05:44 +00:00
UNION ALL
SELECT * FROM entriesOut
UNION ALL
2024-07-04 07:17:22 +00:00
SELECT * FROM sales
UNION ALL
SELECT * FROM orders
2024-05-10 11:05:44 +00:00
ORDER BY shipped,
(inventorySupplierFk = entityId) DESC,
2024-05-10 11:05:44 +00:00
alertLevel DESC,
isTicket,
`order` DESC,
isPicked DESC,
`in` DESC,
`out` DESC;
2024-07-04 07:17:22 +00:00
IF vDated IS NULL THEN
SET @a := 0;
SET @currentLineFk := 0;
SET @shipped := '';
2024-07-05 05:06:40 +00:00
SELECT t.originType,
t.originId,
DATE(@shipped:= t.shipped) shipped,
2024-04-08 09:35:10 +00:00
t.alertLevel,
t.stateName,
t.reference,
2024-07-05 05:06:40 +00:00
t.entityType,
t.entityId,
t.entityName,
2024-04-08 09:35:10 +00:00
t.`in` invalue,
t.`out`,
@a := @a + IFNULL(t.`in`, 0) - IFNULL(t.`out`, 0) balance,
@currentLineFk := IF (@shipped < util.VN_CURDATE()
2024-04-08 11:28:38 +00:00
OR (@shipped = util.VN_CURDATE() AND (t.isPicked OR a.`code` >= 'ON_PREPARATION')),
2024-04-08 09:35:10 +00:00
t.lineFk,
@currentLineFk) lastPreparedLineFk,
2024-04-08 09:35:10 +00:00
t.isTicket,
t.lineFk,
t.isPicked,
t.clientType,
t.claimFk,
t.`order`
2024-04-08 09:35:10 +00:00
FROM tItemDiary t
LEFT JOIN alertLevel a ON a.id = t.alertLevel;
ELSE
2024-05-03 05:51:04 +00:00
SELECT IFNULL(SUM(IFNULL(`in`, 0)) - SUM(IFNULL(`out`, 0)), 0) INTO @a
FROM tItemDiary
2024-07-04 07:17:22 +00:00
WHERE shipped < vDated;
2024-07-05 05:06:40 +00:00
SELECT NULL originType,
NULL originId,
vDated shipped,
NULL alertLevel,
NULL stateName,
NULL reference,
2024-07-05 05:06:40 +00:00
NULL entityType,
NULL entityId,
'Inventario calculado',
@a invalue,
NULL `out`,
@a balance,
NULL lastPreparedLineFk,
NULL isTicket,
NULL lineFk,
NULL isPicked,
NULL clientType,
NULL claimFk,
NULL `order`
UNION ALL
2024-07-05 05:06:40 +00:00
SELECT originType,
originId,
shipped,
alertlevel,
stateName,
2024-07-05 05:06:40 +00:00
reference,
entityType,
entityId,
entityName,
`in`,
`out`,
@a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0),
0,
isTicket,
lineFk,
isPicked,
clientType,
2024-04-08 08:06:33 +00:00
claimFk,
`order`
FROM tItemDiary
2024-07-04 07:17:22 +00:00
WHERE shipped >= vDated;
END IF;
2024-07-11 12:44:46 +00:00
DROP TEMPORARY TABLE tItemDiary;
END$$
DELIMITER ;