refs #6493 refactorizar-procedimientos-vn2008-parte_2 #2235

Merged
jbreso merged 39 commits from 6493-refactorizar-procedimientos-vn2008-parte_2 into dev 2024-04-24 05:18:59 +00:00
3 changed files with 48 additions and 43 deletions
Showing only changes of commit 92cd61460e - Show all commits

View File

@ -5,11 +5,12 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`available_traslate`
vWarehouseShipment INT) vWarehouseShipment INT)
proc: BEGIN proc: BEGIN
/** /**
* Calcular la disponibilidad dependiendo del almacen de origen y destino según la fecha * Calcular la disponibilidad dependiendo del almacen
* de origen y destino según la fecha.
* *
jbreso marked this conversation as resolved
Review

Falta poner un espacio entre vWarehouse y Landing.

Además de que cuando se ponen los params, ninguna descripción del param debe de tener punto (viendo otros procs se puede comprobar)

Falta poner un espacio entre vWarehouse y Landing. Además de que cuando se ponen los params, ninguna descripción del param debe de tener punto (viendo otros procs se puede comprobar)
Review

vWarehouseLanding no se porque quieres el espacio la variable se llama asi, si pongo el espacio en esa también tendía que ponerlo en vWarehouseShipment?

vWarehouseLanding no se porque quieres el espacio la variable se llama asi, si pongo el espacio en esa también tendía que ponerlo en vWarehouseShipment?
Review

Vale no sorry, queria decir que la primera letra del comentario de la variable debe de estár en mayuscula, así en todos los del PR

Vale no sorry, queria decir que la primera letra del comentario de la variable debe de estár en mayuscula, así en todos los del PR
* @param vWarehouseLanding almacén de llegada. * @param vWarehouseLanding almacén de llegada
* @param vDated la fecha para la cual se está calculando la disponibilidad de articulos. * @param vDated fecha del calculo para la disponibilidad de articulos
* @param vWarehouseShipment almacén de destino. * @param vWarehouseShipment almacén de destino
*/ */
DECLARE vDatedFrom DATE; DECLARE vDatedFrom DATE;
DECLARE vDatedTo DATETIME; DECLARE vDatedTo DATETIME;
@ -44,7 +45,8 @@ proc: BEGIN
AND NOT e.isRaid AND NOT e.isRaid
GROUP BY c.itemFk; GROUP BY c.itemFk;
jbreso marked this conversation as resolved
Review

Sobrepasa los carácteres máximos x linea

Sobrepasa los carácteres máximos x linea
-- Tabla con el ultimo dia de last_buy para cada producto que hace un replace de la anterior -- Tabla con el ultimo dia de last_buy para cada producto
-- que hace un replace de la anterior.
CALL buyUltimate(vWarehouseShipment, util.VN_CURDATE()); CALL buyUltimate(vWarehouseShipment, util.VN_CURDATE());
INSERT INTO tItemRange INSERT INTO tItemRange
@ -56,7 +58,8 @@ proc: BEGIN
LEFT JOIN tItemRange i ON t.itemFk = i.itemFk LEFT JOIN tItemRange i ON t.itemFk = i.itemFk
WHERE t.warehouseFk = vWarehouseShipment WHERE t.warehouseFk = vWarehouseShipment
jbreso marked this conversation as resolved
Review

Sobrepasa los carácteres máximos x linea

Sobrepasa los carácteres máximos x linea
AND NOT e.isRaid AND NOT e.isRaid
ON DUPLICATE KEY UPDATE tItemRange.dated = GREATEST(tItemRange.dated, tr.landed); ON DUPLICATE KEY UPDATE tItemRange.dated = GREATEST(tItemRange.dated,
tr.landed);
CREATE OR REPLACE TEMPORARY TABLE tItemRangeLive CREATE OR REPLACE TEMPORARY TABLE tItemRangeLive
(PRIMARY KEY (itemFk)) (PRIMARY KEY (itemFk))
jbreso marked this conversation as resolved
Review

TIMESTAMPADD substituir por INTERVAL

TIMESTAMPADD substituir por INTERVAL
@ -67,18 +70,24 @@ proc: BEGIN
JOIN itemType it ON it.id = i.typeFk JOIN itemType it ON it.id = i.typeFk
HAVING dated >= vDatedFrom OR dated IS NULL; HAVING dated >= vDatedFrom OR dated IS NULL;
-- Calcula el ATP -- Calcula el ATP.
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
(INDEX (itemFk,warehouseFk)) (INDEX (itemFk,warehouseFk))
ENGINE = MEMORY ENGINE = MEMORY
SELECT i.itemFk, vWarehouseLanding warehouseFk, i.shipped dated, i.quantity SELECT i.itemFk,
vWarehouseLanding warehouseFk,
i.shipped dated,
i.quantity
FROM itemTicketOut i FROM itemTicketOut i
JOIN tItemRangeLive ir ON ir.itemFK = i.itemFk JOIN tItemRangeLive ir ON ir.itemFK = i.itemFk
WHERE i.shipped >= vDatedFrom WHERE i.shipped >= vDatedFrom
AND (ir.dated IS NULL OR i.shipped <= ir.dated) AND (ir.dated IS NULL OR i.shipped <= ir.dated)
AND i.warehouseFk = vWarehouseLanding AND i.warehouseFk = vWarehouseLanding
UNION ALL UNION ALL
SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity SELECT b.itemFk,
vWarehouseLanding,
t.landed,
b.quantity
FROM buy b FROM buy b
JOIN entry e ON b.entryFk = e.id JOIN entry e ON b.entryFk = e.id
JOIN travel t ON t.id = e.travelFk JOIN travel t ON t.id = e.travelFk

View File

@ -7,13 +7,14 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balance_create`(
IN vInterGroupSalesIncluded BOOLEAN) IN vInterGroupSalesIncluded BOOLEAN)
BEGIN BEGIN
/** /**
* Crea un balance financiero para una empresa durante un período de tiempo determinado * Crea un balance financiero para una empresa durante
* un período de tiempo determinado.
* *
* @param vStartingMonth Mes de inicio del período * @param vStartingMonth Mes de inicio del período
* @param vEndingMonth Mes de finalización del período * @param vEndingMonth Mes de finalización del período
* @param vCompany Identificador de la empresa * @param vCompany Identificador de la empresa
* @param vIsConsolidated Indica si se trata de un balance consolidado * @param vIsConsolidated Indica si se trata de un balance consolidado
jbreso marked this conversation as resolved
Review

Sobrepasa los caracteres máximos, acortar

Sobrepasa los caracteres máximos, acortar
* @param vInterGroupSalesIncluded Indica si se incluyen las ventas dentro del grupo * @param vInterGroupSalesIncluded Indica si se incluyen las ventas del grupo
*/ */
DECLARE intGAP INT DEFAULT 7; DECLARE intGAP INT DEFAULT 7;
DECLARE vYears INT DEFAULT 2; DECLARE vYears INT DEFAULT 2;
@ -32,19 +33,20 @@ BEGIN
SET vOneYearAgo = util.quoteIdentifier(vCurYear-1); SET vOneYearAgo = util.quoteIdentifier(vCurYear-1);
jbreso marked this conversation as resolved
Review

En el string donde hay una consulta SQL, linea 38, no poner la coma al principio, sino al final:

SELECT node.id,
CONCAT( REPEA...

A parte de quitar los AS (Menos el del CAST que es necesario).

Cast va en mayuscula.

Cambiar CONCAT( REPE... por CONCAT(REPE...

En el string donde hay una consulta SQL, linea 38, no poner la coma al principio, sino al final: SELECT node.id, CONCAT( REPEA... A parte de quitar los AS (Menos el del CAST que es necesario). Cast va en mayuscula. Cambiar `CONCAT( REPE...` por `CONCAT(REPE...`
SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2); SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2);
-- Solicitamos la tabla tmp.nest, como base para el balance -- Solicitamos la tabla tmp.nest, como base para el balance.
DROP TEMPORARY TABLE IF EXISTS tmp.nest; DROP TEMPORARY TABLE IF EXISTS tmp.nest;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'CREATE TEMPORARY TABLE tmp.nest 'CREATE TEMPORARY TABLE tmp.nest
SELECT node.id SELECT node.id
,CONCAT( REPEAT(REPEAT(" ",?), COUNT(parent.id) - 1), node.name) AS name ,CONCAT( REPEAT(REPEAT(" ",?), COUNT(parent.id) - 1),
,node.lft node.name) name,
,node.rgt node.lft,
,COUNT(parent.id) - 1 as depth node.rgt,
,cast((node.rgt - node.lft - 1) / 2 as DECIMAL) as sons COUNT(parent.id) - 1 depth,
FROM ', vTable, ' AS node, CAST((node.rgt - node.lft - 1) / 2 AS DECIMAL) sons
', vTable, ' AS parent FROM ', vTable, ' node,
', vTable, ' parent
WHERE node.lft BETWEEN parent.lft AND parent.rgt WHERE node.lft BETWEEN parent.lft AND parent.rgt
GROUP BY node.id GROUP BY node.id
ORDER BY node.lft') ORDER BY node.lft')
@ -76,7 +78,8 @@ BEGIN
END IF; END IF;
jbreso marked this conversation as resolved
Review

Sobrepasa los caracteres máximos x linea

Sobrepasa los caracteres máximos x linea
-- Se calculan las facturas que intervienen, para luego poder servir el desglose desde aqui -- Se calculan las facturas que intervienen,
-- para luego poder servir el desglose desde aqui.
CREATE OR REPLACE TEMPORARY TABLE tmp.balanceDetail CREATE OR REPLACE TEMPORARY TABLE tmp.balanceDetail
SELECT cr.companyFk receivingId, SELECT cr.companyFk receivingId,
ci.companyFk issuingId, ci.companyFk issuingId,
@ -90,30 +93,30 @@ BEGIN
JOIN tCompanyIssuing ci ON ci.companyFk = r.supplierFk JOIN tCompanyIssuing ci ON ci.companyFk = r.supplierFk
WHERE COALESCE(r.bookEntried, r.booked, r.issued) >= vStartingDate WHERE COALESCE(r.bookEntried, r.booked, r.issued) >= vStartingDate
AND r.isBooked AND r.isBooked
GROUP BY expenseFk, year, month, ci.companyFk, cr.companyFk; GROUP BY expenseFk, `year`, `month`, ci.companyFk, cr.companyFk;
INSERT INTO tmp.balanceDetail( INSERT INTO tmp.balanceDetail(
receivingId, receivingId,
issuingId, issuingId,
year, `year`,
month, `month`,
expenseFk, expenseFk,
amount) amount)
SELECT em.companyFk, SELECT em.companyFk,
em.companyFk, em.companyFk,
year, `year`,
month, `month`,
expenseFk, expenseFk,
SUM(em.amount) SUM(em.amount)
FROM expenseManual em FROM expenseManual em
JOIN tCompanyReceiving er ON er.companyFk = em.companyFk JOIN tCompanyReceiving er ON er.companyFk = em.companyFk
WHERE year >= vStartingYear WHERE `year` >= vStartingYear
AND month BETWEEN vStartingMonth AND vEndingMonth AND `month` BETWEEN vStartingMonth AND vEndingMonth
GROUP BY expenseFk, year, month, em.companyFk; GROUP BY expenseFk, `year`, `month`, em.companyFk;
DELETE FROM tmp.balanceDetail DELETE FROM tmp.balanceDetail
WHERE month < vStartingMonth WHERE `month` < vStartingMonth
OR month > vEndingMonth; OR `month` > vEndingMonth;
-- Ahora el balance -- Ahora el balance
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
@ -130,8 +133,8 @@ BEGIN
JOIN (SELECT id, name JOIN (SELECT id, name
FROM expense FROM expense
GROUP BY id) g ON g.id = bnt.expenseFk 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 SET b.expenseFk = g.id COLLATE utf8_general_ci,
, b.expenseName = 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 -- Rellenamos los valores de primer nivel, los que corresponden a los gastos simples
WHILE vYears >= 0 DO WHILE vYears >= 0 DO
@ -208,8 +211,7 @@ BEGIN
SELECT *, CONCAT('',IFNULL(expenseFk,'')) newgasto SELECT *, CONCAT('',IFNULL(expenseFk,'')) newgasto
FROM tmp.balance; FROM tmp.balance;
DROP TEMPORARY TABLE IF EXISTS tCompanyReceiving; DROP TEMPORARY TABLE IF EXISTS tCompanyReceiving, tCompanyIssuing;
DROP TEMPORARY TABLE IF EXISTS tCompanyIssuing;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -2,14 +2,8 @@ CREATE OR REPLACE PROCEDURE `vn`.`balance_create`() BEGIN END;
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByEntry`() BEGIN END; CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByEntry`() BEGIN END;
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByBuy`() 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 `financialBoss`, `hrBoss`;
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 `buyer`, `claimManager`, `employee`;
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 `buyer`, `entryEditor`, `claimManager`, `employee`;
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`;