DROP procedure IF EXISTS `vn`.`catalog_componentCalculate`; DELIMITER $$ CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`catalog_componentCalculate`( vZoneFk INT, vAddressFk INT, vShipped DATE) proc: BEGIN /** * Calcula los componentes de los articulos de tmp.ticketLot * * @param vZoneFk para calcular el transporte * @param vAgencyModeFk Id del modo de agencia * @param tmp.ticketLot (warehouseFk,available,itemFk,buyFk) * * @return tmp.ticketComponent(itemFk, warehouseFk, available, rate2, rate3, minPrice, * packing, grouping, groupingMode, buyFk, typeFk) * @return tmp.ticketComponentPrice (warehouseFk, itemFk, rate, grouping, price) */ DECLARE vClientFk INT; DECLARE vGeneralInflationCoefficient INT DEFAULT 1; DECLARE vMinimumDensityWeight INT DEFAULT 167; DECLARE vBoxFreightItem INT DEFAULT 71; DECLARE vBoxVolume BIGINT; -- DEFAULT 138000; DECLARE vSpecialPriceComponent INT DEFAULT 10; DECLARE vDeliveryComponent INT DEFAULT 15; DECLARE vRecoveryComponent INT DEFAULT 17; DECLARE vSellByPacketComponent INT DEFAULT 22; DECLARE vBuyValueComponent INT DEFAULT 28; DECLARE vMarginComponent INT DEFAULT 29; DECLARE vDiscountLastItemComponent INT DEFAULT 32; DECLARE vExtraBaggedComponent INT DEFAULT 38; DECLARE vManaAutoComponent INT DEFAULT 39; SELECT volume INTO vBoxVolume FROM vn.packaging WHERE id = '94'; SELECT clientFk INTO vClientFK FROM address WHERE id = vAddressFk; SET @rate2 := 0; SET @rate3 := 0; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentCalculate; CREATE TEMPORARY TABLE tmp.ticketComponentCalculate (PRIMARY KEY (itemFk, warehouseFk)) ENGINE = MEMORY SELECT tl.itemFk, tl.warehouseFk, tl.available, IF((@rate2 := IFNULL(pf.rate2, b.price2)) < i.minPrice AND i.hasMinPrice, i.minPrice, @rate2) * 1.0 rate2, IF((@rate3 := IFNULL(pf.rate3, b.price3)) < i.minPrice AND i.hasMinPrice, i.minPrice, @rate3) * 1.0 rate3, IFNULL(pf.rate3, 0) AS minPrice, IFNULL(pf.packing, b.packing) packing, IFNULL(pf.`grouping`, b.`grouping`) grouping, ABS(IFNULL(pf.box, b.groupingMode)) groupingMode, tl.buyFk, i.typeFk, IF(i.hasKgPrice,(b.packing * b.weight) / 1000, NULL) weightPacking FROM tmp.ticketLot tl JOIN buy b ON b.id = tl.buyFk JOIN item i ON i.id = tl.itemFk JOIN itemType it ON it.id = i.typeFk LEFT JOIN itemCategory ic ON ic.id = it.categoryFk LEFT JOIN specialPrice sp ON sp.itemFk = i.id AND sp.clientFk = vClientFk LEFT JOIN ( SELECT * FROM ( SELECT pf.itemFk, pf.`grouping`, pf.packing, pf.box, pf.rate2, pf.rate3, z.warehouseFk FROM priceFixed pf JOIN zone z ON z.warehouseFk = pf.warehouseFk OR pf.warehouseFk = 0 WHERE vShipped BETWEEN pf.started AND pf.ended ORDER BY pf.itemFk, pf.warehouseFk DESC ) tpf GROUP BY tpf.itemFk, tpf.warehouseFk ) pf ON pf.itemFk = tl.itemFk AND pf.warehouseFk = tl.warehouseFk WHERE b.buyingValue + b.freightValue + b.packageValue + b.comissionValue > 0.01 AND ic.display <> 0; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponent; CREATE TEMPORARY TABLE tmp.ticketComponent ( `warehouseFk` INT UNSIGNED NOT NULL, `itemFk` INT NOT NULL, `componentFk` INT UNSIGNED NOT NULL, `cost` DECIMAL(10,4) NOT NULL, INDEX `itemWarehouse` USING BTREE (`itemFk` ASC, `warehouseFk` ASC), UNIQUE INDEX `itemWarehouseComponent` (`itemFk` ASC, `warehouseFk` ASC, `componentFk` ASC)); INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost) SELECT tcc.warehouseFk, tcc.itemFk, vBuyValueComponent, b.buyingValue + b.freightValue + b.packageValue + b.comissionValue FROM tmp.ticketComponentCalculate tcc JOIN buy b ON b.id = tcc.buyFk; INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost) SELECT tcc.warehouseFk, tcc.itemFk, vMarginComponent, tcc.rate3 - b.buyingValue - b.freightValue - b.packageValue - b.comissionValue FROM tmp.ticketComponentCalculate tcc JOIN buy b ON b.id = tcc.buyFk; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentBase; CREATE TEMPORARY TABLE tmp.ticketComponentBase ENGINE = MEMORY SELECT tc.itemFk, ROUND(SUM(tc.cost), 4) AS base, tc.warehouseFk FROM tmp.ticketComponent tc GROUP BY tc.itemFk, warehouseFk; INSERT INTO tmp.ticketComponent SELECT tcb.warehouseFk, tcb.itemFk, vRecoveryComponent, ROUND(tcb.base * LEAST(cr.recobro, 0.25), 3) FROM tmp.ticketComponentBase tcb JOIN bi.claims_ratio cr ON cr.Id_Cliente = vClientFk WHERE cr.recobro > 0.009; INSERT INTO tmp.ticketComponent SELECT tcb.warehouseFk, tcb.itemFk, vManaAutoComponent, ROUND(base * (0.01 + prices_modifier_rate), 3) as manaAuto FROM tmp.ticketComponentBase tcb JOIN `client` c on c.id = vClientFk JOIN bs.mana_spellers ms ON c.salesPersonFk = ms.Id_Trabajador WHERE ms.prices_modifier_activated HAVING manaAuto <> 0; INSERT INTO tmp.ticketComponent SELECT tcb.warehouseFk, tcb.itemFk, cr.id, GREATEST(IFNULL(ROUND(tcb.base * cr.tax, 4), 0), tcc.minPrice - tcc.rate3) FROM tmp.ticketComponentBase tcb JOIN componentRate cr JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tcb.itemFk AND tcc.warehouseFk = tcb.warehouseFk LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk WHERE cr.id = vDiscountLastItemComponent AND cr.tax <> 0 AND tcc.minPrice < tcc.rate3 AND sp.value IS NULL; INSERT INTO tmp.ticketComponent SELECT tcc.warehouseFk, tcc.itemFk, vSellByPacketComponent, tcc.rate2 - tcc.rate3 FROM tmp.ticketComponentCalculate tcc JOIN buy b ON b.id = tcc.buyFk LEFT JOIN specialPrice sp ON sp.clientFk = vClientFk AND sp.itemFk = tcc.itemFk WHERE sp.value IS NULL; INSERT INTO tmp.ticketComponent SELECT tcc.warehouseFK, tcc.itemFk, vDeliveryComponent, vGeneralInflationCoefficient * ROUND(( i.compression * r.cm3 * IF(am.deliveryMethodFk = 1, (GREATEST(i.density, vMinimumDensityWeight) / vMinimumDensityWeight), 1) * IFNULL((z.price - z.bonus) * 1/*amz.inflation*/ , 50)) / vBoxVolume, 4 ) cost FROM tmp.ticketComponentCalculate tcc JOIN item i ON i.id = tcc.itemFk JOIN zone z ON z.id = vZoneFk JOIN agencyMode am ON am.id = z.agencyModeFk LEFT JOIN bi.rotacion r ON r.warehouse_id = tcc.warehouseFk AND r.Id_Article = tcc.itemFk HAVING cost <> 0; IF (SELECT COUNT(*) FROM vn.addressForPackaging WHERE addressFk = vAddressFk) THEN INSERT INTO tmp.ticketComponent SELECT tcc.warehouseFk, b.itemFk, vExtraBaggedComponent, ap.packagingValue cost FROM tmp.ticketComponentCalculate tcc JOIN vn.addressForPackaging ap WHERE ap.addressFk = vAddressFk; END IF; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentCopy; CREATE TEMPORARY TABLE tmp.ticketComponentCopy ENGINE = MEMORY SELECT * FROM tmp.ticketComponent; INSERT INTO tmp.ticketComponent SELECT tcc.warehouseFk, tcc.itemFk, vSpecialPriceComponent, sp.value - SUM(tcc.cost) sumCost FROM tmp.ticketComponentCopy tcc JOIN componentRate cr ON cr.id = tcc.componentFk JOIN specialPrice sp ON sp.clientFk = vClientFK AND sp.itemFk = tcc.itemFk WHERE cr.classRate IS NULL GROUP BY tcc.itemFk, tcc.warehouseFk HAVING ABS(sumCost) > 0.001; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentSum; CREATE TEMPORARY TABLE tmp.ticketComponentSum (INDEX (itemFk, warehouseFk)) ENGINE = MEMORY SELECT SUM(cost) sumCost, tc.itemFk, tc.warehouseFk, cr.classRate FROM tmp.ticketComponent tc JOIN componentRate cr ON cr.id = tc.componentFk GROUP BY tc.itemFk, tc.warehouseFk, cr.classRate; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentRate; CREATE TEMPORARY TABLE tmp.ticketComponentRate ENGINE = MEMORY SELECT tcc.warehouseFk, tcc.itemFk, 1 rate, IF(tcc.groupingMode = 1, tcc.`grouping`, 1) grouping, CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) price, CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) / weightPacking priceKg FROM tmp.ticketComponentCalculate tcc JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk AND tcs.warehouseFk = tcc.warehouseFk WHERE IFNULL(tcs.classRate, 1) = 1 AND tcc.groupingMode < 2 AND (tcc.packing > tcc.`grouping` or tcc.groupingMode = 0) GROUP BY tcs.warehouseFk, tcs.itemFk; INSERT INTO tmp.ticketComponentRate (warehouseFk, itemFk, rate, grouping, price, priceKg) SELECT tcc.warehouseFk, tcc.itemFk, 2 rate, tcc.packing grouping, SUM(tcs.sumCost) price, SUM(tcs.sumCost) / weightPacking priceKg FROM tmp.ticketComponentCalculate tcc JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk AND tcs.warehouseFk = tcc.warehouseFk WHERE tcc.available IS NULL OR (IFNULL(tcs.classRate, 2) = 2 AND tcc.packing > 0 AND tcc.available >= tcc.packing) GROUP BY tcs.warehouseFk, tcs.itemFk; INSERT INTO tmp.ticketComponentRate (warehouseFk, itemFk, rate, grouping, price, priceKg) SELECT tcc.warehouseFk, tcc.itemFk, 3 rate, tcc.available grouping, SUM(tcs.sumCost) price, SUM(tcs.sumCost) / weightPacking priceKg FROM tmp.ticketComponentCalculate tcc JOIN tmp.ticketComponentSum tcs ON tcs.itemFk = tcc.itemFk AND tcs.warehouseFk = tcc.warehouseFk WHERE IFNULL(tcs.classRate, 3) = 3 GROUP BY tcs.warehouseFk, tcs.itemFk; DROP TEMPORARY TABLE IF EXISTS tmp.ticketComponentPrice; CREATE TEMPORARY TABLE tmp.ticketComponentPrice ENGINE = MEMORY SELECT * FROM ( SELECT * FROM tmp.ticketComponentRate ORDER BY price ) t GROUP BY itemFk, warehouseFk, `grouping`; DROP TEMPORARY TABLE tmp.ticketComponentCalculate, tmp.ticketComponentSum, tmp.ticketComponentBase, tmp.ticketComponentRate, tmp.ticketComponentCopy; END$$ DELIMITER ;