feat: refs #6493 refactorizar procedimientos vn2008 parte2
gitea/salix/pipeline/head This commit looks good Details
gitea/salix/pipeline/pr-dev This commit looks good Details

This commit is contained in:
Juanjo Breso 2024-01-31 09:54:47 +01:00
parent eb3d344957
commit dc1ef34aba
9 changed files with 345 additions and 35 deletions

View File

@ -0,0 +1,123 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`available_traslate`(
vWarehouseLanding INT,
vDated DATE,
vWarehouseShipment INT)
proc: BEGIN
DECLARE vDatedFrom DATE;
DECLARE vDatedTo DATETIME;
DECLARE vDatedReserve DATETIME;
DECLARE vDatedInventory DATE;
IF vDated < util.VN_CURDATE() THEN
LEAVE proc;
END IF;
CALL item_getStock (vWarehouseLanding, vDated, NULL);
-- Calcula algunos parámetros necesarios
SET vDatedFrom = TIMESTAMP(vDated, '00:00:00');
SET vDatedTo = TIMESTAMP(TIMESTAMPADD(DAY, 4, vDated), '23:59:59');
SELECT FechaInventario INTO vDatedInventory FROM tblContadores;
SELECT SUBTIME(util.VN_NOW(), reserveTime) INTO vDatedReserve
FROM hedera.orderConfig;
-- Calcula el ultimo dia de vida para cada producto
CREATE OR REPLACE TEMPORARY TABLE tItemRange
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
SELECT c.itemFk, MAX(t.landed) dated
FROM buy c
JOIN entry e ON c.entryFk = e.id
JOIN travel t ON t.id = e.travelFk
JOIN warehouse w ON w.id = t.warehouseInFk
WHERE t.landed BETWEEN vDatedInventory AND vDatedFrom
AND t.warehouseInFk = vWarehouseLanding
AND NOT e.isExcludedFromAvailable
AND NOT e.isRaid
GROUP BY c.itemFk;
-- Tabla con el ultimo dia de last_buy para cada producto que hace un replace de la anterior
CALL buyUltimate(vWarehouseShipment, util.VN_CURDATE());
INSERT INTO tItemRange
SELECT t.itemFk, tr.landed
FROM tmp.buyUltimate t
JOIN buy b ON b.id = t.buyFk
JOIN entry e ON e.id = b.entryFk
JOIN travel tr ON tr.id = e.travelFk
LEFT JOIN tItemRange i ON t.itemFk = i.itemFk
WHERE t.warehouseFk = vWarehouseShipment
AND NOT e.isRaid
ON DUPLICATE KEY UPDATE tItemRange.dated = GREATEST(tItemRange.dated, tr.landed);
CREATE OR REPLACE TEMPORARY TABLE tItemRangeLive
(PRIMARY KEY (itemFk))
ENGINE = MEMORY
SELECT ir.itemFk, TIMESTAMP(TIMESTAMPADD(DAY, it.life, ir.dated), '23:59:59') dated
FROM tItemRange ir
JOIN item i ON i.id = ir.itemFk
JOIN itemType it ON it.id = i.typeFk
HAVING dated >= vDatedFrom OR dated IS NULL;
-- Calcula el ATP
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
(INDEX (itemFk,warehouseFk))
ENGINE = MEMORY
SELECT i.item_id itemFk, vWarehouseLanding warehouseFk, i.dat dated, i.amount quantity
FROM vn2008.item_out i
JOIN tItemRangeLive ir ON ir.itemFK = i.item_id
WHERE i.dat >= vDatedFrom
AND (ir.dated IS NULL OR i.dat <= ir.dated)
AND i.warehouse_id = vWarehouseLanding
UNION ALL
SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity
FROM buy b
JOIN entry e ON b.entryFk = e.id
JOIN travel t ON t.id = e.travelFk
JOIN tItemRangeLive ir ON ir.itemFk = b.itemFk
WHERE NOT e.isExcludedFromAvailable
AND b.quantity <> 0
AND NOT e.isRaid
AND t.warehouseInFk = vWarehouseLanding
AND t.landed >= vDatedFrom
AND (ir.dated IS NULL OR t.landed <= ir.dated)
UNION ALL
SELECT i.item_id, vWarehouseLanding, i.dat, i.amount
FROM vn2008.item_entry_out i
JOIN tItemRangeLive ir ON ir.itemFk = i.item_id
WHERE i.dat >= vDatedFrom
AND (ir.dated IS NULL OR i.dat <= ir.dated)
AND i.warehouse_id = vWarehouseLanding
UNION ALL
SELECT r.item_id, vWarehouseLanding, r.shipment, -r.amount
FROM hedera.order_row r
JOIN hedera.`order` o ON o.id = r.order_id
JOIN tItemRangeLive ir ON ir.itemFk = r.item_id
WHERE r.shipment >= vDatedFrom
AND (ir.dated IS NULL OR r.shipment <= ir.dated)
AND r.warehouse_id = vWarehouseLanding
AND r.created >= vDatedReserve
AND NOT o.confirmed;
CALL item_getAtp(vDated);
CREATE OR REPLACE TEMPORARY TABLE availableTraslate
(PRIMARY KEY (item_id))
ENGINE = MEMORY
SELECT t.item_id, SUM(stock) available
FROM (
SELECT ti.itemFk item_id, stock
FROM tmp.itemList ti
JOIN tItemRange ir ON ir.itemFk = ti.itemFk
UNION ALL
SELECT itemFk, quantity
FROM tmp.itemAtp
) t
GROUP BY t.item_id
HAVING available <> 0;
DROP TEMPORARY TABLE tmp.itemList, tItemRange, tItemRangeLive;
END$$
DELIMITER ;

View File

@ -0,0 +1,204 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balance_create`(
IN vStartingMonth INT,
IN vEndingMonth INT,
IN vCompany INT,
IN vIsConsolidated BOOLEAN,
IN vInterGroupSalesIncluded BOOLEAN)
BEGIN
DECLARE intGAP INT DEFAULT 7;
DECLARE vYears INT DEFAULT 2;
DECLARE vYear TEXT;
DECLARE vOneYearAgo TEXT;
DECLARE vTwoYearsAgo TEXT;
DECLARE vQuery TEXT;
DECLARE vConsolidatedGroup INT;
DECLARE vStartingDate DATE DEFAULT '2020-01-01';
DECLARE vCurYear INT DEFAULT YEAR(util.VN_CURDATE());
DECLARE vStartingYear INT DEFAULT vCurYear - 2;
DECLARE vTable TEXT;
SET vTable = util.quoteIdentifier('balance_nest_tree');
SET vYear = util.quoteIdentifier(vCurYear);
SET vOneYearAgo = util.quoteIdentifier(vCurYear-1);
SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2);
-- Solicitamos la tabla tmp.nest, como base para el balance
DROP TEMPORARY TABLE IF EXISTS tmp.nest;
EXECUTE IMMEDIATE CONCAT(
'CREATE TEMPORARY TABLE tmp.nest
SELECT node.id
,CONCAT( REPEAT(REPEAT(" ",?), COUNT(parent.id) - 1), node.name) AS name
,node.lft
,node.rgt
,COUNT(parent.id) - 1 as depth
,cast((node.rgt - node.lft - 1) / 2 as DECIMAL) as sons
FROM ', vTable, ' AS node,
', vTable, ' AS parent
WHERE node.lft BETWEEN parent.lft AND parent.rgt
GROUP BY node.id
ORDER BY node.lft')
USING intGAP;
CREATE OR REPLACE TEMPORARY TABLE tmp.balance
SELECT * FROM tmp.nest;
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_receptoras;
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_emisoras;
SELECT companyGroupFk INTO vConsolidatedGroup
FROM company
WHERE id = vCompany;
CREATE OR REPLACE TEMPORARY TABLE tmp.empresas_receptoras
SELECT id empresa_id
FROM company
WHERE id = vCompany
OR companyGroupFk = IF(vIsConsolidated, vConsolidatedGroup, NULL);
CREATE OR REPLACE TEMPORARY TABLE tmp.empresas_emisoras
SELECT id empresa_id FROM supplier p;
IF vInterGroupSalesIncluded = FALSE THEN
DELETE ee.*
FROM tmp.empresas_emisoras ee
JOIN company e on e.id = ee.empresa_id
WHERE e.companyGroupFk = vConsolidatedGroup;
END IF;
-- Se calculan las facturas que intervienen, para luego poder servir el desglose desde aqui
CREATE OR REPLACE TEMPORARY TABLE tmp.balance_desglose
SELECT er.empresa_id receptora_id,
ee.empresa_id emisora_id,
year(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `year`,
month(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `month`,
expenseFk Id_Gasto,
SUM(bi) importe
FROM invoiceIn r
JOIN invoiceInTax ri on ri.invoiceInFk = r.id
JOIN tmp.empresas_receptoras er on er.empresa_id = r.companyFk
JOIN tmp.empresas_emisoras ee ON ee.empresa_id = r.supplierFk
WHERE IFNULL(r.bookEntried,IFNULL(r.booked, r.issued)) >= vStartingDate
AND r.isBooked
GROUP BY Id_Gasto, year, month, emisora_id, receptora_id;
INSERT INTO tmp.balance_desglose(
receptora_id,
emisora_id,
year,
month,
Id_Gasto,
importe)
SELECT gr.empresa_id,
gr.empresa_id,
year,
month,
Id_Gasto,
SUM(importe)
FROM vn2008.gastos_resumen gr
JOIN tmp.empresas_receptoras er on gr.empresa_id = er.empresa_id
WHERE year >= vStartingYear
AND month BETWEEN vStartingMonth AND vEndingMonth
GROUP BY Id_Gasto, year, month, gr.empresa_id;
DELETE FROM tmp.balance_desglose
WHERE month < vStartingMonth
OR month > vEndingMonth;
-- Ahora el balance
EXECUTE IMMEDIATE CONCAT(
'ALTER TABLE tmp.balance
ADD COLUMN ', vTwoYearsAgo ,' INT(10) NULL ,
ADD COLUMN ', vOneYearAgo ,' INT(10) NULL ,
ADD COLUMN ', vYear,' INT(10) NULL ,
ADD COLUMN Id_Gasto VARCHAR(10) NULL,
ADD COLUMN Gasto VARCHAR(45) NULL');
-- Añadimos los gastos, para facilitar el formulario
UPDATE tmp.balance b
JOIN vn2008.balance_nest_tree bnt on bnt.id = b.id
JOIN (SELECT id, name
FROM expense
GROUP BY id) g ON g.id = bnt.Id_Gasto COLLATE utf8_general_ci
SET b.Id_Gasto = g.id COLLATE utf8_general_ci
, b.Gasto = g.id COLLATE utf8_general_ci ;
-- Rellenamos los valores de primer nivel, los que corresponden a los gastos simples
WHILE vYears >= 0 DO
SET vQuery = CONCAT(
'UPDATE tmp.balance b
JOIN
(SELECT Id_Gasto, SUM(Importe) as Importe
FROM tmp.balance_desglose
WHERE year = ?
GROUP BY Id_Gasto
) sub on sub.Id_Gasto = b.Id_Gasto COLLATE utf8_general_ci
SET ', util.quoteIdentifier(vCurYear - vYears), ' = - Importe');
EXECUTE IMMEDIATE vQuery
USING vCurYear - vYears;
SET vYears = vYears - 1;
END WHILE;
-- Añadimos las ventas
EXECUTE IMMEDIATE CONCAT(
'UPDATE tmp.balance b
JOIN (
SELECT SUM(IF(year = ?, venta, 0)) y2,
SUM(IF(year = ?, venta, 0)) y1,
SUM(IF(year = ?, venta, 0)) y0,
c.Gasto
FROM bs.ventas_contables c
JOIN tmp.empresas_receptoras er on er.empresa_id = c.empresa_id
WHERE month BETWEEN ? AND ?
GROUP BY c.Gasto
) sub ON sub.Gasto = b.Id_Gasto COLLATE utf8_general_ci
SET b.', vTwoYearsAgo, '= IFNULL(b.', vTwoYearsAgo, ', 0) + sub.y2,
b.', vOneYearAgo, '= IFNULL(b.', vOneYearAgo, ', 0) + sub.y1,
b.', vYear, '= IFNULL(b.', vYear, ', 0) + sub.y0')
USING vCurYear-2,
vCurYear-1,
vCurYear,
vStartingMonth,
vEndingMonth;
-- Ventas intra grupo
IF NOT vInterGroupSalesIncluded THEN
SELECT lft, rgt INTO @grupoLft, @grupoRgt
FROM tmp.balance b
WHERE TRIM(b.`name`) = 'Grupo';
DELETE
FROM tmp.balance
WHERE lft BETWEEN @grupoLft AND @grupoRgt;
END IF;
-- Rellenamos el valor de los padres con la suma de los hijos
CREATE OR REPLACE TEMPORARY TABLE tmp.balance_aux
SELECT * FROM tmp.balance;
EXECUTE IMMEDIATE
CONCAT('UPDATE tmp.balance b
JOIN (
SELECT b1.id,
b1.name,
SUM(b2.', vYear,') thisYear,
SUM(b2.', vOneYearAgo,') oneYearAgo,
SUM(b2.', vTwoYearsAgo,') twoYearsAgo
FROM tmp.nest b1
JOIN tmp.balance_aux b2 on b2.lft BETWEEN b1.lft and b1.rgt
GROUP BY b1.id)sub ON sub.id = b.id
SET b.', vYear, ' = thisYear,
b.', vOneYearAgo, ' = oneYearAgo,
b.', vTwoYearsAgo, ' = twoYearsAgo');
SELECT *, CONCAT('',ifnull(Id_Gasto,'')) newgasto
FROM tmp.balance;
END$$
DELIMITER ;

View File

@ -26,7 +26,7 @@ BEGIN
LEAVE l;
END IF;
CALL vn2008.buy_tarifas_entry(vEntryFk);
CALL buy_recalcPricesByEntry(vEntryFk);
END LOOP;
CLOSE vCur;

View File

@ -1,6 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`article_multiple_buy`(v_date DATETIME, wh INT)
BEGIN
CALL vn.item_multipleBuy(v_date, wh);
END$$
DELIMITER ;

View File

@ -1,9 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`article_multiple_buy_date`(
IN vDated DATETIME,
IN vWarehouseFk TINYINT(3)
)
BEGIN
CALL vn.item_multipleBuyByDate(vDated, vWarehouseFk);
END$$
DELIMITER ;

View File

@ -1,6 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_tarifas`(vBuyFk INT)
BEGIN
CALL vn.buy_recalcPricesByBuy(vBuyFk);
END$$
DELIMITER ;

View File

@ -1,11 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_tarifas_entry`(IN vEntryFk INT(11))
BEGIN
/**
* Recalcula los precios de una entrada
*
* @param vEntryFk
*/
CALL vn.buy_recalcPricesByEntry(vEntryFk);
END$$
DELIMITER ;

View File

@ -61,7 +61,7 @@ BEGIN
AND v.`visible`
ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`;
CALL availableTraslate(warehouseShipment, dateShipment, NULL);
CALL vn.available_traslate(warehouseShipment, dateShipment, NULL);
INSERT INTO tmp.item(itemFk, available)
SELECT a.item_id, a.available
@ -69,7 +69,7 @@ BEGIN
WHERE a.available
ON DUPLICATE KEY UPDATE available = a.available;
CALL availableTraslate(warehouseLanding, dateLanding, warehouseShipment);
CALL vn.available_traslate(warehouseLanding, dateLanding, warehouseShipment);
INSERT INTO tmp.item(itemFk, availableLanding)
SELECT a.item_id, a.available

View File

@ -0,0 +1,15 @@
CREATE OR REPLACE PROCEDURE `vn`.`balance_create`() BEGIN END;
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByEntry`() BEGIN END;
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByBuy`() BEGIN END;
GRANT EXECUTE ON PROCEDURE vn.balance_create TO `financialBoss`;
GRANT EXECUTE ON PROCEDURE vn.balance_create TO `hrBoss`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `buyer`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `claimManager`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `employee`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `buyer`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `entryEditor`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `claimManager`;
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `employee`;