feat: refs #6769 itemDiary #2683
|
@ -2,25 +2,65 @@ DELIMITER $$
|
|||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`(
|
||||
vItemFk INT,
|
||||
vWarehouseFk INT,
|
||||
vDate DATETIME
|
||||
vDated DATETIME
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* @vItemFk item a buscar
|
||||
* @vWarehouseFk almacen donde buscar
|
||||
* @vDate 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 vDate.
|
||||
* Calcula el disponible.
|
||||
*
|
||||
* @vItemFk Id de artículo
|
||||
* @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 vLifeScope DATE;
|
||||
DECLARE vWarehouseInventoryFk INT;
|
||||
DECLARE vSupplierInventoryFk INT;
|
||||
|
||||
IF vDate IS NULL THEN
|
||||
SELECT inventoried INTO vDateInventory
|
||||
FROM config;
|
||||
ELSE
|
||||
SELECT mockUtcTime INTO vDateInventory
|
||||
FROM util.config;
|
||||
SELECT IF(vDated, uc.mockUtcTime, c.inventoried) INTO vDateInventory
|
||||
FROM config c
|
||||
JOIN util.config uc;
|
||||
|
||||
SELECT COALESCE(vDated, vDateInventory) - INTERVAL MAX(life) DAY
|
||||
INTO vLifeScope
|
||||
FROM itemType;
|
||||
|
||||
guillermo marked this conversation as resolved
Outdated
|
||||
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;
|
||||
|
||||
-- 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(
|
||||
shipped DATE,
|
||||
`in` INT(11),
|
||||
|
@ -37,8 +77,9 @@ BEGIN
|
|||
`order` TINYINT(3) UNSIGNED,
|
||||
clientType VARCHAR(20),
|
||||
claimFk INT(10) UNSIGNED,
|
||||
inventorySupplierFk INT(10)
|
||||
);
|
||||
inventorySupplierFk INT(10),
|
||||
orderFk INT(10) UNSIGNED
|
||||
) ENGINE = MEMORY;
|
||||
|
||||
INSERT INTO tItemDiary
|
||||
WITH entriesIn AS (
|
||||
|
@ -57,7 +98,8 @@ BEGIN
|
|||
NULL `order`,
|
||||
NULL clientType,
|
||||
NULL claimFk,
|
||||
ec.inventorySupplierFk
|
||||
vSupplierInventoryFk inventorySupplierFk,
|
||||
NULL orderFk
|
||||
FROM vn.buy b
|
||||
JOIN vn.entry e ON e.id = b.entryFk
|
||||
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||
|
@ -66,14 +108,14 @@ BEGIN
|
|||
OR (util.VN_CURDATE() AND tr.isReceived),
|
||||
'DELIVERED',
|
||||
'FREE')
|
||||
JOIN vn.entryConfig ec
|
||||
WHERE tr.landed >= vDateInventory
|
||||
AND vWarehouseFk = tr.warehouseInFk
|
||||
AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL)
|
||||
AND tr.warehouseInFk = vWarehouseFk
|
||||
AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
|
||||
AND b.itemFk = vItemFk
|
||||
AND NOT e.isExcludedFromAvailable
|
||||
AND NOT e.isRaid
|
||||
), entriesOut AS (
|
||||
),
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
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,
|
||||
NULL,
|
||||
b.quantity,
|
||||
|
@ -89,7 +131,8 @@ BEGIN
|
|||
NULL `order`,
|
||||
NULL clientType,
|
||||
NULL claimFk,
|
||||
ec.inventorySupplierFk
|
||||
vSupplierInventoryFk,
|
||||
NULL orderFk
|
||||
FROM vn.buy b
|
||||
JOIN vn.entry e ON e.id = b.entryFk
|
||||
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||
|
@ -102,12 +145,14 @@ BEGIN
|
|||
JOIN vn.entryConfig ec
|
||||
WHERE tr.shipped >= vDateInventory
|
||||
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 NOT e.isExcludedFromAvailable
|
||||
AND NOT w.isFeedStock
|
||||
AND NOT e.isRaid
|
||||
), sales AS (
|
||||
),
|
||||
sales AS (
|
||||
WITH itemSales AS (
|
||||
SELECT DATE(t.shipped) shipped,
|
||||
s.quantity,
|
||||
st2.alertLevel,
|
||||
|
@ -134,7 +179,7 @@ BEGIN
|
|||
WHERE t.shipped >= vDateInventory
|
||||
AND s.itemFk = vItemFk
|
||||
AND vWarehouseFk = t.warehouseFk
|
||||
),sale AS (
|
||||
)
|
||||
SELECT s.shipped,
|
||||
NULL `in`,
|
||||
s.quantity,
|
||||
|
@ -144,39 +189,55 @@ BEGIN
|
|||
s.refFk,
|
||||
s.ticketFk,
|
||||
s.clientFk,
|
||||
IF(stk.saleFk, TRUE, NULL),
|
||||
IF(stk.saleFk, TRUE, FALSE),
|
||||
TRUE,
|
||||
s.saleFk,
|
||||
s.`order`,
|
||||
s.typeFk,
|
||||
s.claimFk,
|
||||
NULL
|
||||
FROM sales s
|
||||
NULL,
|
||||
NULL orderFk
|
||||
FROM itemSales s
|
||||
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
|
||||
) SELECT shipped,
|
||||
`in`,
|
||||
`out`,
|
||||
alertLevel,
|
||||
stateName,
|
||||
`name`,
|
||||
reference,
|
||||
origin,
|
||||
clientFk,
|
||||
isPicked,
|
||||
isTicket,
|
||||
lineFk,
|
||||
`order`,
|
||||
clientType,
|
||||
claimFk,
|
||||
inventorySupplierFk
|
||||
FROM entriesIn
|
||||
),
|
||||
orders AS (
|
||||
SELECT r.shipment,
|
||||
NULL 'in',
|
||||
r.amount,
|
||||
NULL alertLevel,
|
||||
NULL stateName,
|
||||
NULL,
|
||||
NULL invoiceNumber,
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
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..
|
||||
NULL entryFk,
|
||||
NULL supplierFk,
|
||||
FALSE,
|
||||
FALSE isTicket,
|
||||
NULL buyFk,
|
||||
NULL 'order',
|
||||
c.typeFk,
|
||||
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
|
||||
SELECT * FROM entriesOut
|
||||
UNION ALL
|
||||
SELECT * FROM sale
|
||||
SELECT * FROM sales
|
||||
UNION ALL
|
||||
SELECT * FROM orders
|
||||
ORDER BY shipped,
|
||||
(inventorySupplierFk = clientFk) DESC,
|
||||
alertLevel DESC,
|
||||
|
@ -186,8 +247,7 @@ BEGIN
|
|||
`in` DESC,
|
||||
`out` DESC;
|
||||
|
||||
IF vDate IS NULL THEN
|
||||
|
||||
IF vDated IS NULL THEN
|
||||
SET @a := 0;
|
||||
SET @currentLineFk := 0;
|
||||
SET @shipped := '';
|
||||
|
@ -211,16 +271,16 @@ BEGIN
|
|||
t.isPicked,
|
||||
t.clientType,
|
||||
t.claimFk,
|
||||
t.`order`
|
||||
t.`order`,
|
||||
t.orderFk
|
||||
FROM tItemDiary t
|
||||
LEFT JOIN alertLevel a ON a.id = t.alertLevel;
|
||||
|
||||
ELSE
|
||||
SELECT IFNULL(SUM(IFNULL(`in`, 0)) - SUM(IFNULL(`out`, 0)), 0) INTO @a
|
||||
FROM tItemDiary
|
||||
WHERE shipped < vDate;
|
||||
WHERE shipped < vDated;
|
||||
|
||||
SELECT vDate shipped,
|
||||
SELECT vDated shipped,
|
||||
0 alertLevel,
|
||||
0 stateName,
|
||||
0 origin,
|
||||
|
@ -236,7 +296,8 @@ BEGIN
|
|||
0 isPicked,
|
||||
0 clientType,
|
||||
0 claimFk,
|
||||
NULL `order`
|
||||
NULL `order`,
|
||||
0 orderFk
|
||||
UNION ALL
|
||||
SELECT shipped,
|
||||
alertlevel,
|
||||
|
@ -253,11 +314,14 @@ BEGIN
|
|||
isPicked,
|
||||
clientType,
|
||||
claimFk,
|
||||
`order`
|
||||
`order`,
|
||||
orderFk
|
||||
FROM tItemDiary
|
||||
WHERE shipped >= vDate;
|
||||
WHERE shipped >= vDated;
|
||||
END IF;
|
||||
|
||||
DROP TEMPORARY TABLE tItemDiary;
|
||||
DROP TEMPORARY TABLE
|
||||
tItemDiary,
|
||||
tItemRange;
|
||||
END$$
|
||||
DELIMITER ;
|
||||
|
|
Loading…
Reference in New Issue
vWarehouseInventoryFk realment si esta o no configurada en este cas, no veig que afecte en res, no es gasta ni es consulta