DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`catalog_componentCalculate`(
	vZoneFk INT,
	vAddressFk INT,
	vShipped DATE,
	vWarehouseFk INT
)
BEGIN
/**
 * Calcula los componentes de los articulos de la tabla tmp.ticketLot
 *
 * @param vZoneFk para calcular el transporte
 * @param vAddressFk Consignatario
 * @param vShipped dia de salida del pedido
 * @param vWarehouseFk warehouse de salida del pedido
 * @table tmp.ticketLot (warehouseFk, available, itemFk, buyFk, zoneFk)
 * @table tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
 *
 * @return tmp.ticketComponentPrice (warehouseFk, itemFk, rate, `grouping`, price, priceKg)
 */
	DECLARE vClientFk INT;
	DECLARE vVNHWarehouseFk INT DEFAULT 7;

	SELECT clientFk INTO vClientFK
		FROM address
		WHERE id = vAddressFk;

	CREATE OR REPLACE TEMPORARY TABLE tPriceDelta
	(INDEX (itemFk))
	ENGINE = MEMORY
	SELECT i.id itemFk,
			SUM(IFNULL(pd.absIncreasing,0)) absIncreasing,
			SUM(IFNULL(pd.ratIncreasing,0)) ratIncreasing,
			pd.warehouseFk
			FROM item i
				JOIN priceDelta pd
					ON pd.itemTypeFk = i.typeFk
					AND (pd.minSize IS NULL OR pd.minSize <= i.`size`)
					AND (pd.maxSize IS NULL OR pd.maxSize >= i.`size`)
					AND (pd.inkFk IS NULL OR pd.inkFk = i.inkFk)
					AND (pd.originFk IS NULL OR pd.originFk = i.originFk)
					AND (pd.producerFk IS NULL OR pd.producerFk = i.producerFk)
					AND (pd.warehouseFk IS NULL OR pd.warehouseFk = vWarehouseFk)
				LEFT JOIN zoneGeo zg ON zg.id = pd.zoneGeoFk
				LEFT JOIN zoneGeo zg2 ON zg2.id = address_getGeo(vAddressFk)
			WHERE (pd.fromDated IS NULL OR pd.fromDated <= vShipped)
				AND (pd.toDated IS NULL OR pd.toDated >= vShipped)
				AND (pd.zoneGeoFk IS NULL OR zg2.lft BETWEEN zg.lft AND zg.rgt)
			GROUP BY itemFk;

	CREATE OR REPLACE TEMPORARY TABLE tSpecialPrice
	(INDEX (itemFk))
	ENGINE = MEMORY
	SELECT * FROM (
		SELECT *
			FROM specialPrice
			WHERE (clientFk = vClientFk OR clientFk IS NULL)
			AND started <= vShipped
			AND (ended >= vShipped OR ended IS NULL)
		ORDER BY (clientFk = vClientFk) DESC, id DESC
		LIMIT 10000000000000000000) t
		GROUP BY itemFk;

	CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentCalculate
	(PRIMARY KEY (itemFk, warehouseFk))
	ENGINE = MEMORY
		SELECT tl.itemFk,
			tl.warehouseFk,
			tl.available,
			IF(i.hasMinPrice, GREATEST(i.minPrice,IFNULL(pf.rate2, b.price2)),IFNULL(pf.rate2, b.price2)) rate2,
			IF(i.hasMinPrice, GREATEST(i.minPrice,IFNULL(pf.rate3, b.price3)),IFNULL(pf.rate3, b.price3)) rate3,
			IFNULL(pf.packing, GREATEST(b.grouping, b.packing)) packing,
			IFNULL(pf.`grouping`, b.`grouping`) `grouping`,
			b.groupingMode groupingMode,
			tl.buyFk,
			i.typeFk,
			IF(i.hasKgPrice, b.weight / b.packing, NULL) weightGrouping
		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
			JOIN itemCategory ic ON ic.id = it.categoryFk
			LEFT JOIN tSpecialPrice sp ON sp.itemFk = i.id
			LEFT JOIN (
					SELECT * FROM (
						SELECT 	pf.itemFk,
								pf.`grouping`,
								pf.packing,
								pf.box,
								pf.rate2,
								pf.rate3,
								zw.warehouseFk
							FROM priceFixed pf
								JOIN zoneWarehouse zw ON zw.zoneFk = vZoneFk
									AND zw.warehouseFk IN (pf.warehouseFk,0)
							WHERE vShipped BETWEEN pf.started AND pf.ended
							ORDER BY pf.itemFk, pf.warehouseFk DESC
							LIMIT 10000000000000000000
								) 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.merchandise
			AND tl.zoneFk = vZoneFk
			AND tl.warehouseFk = vWarehouseFk;

	-- Coste
	INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost)
		SELECT tcc.warehouseFk,
				tcc.itemFk,
				c2.id,
				b.buyingValue + b.freightValue + b.packageValue + b.comissionValue
			FROM tmp.ticketComponentCalculate tcc
				JOIN vn.component c2 ON c2.code = 'purchaseValue'
				JOIN buy b ON b.id = tcc.buyFk;

	-- Margen
	INSERT INTO tmp.ticketComponent (warehouseFk, itemFk, componentFk, cost)
		SELECT tcc.warehouseFk,
				tcc.itemFk,
				c2.id,
				tcc.rate3 - b.buyingValue - b.freightValue - b.packageValue - b.comissionValue
			FROM tmp.ticketComponentCalculate tcc
				JOIN vn.component c2 ON c2.code = 'margin'
				JOIN buy b ON b.id = tcc.buyFk;

	CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentBase ENGINE = MEMORY
		SELECT tc.itemFk, ROUND(SUM(tc.cost), 4) AS base, tc.warehouseFk
			FROM tmp.ticketComponent tc
				JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk
			GROUP BY tc.itemFk, warehouseFk;

	-- Bonus del comprador a un rango de productos
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT
			tcb.warehouseFk,
			tcb.itemFk,
			c.id,
			IFNULL(tcb.base * tpd.ratIncreasing / 100,0) + IFNULL(tpd.absIncreasing,0)
			FROM tmp.ticketComponentBase tcb
				JOIN component c ON c.code = 'bonus'
				JOIN tPriceDelta tpd
					ON tpd.itemFk = tcb.itemFk
					AND tpd.warehouseFk = tcb.warehouseFk;

	-- RECOBRO
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT tcb.warehouseFk, tcb.itemFk, c2.id,
			ROUND(tcb.base *
							LEAST(
								MAX(GREATEST(IFNULL(cr.priceIncreasing,0),
											IFNULL(cr1.priceIncreasing,0),
											IFNULL(cr2.priceIncreasing,0))
									),
								cc.maxPriceIncreasingRatio),
				3)
			FROM tmp.ticketComponentBase tcb
			JOIN vn.component c2 ON c2.code = 'debtCollection'
			JOIN vn.clientConfig cc
			JOIN claimRatio cr ON cr.clientFk = vClientFk
			LEFT JOIN clientYoke cy1 ON cy1.leftOx = cr.clientFk
			LEFT JOIN claimRatio cr1 ON cr1.clientFk = cy1.rightOx
			LEFT JOIN clientYoke cy2  ON cy2.rightOx = cr.clientFk
			LEFT JOIN claimRatio cr2 ON cr2.clientFk = cy2.leftOx
				WHERE GREATEST(
					IFNULL(cr.priceIncreasing,0),
					IFNULL(cr1.priceIncreasing,0),
					IFNULL(cr2.priceIncreasing,0)) > 0.009
			GROUP BY tcb.itemFk;

	-- Mana auto
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT tcb.warehouseFk,
				tcb.itemFk,
				c2.id,
				ROUND(base * wm.pricesModifierRate, 3) manaAuto
			FROM tmp.ticketComponentBase tcb
				JOIN `client` c on c.id = vClientFk
				JOIN workerMana wm ON c.salesPersonFk = wm.workerFk
				JOIN vn.component c2 ON c2.code = 'autoMana'
			WHERE wm.isPricesModifierActivated
			HAVING manaAuto <> 0;

	-- Precios especiales
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT tcb.warehouseFk,
				tcb.itemFk,
				c2.id,
				GREATEST(
						IFNULL(ROUND(tcb.base * c2.tax, 4), 0),
						IF(i.hasMinPrice, i.minPrice,0) - tcc.rate3
						) cost
			FROM tmp.ticketComponentBase tcb
				JOIN vn.component c2 ON c2.code = 'lastUnitsDiscount'
				JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tcb.itemFk AND tcc.warehouseFk = tcb.warehouseFk
				LEFT JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
				JOIN vn.item i ON i.id = tcb.itemFk
			WHERE sp.value IS NULL
				AND i.supplyResponseFk IS NULL;

	-- Individual
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT	tcb.warehouseFk,
				tcb.itemFk,
				c2.id,
				IFNULL(ROUND(tcb.base * c2.tax, 4), 0) cost
			FROM tmp.ticketComponentBase tcb
				JOIN vn.component c2 ON c2.code = 'individual'
				JOIN vn.client c ON c.id = vClientFk
				JOIN vn.businessType bt ON bt.code = c.businessTypeFk
			WHERE bt.code = 'individual';

	-- Venta por paquetes
	INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost)
		SELECT tcc.warehouseFk, tcc.itemFk, c2.id, tcc.rate2 - tcc.rate3
			FROM tmp.ticketComponentCalculate tcc
				JOIN vn.component c2 ON c2.code = 'salePerPackage'
				JOIN buy b ON b.id = tcc.buyFk
			LEFT JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
		WHERE sp.value IS NULL;

	CREATE OR REPLACE TEMPORARY TABLE tmp.`zone` (INDEX (id))
			ENGINE = MEMORY
		SELECT vZoneFk id;

	CALL zone_getOptionsForShipment(vShipped, TRUE);

	-- Reparto
	INSERT INTO tmp.ticketComponent
		SELECT tcc.warehouseFK,
				tcc.itemFk,
				c2.id,
				z.inflation * ROUND(ic.cm3delivery * (IFNULL(zo.price,5000) - IFNULL(zo.bonus,0)) / (1000 * vc.standardFlowerBox) , 4) cost
		FROM tmp.ticketComponentCalculate tcc
			JOIN item i ON i.id = tcc.itemFk
			JOIN tmp.zoneOption zo ON zo.zoneFk = vZoneFk
			JOIN zone z ON z.id = vZoneFk
			JOIN agencyMode am ON am.id = z.agencyModeFk
			JOIN vn.volumeConfig vc
			JOIN vn.component c2 ON c2.code = 'delivery'
			LEFT JOIN itemCost ic ON ic.warehouseFk = tcc.warehouseFk
				AND ic.itemFk = tcc.itemFk
			HAVING cost <> 0;

	DROP TEMPORARY TABLE tmp.zoneOption;

	CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentCopy ENGINE = MEMORY
		SELECT * FROM tmp.ticketComponent;

	-- Precio especial
	INSERT INTO tmp.ticketComponent
		SELECT tcc.warehouseFk,
				tcc.itemFk,
				c2.id,
				sp.value - SUM(tcc.cost) sumCost
			FROM tmp.ticketComponentCopy tcc
				JOIN component c ON c.id = tcc.componentFk
				JOIN tSpecialPrice sp ON sp.itemFk = tcc.itemFk
				JOIN vn.component c2 ON c2.code = 'specialPrices'
			WHERE c.classRate IS NULL
				AND tcc.warehouseFk = vWarehouseFk
			GROUP BY tcc.itemFk, tcc.warehouseFk
			HAVING ABS(sumCost) > 0.001;

	-- Rappel
	INSERT INTO tmp.ticketComponent
		SELECT tcc.warehouseFk,
				tcc.itemFk,
				IFNULL(c.componentFk ,c2.id),
				SUM(tcc.cost) * ((1/(1-c.rappel/100)) -1) sumCost
			FROM tmp.ticketComponentCopy tcc
				JOIN vn.clientChain cc ON cc.clientFk = vClientFk
				JOIN vn.`chain` c ON c.id = cc.chainFk
				JOIN vn.component c2 ON c2.code = 'rappel'
			WHERE tcc.warehouseFk = vWarehouseFk
			GROUP BY tcc.itemFk, tcc.warehouseFk;

	CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentSum
		(INDEX (itemFk, warehouseFk))
		ENGINE = MEMORY
		SELECT SUM(cost) sumCost, tc.itemFk, tc.warehouseFk, c.classRate
			FROM tmp.ticketComponent tc
				JOIN component c ON c.id = tc.componentFk
			GROUP BY tc.itemFk, tc.warehouseFk, c.classRate;

	CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentRate ENGINE = MEMORY
		SELECT tcc.warehouseFk,
				tcc.itemFk,
				1 rate,
				IF(tcc.groupingMode = 'grouping', tcc.`grouping`, 1) `grouping`,
				CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) price,
				CAST(SUM(tcs.sumCost) AS DECIMAL(10,2)) / weightGrouping 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 = 'grouping' OR tcc.groupingMode IS NULL)
				AND (tcc.packing > tcc.`grouping` OR tcc.groupingMode IS NULL)
			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) / weightGrouping 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) / weightGrouping 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;

	INSERT INTO tmp.ticketComponentPrice (warehouseFk, itemFk, rate, `grouping`, price, priceKg)
		SELECT * FROM (
			SELECT * FROM tmp.ticketComponentRate ORDER BY price LIMIT 10000000000000000000
		) t
		GROUP BY itemFk, warehouseFk, `grouping`;

	DROP TEMPORARY TABLE
		tmp.ticketComponentCalculate,
		tmp.ticketComponentSum,
		tmp.ticketComponentBase,
		tmp.ticketComponentRate,
		tmp.ticketComponentCopy,
		tPriceDelta,
		tSpecialPrice;
END$$
DELIMITER ;