DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`item_getVisible`( vWarehouse TINYINT, vDate DATE, vType INT, vPrefix VARCHAR(255)) BEGIN /** * Gets visible items of the specified type at specified date. * * @param vWarehouse The warehouse id * @param vDate The visible date * @param vType The type id * @param vPrefix The article prefix to filter or %NULL for all * @return tmp.itemVisible Visible items */ DECLARE vPrefixLen SMALLINT; DECLARE vFilter VARCHAR(255) DEFAULT NULL; DECLARE vDateInv DATE DEFAULT vn.getInventoryDate(); DECLARE EXIT HANDLER FOR 1114 BEGIN GET DIAGNOSTICS CONDITION 1 @message = MESSAGE_TEXT; CALL vn.mail_insert( 'cau@verdnatura.es', NULL, CONCAT('hedera.item_getVisible error: ', @message), CONCAT( 'warehouse: ', IFNULL(vWarehouse, ''), ', Fecha:', IFNULL(vDate, ''), ', tipo: ', IFNULL(vType,''), ', prefijo: ', IFNULL(vPrefix,''))); RESIGNAL; END; SET vPrefixLen = IFNULL(LENGTH(vPrefix), 0) + 1; IF vPrefixLen > 1 THEN SET vFilter = CONCAT(vPrefix, '%'); END IF; DROP TEMPORARY TABLE IF EXISTS `filter`; CREATE TEMPORARY TABLE `filter` (INDEX (itemFk)) ENGINE = MEMORY SELECT id itemFk FROM vn.item WHERE typeFk = vType AND (vFilter IS NULL OR `name` LIKE vFilter); DROP TEMPORARY TABLE IF EXISTS currentStock; CREATE TEMPORARY TABLE currentStock (INDEX (itemFk)) ENGINE = MEMORY SELECT itemFk, SUM(quantity) quantity FROM ( SELECT b.itemFk, b.quantity FROM vn.buy b JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel t ON t.id = e.travelFk WHERE t.landed BETWEEN vDateInv AND vDate AND t.warehouseInFk = vWarehouse AND NOT t.isRaid UNION ALL SELECT b.itemFk, -b.quantity FROM vn.buy b JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel t ON t.id = e.travelFk WHERE t.shipped BETWEEN vDateInv AND util.VN_CURDATE() AND t.warehouseOutFk = vWarehouse AND NOT t.isRaid AND t.isDelivered UNION ALL SELECT m.itemFk, -m.quantity FROM vn.sale m JOIN vn.ticket t ON t.id = m.ticketFk JOIN vn.ticketState s ON s.ticketFk = t.id JOIN vn.alertLevel al ON al.code = 'DELIVERED' WHERE t.shipped BETWEEN vDateInv AND util.VN_CURDATE() AND t.warehouseFk = vWarehouse AND s.alertLevel = al.id ) t GROUP BY itemFk HAVING quantity > 0; DROP TEMPORARY TABLE IF EXISTS tmp; CREATE TEMPORARY TABLE tmp (INDEX (itemFk)) ENGINE = MEMORY SELECT * FROM ( SELECT b.itemFk, b.packagingFk, b.packing FROM vn.buy b JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel t ON t.id = e.travelFk WHERE t.landed BETWEEN vDateInv AND vDate AND NOT b.isIgnored AND b.price2 >= 0 AND b.packagingFk IS NOT NULL ORDER BY t.warehouseInFk = vWarehouse DESC, t.landed DESC LIMIT 10000000000000000000 ) t GROUP BY itemFk; DROP TEMPORARY TABLE IF EXISTS tmp.itemVisible; CREATE TEMPORARY TABLE tmp.itemVisible ENGINE = MEMORY SELECT i.id Id_Article, SUBSTRING(i.`name`, vPrefixLen) Article, t.packing, p.id Id_Cubo, IF(p.depth > 0, p.depth, 0) depth, p.width, p.height, CEIL(s.quantity / t.packing) etiquetas FROM vn.item i JOIN `filter` f ON f.itemFk = i.id JOIN currentStock s ON s.itemFk = i.id LEFT JOIN tmp t ON t.itemFk = i.id LEFT JOIN vn.packaging p ON p.id = t.packagingFk WHERE CEIL(s.quantity / t.packing) > 0 -- FIXME: Column Cubos.box not included in view vn.packaging /* AND p.box */ ; DROP TEMPORARY TABLE `filter`, currentStock, tmp; END$$ DELIMITER ;