diff --git a/db/dump/fixtures.before.sql b/db/dump/fixtures.before.sql index 6fb70cb58..872d86a1b 100644 --- a/db/dump/fixtures.before.sql +++ b/db/dump/fixtures.before.sql @@ -3736,3 +3736,18 @@ INSERT INTO vn.ticketLog (originFk,userFk,`action`,creationDate,changedModel,new INSERT INTO `vn`.`supplierDms`(`supplierFk`, `dmsFk`, `editorFk`) VALUES (1, 10, 9); + +INSERT INTO `vn`.`accountReconciliation` (supplierAccountFk,operationDated,valueDated,amount,concept,debitCredit,calculatedCode,created) + VALUES + (241,'2023-12-13 00:00:00.000','2023-12-07 00:00:00.000',19.36,'BEL 1','debit','2','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-07 00:00:00.000',30226.43,'BEL 2','debit','1','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',118.81,'RCBO','debit','10','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',150.03,'TJ','debit','12','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',150.03,'TJ','debit','12','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',2149.71,'RCBO.AMAZON','debit','122','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',3210.5,'RCBO.VOLVO','debit','121','2023-12-14 08:39:53.000'), + (241,'2023-12-13 00:00:00.000','2023-12-13 00:00:00.000',6513.7,'RCBO.ENERPLUS','debit','120','2023-12-14 08:39:53.000'); + +INSERT INTO `vn`.`accountReconciliationConfig`(currencyFk, warehouseFk) + VALUES + (1, 1); diff --git a/db/routines/vn/procedures/addAccountReconciliation.sql b/db/routines/vn/procedures/addAccountReconciliation.sql new file mode 100644 index 000000000..8effbd76c --- /dev/null +++ b/db/routines/vn/procedures/addAccountReconciliation.sql @@ -0,0 +1,66 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`addAccountReconciliation`() +BEGIN +/** + * Updates duplicate records in the accountReconciliation table, + * by assigning them a new identifier and then inserts a new entry in the till table. + */ + UPDATE accountReconciliation ar + JOIN ( + SELECT id, + calculatedCode, + CONCAT( + calculatedCode, + '(', + ROW_NUMBER() OVER (PARTITION BY calculatedCode ORDER BY id), + ')' + ) newId + FROM accountReconciliation ar + WHERE calculatedCode IN ( + SELECT calculatedCode + FROM accountReconciliation + GROUP BY calculatedCode + HAVING COUNT(*) > 1 + ) + ORDER BY calculatedCode, id + ) sub2 ON ar.id = sub2.id + SET ar.calculatedCode = sub2.newId; + + INSERT INTO till( + dated, + isAccountable, + serie, + concept, + `in`, + `out`, + bankFk, + companyFk, + warehouseFk, + supplierAccountFk, + calculatedCode, + InForeignValue, + OutForeignValue, + workerFk + ) + SELECT ar.operationDated, + TRUE, + 'MB', + ar.concept, + IF(ar.debitCredit = 'credit' AND a.currencyFk = arc.currencyFk, ar.amount, NULL), + IF(ar.debitCredit = 'debit' AND a.currencyFk = arc.currencyFk, ar.amount, NULL), + a.id, + sa.supplierFk, + arc.warehouseFk, + ar.supplierAccountFk, + ar.calculatedCode, + IF(ar.debitCredit = 'credit' AND NOT a.currencyFk = arc.currencyFk, ar.amount, NULL), + IF(ar.debitCredit = 'debit' AND NOT a.currencyFk = arc.currencyFk, ar.amount, NULL), + account.myUser_getId() + FROM accountReconciliation ar + JOIN supplierAccount sa ON sa.id = ar.supplierAccountFk + JOIN accounting a ON a.id = sa.accountingFk + LEFT JOIN till t ON t.calculatedCode = ar.calculatedCode + JOIN accountReconciliationConfig arc + WHERE t.id IS NULL; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn/procedures/agencyVolume.sql b/db/routines/vn/procedures/agencyVolume.sql new file mode 100644 index 000000000..176b77726 --- /dev/null +++ b/db/routines/vn/procedures/agencyVolume.sql @@ -0,0 +1,38 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`agencyVolume`() +BEGIN +/** + * Calculates and presents information on shipment and packaging volumes + * for agencies that are not owned for a specific period. + */ + DECLARE vStarted DATETIME DEFAULT util.VN_CURDATE(); + DECLARE vEnded DATETIME DEFAULT util.dayEnd(util.VN_CURDATE()); + + SELECT ag.id agency_id, + CONCAT(RPAD(c.country, 16,' _') ,' ',ag.name) Agencia, + COUNT(*) expediciones, + SUM(t.packages) Bultos, + SUM(tpe.boxes) Faltan + FROM ticket t + JOIN warehouse w ON w.id = t.warehouseFk + JOIN country c ON w.countryFk = c.id + JOIN address a ON a.id = t.addressFk + JOIN agencyMode am ON am.id = t.agencyModeFk + JOIN agency ag ON ag.id = am.agencyFk + JOIN ( + SELECT sv.ticketFk, + CEIL(1000 * SUM(sv.volume) / vc.standardFlowerBox) boxes + FROM ticket t + JOIN saleVolume sv ON sv.ticketFk = t.id + JOIN volumeConfig vc + WHERE t.shipped BETWEEN vStarted AND vEnded + AND (t.packages IS NULL OR NOT t.packages) + GROUP BY t.id + ) tpe ON tpe.ticketFk = t.id + WHERE t.shipped BETWEEN vStarted AND vEnded + AND NOT ag.isOwn + GROUP BY ag.id + ORDER BY Agencia; + +END$$ +DELIMITER ; \ No newline at end of file diff --git a/db/routines/vn2008/procedures/account_conciliacion_add.sql b/db/routines/vn2008/procedures/account_conciliacion_add.sql deleted file mode 100644 index 94ef0b14b..000000000 --- a/db/routines/vn2008/procedures/account_conciliacion_add.sql +++ /dev/null @@ -1,33 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`account_conciliacion_add`() -BEGIN - UPDATE account_conciliacion ac - JOIN - ( - SELECT idaccount_conciliacion, @c:= if(@id = id_calculated, @c + 1, 1) contador, - @id:= id_calculated as id_calculated, concat(id_calculated,'(',@c,')') as new_id - FROM account_conciliacion - JOIN - ( - select id_calculated, count(*) rep, @c:= 0, @id:= concat('-',id_calculated) - from account_conciliacion - group by id_calculated - having rep > 1 - ) sub using(id_calculated) - ) sub2 using(idaccount_conciliacion) - SET ac.id_calculated = sub2.new_id; - - INSERT INTO Cajas(Cajafecha, Partida, Serie, Concepto, Entrada, - Salida, Id_Banco,empresa_id, warehouse_id, - Proveedores_account_id, id_calculated, InForeignValue, OutForeignValue, Id_Trabajador) - SELECT Fechaoperacion, TRUE, 'MB', ac.Concepto, IF(DebeHaber = 2 AND currencyFk = 1, importe,null), - IF(DebeHaber = 1 AND currencyFk = 1, importe, null), a.id, sa.supplierFk, 1, - ac.Id_Proveedores_account, ac.id_calculated, IF(DebeHaber = 2 AND NOT currencyFk = 1, importe, null), - IF(DebeHaber = 1 AND NOT currencyFk = 1, importe, null), account.myUser_getId() - FROM account_conciliacion ac - JOIN vn.supplierAccount sa on sa.id = ac.Id_Proveedores_account - JOIN vn.accounting a ON a.id = sa.accountingFk - LEFT JOIN Cajas c on c.id_calculated = ac.id_calculated - WHERE c.Id_Caja IS NULL; -END$$ -DELIMITER ; diff --git a/db/routines/vn2008/procedures/agencia_volume.sql b/db/routines/vn2008/procedures/agencia_volume.sql deleted file mode 100644 index ea631793d..000000000 --- a/db/routines/vn2008/procedures/agencia_volume.sql +++ /dev/null @@ -1,44 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`agencia_volume`() -BEGIN - DECLARE vStarted DATETIME DEFAULT TIMESTAMP(util.VN_CURDATE()); - DECLARE vEnded DATETIME DEFAULT TIMESTAMP(util.VN_CURDATE(), '23:59:59'); - - DROP TEMPORARY TABLE IF EXISTS tmp.ticket_PackagingEstimated; - CREATE TEMPORARY TABLE tmp.ticket_PackagingEstimated - ( - ticketFk INT PRIMARY KEY - ,boxes INT DEFAULT 0 - ); - - INSERT INTO tmp.ticket_PackagingEstimated(ticketFk, boxes) - SELECT sv.ticketFk, CEIL(1000 * sum(sv.volume) / vc.standardFlowerBox) - FROM vn.ticket t - JOIN vn.saleVolume sv ON sv.ticketFk = t.id - JOIN vn.volumeConfig vc - WHERE t.shipped BETWEEN vStarted AND vEnded - AND IFNULL(t.packages,0) = 0 - GROUP BY t.id; - SELECT * FROM - ( - SELECT ag.id agency_id, - CONCAT(RPAD(c.country, 16,' _') ,' ',ag.name) Agencia, - count(*) expediciones, - sum(t.packages) Bultos, - sum(tpe.boxes) Faltan - FROM vn.ticket t - JOIN vn.warehouse w ON w.id = t.warehouseFk - JOIN vn.country c ON w.countryFk = c.id - JOIN vn.address a ON a.id = t.addressFk - JOIN vn.agencyMode am ON am.id = t.agencyModeFk - JOIN vn.agency ag ON ag.id = am.agencyFk - JOIN tmp.ticket_PackagingEstimated tpe ON tpe.ticketFk = t.id - WHERE t.shipped BETWEEN vStarted AND vEnded - AND ag.isOwn = FALSE - GROUP BY ag.id - ) sub - ORDER BY Agencia; - - DROP TEMPORARY TABLE tmp.ticket_PackagingEstimated; -END$$ -DELIMITER ; diff --git a/db/routines/vn2008/procedures/article.sql b/db/routines/vn2008/procedures/article.sql deleted file mode 100644 index 3c2664c0f..000000000 --- a/db/routines/vn2008/procedures/article.sql +++ /dev/null @@ -1,15 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`article`() -BEGIN -/** - * Crea la tabla temporal: article_inventory - */ - DROP TEMPORARY TABLE IF EXISTS article_inventory; - CREATE TEMPORARY TABLE article_inventory - ( - `article_id` INT(11) NOT NULL PRIMARY KEY, - `future` DATETIME - ) - ENGINE = MEMORY; -END$$ -DELIMITER ; diff --git a/db/versions/10948-azureSalal/00-addReconciliationConfig.sql b/db/versions/10948-azureSalal/00-addReconciliationConfig.sql new file mode 100644 index 000000000..1da6473b4 --- /dev/null +++ b/db/versions/10948-azureSalal/00-addReconciliationConfig.sql @@ -0,0 +1,8 @@ + CREATE OR REPLACE TABLE `vn`.`accountReconciliationConfig` ( + `id` INT AUTO_INCREMENT, + `currencyFk` TINYINT(3) unsigned, + `warehouseFk` SMALLINT(6) unsigned, + PRIMARY KEY (`id`), + CONSTRAINT `account_fk_currency` FOREIGN KEY (`currencyFk`) REFERENCES `currency` (`id`), + CONSTRAINT `account_fk_warehouse` FOREIGN KEY (`warehouseFk`) REFERENCES `warehouse` (`id`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; \ No newline at end of file diff --git a/db/versions/10948-azureSalal/01-addReconciliationConfig.vn.sql b/db/versions/10948-azureSalal/01-addReconciliationConfig.vn.sql new file mode 100644 index 000000000..21743a007 --- /dev/null +++ b/db/versions/10948-azureSalal/01-addReconciliationConfig.vn.sql @@ -0,0 +1,2 @@ +INSERT INTO `vn`.`accountReconciliationConfig`(currencyFk, warehouseFk) + VALUES (1, 1); \ No newline at end of file diff --git a/db/versions/10948-azureSalal/02-grantPrivileges.sql b/db/versions/10948-azureSalal/02-grantPrivileges.sql new file mode 100644 index 000000000..d6853f759 --- /dev/null +++ b/db/versions/10948-azureSalal/02-grantPrivileges.sql @@ -0,0 +1,13 @@ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`agencyVolume`() +BEGIN +END; + +REVOKE EXECUTE ON PROCEDURE `vn2008`.`agencia_volume` FROM `agency`; +GRANT EXECUTE ON PROCEDURE `vn`.`agencyVolume` TO `agency`; + +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`addAccountReconciliation`() +BEGIN +END; + +REVOKE EXECUTE ON PROCEDURE `vn2008`.`account_conciliacion_add` FROM `financial`; +GRANT EXECUTE ON PROCEDURE `vn`.`addAccountReconciliation` TO `financial`; diff --git a/db/versions/10948-azureSalal/03-modifyColumn.sql b/db/versions/10948-azureSalal/03-modifyColumn.sql new file mode 100644 index 000000000..95b7d9c74 --- /dev/null +++ b/db/versions/10948-azureSalal/03-modifyColumn.sql @@ -0,0 +1 @@ +ALTER TABLE `vn`.`accountReconciliation` MODIFY debitCredit ENUM('debit', 'credit'); \ No newline at end of file