feat: refs #6769 itemDiary #2683

Merged
guillermo merged 10 commits from 6769-itemDiary into dev 2024-07-12 08:13:29 +00:00
1 changed files with 144 additions and 80 deletions
Showing only changes of commit a7895ab0a4 - Show all commits

View File

@ -2,25 +2,65 @@ 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 disponible.
* @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
* Si la fecha es NULL, muestra el histórico desde el inventario.
* Si la fecha no es NULL, muestra histórico desde la fecha de vDated.
*/ */
DECLARE vDateInventory DATETIME; DECLARE vDateInventory DATETIME;
DECLARE vLifeScope DATE;
DECLARE vWarehouseInventoryFk INT;
DECLARE vSupplierInventoryFk INT;
IF vDate IS NULL THEN SELECT IF(vDated, uc.mockUtcTime, c.inventoried) INTO vDateInventory
SELECT inventoried INTO vDateInventory FROM config c
FROM config; JOIN util.config uc;
ELSE
SELECT mockUtcTime INTO vDateInventory SELECT COALESCE(vDated, vDateInventory) - INTERVAL MAX(life) DAY
FROM util.config; INTO vLifeScope
FROM itemType;
guillermo marked this conversation as resolved Outdated

vWarehouseInventoryFk realment si esta o no configurada en este cas, no veig que afecte en res, no es gasta ni es consulta

vWarehouseInventoryFk realment si esta o no configurada en este cas, no veig que afecte en res, no es gasta ni es consulta
SELECT warehouseOutFk, supplierFk
INTO vWarehouseInventoryFk, vSupplierInventoryFk
FROM inventoryConfig;
IF NOT vWarehouseInventoryFk OR NOT vSupplierInventoryFk THEN
CALL util.throw('Config variables are not set');
END IF; END IF;
-- Calcula el ultimo dia de vida para cada producto
CREATE OR REPLACE TEMPORARY TABLE tItemRange
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
SELECT i.id itemFk,
util.dayEnd(c.maxLanded + INTERVAL it.life DAY) ended,
it.life
FROM item i
LEFT JOIN (
SELECT b.itemFk, MAX(t.landed) maxLanded
FROM buy b
JOIN entry e ON b.entryFk = e.id
JOIN travel t ON t.id = e.travelFk
JOIN warehouse w ON w.id = t.warehouseInFk
JOIN item i ON i.id = b.itemFk
JOIN itemType it ON it.id = i.typeFk
WHERE t.landed BETWEEN vLifeScope AND COALESCE(vDated, vDateInventory)
AND t.warehouseInFk = vWarehouseFk
AND t.warehouseOutFk <> vWarehouseInventoryFk
AND it.life
AND NOT e.isExcludedFromAvailable
GROUP BY b.itemFk
) c ON i.id = c.itemFk
JOIN itemType it ON it.id = i.typeFk
HAVING ended >= COALESCE(vDated, vDateInventory) OR life IS NULL;
CREATE OR REPLACE TEMPORARY TABLE tItemDiary( CREATE OR REPLACE TEMPORARY TABLE tItemDiary(
shipped DATE, shipped DATE,
`in` INT(11), `in` INT(11),
@ -37,8 +77,9 @@ BEGIN
`order` TINYINT(3) UNSIGNED, `order` TINYINT(3) UNSIGNED,
clientType VARCHAR(20), clientType VARCHAR(20),
claimFk INT(10) UNSIGNED, claimFk INT(10) UNSIGNED,
inventorySupplierFk INT(10) inventorySupplierFk INT(10),
); orderFk INT(10) UNSIGNED
) ENGINE = MEMORY;
INSERT INTO tItemDiary INSERT INTO tItemDiary
WITH entriesIn AS ( WITH entriesIn AS (
@ -57,7 +98,8 @@ BEGIN
NULL `order`, NULL `order`,
NULL clientType, NULL clientType,
NULL claimFk, NULL claimFk,
ec.inventorySupplierFk vSupplierInventoryFk inventorySupplierFk,
NULL orderFk
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
@ -66,20 +108,20 @@ BEGIN
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 ( ),
guillermo marked this conversation as resolved Outdated

este es el troç de la vista que hem comentat

este es el troç de la vista que hem comentat
entriesOut AS (
SELECT tr.shipped, SELECT tr.shipped,
NULL, NULL,
b.quantity, b.quantity,
st.alertLevel, st.alertLevel,
st.name stateName, st.name stateName,
s.name , s.name,
e.invoiceNumber, e.invoiceNumber,
e.id entryFk, e.id entryFk,
s.id supplierFk, s.id supplierFk,
@ -89,7 +131,8 @@ BEGIN
NULL `order`, NULL `order`,
NULL clientType, NULL clientType,
NULL claimFk, NULL claimFk,
ec.inventorySupplierFk vSupplierInventoryFk,
NULL orderFk
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
@ -102,39 +145,41 @@ BEGIN
JOIN vn.entryConfig ec JOIN vn.entryConfig ec
WHERE tr.shipped >= vDateInventory WHERE tr.shipped >= vDateInventory
AND vWarehouseFk = tr.warehouseOutFk AND vWarehouseFk = tr.warehouseOutFk
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.nickname,
t.clientFk, t.refFk,
s.id saleFk, t.id ticketFk,
st.`order`, t.clientFk,
c.typeFk, s.id saleFk,
cb.claimFk st.`order`,
FROM vn.sale s c.typeFk,
JOIN vn.ticket t ON t.id = s.ticketFk cb.claimFk
LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id FROM vn.sale s
LEFT JOIN vn.state st ON st.`code` = ts.`code` JOIN vn.ticket t ON t.id = s.ticketFk
JOIN vn.client c ON c.id = t.clientFk LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id
JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(), LEFT JOIN vn.state st ON st.`code` = ts.`code`
'DELIVERED', JOIN vn.client c ON c.id = t.clientFk
IF (t.shipped > util.dayEnd(util.VN_CURDATE()), JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(),
'FREE', 'DELIVERED',
IFNULL(ts.code, 'FREE'))) IF (t.shipped > util.dayEnd(util.VN_CURDATE()),
LEFT JOIN vn.claimBeginning cb ON s.id = cb.saleFk 'FREE',
WHERE t.shipped >= vDateInventory IFNULL(ts.code, 'FREE')))
AND s.itemFk = vItemFk LEFT JOIN vn.claimBeginning cb ON s.id = cb.saleFk
AND vWarehouseFk = t.warehouseFk WHERE t.shipped >= vDateInventory
),sale AS ( AND s.itemFk = vItemFk
AND vWarehouseFk = t.warehouseFk
)
SELECT s.shipped, SELECT s.shipped,
NULL `in`, NULL `in`,
s.quantity, s.quantity,
@ -144,39 +189,55 @@ BEGIN
s.refFk, s.refFk,
s.ticketFk, s.ticketFk,
s.clientFk, s.clientFk,
IF(stk.saleFk, TRUE, NULL), 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 NULL orderFk
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 r.shipment,
alertLevel, NULL 'in',
stateName, r.amount,
`name`, NULL alertLevel,
reference, NULL stateName,
origin, NULL,
clientFk, NULL invoiceNumber,
guillermo marked this conversation as resolved Outdated

crec que no fa falta tindre una taula temporal nova, si l'article s'ha venut es mostra, sino no..

crec que no fa falta tindre una taula temporal nova, si l'article s'ha venut es mostra, sino no..
isPicked, NULL entryFk,
isTicket, NULL supplierFk,
lineFk, FALSE,
`order`, FALSE isTicket,
clientType, NULL buyFk,
claimFk, NULL 'order',
inventorySupplierFk c.typeFk,
FROM entriesIn NULL claimFk,
NULL inventorySupplierFk,
o.id
FROM hedera.orderRow r
JOIN hedera.`order` o ON o.id = r.orderFk
JOIN tItemRange ir ON ir.itemFk = r.itemFk
JOIN vn.client c ON c.id = o.customer_id
WHERE r.shipment >= vDateInventory
AND (ir.ended IS NULL OR r.shipment <= ir.ended)
AND r.warehouseFk = vWarehouseFk
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 = clientFk) DESC,
alertLevel DESC, alertLevel DESC,
@ -186,8 +247,7 @@ 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 := '';
@ -211,16 +271,16 @@ BEGIN
t.isPicked, t.isPicked,
t.clientType, t.clientType,
t.claimFk, t.claimFk,
t.`order` t.`order`,
t.orderFk
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 vDated shipped,
0 alertLevel, 0 alertLevel,
0 stateName, 0 stateName,
0 origin, 0 origin,
@ -236,7 +296,8 @@ BEGIN
0 isPicked, 0 isPicked,
0 clientType, 0 clientType,
0 claimFk, 0 claimFk,
NULL `order` NULL `order`,
0 orderFk
UNION ALL UNION ALL
SELECT shipped, SELECT shipped,
alertlevel, alertlevel,
@ -253,11 +314,14 @@ BEGIN
isPicked, isPicked,
clientType, clientType,
claimFk, claimFk,
`order` `order`,
orderFk
FROM tItemDiary FROM tItemDiary
WHERE shipped >= vDate; WHERE shipped >= vDated;
END IF; END IF;
DROP TEMPORARY TABLE tItemDiary; DROP TEMPORARY TABLE
tItemDiary,
tItemRange;
END$$ END$$
DELIMITER ; DELIMITER ;