DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`item_getBalance`(
	vItemFk INT,
	vWarehouseFk INT,
	vDated DATETIME
)
BEGIN
/**
 * Calcula el balance de un artículo.
 *
 * @vItemFk Id de artículo
 * @vWarehouseFk Id de almacén
 * @vDated Fecha a calcular, si es NULL muestra el histórico desde el inventario
 */
	DECLARE vDateInventory DATETIME
		DEFAULT (
			SELECT IF(vDated, uc.mockUtcTime, c.inventoried)
				FROM config c
					JOIN util.config uc
		);
	DECLARE vSupplierInventoryFk INT
		DEFAULT (SELECT supplierFk FROM inventoryConfig);

	IF NOT vSupplierInventoryFk OR NOT vDateInventory THEN
		CALL util.throw('Config variables are not set');
	END IF;

	CREATE OR REPLACE TEMPORARY TABLE tItemDiary
		ENGINE = MEMORY
		WITH entriesIn AS (
			SELECT 'entry' originType,
					e.id originId,
					tr.landed shipped,
					b.quantity `in`,
					NULL `out`,
					st.alertLevel ,
					st.name stateName,
					e.invoiceNumber reference,
					'supplier' entityType,
					s.id entityId,
					s.name entityName,
					IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked,
					FALSE isTicket,
					b.id lineFk,
					NULL `order`,
					NULL clientType,
					NULL claimFk,
					vSupplierInventoryFk 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')
				WHERE tr.landed >= vDateInventory
					AND tr.warehouseInFk = vWarehouseFk
					AND (s.id <> vSupplierInventoryFk OR vDated IS NULL) 
					AND b.itemFk = vItemFk
					AND NOT e.isExcludedFromAvailable
					AND NOT e.isRaid
		),
		entriesOut AS (
			SELECT 'entry',
					e.id originType,
					tr.shipped,
					NULL,
					b.quantity,
					st.alertLevel,
					st.name stateName,
					e.invoiceNumber,
					'supplier' entityType,
					s.id entityId,
					s.name,
					IF(st.`code` = 'DELIVERED' , TRUE, FALSE),
					FALSE isTicket,
					b.id,
					NULL `order`,
					NULL clientType,
					NULL claimFk,
					vSupplierInventoryFk
				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')
				WHERE tr.shipped >= vDateInventory
					AND tr.warehouseOutFk = vWarehouseFk
					AND (s.id <> vSupplierInventoryFk OR vDated IS NULL)
						AND b.itemFk = vItemFk
						AND NOT e.isExcludedFromAvailable
						AND NOT w.isFeedStock
						AND NOT e.isRaid
		),
		sales AS (
			WITH itemSales AS (
				SELECT DATE(t.shipped) shipped,
						s.quantity,
						st2.alertLevel,
						st2.name,
						t.refFk,
						t.id ticketFk,
						'client' entityType,
						t.clientFk entityId,
						t.nickname,
						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(st.code, 'FREE')))
						LEFT JOIN vn.claimBeginning cb ON cb.saleFk = s.id
					WHERE t.shipped >= vDateInventory
						AND s.itemFk = vItemFk
						AND t.warehouseFk = vWarehouseFk
			)
			SELECT 'ticket',
					s.ticketFk,
					s.shipped,
					NULL `in`,
					s.quantity,
					s.alertLevel,
					s.name,
					s.refFk,
					s.entityType,
					s.entityId,
					s.nickname,
					IF(stk.saleFk, TRUE, FALSE),
					TRUE,
					s.saleFk,
					s.`order`,
					s.typeFk,
					s.claimFk,
					NULL
				FROM itemSales 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
		), 
		orders AS (
			SELECT 'order' originType,
					o.id originId,
					r.shipment,
					NULL 'in',
					r.amount,
					NULL alertLevel,
					NULL stateName,
					NULL invoiceNumber,
					'client' entityType,
					c.id,
					c.name,
					FALSE,
					FALSE isTicket,
					NULL buyFk,
					NULL 'order',
					c.typeFk,
					NULL claimFk,
					NULL
				FROM hedera.orderRow r
					JOIN hedera.`order` o ON o.id = r.orderFk
					JOIN vn.client c ON c.id = o.customer_id
				WHERE r.shipment >= vDateInventory
					AND r.warehouseFk = vWarehouseFk
					AND r.created >= (
						SELECT SUBTIME(util.VN_NOW(), reserveTime)
							FROM hedera.orderConfig
					)
					AND NOT o.confirmed
					AND r.itemFk = vItemFk
		)
		SELECT * FROM entriesIn
			UNION ALL
			SELECT * FROM entriesOut
			UNION ALL
			SELECT * FROM sales
			UNION ALL
			SELECT * FROM orders
			ORDER BY shipped,
				(inventorySupplierFk = entityId) DESC,
				alertLevel DESC,
				isTicket,
				`order` DESC,
				isPicked DESC,
				`in` DESC,
				`out` DESC;

	IF vDated IS NULL THEN
		SET @a := 0;
		SET @currentLineFk := 0;
		SET @shipped := '';

		SELECT t.originType,
			t.originId,
			DATE(@shipped:= t.shipped) shipped,
			t.alertLevel,
			t.stateName,
			t.reference,
			t.entityType,
			t.entityId,
			t.entityName,
			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 < vDated;

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

	DROP TEMPORARY TABLE tItemDiary;
END$$
DELIMITER ;