diff --git a/db/routines/vn/procedures/route_calcCommission.sql b/db/routines/vn/procedures/route_calcCommission.sql index 7c911a5e2..8892b8f2b 100644 --- a/db/routines/vn/procedures/route_calcCommission.sql +++ b/db/routines/vn/procedures/route_calcCommission.sql @@ -11,6 +11,8 @@ BEGIN */ DECLARE vIsUpdatable, vIsFreelance BOOL DEFAULT 0; DECLARE vAgencyModePricePercentage DOUBLE; + DECLARE vIsKmTruckRate BOOL; + DECLARE vCountryFk INT; SELECT r.created >= rc.cutoffDated INTO vIsUpdatable FROM route r @@ -21,10 +23,16 @@ BEGIN DELETE FROM routeCommission WHERE routeFk = vSelf; - SELECT w.isFreelance INTO vIsFreelance + SELECT w.isFreelance, v.isKmTruckRate, c.countryFk INTO vIsFreelance, vIsKmTruckRate, vCountryFk FROM route r JOIN worker w ON w.id = r.workerFk - WHERE r.id = vSelf; + JOIN vehicle v ON v.id = r.vehicleFk + LEFT JOIN ticket t ON t.routeFk = r.id + LEFT JOIN client c ON c.id = t.clientFk + WHERE r.id = vSelf + GROUP BY c.countryFk + ORDER BY COUNT(*) DESC + LIMIT 1; SELECT ampp.percentage INTO vAgencyModePricePercentage FROM route r @@ -39,7 +47,9 @@ BEGIN workCenterFk, freelanceYearlyM3, cat4m3, - cat5m3 + cat5m3, + isKmTruckRate, + countryFk ) SELECT vSelf, r.commissionWorkCenterFk, @@ -51,11 +61,14 @@ BEGIN IFNULL(r.m3, 0), 0 ), - rc.distributionCat4M3 * IFNULL(r.m3, 0), - rc.distributionCat5M3 * IFNULL(r.m3, 0) + IFNULL(wc.distributionCat4M3, rc.distributionCat4M3) * IFNULL(r.m3, 0), + IFNULL(wc.distributionCat5M3, rc.distributionCat5M3) * IFNULL(r.m3, 0), + vIsKmTruckRate, + vCountryFk FROM route r JOIN vehicle v ON v.id = r.vehicleFk JOIN routeConfig rc + LEFT JOIN workCenterConfig wc ON wc.workCenter = r.workCenterFk WHERE r.id = vSelf AND r.workerFk AND r.commissionWorkCenterFk; @@ -68,7 +81,9 @@ BEGIN yearlyKm, yearlyM3, cat4m3, - cat5m3 + cat5m3, + isKmTruckRate, + countryFk ) SELECT vSelf, r.commissionWorkCenterFk, @@ -78,11 +93,14 @@ BEGIN IF(v.isKmTruckRate, rc.deliveryM3Cat5, rc.deliveryM3Cat4), (r.kmEnd - r.kmStart) * rc.kmYearly, IFNULL(r.m3, 0) * rc.m3Yearly, - rc.distributionCat4M3 * IFNULL(r.m3, 0), - rc.distributionCat5M3 * IFNULL(r.m3, 0) + IFNULL(wc.distributionCat4M3, rc.distributionCat4M3) * IFNULL(r.m3, 0), + IFNULL(wc.distributionCat5M3, rc.distributionCat5M3) * IFNULL(r.m3, 0), + vIsKmTruckRate, + vCountryFk FROM route r JOIN vehicle v ON v.id = r.vehicleFk JOIN routeConfig rc + LEFT JOIN workCenterConfig wc ON wc.workCenter = r.workCenterFk WHERE r.id = vSelf AND r.kmStart AND r.kmEnd diff --git a/db/versions/11310-turquoiseGalax/00-firstScript.sql b/db/versions/11310-turquoiseGalax/00-firstScript.sql new file mode 100644 index 000000000..a180e3f7f --- /dev/null +++ b/db/versions/11310-turquoiseGalax/00-firstScript.sql @@ -0,0 +1,51 @@ + ALTER TABLE vn.routeCommission ADD IF NOT EXISTS countryFk mediumint(8) unsigned DEFAULT NULL NULL; + ALTER TABLE vn.routeCommission ADD IF NOT EXISTS isKmTruckRate TINYINT(1) DEFAULT NULL NULL; + + ALTER TABLE vn.routeCommission DROP FOREIGN KEY IF EXISTS routeCommission_country_FK; + ALTER TABLE vn.routeCommission ADD CONSTRAINT routeCommission_country_FK FOREIGN KEY (countryFk) + REFERENCES vn.country(id) ON DELETE RESTRICT ON UPDATE CASCADE; + + CREATE TABLE IF NOT EXISTS vn.workCenterConfig ( + `workCenterFk` INT(11) NOT NULL, + `deliveryManAdjustment` DECIMAL(4,2) DEFAULT NULL + COMMENT 'Número de trabajadores para equilibrar los repartidores de diferentes centros. + Utilizado en repartidores de grafana', + `distributionM3Category1` decimal(5,2) DEFAULT NULL, + `distributionM3Category2` decimal(5,2) DEFAULT NULL, + `distributionCat4M3` DECIMAL(5,2) DEFAULT NULL + COMMENT 'Comisión por gestión de la distribución Cat IV', + `distributionCat5M3` DECIMAL(5,2) DEFAULT NULL + COMMENT 'Comisión por gestión de la distribución Cat V', + PRIMARY KEY (`workCenterFk`), + CONSTRAINT `workCenterConfig_workCenterFk` FOREIGN KEY (`workCenterFk`) + REFERENCES `workCenter` (`id`) ON UPDATE CASCADE ON DELETE RESTRICT + ); + + UPDATE vn.routeCommission rc + JOIN (SELECT id, countryFk, isKmTruckRate + FROM (SELECT r.id, c.countryFk, v.isKmTruckRate + FROM vn.route r + JOIN vn.routeCommission rc ON rc.routeFk = r.id + LEFT JOIN vn.ticket t ON t.routeFk = r.id + LEFT JOIN vn.client c ON c.id = t.clientFk + LEFT JOIN vn.vehicle v ON v.id = r.vehicleFk + WHERE r.created >= '2023-12-01' + GROUP BY r.id, c.countryFk + ORDER BY r.id, COUNT(*) DESC + LIMIT 100000000000 + )sub + GROUP BY id + )sub ON sub.id = rc.routeFk + SET rc.isKmTruckRate = sub.isKmTruckRate, + rc.countryFk = sub.countryFk; + + ALTER TABLE vn.workerDistributionCategory ADD IF NOT EXISTS countryFk mediumint(8) unsigned DEFAULT NULL NULL; + ALTER TABLE vn.workerDistributionCategory ADD IF NOT EXISTS isKmTruckRate TINYINT(1) DEFAULT NULL NULL; + + ALTER TABLE vn.workerDistributionCategory DROP FOREIGN KEY IF EXISTS workerDistributionCategory_country_FK; + ALTER TABLE vn.workerDistributionCategory ADD CONSTRAINT workerDistributionCategory_country_FK FOREIGN KEY (countryFk) + REFERENCES vn.country(id) ON DELETE RESTRICT ON UPDATE CASCADE; + + ALTER TABLE vn.workerDistributionCategory ADD IF NOT EXISTS commissionSplitWorkers INT UNSIGNED NOT NULL DEFAULT 1 + COMMENT 'Número de enrutadores entr los que se reparte la comsión'; +