salix/db/routines/vn/procedures/route_calcCommission.sql

116 lines
3.2 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`route_calcCommission`(
vSelf INT
)
BEGIN
/**
* Calcula las comisión para una ruta y guarda los valores
* en la tabla vn.routeCommission.
*
* @param vSelf Id de ruta
*/
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
JOIN routeConfig rc
WHERE r.id = vSelf;
IF vIsUpdatable THEN
DELETE FROM routeCommission
WHERE routeFk = vSelf;
SELECT w.isFreelance, v.isKmTruckRate, p.countryFk INTO vIsFreelance, vIsKmTruckRate, vCountryFk
FROM route r
JOIN worker w ON w.id = r.workerFk
JOIN vehicle v ON v.id = r.vehicleFk
LEFT JOIN ticket t ON t.routeFk = r.id
LEFT JOIN address a ON a.id = t.addressFk
LEFT JOIN province p ON p.id = a.provinceFk
WHERE r.id = vSelf
GROUP BY p.countryFk
ORDER BY COUNT(*) DESC
LIMIT 1;
SELECT ampp.percentage INTO vAgencyModePricePercentage
FROM route r
JOIN agencyMode am ON am.id = r.agencyModeFk
JOIN agencyModePricePercentage ampp ON ampp.agencyModeFk = am.id
WHERE r.id = vSelf;
-- Falta calcular el precio, a la espera de saber el/los campo/s exacto/s al que aplicarlo/s
IF vIsFreelance THEN
INSERT INTO routeCommission (
routeFk,
workCenterFk,
freelanceYearlyM3,
cat4m3,
cat5m3,
isKmTruckRate,
countryFk
)
SELECT vSelf,
r.commissionWorkCenterFk,
IF(vAgencyModePricePercentage IS NOT NULL,
vAgencyModePricePercentage / 100,
rc.freelanceM3
) *
IF(IFNULL(r.m3, 0) >= rc.freelanceMinM3,
IFNULL(r.m3, 0),
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 workCenterCommission wc ON wc.workCenterFk = r.commissionWorkCenterFk
WHERE r.id = vSelf
AND r.workerFk
AND r.commissionWorkCenterFk;
ELSE
INSERT INTO routeCommission (
routeFk,
workCenterFk,
km,
m3,
yearlyKm,
yearlyM3,
cat4m3,
cat5m3,
isKmTruckRate,
countryFk
)
SELECT vSelf,
r.commissionWorkCenterFk,
(r.kmEnd - r.kmStart) *
IF(v.isKmTruckRate, rc.kmHeavy, rc.kmLight),
IFNULL(r.m3, 0) *
IF(v.isKmTruckRate,
IFNULL(wc.deliveryM3Cat5, rc.deliveryM3Cat5),
IFNULL(wc.deliveryM3Cat4, rc.deliveryM3Cat4)),
(r.kmEnd - r.kmStart) * rc.kmYearly,
IFNULL(r.m3, 0) * rc.m3Yearly,
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 workCenterCommission wc ON wc.workCenterFk = r.commissionWorkCenterFk
WHERE r.id = vSelf
AND r.kmStart
AND r.kmEnd
AND r.workerFk
AND r.commissionWorkCenterFk;
END IF;
END IF;
END$$
DELIMITER ;