refactor: refs #6499 Migrated procs to vn
gitea/salix/pipeline/pr-dev There was a failure building this commit Details

This commit is contained in:
Guillermo Bonet 2024-02-28 08:23:58 +01:00
parent 89ebd36b9b
commit 80ecd698f8
6 changed files with 210 additions and 212 deletions

View File

@ -1,48 +1,45 @@
DELIMITER $$ DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`nest_child_add`( CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balanceNestTree_addChild`(
vTable VARCHAR(45) vSelfFather INT,
,vChild VARCHAR(45) vName VARCHAR(45)
,vFatherId INT
) )
BEGIN BEGIN
DECLARE vMyLeft INT; DECLARE vTable VARCHAR(45) DEFAULT util.quoteIdentifier('balanceNestTree');
DECLARE vLeft INT;
SET vTable = util.quoteIdentifier(vTable); CREATE OR REPLACE TEMPORARY TABLE tAux
SELECT 0 lft;
DROP TEMPORARY TABLE IF EXISTS aux;
CREATE TEMPORARY TABLE aux
SELECT 0 as lft;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE aux 'UPDATE tAux
SET lft = (SELECT lft SET lft = (SELECT lft
FROM ', vTable, FROM ', vTable,
' WHERE id = ?)') ' WHERE id = ?)')
USING vFatherId; USING vFatherId;
SELECT lft INTO vMyLeft FROM aux; SELECT lft INTO vLeft FROM tAux;
DROP TEMPORARY TABLE aux;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable, ' 'UPDATE ', vTable, '
SET rgt = rgt + 2 SET rgt = rgt + 2
WHERE rgt > ? WHERE rgt > ?
ORDER BY rgt DESC') ORDER BY rgt DESC')
USING vMyLeft; USING vLeft;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable, ' 'UPDATE ', vTable, '
SET lft = lft + 2 SET lft = lft + 2
WHERE lft > ? WHERE lft > ?
ORDER BY lft DESC') ORDER BY lft DESC')
USING vMyLeft; USING vLeft;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'INSERT INTO ', vTable, ' (name, lft, rgt) 'INSERT INTO ', vTable, ' (name, lft, rgt)
VALUES(?, ? + 1, ? + 2)') VALUES(?, ? + 1, ? + 2)')
USING vChild, USING vChild,
vMyLeft, vLeft,
vMyLeft; vLeft;
DROP TEMPORARY TABLE tAux;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -1,51 +1,48 @@
DELIMITER $$ DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`nest_delete`( CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balanceNestTree_delete`(
vTable VARCHAR(45) vSelf INT
,vNodeId INT
) )
BEGIN BEGIN
DECLARE vMyRight INT; DECLARE vTable VARCHAR(45) DEFAULT util.quoteIdentifier('balanceNestTree');
DECLARE vMyLeft INT; DECLARE vRight INT;
DECLARE vMyWidth INT; DECLARE vLeft INT;
DECLARE vWidth INT;
DROP TEMPORARY TABLE IF EXISTS aux; CREATE OR REPLACE TEMPORARY TABLE tAux
CREATE TEMPORARY TABLE aux
SELECT 0 rgt, 0 lft, 0 wdt; SELECT 0 rgt, 0 lft, 0 wdt;
SET vTable = util.quoteIdentifier(vTable);
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE aux a 'UPDATE tAux a
JOIN ', vTable, ' t JOIN ', vTable, ' t
SET a.rgt = t.rgt, SET a.rgt = t.rgt,
a.lft = t.lft, a.lft = t.lft,
a.wdt = t.rgt - t.lft + 1 a.wdt = t.rgt - t.lft + 1
WHERE t.id = ?') WHERE t.id = ?')
USING vNodeId; USING vSelf;
SELECT rgt, lft, wdt SELECT rgt, lft, wdt
INTO vMyRight, vMyLeft, vMyWidth INTO vRight, vLeft, vWidth
FROM aux; FROM tAux;
DROP TEMPORARY TABLE aux;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'DELETE FROM ', vTable, 'DELETE FROM ', vTable,
' WHERE lft BETWEEN ? AND ?') ' WHERE lft BETWEEN ? AND ?')
USING vMyLeft, vMyRight; USING vLeft, vRight;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable, 'UPDATE ', vTable,
' SET rgt = rgt - ? ' SET rgt = rgt - ?
WHERE rgt > ? WHERE rgt > ?
ORDER BY rgt') ORDER BY rgt')
USING vMyWidth,vMyRight; USING vWidth,vRight;
EXECUTE IMMEDIATE CONCAT( EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable, 'UPDATE ', vTable,
' SET lft = lft - ? ' SET lft = lft - ?
WHERE lft > ? WHERE lft > ?
ORDER BY lft') ORDER BY lft')
USING vMyWidth, vMyRight; USING vWidth, vRight;
DROP TEMPORARY TABLE tAux;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -0,0 +1,111 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balanceNestTree_move`(
vSelfNode INT,
vSelfFather INT
)
BEGIN
DECLARE vTable VARCHAR(45) DEFAULT util.quoteIdentifier('balanceNestTree');
DECLARE vRight INT;
DECLARE vLeft INT;
DECLARE vWidth INT;
DECLARE vFatherRight INT;
DECLARE vFatherLeft INT;
DECLARE vGap INT;
CREATE OR REPLACE TEMPORARY TABLE tAux
SELECT 0 rgt, 0 lft, 0 wdt, 0 frg, 0 flf;
-- Averiguamos el ancho de la rama
EXECUTE IMMEDIATE CONCAT(
'UPDATE tAux a
JOIN ', vTable, ' t
SET a.wdt = t.rgt - t.lft + 1
WHERE t.id = ?')
USING vSelfNode;
-- Averiguamos la posicion del nuevo padre
EXECUTE IMMEDIATE CONCAT(
'UPDATE tAux a
JOIN ', vTable, ' t
SET a.frg = t.rgt,
a.flf = t.lft
WHERE t.id = ?')
USING vSelfFather;
SELECT wdt, frg, flf
INTO vWidth, vFatherRight, vFatherLeft
FROM tAux;
-- 1º Incrementamos los valores de todos los nodos a la derecha
-- del punto de inserción (vFatherRight) , para hacer sitio
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt + ?
WHERE rgt >= ?
ORDER BY rgt DESC')
USING vWidth,
vFatherRight;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft + ?
WHERE lft >= ?
ORDER BY lft DESC')
USING vWidth,
vFatherRight;
-- Es preciso recalcular los valores del nodo en el
-- caso de que estuviera a la derecha del nuevo padre
EXECUTE IMMEDIATE CONCAT(
'UPDATE tAux a
JOIN ', vTable, ' t
SET a.rgt = t.rgt,
a.lft = t.lft
WHERE t.id = ?')
USING vSelfNode;
SELECT lft, rgt, frg - lft
INTO vLeft, vRight, vGap
FROM tAux;
-- 2º Incrementamos el valor de todos los nodos a
-- trasladar hasta alcanzar su nueva posicion
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft + ?
WHERE lft BETWEEN ? AND ?
ORDER BY lft DESC')
USING vGap,
vLeft,
vRight;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt + ?
WHERE rgt BETWEEN ? AND ?
ORDER BY rgt DESC')
USING vGap,
vLeft,
vRight;
-- 3º Restaremos a todos los nodos resultantes, a la derecha
-- de la posicion arrancada el ancho de la rama escindida
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft - ?
WHERE lft > ?
ORDER BY lft')
USING vWidth,
vLeft;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt - ?
WHERE rgt > ?
ORDER BY rgt')
USING vWidth,
vRight;
DROP TEMPORARY TABLE tAux;
END$$
DELIMITER ;

View File

@ -0,0 +1,68 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`pay`(
vDated DATE,
vSupplierFk INT,
vAmount DOUBLE,
vCurrencyFk INT,
vDivisa DOUBLE,
vBankFk INT,
vPayMethodFk INT,
vExpenseFk DOUBLE,
vConcept VARCHAR(40),
vCompanyFk INT)
BEGIN
INSERT INTO till(
concept,
serie,
`number`,
`out`,
dated,
isAccountable,
bankFk,
workerFk,
companyFk,
isConciliate
)
SELECT CONCAT('n/pago a ', `name`),
'R',
vSupplierFk,
vAmount,
vDated,
1,
vBankFk,
account.myUser_getId(),
vCompanyFk,
1
FROM supplier
WHERE id = vSupplierFk;
INSERT INTO payment(
received,
dueDated,
supplierFk,
amount,
currencyFk,
divisa,
bankFk,
payMethodFk,
bankingFees,
concept,
companyFk
)
VALUES(
vDated,
vDated,
vSupplierFk,
vAmount,
vCurrencyFk,
IF(NOT vDivisa, NULL, vDivisa),
vBankFk,
vPayMethodFk,
vExpenseFk,
vConcept,
vCompanyFk
);
SELECT LAST_INSERT_ID() pago_id;
END$$
DELIMITER ;

View File

@ -1,108 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`nest_move`(
vTable VARCHAR(45)
,idNODE INT
,idFATHER INT
)
BEGIN
DECLARE myRight INT;
DECLARE myLeft INT;
DECLARE myWidth INT;
DECLARE fatherRight INT;
DECLARE fatherLeft INT;
DECLARE gap INT;
SET vTable = util.quoteIdentifier(vTable);
DROP TEMPORARY TABLE IF EXISTS aux;
CREATE TEMPORARY TABLE aux
SELECT 0 as rgt, 0 as lft, 0 as wdt, 0 as frg, 0 as flf;
-- Averiguamos el ancho de la rama
EXECUTE IMMEDIATE CONCAT(
'UPDATE aux a
JOIN ', vTable, ' t
SET a.wdt = t.rgt - t.lft + 1
WHERE t.id = ?')
USING idNODE;
-- Averiguamos la posicion del nuevo padre
EXECUTE IMMEDIATE CONCAT(
'UPDATE aux a
JOIN ', vTable, ' t
SET a.frg = t.rgt,
a.flf = t.lft
WHERE t.id = ?')
USING idFATHER;
SELECT wdt, frg, flf INTO myWidth, fatherRight, fatherLeft
FROM aux;
-- 1º Incrementamos los valores de todos los nodos a la derecha del punto de inserción (fatherRight) , para hacer sitio
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt + ?
WHERE rgt >= ?
ORDER BY rgt DESC')
USING myWidth,
fatherRight;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft + ?
WHERE lft >= ?
ORDER BY lft DESC')
USING myWidth,
fatherRight;
-- Es preciso recalcular los valores del nodo en el caso de que estuviera a la derecha del nuevo padre
EXECUTE IMMEDIATE CONCAT(
'UPDATE aux a
JOIN ', vTable, ' t
SET a.rgt = t.rgt,
a.lft = t.lft
WHERE t.id = ?')
USING idNODE;
SELECT lft, rgt, frg - lft INTO myLeft, myRight, gap
FROM aux;
-- 2º Incrementamos el valor de todos los nodos a trasladar hasta alcanzar su nueva posicion
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft + ?
WHERE lft BETWEEN ? AND ?
ORDER BY lft DESC')
USING gap,
myLeft,
myRight;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt + ?
WHERE rgt BETWEEN ? AND ?
ORDER BY rgt DESC')
USING gap,
myLeft,
myRight;
-- 3º Restaremos a todos los nodos resultantes, a la derecha de la posicion arrancada el ancho de la rama escindida
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET lft = lft - ?
WHERE lft > ?
ORDER BY lft')
USING myWidth,
myLeft;
EXECUTE IMMEDIATE CONCAT(
'UPDATE ', vTable,
'SET rgt = rgt - ?
WHERE rgt > ?
ORDER BY rgt')
USING myWidth,
myRight;
DROP TEMPORARY TABLE aux;
END$$
DELIMITER ;

View File

@ -1,67 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`pay`(IN datFEC DATE
, IN idPROV INT
, IN dblIMPORTE DOUBLE
, IN idMONEDA INT
, IN dblDIVISA DOUBLE
, IN idCAJA INT
, IN idPAYMET INT
, IN dblGASTOS DOUBLE
, IN strCONCEPTO VARCHAR(40)
, IN idEMP INT)
BEGIN
-- Registro en la tabla Cajas
INSERT INTO Cajas ( Concepto
, Serie
, Numero
, Salida
, Cajafecha
, Partida
, Id_Banco
, Id_Trabajador
,empresa_id
,conciliado)
SELECT CONCAT('n/pago a ', Proveedor)
, 'R'
, idPROV
, dblIMPORTE
, datFEC
, 1
, idCAJA
, account.myUser_getId()
, idEMP
, 1
FROM Proveedores
WHERE Id_Proveedor = idPROV;
-- Registro en la tabla pago
INSERT INTO pago(fecha
, dueDated
, id_proveedor
, importe
, id_moneda
, divisa
, id_banco
, pay_met_id
, g_bancarios
, concepte
, empresa_id)
VALUES(datFEC
, datFEC
, idPROV
, dblIMPORTE
, idMONEDA
, IF(dblDIVISA = 0, NULL, dblDIVISA)
, idCAJA
, idPAYMET
, dblGASTOS
, strCONCEPTO
, idEMP);
SELECT LAST_INSERT_ID() as pago_id;
END$$
DELIMITER ;