DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`(
	vItemFk INT,
	vWarehouseFk INT,
	vDate DATETIME
)
BEGIN
/**
 * @vItemFk item a buscar
 * @vWarehouseFk almacen donde buscar
 * @vDate Si la fecha es null, muestra el histórico desde el inventario. 
 * Si la fecha no es null, muestra histórico desde la fecha de vDate.
 */
	DECLARE vDateInventory DATETIME;

	IF vDate IS NULL THEN
		SELECT inventoried INTO vDateInventory 
			FROM config;
	ELSE
		SELECT mockUtcTime INTO vDateInventory
			FROM util.config;
	END IF;

	CREATE OR REPLACE TEMPORARY TABLE tItemDiary(
		shipped DATE,
		`in` INT(11),
		`out` INT(11),
		alertLevel INT(11),
		stateName VARCHAR(20),
		`name` VARCHAR(50),
		reference VARCHAR(50),
		origin INT(11),
		clientFk INT(11),
		isPicked INT(11),
		isTicket TINYINT(1),
		lineFk INT(11),
		`order` TINYINT(3) UNSIGNED,
		clientType VARCHAR(20),
		claimFk INT(10) UNSIGNED,
		inventorySupplierFk INT(10)
	);

	INSERT INTO tItemDiary
		WITH entriesIn AS (
			SELECT tr.landed shipped,
					b.quantity `in`,
					NULL `out`,
					st.alertLevel ,
					st.name stateName,
					s.name `name`,
					e.invoiceNumber reference,
					e.id origin,
					s.id clientFk,
					IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked,
					FALSE isTicket,
					b.id lineFk,
					NULL `order`,
					NULL clientType,
					NULL claimFk,
					ec.inventorySupplierFk
				FROM vn.buy b
					JOIN vn.entry e ON e.id = b.entryFk
					JOIN vn.travel tr ON tr.id = e.travelFk
					JOIN vn.supplier s ON s.id = e.supplierFk
					JOIN vn.state st ON st.`code` = IF( tr.landed < util.VN_CURDATE() 
						OR (util.VN_CURDATE() AND tr.isReceived),
							'DELIVERED',
							'FREE')
					JOIN vn.entryConfig ec
				WHERE tr.landed >= vDateInventory
					AND vWarehouseFk = tr.warehouseInFk
					AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL) 
					AND b.itemFk = vItemFk
					AND NOT e.isExcludedFromAvailable
					AND NOT e.isRaid
		), entriesOut AS (
			SELECT tr.shipped,
					NULL,
					b.quantity,
					st.alertLevel,
					st.name stateName,
					s.name ,
					e.invoiceNumber,
					e.id entryFk,
					s.id supplierFk,
					IF(st.`code` = 'DELIVERED' , TRUE, FALSE),
					FALSE isTicket,
					b.id,
					NULL `order`,
					NULL clientType,
					NULL claimFk,
					ec.inventorySupplierFk
				FROM vn.buy b
					JOIN vn.entry e ON e.id = b.entryFk
					JOIN vn.travel tr ON tr.id = e.travelFk
					JOIN vn.warehouse w ON w.id = tr.warehouseOutFk
					JOIN vn.supplier s ON s.id = e.supplierFk
					JOIN vn.state st ON st.`code` = IF(tr.shipped < util.VN_CURDATE()
						OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived),
							'DELIVERED',
							'FREE')
					JOIN vn.entryConfig ec
				WHERE tr.shipped >= vDateInventory
					AND vWarehouseFk = tr.warehouseOutFk
					AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL)
						AND b.itemFk = vItemFk
						AND NOT e.isExcludedFromAvailable
						AND NOT w.isFeedStock
						AND NOT e.isRaid
		), sales AS (
			SELECT DATE(t.shipped) shipped,
					s.quantity,
					st2.alertLevel,
					st2.name,
					t.nickname,
					t.refFk,
					t.id ticketFk,
					t.clientFk,
					s.id saleFk,
					st.`order`,
					c.typeFk,
					cb.claimFk
				FROM vn.sale s
					JOIN vn.ticket t ON t.id = s.ticketFk
					LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id
					LEFT JOIN vn.state st ON st.`code` = ts.`code`
					JOIN vn.client c ON c.id = t.clientFk
					JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(),
						'DELIVERED',
						IF (t.shipped > util.dayEnd(util.VN_CURDATE()),
							'FREE',
							IFNULL(ts.code, 'FREE')))
					LEFT JOIN vn.claimBeginning cb ON s.id = cb.saleFk
				WHERE t.shipped >= vDateInventory
					AND s.itemFk = vItemFk
					AND vWarehouseFk = t.warehouseFk
		),sale AS (
			SELECT s.shipped,
					NULL `in`,
					s.quantity,
					s.alertLevel,
					s.name,
					s.nickname,
					s.refFk,
					s.ticketFk,
					s.clientFk,
					IF(stk.saleFk, TRUE, NULL),
					TRUE,
					s.saleFk,
					s.`order`,
					s.typeFk,
					s.claimFk,
					NULL
				FROM sales s
					LEFT JOIN vn.state stPrep ON stPrep.`code` = 'PREPARED'
					LEFT JOIN vn.saleTracking stk ON stk.saleFk = s.saleFk 
						AND stk.stateFk = stPrep.id
				GROUP BY s.saleFk
		)	SELECT shipped,
				`in`,
				`out`,
				alertLevel,
				stateName,
				`name`,
				reference,
				origin,
				clientFk,
				isPicked,
				isTicket,
				lineFk,
				`order`,
				clientType,
				claimFk,
				inventorySupplierFk
				FROM entriesIn
			UNION ALL
			SELECT * FROM entriesOut
			UNION ALL
			SELECT * FROM sale
			ORDER BY shipped,
				(inventorySupplierFk = clientFk) DESC,
				alertLevel DESC,
				isTicket,
				`order` DESC,
				isPicked DESC,
				`in` DESC,
				`out` DESC;

	IF vDate IS NULL THEN

		SET @a := 0;
		SET @currentLineFk := 0;
		SET @shipped := '';

		SELECT DATE(@shipped:= t.shipped) shipped,
			t.alertLevel,
			t.stateName,
			t.origin,
			t.reference,
			t.clientFk,
			t.name,
			t.`in` invalue,
			t.`out`,
			@a := @a + IFNULL(t.`in`, 0) - IFNULL(t.`out`, 0) balance,
			@currentLineFk := IF (@shipped < util.VN_CURDATE() 
								OR (@shipped = util.VN_CURDATE() AND (t.isPicked OR a.`code` >= 'ON_PREPARATION')),
									t.lineFk, 
									@currentLineFk) lastPreparedLineFk,
			t.isTicket,
			t.lineFk,
			t.isPicked,
			t.clientType,
			t.claimFk,
			t.`order`
			FROM tItemDiary t
				LEFT JOIN alertLevel a ON a.id = t.alertLevel;

	ELSE
		SELECT IFNULL(SUM(IFNULL(`in`, 0)) - SUM(IFNULL(`out`, 0)), 0) INTO @a
			FROM tItemDiary
			WHERE shipped < vDate;

		SELECT vDate shipped,
			0 alertLevel,
			0 stateName,
			0 origin,
			'' reference,
			0 clientFk,
			'Inventario calculado',
			@a invalue,
			NULL `out`,
			@a balance,
			0 lastPreparedLineFk,
			0 isTicket,
			0 lineFk,
			0 isPicked,
			0 clientType,
			0 claimFk,
			NULL `order`
		UNION ALL
		SELECT shipped, 
				alertlevel, 
				stateName, 
				origin, 
				reference, 
				clientFk, 
				name, `in`, 
				`out`, 
				@a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0), 
				0, 
				isTicket, 
				lineFk, 
				isPicked, 
				clientType, 
				claimFk,
				`order`
			FROM tItemDiary
				WHERE shipped >= vDate;
	END IF;

	DROP TEMPORARY TABLE tItemDiary;
END$$
DELIMITER ;