DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getFromFloramondo`(vDateFrom DATE, vDateTo DATE) BEGIN /** * Genera una tabla con la lista de tickets de Floramondo * para una fecha determinada. * * @param vDated Fecha de preparaciĆ³n de los pedidos * @table tmp.ticketFloramondo(ticketFk, clientName, agencyName, * agencyModeFk, supplierName, supplierFk, freight, expeditionCount, * margin, trolleys, pallets, shipped, created) */ DROP TEMPORARY TABLE IF EXISTS tmp.ticketFloramondo; CREATE TEMPORARY TABLE tmp.ticketFloramondo (ticketFk INT PRIMARY KEY, clientName VARCHAR(50), agencyName VARCHAR(50), agencyModeFk INT, supplierName VARCHAR(50), supplierFk INT, freight DECIMAL(10,2) DEFAULT 0, expeditionCount INT, margin DECIMAL(10,3) DEFAULT 0, trolleys INT DEFAULT 0, pallets INT DEFAULT 0, shipped DATE, created DATE) ENGINE = MEMORY; INSERT INTO tmp.ticketFloramondo(ticketFk, clientName, agencyName, agencyModeFk, shipped, supplierName, supplierFk, created) SELECT t.id ticketFk, t.nickname, am.name, am.id, t.shipped, s.name, sat.supplierFk, t.created FROM vn.ticket t JOIN vn.agencyMode am ON am.id = t.agencyModeFk JOIN vn.warehouse w ON w.id = t.warehouseFk AND w.code IN ('VNH','FLM') AND t.shipped BETWEEN vDateFrom AND util.dayend(vDateTo) JOIN vn.agency a ON a.id = am.agencyFk LEFT JOIN vn.supplierAgencyTerm sat ON sat.agencyFk = a.id LEFT JOIN vn.supplier s ON s.id = sat.supplierFk; DROP TEMPORARY TABLE IF EXISTS tmp.ticket; CREATE TEMPORARY TABLE tmp.ticket (ticketFk INT(11) PRIMARY KEY) SELECT ticketFk FROM tmp.ticketFloramondo; -- Freight UPDATE tmp.ticketFloramondo tf JOIN (SELECT SUM(sc.value * s.quantity) freight, t.ticketFk FROM vn.saleComponent sc JOIN vn.component c ON c.id = sc.componentFk JOIN vn.componentType ct ON ct.id = c.typeFk JOIN vn.sale s ON s.id = sc.saleFk JOIN tmp.ticket t ON t.ticketFk = s.ticketFk WHERE ct.code = 'FREIGHT' GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.freight = sb.freight; -- Freight service UPDATE tmp.ticketFloramondo tf JOIN (SELECT SUM(ts.price * ts.quantity) service, t.ticketFk FROM vn.ticketService ts JOIN tmp.ticket t ON t.ticketFk = ts.ticketFk GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.freight = tf.freight + sb.service; -- Expedition Count UPDATE tmp.ticketFloramondo tf JOIN (SELECT COUNT(e.id) expeditionCount, t.ticketFk FROM vn.expedition e RIGHT JOIN tmp.ticket t ON t.ticketFk = e.ticketFk GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.expeditionCount = sb.expeditionCount; -- Margin UPDATE tmp.ticketFloramondo tf JOIN (SELECT SUM(IF(ct.code = 'COST',sc.value, 0)) cost, SUM(IF(ct.isMargin, sc.value, 0)) margin, t.ticketFk FROM vn.saleComponent sc JOIN vn.component c ON c.id = sc.componentFk JOIN vn.componentType ct ON ct.id = c.typeFk JOIN vn.sale s ON s.id = sc.saleFk JOIN tmp.ticket t ON t.ticketFk = s.ticketFk GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.margin = sb.margin / sb.cost; -- Trolleys UPDATE tmp.ticketFloramondo tf JOIN (SELECT SUM(tp.quantity) trolleys, t.ticketFk FROM vn.ticketPackaging tp JOIN tmp.ticket t ON t.ticketFk = tp.ticketFk JOIN vn.packaging p ON p.id = tp.packagingFk WHERE p.isTrolley GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.trolleys = sb.trolleys; -- Pallets UPDATE tmp.ticketFloramondo tf JOIN (SELECT SUM(tp.quantity) pallets, t.ticketFk FROM vn.ticketPackaging tp JOIN tmp.ticket t ON t.ticketFk = tp.ticketFk JOIN vn.packaging p ON p.id = tp.packagingFk WHERE p.isPallet GROUP BY t.ticketFk) sb ON sb.ticketFk = tf.ticketFk SET tf.pallets = sb.pallets; SELECT * FROM tmp.ticketFloramondo; DROP TEMPORARY TABLE tmp.ticket; DROP TEMPORARY TABLE tmp.ticketFloramondo; END$$ DELIMITER ;