#6492 refactor vn2008 procedures #2159

Merged
jorgep merged 18 commits from 6492-refactorProceduresVn2008 into dev 2024-04-10 09:42:07 +00:00
6 changed files with 147 additions and 1 deletions
Showing only changes of commit 10c2d25cbd - Show all commits

View File

@ -3733,3 +3733,27 @@ INSERT INTO vn.report (name) VALUES ('LabelCollection');
INSERT INTO vn.parkingLog(originFk, userFk, `action`, creationDate, description, changedModel,oldInstance, newInstance, changedModelId, changedModelValue)
VALUES(1, 18, 'update', util.VN_CURDATE(), NULL, 'SaleGroup', '{"parkingFk":null}', '{"parkingFk":1}', 1, NULL);
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',1,'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',1,'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',1,'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',1,'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',1,'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',1,'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',1,'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',1,'120','2023-12-14 08:39:53.000');
INSERT INTO `vn`.`accountReconciliationConfig`(debitCredit, debitCredit2, currencyFk, warehouseFk)
VALUES
(1, 2, 1, 1);

View File

@ -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,
calculatedId,
CONCAT(
calculatedId,
'(',
ROW_NUMBER() OVER (PARTITION BY calculatedId ORDER BY id),
')'
) newId
FROM accountReconciliation
WHERE calculatedId IN (
SELECT calculatedId
FROM accountReconciliation
GROUP BY calculatedId
HAVING COUNT(*) > 1
)
ORDER BY calculatedId, id
) sub2 ON ar.id = sub2.id
SET ar.calculatedId = sub2.newId;
INSERT INTO till(
dated,
isAccountable,
serie,
concept,
`in`,
`out`,
bankFk,
companyFk,
warehouseFk,
supplierAccountFk,
calculatedCode,
InForeignValue,
OutForeignValue,
workerFk
)
SELECT ar.operationDate dated,
TRUE isAccountable,
'MB' serie,
ar.concept concept,
@totalIn := IF(ar.debitCredit = arc.debitCredit2 AND a.currencyFk = arc.currencyFk, ar.amount, NULL) `in`,
@totalOut := IF(ar.debitCredit = arc.debitCredit AND a.currencyFk = arc.currencyFk, ar.amount, NULL) `out`,
a.id bankFk,
sa.supplierFk companyFk,
arc.warehouseFk warehouseFk,
ar.supplierAccountFk supplierAccountFk,
ar.calculatedId calculatedCode,
@totalIn InForeignValue,
@totalOut OutForeignValue,
account.myUser_getId() user
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.calculatedId
JOIN accountReconciliationConfig arc
WHERE t.id IS NULL;
END$$
DELIMITER ;

View File

@ -0,0 +1,38 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`agencyVolume`()
BEGIN
/**
* Calcula y presenta información sobre volúmenes de expediciones y empaques
* para agencias que no son propias durante un período específico.
*/
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)
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 ;

View File

@ -0,0 +1,10 @@
CREATE OR REPLACE TABLE `vn`.`accountReconciliationConfig` (
`id` INT AUTO_INCREMENT,
`debitCredit` INT(6),
`debitCredit2` INT(6),
`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;

View File

@ -0,0 +1,2 @@
INSERT INTO `vn`.`accountReconciliationConfig`(debitCredit, debitCredit2, currencyFk, warehouseFk)
VALUES (1, 2, 1, 1);

View File

@ -0,0 +1,6 @@
REVOKE EXECUTE ON PROCEDURE `agencia_volume` FROM `agency`;
GRANT EXECUTE ON PROCEDURE `agencyVolume` TO `agency`;
REVOKE EXECUTE ON PROCEDURE `account_conciliacion_add` FROM `financial`;
GRANT EXECUTE ON PROCEDURE `addAccountConciliation` TO `financial`;