DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`sale_add`( IN vStarted DATE, IN vEnded DATE) BEGIN /** * AƱade las ventas que se realizaron entre 2 fechas a la tabla bs.sale * * @param vStarted Fecha de inicio * @param vEnded Fecha de fin * */ DECLARE vLoopDate DATE; DECLARE vLoopDateTime DATETIME; IF vStarted < (util.VN_CURDATE() - INTERVAL 5 YEAR) OR vStarted > vEnded THEN CALL util.throw('Wrong date'); END IF; SET vLoopDate = vStarted; DELETE FROM sale WHERE dated BETWEEN vStarted AND vEnded; WHILE vLoopDate <= vEnded DO SET vLoopDateTime = util.dayEnd(vLoopDate); REPLACE sale( saleFk, amount, surcharge, dated, typeFk, clientFk, companyFk, margin )WITH calculatedSales AS( SELECT s.id saleFk, SUM(IF(ct.isBase, s.quantity * sc.value, 0)) amount, SUM(IF(ct.isBase, 0, s.quantity * sc.value)) surcharge, s.total pvp, DATE(t.shipped) dated, i.typeFk, t.clientFk, t.companyFk, SUM(IF(ct.isMargin, s.quantity * sc.value, 0 )) marginComponents FROM vn.ticket t STRAIGHT_JOIN vn.sale s ON s.ticketFk = t.id JOIN vn.item i ON i.id = s.itemFk JOIN vn.itemType it ON it.id = i.typeFk JOIN vn.itemCategory ic ON ic.id = it.categoryFk JOIN vn.saleComponent sc ON sc.saleFk = s.id JOIN vn.component c ON c.id = sc.componentFk JOIN vn.componentType ct ON ct.id = c.typeFk WHERE t.shipped BETWEEN vLoopDate AND vLoopDateTime AND s.quantity <> 0 AND ic.merchandise GROUP BY s.id )SELECT saleFk, amount, surcharge, dated, typeFk, clientFk, companyFk, marginComponents + amount + surcharge - pvp FROM calculatedSales; SET vLoopDate = vLoopDate + INTERVAL 1 DAY; END WHILE; END$$ DELIMITER ;