refactor: refs #7505 item_getVisible refactor #2573
|
@ -1,13 +1,13 @@
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `cache`.`visible_refresh`(OUT v_calc INT, v_refresh BOOL, v_warehouse INT)
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `cache`.`visible_refresh`(OUT v_calc INT, v_refresh BOOL, v_warehouse INT)
|
||||||
proc: BEGIN
|
proc:BEGIN
|
||||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
BEGIN
|
BEGIN
|
||||||
CALL cache_calc_unlock (v_calc);
|
CALL cache_calc_unlock (v_calc);
|
||||||
RESIGNAL;
|
RESIGNAL;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CALL cache_calc_start (v_calc, v_refresh, 'visible', v_warehouse);
|
CALL cache_calc_start (v_calc, v_refresh, 'visible', v_warehouse);
|
||||||
|
|
||||||
IF !v_refresh THEN
|
IF !v_refresh THEN
|
||||||
LEAVE proc;
|
LEAVE proc;
|
||||||
|
@ -15,22 +15,23 @@ proc: BEGIN
|
||||||
|
|
||||||
-- Calculamos el stock hasta ayer
|
-- Calculamos el stock hasta ayer
|
||||||
|
|
||||||
CALL `cache`.stock_refresh(false);
|
CALL cache.stock_refresh(false);
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.itemVisible
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemVisible
|
||||||
(PRIMARY KEY (item_id))
|
(PRIMARY KEY (item_id))
|
||||||
ENGINE = MEMORY
|
ENGINE = MEMORY
|
||||||
SELECT item_id, amount stock, amount visible FROM `cache`.stock
|
SELECT item_id, amount stock, amount visible
|
||||||
|
FROM cache.stock
|
||||||
WHERE warehouse_id = v_warehouse;
|
WHERE warehouse_id = v_warehouse;
|
||||||
|
|
||||||
-- Calculamos los movimientos confirmados de hoy
|
-- Calculamos los movimientos confirmados de hoy
|
||||||
CALL vn.item_GetVisible(v_warehouse, NULL);
|
CALL vn.item_calcVisible(NULL, v_warehouse);
|
||||||
DELETE FROM visible WHERE calc_id = v_calc;
|
DELETE FROM visible WHERE calc_id = v_calc;
|
||||||
|
|
||||||
INSERT INTO visible (calc_id, item_id,visible)
|
INSERT INTO visible (calc_id, item_id,visible)
|
||||||
guillermo marked this conversation as resolved
|
|||||||
SELECT v_calc, item_id, visible FROM tmp.itemVisible;
|
SELECT v_calc, item_id, visible FROM tmp.itemVisible;
|
||||||
|
|
||||||
CALL cache_calc_end (v_calc);
|
CALL cache_calc_end (v_calc);
|
||||||
|
|
||||||
DROP TEMPORARY TABLE tmp.itemVisible;
|
DROP TEMPORARY TABLE tmp.itemVisible;
|
||||||
END$$
|
END$$
|
||||||
|
|
|
@ -1,43 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_GetVisible`(vWarehouse SMALLINT, vItem INT)
|
|
||||||
BEGIN
|
|
||||||
DECLARE vTomorrow DATETIME DEFAULT TIMESTAMPADD(DAY, 1, util.VN_CURDATE());
|
|
||||||
|
|
||||||
INSERT INTO tmp.itemVisible (item_id, visible)
|
|
||||||
SELECT item_id, SUM(amount) amount
|
|
||||||
FROM (
|
|
||||||
SELECT i.itemFk AS item_id, quantity AS amount
|
|
||||||
FROM itemTicketOut i
|
|
||||||
LEFT JOIN ticketState ts ON ts.ticketFk = i.ticketFk
|
|
||||||
JOIN state s ON s.id = ts.stateFk
|
|
||||||
LEFT JOIN (SELECT DISTINCT saleFk
|
|
||||||
FROM saleTracking st
|
|
||||||
JOIN state s ON s.id = st.stateFk
|
|
||||||
WHERE st.created > util.VN_CURDATE()
|
|
||||||
AND (s.isPicked OR st.isChecked)
|
|
||||||
) stPrevious ON `stPrevious`.`saleFk` = i.saleFk
|
|
||||||
WHERE i.warehouseFk = vWarehouse
|
|
||||||
AND (vItem IS NULL OR i.itemFk = vItem)
|
|
||||||
AND (s.isPicked OR i.reserved OR stPrevious.saleFk )
|
|
||||||
AND i.shipped >= util.VN_CURDATE() AND i.shipped < vTomorrow
|
|
||||||
UNION ALL
|
|
||||||
SELECT iei.itemFk, quantity
|
|
||||||
FROM itemEntryIn iei
|
|
||||||
WHERE (iei.isReceived != FALSE /*OR ip.modificationDate > util.VN_CURDATE()*/)
|
|
||||||
AND iei.landed >= util.VN_CURDATE() AND iei.landed < vTomorrow
|
|
||||||
AND iei.warehouseInFk = vWarehouse
|
|
||||||
AND (vItem IS NULL OR iei.itemFk = vItem)
|
|
||||||
AND iei.isVirtualStock is FALSE
|
|
||||||
UNION ALL
|
|
||||||
SELECT itemFk, quantity
|
|
||||||
FROM itemEntryOut
|
|
||||||
WHERE isDelivered != FALSE
|
|
||||||
AND shipped >= util.VN_CURDATE() AND shipped < vTomorrow
|
|
||||||
AND warehouseOutFk = vWarehouse
|
|
||||||
AND (vItem IS NULL OR itemFk = vItem)
|
|
||||||
) t
|
|
||||||
GROUP BY item_id
|
|
||||||
ON DUPLICATE KEY UPDATE
|
|
||||||
visible = IFNULL(stock,0) + VALUES(visible);
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -0,0 +1,56 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_calcVisible`(
|
||||||
|
vSelf INT,
|
||||||
|
vWarehouseFk INT
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Calcula el visible de un artículo o de todos.
|
||||||
|
*
|
||||||
|
* @param vWarehouse Warehouse id
|
||||||
|
* @param vSelf Item id
|
||||||
|
* @param tmp.itemVisible(item_id, stock, visible)
|
||||||
|
*/
|
||||||
|
DECLARE vDated DATE DEFAULT util.VN_CURDATE();
|
||||||
|
DECLARE vTomorrow DATETIME DEFAULT util.tomorrow();
|
||||||
|
|
||||||
|
INSERT INTO tmp.itemVisible(item_id, visible)
|
||||||
|
SELECT itemFk, SUM(quantity)
|
||||||
|
FROM (
|
||||||
|
SELECT i.itemFk, i.quantity
|
||||||
|
FROM itemTicketOut i
|
||||||
|
LEFT JOIN ticketState ts ON ts.ticketFk = i.ticketFk
|
||||||
|
JOIN `state` s ON s.id = ts.stateFk
|
||||||
|
LEFT JOIN (
|
||||||
|
SELECT DISTINCT st.saleFk
|
||||||
|
FROM saleTracking st
|
||||||
|
JOIN state s ON s.id = st.stateFk
|
||||||
|
WHERE st.created > vDated
|
||||||
|
AND (s.isPicked OR st.isChecked)
|
||||||
|
) stPrevious ON `stPrevious`.`saleFk` = i.saleFk
|
||||||
|
WHERE IFNULL(vWarehouseFk, i.warehouseFk) = i.warehouseFk
|
||||||
|
AND (vSelf IS NULL OR i.itemFk = vSelf)
|
||||||
|
AND (s.isPicked OR i.reserved OR stPrevious.saleFk)
|
||||||
|
AND i.shipped >= vDated AND i.shipped < vTomorrow
|
||||||
|
UNION ALL
|
||||||
|
SELECT itemFk, quantity
|
||||||
|
FROM itemEntryIn
|
||||||
|
WHERE isReceived
|
||||||
|
AND landed >= vDated AND landed < vTomorrow
|
||||||
|
AND IFNULL(vWarehouseFk, warehouseInFk) = warehouseInFk
|
||||||
|
AND (vSelf IS NULL OR itemFk = vSelf)
|
||||||
|
AND NOT isVirtualStock
|
||||||
|
UNION ALL
|
||||||
|
SELECT itemFk, quantity
|
||||||
|
FROM itemEntryOut
|
||||||
|
WHERE isDelivered
|
||||||
|
AND shipped >= vDated
|
||||||
|
AND shipped < vTomorrow
|
||||||
|
AND IFNULL(vWarehouseFk, warehouseOutFk) = warehouseOutFk
|
||||||
|
AND (vSelf IS NULL OR itemFk = vSelf)
|
||||||
|
) t
|
||||||
|
GROUP BY itemFk
|
||||||
|
ON DUPLICATE KEY UPDATE
|
||||||
|
visible = IFNULL(stock, 0) + VALUES(visible);
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -10,6 +10,7 @@ proc: BEGIN
|
||||||
DECLARE vDateTo DATETIME;
|
DECLARE vDateTo DATETIME;
|
||||||
DECLARE vDateToTomorrow DATETIME;
|
DECLARE vDateToTomorrow DATETIME;
|
||||||
DECLARE vDefaultDayRange INT;
|
DECLARE vDefaultDayRange INT;
|
||||||
|
DECLARE vCalcFk INT;
|
||||||
|
|
||||||
IF vDate < util.VN_CURDATE() THEN
|
IF vDate < util.VN_CURDATE() THEN
|
||||||
LEAVE proc;
|
LEAVE proc;
|
||||||
|
@ -82,50 +83,18 @@ proc: BEGIN
|
||||||
ai.sd = iic.quantity;
|
ai.sd = iic.quantity;
|
||||||
|
|
||||||
-- Cálculo del visible
|
-- Cálculo del visible
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tItemVisibleCalc
|
CALL cache.visible_refresh(vCalcFk, FALSE, vWarehouseFk);
|
||||||
(PRIMARY KEY (itemFk))
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT itemFk, SUM(quantity) visible
|
|
||||||
FROM (
|
|
||||||
SELECT s.itemFk, s.quantity
|
|
||||||
FROM sale s
|
|
||||||
JOIN ticket t ON t.id = s.ticketFk
|
|
||||||
JOIN warehouse w ON w.id = t.warehouseFk
|
|
||||||
WHERE t.shipped >= vDate
|
|
||||||
AND t.shipped < vDateTomorrow
|
|
||||||
AND (NOT isPicked AND NOT t.isLabeled AND t.refFk IS NULL)
|
|
||||||
AND IFNULL(vWarehouseFk, t.warehouseFk) = t.warehouseFk
|
|
||||||
AND w.isComparative
|
|
||||||
UNION ALL
|
|
||||||
SELECT b.itemFk, - b.quantity
|
|
||||||
FROM buy b
|
|
||||||
JOIN entry e ON e.id = b.entryFk
|
|
||||||
JOIN travel t ON t.id = e.travelFk
|
|
||||||
JOIN warehouse w ON w.id = t.warehouseInFk
|
|
||||||
WHERE t.landed = vDate
|
|
||||||
AND NOT t.isReceived
|
|
||||||
AND NOT e.isExcludedFromAvailable
|
|
||||||
AND NOT e.isRaid
|
|
||||||
AND IFNULL(vWarehouseFk, t.warehouseInFk) = t.warehouseInFk
|
|
||||||
AND w.isComparative
|
|
||||||
UNION ALL
|
|
||||||
SELECT b.itemFk, b.quantity
|
|
||||||
FROM buy b
|
|
||||||
JOIN entry e ON e.id = b.entryFk
|
|
||||||
JOIN travel t ON t.id = e.travelFk
|
|
||||||
JOIN warehouse w ON w.id = t.warehouseOutFk
|
|
||||||
WHERE t.shipped = vDate
|
|
||||||
AND NOT t.isReceived
|
|
||||||
AND NOT e.isExcludedFromAvailable
|
|
||||||
AND NOT e.isRaid
|
|
||||||
AND IFNULL(vWarehouseFk, t.warehouseOutFk) = t.warehouseOutFk
|
|
||||||
AND w.isComparative
|
|
||||||
) sub2
|
|
||||||
GROUP BY itemFk;
|
|
||||||
|
|
||||||
UPDATE tmp.itemInventory ai
|
CREATE OR REPLACE TEMPORARY TABLE tItemVisibleCalc
|
||||||
JOIN tItemVisibleCalc ivc ON ivc.itemFk = ai.id
|
(PRIMARY KEY (item_id))
|
||||||
SET ai.visible = ai.visible + ivc.visible;
|
ENGINE = MEMORY
|
||||||
|
SELECT item_id, visible
|
||||||
|
FROM cache.visible
|
||||||
|
WHERE calc_id = vCalcFk;
|
||||||
|
|
||||||
|
UPDATE tmp.itemInventory it
|
||||||
|
JOIN tItemVisibleCalc ivc ON ivc.item_id = it.id
|
||||||
|
SET it.visible = it.visible + ivc.visible;
|
||||||
|
|
||||||
-- Calculo del disponible
|
-- Calculo del disponible
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
|
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
|
||||||
|
@ -196,8 +165,8 @@ proc: BEGIN
|
||||||
DROP TEMPORARY TABLE
|
DROP TEMPORARY TABLE
|
||||||
tmp.itemTravel,
|
tmp.itemTravel,
|
||||||
tmp.itemCalc,
|
tmp.itemCalc,
|
||||||
|
tmp.itemAtp,
|
||||||
tItemInventoryCalc,
|
tItemInventoryCalc,
|
||||||
tItemVisibleCalc,
|
tItemVisibleCalc;
|
||||||
tmp.itemAtp;
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
Loading…
Reference in New Issue
el visible no es guarda per dia, no es pot calcular per dia. Tampoc aporta res. El concepte "visible per dia" seria l'stock .