feat: refs #6769 itemDiary #2683

Merged
guillermo merged 10 commits from 6769-itemDiary into dev 2024-07-12 08:13:29 +00:00
3 changed files with 148 additions and 130 deletions

View File

@ -2,94 +2,84 @@ DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`( CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`(
vItemFk INT, vItemFk INT,
vWarehouseFk INT, vWarehouseFk INT,
vDate DATETIME vDated DATETIME
) )
BEGIN BEGIN
/** /**
* @vItemFk item a buscar * Calcula el balance de un artículo.
* @vWarehouseFk almacen donde buscar *
* @vDate Si la fecha es null, muestra el histórico desde el inventario. * @vItemFk Id de artículo
* Si la fecha no es null, muestra histórico desde la fecha de vDate. * @vWarehouseFk Id de almacén
* @vDated Fecha a calcular, si es NULL muestra el histórico desde el inventario
*/ */
DECLARE vDateInventory DATETIME; 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);
IF vDate IS NULL THEN IF NOT vSupplierInventoryFk OR NOT vDateInventory THEN
SELECT inventoried INTO vDateInventory CALL util.throw('Config variables are not set');
FROM config;
ELSE
SELECT mockUtcTime INTO vDateInventory
FROM util.config;
END IF; END IF;
CREATE OR REPLACE TEMPORARY TABLE tItemDiary( CREATE OR REPLACE TEMPORARY TABLE tItemDiary
shipped DATE, ENGINE = MEMORY
`in` INT(11),
`out` INT(11),
alertLevel INT(11),
stateName VARCHAR(20),
`name` VARCHAR(50),
reference VARCHAR(50),
origin INT(11),
clientFk INT(11),
isPicked INT(11),
isTicket TINYINT(1),
lineFk INT(11),
`order` TINYINT(3) UNSIGNED,
clientType VARCHAR(20),
claimFk INT(10) UNSIGNED,
inventorySupplierFk INT(10)
);
INSERT INTO tItemDiary
WITH entriesIn AS ( WITH entriesIn AS (
SELECT tr.landed shipped, SELECT 'entry' originType,
e.id originId,
tr.landed shipped,
b.quantity `in`, b.quantity `in`,
NULL `out`, NULL `out`,
st.alertLevel , st.alertLevel ,
st.name stateName, st.name stateName,
s.name `name`,
e.invoiceNumber reference, e.invoiceNumber reference,
e.id origin, 'supplier' entityType,
s.id clientFk, s.id entityId,
s.name entityName,
IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked, IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked,
FALSE isTicket, FALSE isTicket,
b.id lineFk, b.id lineFk,
NULL `order`, NULL `order`,
NULL clientType, NULL clientType,
NULL claimFk, NULL claimFk,
ec.inventorySupplierFk vSupplierInventoryFk inventorySupplierFk
FROM vn.buy b FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk JOIN vn.entry e ON e.id = b.entryFk
JOIN vn.travel tr ON tr.id = e.travelFk JOIN vn.travel tr ON tr.id = e.travelFk
JOIN vn.supplier s ON s.id = e.supplierFk JOIN vn.supplier s ON s.id = e.supplierFk
JOIN vn.state st ON st.`code` = IF( tr.landed < util.VN_CURDATE() JOIN vn.state st ON st.`code` = IF(tr.landed < util.VN_CURDATE()
OR (util.VN_CURDATE() AND tr.isReceived), OR (util.VN_CURDATE() AND tr.isReceived),
'DELIVERED', 'DELIVERED',
'FREE') 'FREE')
JOIN vn.entryConfig ec
WHERE tr.landed >= vDateInventory WHERE tr.landed >= vDateInventory
AND vWarehouseFk = tr.warehouseInFk AND tr.warehouseInFk = vWarehouseFk
AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL) AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
AND b.itemFk = vItemFk AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable AND NOT e.isExcludedFromAvailable
AND NOT e.isRaid AND NOT e.isRaid
), entriesOut AS ( ),
SELECT tr.shipped, entriesOut AS (
SELECT 'entry',
e.id originType,
tr.shipped,
NULL, NULL,
b.quantity, b.quantity,
st.alertLevel, st.alertLevel,
st.name stateName, st.name stateName,
s.name ,
e.invoiceNumber, e.invoiceNumber,
e.id entryFk, 'supplier' entityType,
s.id supplierFk, s.id entityId,
s.name,
IF(st.`code` = 'DELIVERED' , TRUE, FALSE), IF(st.`code` = 'DELIVERED' , TRUE, FALSE),
FALSE isTicket, FALSE isTicket,
b.id, b.id,
NULL `order`, NULL `order`,
NULL clientType, NULL clientType,
NULL claimFk, NULL claimFk,
ec.inventorySupplierFk vSupplierInventoryFk
FROM vn.buy b FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk JOIN vn.entry e ON e.id = b.entryFk
JOIN vn.travel tr ON tr.id = e.travelFk JOIN vn.travel tr ON tr.id = e.travelFk
@ -99,86 +89,108 @@ BEGIN
OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived), OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived),
'DELIVERED', 'DELIVERED',
'FREE') 'FREE')
JOIN vn.entryConfig ec
WHERE tr.shipped >= vDateInventory WHERE tr.shipped >= vDateInventory
AND vWarehouseFk = tr.warehouseOutFk AND tr.warehouseOutFk = vWarehouseFk
AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL) AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
AND b.itemFk = vItemFk AND b.itemFk = vItemFk
AND NOT e.isExcludedFromAvailable AND NOT e.isExcludedFromAvailable
AND NOT w.isFeedStock AND NOT w.isFeedStock
AND NOT e.isRaid AND NOT e.isRaid
), sales AS ( ),
SELECT DATE(t.shipped) shipped, sales AS (
s.quantity, WITH itemSales AS (
st2.alertLevel, SELECT DATE(t.shipped) shipped,
st2.name, s.quantity,
t.nickname, st2.alertLevel,
t.refFk, st2.name,
t.id ticketFk, t.refFk,
t.clientFk, t.id ticketFk,
s.id saleFk, 'client' entityType,
st.`order`, t.clientFk entityId,
c.typeFk, t.nickname,
cb.claimFk s.id saleFk,
FROM vn.sale s st.`order`,
JOIN vn.ticket t ON t.id = s.ticketFk c.typeFk,
LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id cb.claimFk
LEFT JOIN vn.state st ON st.`code` = ts.`code` FROM vn.sale s
JOIN vn.client c ON c.id = t.clientFk JOIN vn.ticket t ON t.id = s.ticketFk
JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(), LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id
'DELIVERED', LEFT JOIN vn.state st ON st.code = ts.code
IF (t.shipped > util.dayEnd(util.VN_CURDATE()), JOIN vn.client c ON c.id = t.clientFk
'FREE', JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(),
IFNULL(ts.code, 'FREE'))) 'DELIVERED',
LEFT JOIN vn.claimBeginning cb ON s.id = cb.saleFk IF (t.shipped > util.dayEnd(util.VN_CURDATE()),
WHERE t.shipped >= vDateInventory 'FREE',
AND s.itemFk = vItemFk IFNULL(st.code, 'FREE')))
AND vWarehouseFk = t.warehouseFk LEFT JOIN vn.claimBeginning cb ON cb.saleFk = s.id
),sale AS ( WHERE t.shipped >= vDateInventory
SELECT s.shipped, AND s.itemFk = vItemFk
AND t.warehouseFk = vWarehouseFk
)
SELECT 'ticket',
s.ticketFk,
s.shipped,
NULL `in`, NULL `in`,
s.quantity, s.quantity,
s.alertLevel, s.alertLevel,
s.name, s.name,
s.nickname,
s.refFk, s.refFk,
s.ticketFk, s.entityType,
s.clientFk, s.entityId,
IF(stk.saleFk, TRUE, NULL), s.nickname,
IF(stk.saleFk, TRUE, FALSE),
TRUE, TRUE,
s.saleFk, s.saleFk,
s.`order`, s.`order`,
s.typeFk, s.typeFk,
s.claimFk, s.claimFk,
NULL NULL
FROM sales s FROM itemSales s
LEFT JOIN vn.state stPrep ON stPrep.`code` = 'PREPARED' LEFT JOIN vn.state stPrep ON stPrep.`code` = 'PREPARED'
LEFT JOIN vn.saleTracking stk ON stk.saleFk = s.saleFk LEFT JOIN vn.saleTracking stk ON stk.saleFk = s.saleFk
AND stk.stateFk = stPrep.id AND stk.stateFk = stPrep.id
GROUP BY s.saleFk GROUP BY s.saleFk
) SELECT shipped, ),
`in`, orders AS (
`out`, SELECT 'order' originType,
alertLevel, o.id originId,
stateName, r.shipment,
`name`, NULL 'in',
reference, r.amount,
origin, NULL alertLevel,
clientFk, NULL stateName,
isPicked, NULL invoiceNumber,
isTicket, 'client' entityType,
lineFk, c.id,
`order`, c.name,
clientType, FALSE,
claimFk, FALSE isTicket,
inventorySupplierFk NULL buyFk,
FROM entriesIn NULL 'order',
c.typeFk,
NULL claimFk,
NULL
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
)
AND NOT o.confirmed
AND r.itemFk = vItemFk
)
SELECT * FROM entriesIn
UNION ALL UNION ALL
SELECT * FROM entriesOut SELECT * FROM entriesOut
UNION ALL UNION ALL
SELECT * FROM sale SELECT * FROM sales
UNION ALL
SELECT * FROM orders
ORDER BY shipped, ORDER BY shipped,
(inventorySupplierFk = clientFk) DESC, (inventorySupplierFk = entityId) DESC,
alertLevel DESC, alertLevel DESC,
isTicket, isTicket,
`order` DESC, `order` DESC,
@ -186,19 +198,20 @@ BEGIN
`in` DESC, `in` DESC,
`out` DESC; `out` DESC;
IF vDate IS NULL THEN IF vDated IS NULL THEN
SET @a := 0; SET @a := 0;
SET @currentLineFk := 0; SET @currentLineFk := 0;
SET @shipped := ''; SET @shipped := '';
SELECT DATE(@shipped:= t.shipped) shipped, SELECT t.originType,
t.originId,
DATE(@shipped:= t.shipped) shipped,
t.alertLevel, t.alertLevel,
t.stateName, t.stateName,
t.origin,
t.reference, t.reference,
t.clientFk, t.entityType,
t.name, t.entityId,
t.entityName,
t.`in` invalue, t.`in` invalue,
t.`out`, t.`out`,
@a := @a + IFNULL(t.`in`, 0) - IFNULL(t.`out`, 0) balance, @a := @a + IFNULL(t.`in`, 0) - IFNULL(t.`out`, 0) balance,
@ -214,37 +227,41 @@ BEGIN
t.`order` t.`order`
FROM tItemDiary t FROM tItemDiary t
LEFT JOIN alertLevel a ON a.id = t.alertLevel; LEFT JOIN alertLevel a ON a.id = t.alertLevel;
ELSE ELSE
SELECT IFNULL(SUM(IFNULL(`in`, 0)) - SUM(IFNULL(`out`, 0)), 0) INTO @a SELECT IFNULL(SUM(IFNULL(`in`, 0)) - SUM(IFNULL(`out`, 0)), 0) INTO @a
FROM tItemDiary FROM tItemDiary
WHERE shipped < vDate; WHERE shipped < vDated;
SELECT vDate shipped, SELECT NULL originType,
0 alertLevel, NULL originId,
0 stateName, vDated shipped,
0 origin, NULL alertLevel,
'' reference, NULL stateName,
0 clientFk, NULL reference,
NULL entityType,
NULL entityId,
'Inventario calculado', 'Inventario calculado',
@a invalue, @a invalue,
NULL `out`, NULL `out`,
@a balance, @a balance,
0 lastPreparedLineFk, NULL lastPreparedLineFk,
0 isTicket, NULL isTicket,
0 lineFk, NULL lineFk,
0 isPicked, NULL isPicked,
0 clientType, NULL clientType,
0 claimFk, NULL claimFk,
NULL `order` NULL `order`
UNION ALL UNION ALL
SELECT shipped, SELECT originType,
originId,
shipped,
alertlevel, alertlevel,
stateName, stateName,
origin, reference,
reference, entityType,
clientFk, entityId,
name, `in`, entityName,
`in`,
`out`, `out`,
@a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0), @a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0),
0, 0,
@ -255,7 +272,7 @@ BEGIN
claimFk, claimFk,
`order` `order`
FROM tItemDiary FROM tItemDiary
WHERE shipped >= vDate; WHERE shipped >= vDated;
END IF; END IF;
DROP TEMPORARY TABLE tItemDiary; DROP TEMPORARY TABLE tItemDiary;

View File

@ -0,0 +1 @@
CREATE INDEX travel_landed_IDX USING BTREE ON vn.travel (landed DESC,warehouseInFk,warehouseOutFk);

View File

@ -61,7 +61,7 @@ describe('item getBalance()', () => {
const secondItemBalance = await models.Item.getBalance(ctx, secondFilter, options); const secondItemBalance = await models.Item.getBalance(ctx, secondFilter, options);
expect(firstItemBalance[9].claimFk).toEqual(null); expect(firstItemBalance[9].claimFk).toEqual(null);
expect(secondItemBalance[7].claimFk).toEqual(2); expect(secondItemBalance[7].claimFk).toEqual(1);
await tx.rollback(); await tx.rollback();
} catch (e) { } catch (e) {