From dc1ef34abacf790b0a4b6e49e465550775e12de7 Mon Sep 17 00:00:00 2001 From: Jbreso Date: Wed, 31 Jan 2024 09:54:47 +0100 Subject: [PATCH 1/7] feat: refs #6493 refactorizar procedimientos vn2008 parte2 --- .../vn/procedures/available_traslate.sql | 123 +++++++++++ db/routines/vn/procedures/balance_create.sql | 204 ++++++++++++++++++ db/routines/vn/procedures/entry_recalc.sql | 2 +- .../procedures/article_multiple_buy.sql | 6 - .../procedures/article_multiple_buy_date.sql | 9 - db/routines/vn2008/procedures/buy_tarifas.sql | 6 - .../vn2008/procedures/buy_tarifas_entry.sql | 11 - db/routines/vn2008/procedures/traslado.sql | 4 +- .../10859-pinkGerbera/00-firstScript.sql | 15 ++ 9 files changed, 345 insertions(+), 35 deletions(-) create mode 100644 db/routines/vn/procedures/available_traslate.sql create mode 100644 db/routines/vn/procedures/balance_create.sql delete mode 100644 db/routines/vn2008/procedures/article_multiple_buy.sql delete mode 100644 db/routines/vn2008/procedures/article_multiple_buy_date.sql delete mode 100644 db/routines/vn2008/procedures/buy_tarifas.sql delete mode 100644 db/routines/vn2008/procedures/buy_tarifas_entry.sql create mode 100644 db/versions/10859-pinkGerbera/00-firstScript.sql diff --git a/db/routines/vn/procedures/available_traslate.sql b/db/routines/vn/procedures/available_traslate.sql new file mode 100644 index 000000000..44b76d0c2 --- /dev/null +++ b/db/routines/vn/procedures/available_traslate.sql @@ -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 ; \ No newline at end of file diff --git a/db/routines/vn/procedures/balance_create.sql b/db/routines/vn/procedures/balance_create.sql new file mode 100644 index 000000000..9c22a4fd4 --- /dev/null +++ b/db/routines/vn/procedures/balance_create.sql @@ -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 ; \ No newline at end of file diff --git a/db/routines/vn/procedures/entry_recalc.sql b/db/routines/vn/procedures/entry_recalc.sql index 2410d380d..b426a9b5b 100644 --- a/db/routines/vn/procedures/entry_recalc.sql +++ b/db/routines/vn/procedures/entry_recalc.sql @@ -26,7 +26,7 @@ BEGIN LEAVE l; END IF; - CALL vn2008.buy_tarifas_entry(vEntryFk); + CALL buy_recalcPricesByEntry(vEntryFk); END LOOP; CLOSE vCur; diff --git a/db/routines/vn2008/procedures/article_multiple_buy.sql b/db/routines/vn2008/procedures/article_multiple_buy.sql deleted file mode 100644 index 5b0d402c5..000000000 --- a/db/routines/vn2008/procedures/article_multiple_buy.sql +++ /dev/null @@ -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 ; diff --git a/db/routines/vn2008/procedures/article_multiple_buy_date.sql b/db/routines/vn2008/procedures/article_multiple_buy_date.sql deleted file mode 100644 index 7b197cb01..000000000 --- a/db/routines/vn2008/procedures/article_multiple_buy_date.sql +++ /dev/null @@ -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 ; diff --git a/db/routines/vn2008/procedures/buy_tarifas.sql b/db/routines/vn2008/procedures/buy_tarifas.sql deleted file mode 100644 index c6e8dff90..000000000 --- a/db/routines/vn2008/procedures/buy_tarifas.sql +++ /dev/null @@ -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 ; diff --git a/db/routines/vn2008/procedures/buy_tarifas_entry.sql b/db/routines/vn2008/procedures/buy_tarifas_entry.sql deleted file mode 100644 index 3fc0739e0..000000000 --- a/db/routines/vn2008/procedures/buy_tarifas_entry.sql +++ /dev/null @@ -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 ; diff --git a/db/routines/vn2008/procedures/traslado.sql b/db/routines/vn2008/procedures/traslado.sql index 9c1e5efe7..0e302e156 100644 --- a/db/routines/vn2008/procedures/traslado.sql +++ b/db/routines/vn2008/procedures/traslado.sql @@ -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 diff --git a/db/versions/10859-pinkGerbera/00-firstScript.sql b/db/versions/10859-pinkGerbera/00-firstScript.sql new file mode 100644 index 000000000..8fcadf605 --- /dev/null +++ b/db/versions/10859-pinkGerbera/00-firstScript.sql @@ -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`; \ No newline at end of file From e047d445d3fbf7d4bbf1d983178e749ebb0f2be6 Mon Sep 17 00:00:00 2001 From: Jbreso Date: Thu, 29 Feb 2024 12:00:43 +0100 Subject: [PATCH 2/7] feat: refs#6493 modificado entry_getTransfer --- db/routines/vn/procedures/entry_getTransfer.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/db/routines/vn/procedures/entry_getTransfer.sql b/db/routines/vn/procedures/entry_getTransfer.sql index 151bebd4d..89ad5a67f 100644 --- a/db/routines/vn/procedures/entry_getTransfer.sql +++ b/db/routines/vn/procedures/entry_getTransfer.sql @@ -68,19 +68,19 @@ BEGIN AND v.`visible` ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`; - CALL vn2008.availableTraslate(vWarehouseOut, vDateShipped, NULL); + CALL vn.available_traslate(vWarehouseOut, vDateShipped, NULL); INSERT INTO tItem(itemFk, available) SELECT a.item_id, a.available - FROM vn2008.availableTraslate a + FROM availableTraslate a WHERE a.available ON DUPLICATE KEY UPDATE available = a.available; - CALL vn2008.availableTraslate(vWarehouseIn, vDateLanded, vWarehouseOut); + CALL vn.available_traslate(vWarehouseIn, vDateLanded, vWarehouseOut); INSERT INTO tItem(itemFk, availableLanding) SELECT a.item_id, a.available - FROM vn2008.availableTraslate a + FROM availableTraslate a WHERE a.available ON DUPLICATE KEY UPDATE availableLanding = a.available; ELSE From c889353459afd15e3c1ac54423d8dc57fc11c0ad Mon Sep 17 00:00:00 2001 From: Jbreso Date: Fri, 1 Mar 2024 14:37:14 +0100 Subject: [PATCH 3/7] feat: refs#6493 modificar procedimiento balance_create --- db/routines/vn/procedures/balance_create.sql | 96 ++++---- .../vn2008/procedures/availableTraslate.sql | 126 ----------- .../vn2008/procedures/balance_create.sql | 207 ------------------ 3 files changed, 49 insertions(+), 380 deletions(-) delete mode 100644 db/routines/vn2008/procedures/availableTraslate.sql delete mode 100644 db/routines/vn2008/procedures/balance_create.sql diff --git a/db/routines/vn/procedures/balance_create.sql b/db/routines/vn/procedures/balance_create.sql index 9c22a4fd4..9fb8b614c 100644 --- a/db/routines/vn/procedures/balance_create.sql +++ b/db/routines/vn/procedures/balance_create.sql @@ -18,7 +18,7 @@ BEGIN DECLARE vStartingYear INT DEFAULT vCurYear - 2; DECLARE vTable TEXT; - SET vTable = util.quoteIdentifier('balance_nest_tree'); + SET vTable = util.quoteIdentifier('balanceNestTree'); SET vYear = util.quoteIdentifier(vCurYear); SET vOneYearAgo = util.quoteIdentifier(vCurYear-1); SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2); @@ -44,67 +44,65 @@ BEGIN 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 + SELECT companyGroupFk INTO vConsolidatedGroup FROM company WHERE id = vCompany; - CREATE OR REPLACE TEMPORARY TABLE tmp.empresas_receptoras - SELECT id empresa_id + CREATE OR REPLACE TEMPORARY TABLE tCompanyReceiving + SELECT id companyId 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; + CREATE OR REPLACE TEMPORARY TABLE tCompanyIssuing + SELECT id companyId + FROM supplier p; IF vInterGroupSalesIncluded = FALSE THEN - DELETE ee.* - FROM tmp.empresas_emisoras ee - JOIN company e on e.id = ee.empresa_id + DELETE ci.* + FROM tCompanyIssuing ci + JOIN company e on e.id = ci.companyId 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, + CREATE OR REPLACE TEMPORARY TABLE tmp.balanceDetail + SELECT cr.companyId receivingId, + ci.companyId issuingId, 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 + expenseFk, + SUM(taxableBase) amount 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 + JOIN tCompanyReceiving cr on cr.companyId = r.companyFk + JOIN tCompanyIssuing ci ON ci.companyId = 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; + GROUP BY expenseFk, year, month, ci.companyId, cr.companyId; - INSERT INTO tmp.balance_desglose( - receptora_id, - emisora_id, + INSERT INTO tmp.balanceDetail( + receivingId, + issuingId, year, month, - Id_Gasto, - importe) - SELECT gr.empresa_id, - gr.empresa_id, + expenseFk, + amount) + SELECT em.companyFk, + em.companyFk, year, month, - Id_Gasto, - SUM(importe) - FROM vn2008.gastos_resumen gr - JOIN tmp.empresas_receptoras er on gr.empresa_id = er.empresa_id + expenseFk, + SUM(amount) + FROM expenseManual em + JOIN tCompanyReceiving er on em.companyFk = em.companyFk WHERE year >= vStartingYear AND month BETWEEN vStartingMonth AND vEndingMonth - GROUP BY Id_Gasto, year, month, gr.empresa_id; + GROUP BY expenseFk, year, month, em.companyFk; - DELETE FROM tmp.balance_desglose + DELETE FROM tmp.balanceDetail WHERE month < vStartingMonth OR month > vEndingMonth; @@ -114,29 +112,29 @@ BEGIN 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'); + ADD COLUMN expenseFk VARCHAR(10) NULL, + ADD COLUMN expenseName 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 balanceNestTree 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 ; + GROUP BY id) g ON g.id = bnt.expenseFk COLLATE utf8_general_ci + SET b.expenseFk = g.id COLLATE utf8_general_ci + , b.expenseName = 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 + (SELECT expenseFk, SUM(amount) as amount + FROM tmp.balanceDetail WHERE year = ? - GROUP BY Id_Gasto - ) sub on sub.Id_Gasto = b.Id_Gasto COLLATE utf8_general_ci - SET ', util.quoteIdentifier(vCurYear - vYears), ' = - Importe'); + GROUP BY expenseFk + ) sub on sub.expenseFk = b.expenseFk COLLATE utf8_general_ci + SET ', util.quoteIdentifier(vCurYear - vYears), ' = - amount'); EXECUTE IMMEDIATE vQuery USING vCurYear - vYears; @@ -153,10 +151,10 @@ BEGIN 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 + JOIN tCompanyReceiving cr on cr.companyId = c.empresa_id WHERE month BETWEEN ? AND ? GROUP BY c.Gasto - ) sub ON sub.Gasto = b.Id_Gasto COLLATE utf8_general_ci + ) sub ON sub.gasto = b.expenseFk 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') @@ -198,7 +196,11 @@ BEGIN b.', vOneYearAgo, ' = oneYearAgo, b.', vTwoYearsAgo, ' = twoYearsAgo'); - SELECT *, CONCAT('',ifnull(Id_Gasto,'')) newgasto + SELECT *, CONCAT('',ifnull(expenseFk,'')) newgasto FROM tmp.balance; + + DROP TEMPORARY TABLE IF EXISTS tCompanyReceiving; + DROP TEMPORARY TABLE IF EXISTS tCompanyIssuing; + END$$ DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn2008/procedures/availableTraslate.sql b/db/routines/vn2008/procedures/availableTraslate.sql deleted file mode 100644 index a3d2c8bea..000000000 --- a/db/routines/vn2008/procedures/availableTraslate.sql +++ /dev/null @@ -1,126 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`availableTraslate`( - 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 vn.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 - DROP TEMPORARY TABLE IF EXISTS itemRange; - CREATE TEMPORARY TABLE itemRange - (PRIMARY KEY (itemFk)) - ENGINE = MEMORY - SELECT c.itemFk, MAX(t.landed) dated - FROM vn.buy c - JOIN vn.entry e ON c.entryFk = e.id - JOIN vn.travel t ON t.id = e.travelFk - JOIN vn.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 vn.buyUltimate(vWarehouseShipment, util.VN_CURDATE()); - - INSERT INTO itemRange - SELECT t.itemFk, tr.landed - FROM tmp.buyUltimate t - JOIN vn.buy b ON b.id = t.buyFk - JOIN vn.entry e ON e.id = b.entryFk - JOIN vn.travel tr ON tr.id = e.travelFk - LEFT JOIN itemRange i ON t.itemFk = i.itemFk - WHERE t.warehouseFk = vWarehouseShipment - AND NOT e.isRaid - ON DUPLICATE KEY UPDATE itemRange.dated = GREATEST(itemRange.dated, tr.landed); - - DROP TEMPORARY TABLE IF EXISTS itemRangeLive; - CREATE TEMPORARY TABLE itemRangeLive - (PRIMARY KEY (itemFk)) - ENGINE = MEMORY - SELECT ir.itemFk, TIMESTAMP(TIMESTAMPADD(DAY, it.life, ir.dated), '23:59:59') dated - FROM itemRange ir - JOIN vn.item i ON i.id = ir.itemFk - JOIN vn.itemType it ON it.id = i.typeFk - HAVING dated >= vDatedFrom OR dated IS NULL; - - -- Calcula el ATP - DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc; - CREATE TEMPORARY TABLE tmp.itemCalc - (INDEX (itemFk,warehouseFk)) - ENGINE = MEMORY - SELECT i.itemFk, vWarehouseLanding warehouseFk, i.shipped dated, i.quantity - FROM vn.itemTicketOut i - JOIN itemRangeLive ir ON ir.itemFK = i.itemFk - WHERE i.shipped >= vDatedFrom - AND (ir.dated IS NULL OR i.shipped <= ir.dated) - AND i.warehouseFk = vWarehouseLanding - UNION ALL - SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity - FROM vn.buy b - JOIN vn.entry e ON b.entryFk = e.id - JOIN vn.travel t ON t.id = e.travelFk - JOIN itemRangeLive 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.itemFk, vWarehouseLanding, i.shipped, i.quantity - FROM vn.itemEntryOut i - JOIN itemRangeLive ir ON ir.itemFk = i.itemFk - WHERE i.shipped >= vDatedFrom - AND (ir.dated IS NULL OR i.shipped <= ir.dated) - AND i.warehouseOutFk = 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 itemRangeLive 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 vn.item_getAtp(vDated); - - DROP TEMPORARY TABLE IF EXISTS availableTraslate; - CREATE 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 itemRange 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, itemRange, itemRangeLive; -END$$ -DELIMITER ; diff --git a/db/routines/vn2008/procedures/balance_create.sql b/db/routines/vn2008/procedures/balance_create.sql deleted file mode 100644 index 2acd26834..000000000 --- a/db/routines/vn2008/procedures/balance_create.sql +++ /dev/null @@ -1,207 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`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; - - DROP TEMPORARY TABLE IF EXISTS tmp.balance; - CREATE 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 empresa_grupo INTO vConsolidatedGroup - FROM empresa - WHERE id = vCompany; - - CREATE TEMPORARY TABLE tmp.empresas_receptoras - SELECT id as empresa_id - FROM vn2008.empresa - WHERE id = vCompany - OR empresa_grupo = IF(vIsConsolidated, vConsolidatedGroup, NULL); - - CREATE TEMPORARY TABLE tmp.empresas_emisoras - SELECT Id_Proveedor as empresa_id FROM vn2008.Proveedores p; - - IF vInterGroupSalesIncluded = FALSE THEN - - DELETE ee.* - FROM tmp.empresas_emisoras ee - JOIN vn2008.empresa e on e.id = ee.empresa_id - WHERE e.empresa_grupo = vConsolidatedGroup; - - END IF; - - -- Se calculan las facturas que intervienen, para luego poder servir el desglose desde aqui - DROP TEMPORARY TABLE IF EXISTS tmp.balance_desglose; - CREATE TEMPORARY TABLE tmp.balance_desglose - SELECT er.empresa_id receptora_id, - ee.empresa_id emisora_id, - year(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `year`, - month(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `month`, - gastos_id Id_Gasto, - SUM(bi) importe - FROM recibida r - JOIN recibida_iva ri on ri.recibida_id = r.id - JOIN tmp.empresas_receptoras er on er.empresa_id = r.empresa_id - JOIN tmp.empresas_emisoras ee ON ee.empresa_id = r.proveedor_id - WHERE IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha)) >= vStartingDate - AND r.contabilizada - 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 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 Id_Gasto, name Gasto - FROM vn.expense - GROUP BY id) g ON g.Id_Gasto = bnt.Id_Gasto COLLATE utf8_general_ci - SET b.Id_Gasto = g.Id_Gasto COLLATE utf8_general_ci - , b.Gasto = g.Gasto 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 - DROP TEMPORARY TABLE IF EXISTS tmp.balance_aux; - CREATE 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 ; From f2a1d401ca6abe74dba801987fab8de285dc1527 Mon Sep 17 00:00:00 2001 From: Jbreso Date: Fri, 22 Mar 2024 08:32:38 +0100 Subject: [PATCH 4/7] refs#6493 update --- db/routines/vn/procedures/available_traslate.sql | 2 +- db/routines/vn/procedures/entry_getTransfer.sql | 8 ++++---- 2 files changed, 5 insertions(+), 5 deletions(-) diff --git a/db/routines/vn/procedures/available_traslate.sql b/db/routines/vn/procedures/available_traslate.sql index 44b76d0c2..ad442a724 100644 --- a/db/routines/vn/procedures/available_traslate.sql +++ b/db/routines/vn/procedures/available_traslate.sql @@ -103,7 +103,7 @@ proc: BEGIN CALL item_getAtp(vDated); - CREATE OR REPLACE TEMPORARY TABLE availableTraslate + CREATE OR REPLACE TEMPORARY TABLE tmp.availableTraslate (PRIMARY KEY (item_id)) ENGINE = MEMORY SELECT t.item_id, SUM(stock) available diff --git a/db/routines/vn/procedures/entry_getTransfer.sql b/db/routines/vn/procedures/entry_getTransfer.sql index e7ddcea31..165c87dc7 100644 --- a/db/routines/vn/procedures/entry_getTransfer.sql +++ b/db/routines/vn/procedures/entry_getTransfer.sql @@ -68,19 +68,19 @@ BEGIN AND v.`visible` ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`; - CALL vn.available_traslate(vWarehouseOut, vDateShipped, NULL); + CALL available_traslate(vWarehouseOut, vDateShipped, NULL); INSERT INTO tItem(itemFk, available) SELECT a.item_id, a.available - FROM availableTraslate a + FROM tmp.availableTraslate a WHERE a.available ON DUPLICATE KEY UPDATE available = a.available; - CALL vn.available_traslate(vWarehouseIn, vDateLanded, vWarehouseOut); + CALL available_traslate(vWarehouseIn, vDateLanded, vWarehouseOut); INSERT INTO tItem(itemFk, availableLanding) SELECT a.item_id, a.available - FROM availableTraslate a + FROM tmp.availableTraslate a WHERE a.available ON DUPLICATE KEY UPDATE availableLanding = a.available; ELSE From f4b50dec3e04d0f5a701dc1e8bce1321b0c8e36e Mon Sep 17 00:00:00 2001 From: Jbreso Date: Mon, 25 Mar 2024 09:41:16 +0100 Subject: [PATCH 5/7] feat: refs#6493 modificar procedimiento balance_create --- db/routines/vn/procedures/balance_create.sql | 17 +++++++++++++---- 1 file changed, 13 insertions(+), 4 deletions(-) diff --git a/db/routines/vn/procedures/balance_create.sql b/db/routines/vn/procedures/balance_create.sql index 9fb8b614c..a3f498661 100644 --- a/db/routines/vn/procedures/balance_create.sql +++ b/db/routines/vn/procedures/balance_create.sql @@ -6,6 +6,15 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balance_create`( IN vIsConsolidated BOOLEAN, IN vInterGroupSalesIncluded BOOLEAN) BEGIN +/** + * Crea un balance financiero para una empresa durante un período de tiempo determinado + * + * @param vStartingMonth Mes de inicio del período + * @param vEndingMonth Mes de finalización del período + * @param vCompany Identificador de la empresa + * @param vIsConsolidated Indica si se trata de un balance consolidado + * @param vInterGroupSalesIncluded Indica si se incluyen las ventas dentro del grupo + */ DECLARE intGAP INT DEFAULT 7; DECLARE vYears INT DEFAULT 2; DECLARE vYear TEXT; @@ -71,8 +80,8 @@ BEGIN CREATE OR REPLACE TEMPORARY TABLE tmp.balanceDetail SELECT cr.companyId receivingId, ci.companyId issuingId, - year(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `year`, - month(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `month`, + YEAR(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `year`, + MONTH(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `month`, expenseFk, SUM(taxableBase) amount FROM invoiceIn r @@ -129,7 +138,7 @@ BEGIN SET vQuery = CONCAT( 'UPDATE tmp.balance b JOIN - (SELECT expenseFk, SUM(amount) as amount + (SELECT expenseFk, SUM(amount) FROM tmp.balanceDetail WHERE year = ? GROUP BY expenseFk @@ -151,7 +160,7 @@ BEGIN SUM(IF(year = ?, venta, 0)) y0, c.Gasto FROM bs.ventas_contables c - JOIN tCompanyReceiving cr on cr.companyId = c.empresa_id + JOIN tCompanyReceiving cr ON cr.companyId = c.empresa_id WHERE month BETWEEN ? AND ? GROUP BY c.Gasto ) sub ON sub.gasto = b.expenseFk COLLATE utf8_general_ci From 46f60615bd9a78df72488252e70dda9e4bda0f0a Mon Sep 17 00:00:00 2001 From: Jbreso Date: Thu, 28 Mar 2024 14:27:29 +0100 Subject: [PATCH 6/7] feat: refs#6493 modificar procedimiento available_traslate --- db/routines/vn/procedures/available_traslate.sql | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/db/routines/vn/procedures/available_traslate.sql b/db/routines/vn/procedures/available_traslate.sql index ad442a724..cd472fdbd 100644 --- a/db/routines/vn/procedures/available_traslate.sql +++ b/db/routines/vn/procedures/available_traslate.sql @@ -4,6 +4,13 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`available_traslate` vDated DATE, vWarehouseShipment INT) proc: BEGIN +/** + * Calcular la disponibilidad dependiendo del almacen de origen y destino según la fecha + * + * @param vWarehouseLanding almacén de llegada. + * @param vDated la fecha para la cual se está calculando la disponibilidad de articulos. + * @param vWarehouseShipment almacén de destino. + */ DECLARE vDatedFrom DATE; DECLARE vDatedTo DATETIME; DECLARE vDatedReserve DATETIME; From 4389cd5d746bc4ec2548f6474b5da45b37a40854 Mon Sep 17 00:00:00 2001 From: Jbreso Date: Tue, 2 Apr 2024 09:56:46 +0200 Subject: [PATCH 7/7] feat: refs#6493 modificar procedimiento available_traslate --- .../vn/procedures/available_traslate.sql | 22 +++++++++---------- 1 file changed, 11 insertions(+), 11 deletions(-) diff --git a/db/routines/vn/procedures/available_traslate.sql b/db/routines/vn/procedures/available_traslate.sql index cd472fdbd..3638329bb 100644 --- a/db/routines/vn/procedures/available_traslate.sql +++ b/db/routines/vn/procedures/available_traslate.sql @@ -72,12 +72,12 @@ proc: BEGIN 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 + SELECT i.itemFk, vWarehouseLanding warehouseFk, i.shipped dated, i.quantity + FROM vn.itemTicketOut 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 + WHERE i.shipped >= vDatedFrom + AND (ir.dated IS NULL OR i.shipped <= ir.dated) + AND i.warehouseFk = vWarehouseLanding UNION ALL SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity FROM buy b @@ -91,12 +91,12 @@ proc: BEGIN 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 + SELECT i.itemFk, vWarehouseLanding, i.shipped, i.quantity + FROM vn.itemEntryOut i + JOIN tItemRangeLive ir ON ir.itemFk = i.itemFk + WHERE i.shipped >= vDatedFrom + AND (ir.dated IS NULL OR i.shipped <= ir.dated) + AND i.warehouseOutFk = vWarehouseLanding UNION ALL SELECT r.item_id, vWarehouseLanding, r.shipment, -r.amount FROM hedera.order_row r