DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemTopSeller`()
BEGIN
	DECLARE vCategoryFk INTEGER;
	DECLARE vDone INT DEFAULT FALSE;
	DECLARE rs CURSOR FOR
		 SELECT DISTINCT id
		  FROM  vn.itemCategory
		  WHERE merchandise <> FALSE;
          
	DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
	DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN  
	RESIGNAL;
	END;

	DROP TABLE IF EXISTS tmp.topSellerMin;
	CREATE TEMPORARY TABLE tmp.topSellerMin ENGINE = MEMORY
		SELECT s.itemFk, SUM(s.quantity) AS total, v.tipo_id typeFk
			FROM vn.sale s
				INNER JOIN bs.ventas v ON v.Id_Movimiento = s.id
			WHERE v.fecha BETWEEN TIMESTAMPADD(DAY, - 7, util.VN_CURDATE()) AND util.VN_CURDATE()
			GROUP BY s.itemFk;
        
	DROP TABLE IF EXISTS tmp.topSeller;
	CREATE TEMPORARY TABLE tmp.topSeller   
		(   
			`id` int(11) NOT NULL DEFAULT '0',
			`typeFk` smallint(5) unsigned NOT NULL,
			`itemCategoryFk` int(10) unsigned NOT NULL,
			`total` bigint(21) NOT NULL DEFAULT '0'
		) ENGINE=MEMORY DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
		
	OPEN rs;
	 read_loop: LOOP
		FETCH rs INTO vCategoryFk;
		
		IF vDone THEN
			LEAVE read_loop;
		END IF;
		
		INSERT INTO tmp.topSeller
			SELECT  tsm.itemFk, tsm.typeFk, it.categoryFk, tsm.total
			FROM tmp.topSellerMin tsm
				INNER JOIN vn.itemType it ON  it.id = tsm.typeFk
			WHERE it.categoryFk = vCategoryFk
			ORDER BY  tsm.itemFk ,tsm.total DESC
			LIMIT 5; 

	END LOOP;
	CLOSE rs;
    
    SELECT i.name ,i.id, i.image, i.typeFk, it.categoryFk AS itemCategoryFk,
		ic.name AS itemCategoryName, it.name AS itemTypeName, ts.total
		FROM tmp.topSeller ts
			INNER JOIN vn.item i ON i.id = ts.id
			INNER JOIN vn.itemType it ON  it.id = ts.typeFk
			INNER JOIN vn.itemCategory ic ON ic.id = it.categoryFk;
    
    DROP TABLE IF EXISTS topSellerMin;
    DROP TABLE IF EXISTS tmp.topSeller;
    
END$$
DELIMITER ;