diff --git a/db/routines/bi/procedures/comparativa_add.sql b/db/routines/bi/procedures/comparativa_add.sql deleted file mode 100644 index 4297c8aff..000000000 --- a/db/routines/bi/procedures/comparativa_add.sql +++ /dev/null @@ -1,32 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`comparativa_add`() -BEGIN - DECLARE lastCOMP INT; # Se trata de una variable para almacenar el ultimo valor del Periodo - DECLARE vMaxPeriod INT; - DECLARE vMaxWeek INT; - - SELECT t.period, t.`week` INTO vMaxPeriod, vMaxWeek - FROM vn.`time` t - WHERE t.dated = util.VN_CURDATE(); - - SELECT MAX(Periodo) INTO lastCOMP FROM vn2008.Comparativa; - -- Fijaremos las ventas con más de un mes de antiguedad en la tabla Comparativa - - IF lastCOMP < vMaxPeriod - 3 AND vMaxWeek > 3 THEN - - REPLACE vn2008.Comparativa(Periodo, Id_Article, warehouse_id, Cantidad,price) - SELECT tm.period as Periodo, m.Id_Article, t.warehouse_id, sum(m.Cantidad), sum(v.importe) - FROM bs.ventas v - JOIN vn2008.time tm ON tm.date = v.fecha - JOIN vn2008.Movimientos m ON m.Id_Movimiento = v.Id_Movimiento - JOIN vn2008.Tipos tp ON tp.tipo_id = v.tipo_id - JOIN vn2008.reinos r ON r.id = tp.reino_id - JOIN vn2008.Tickets t ON t.Id_Ticket = m.Id_Ticket - WHERE tm.period BETWEEN lastCOMP AND vMaxPeriod - 3 - AND t.Id_Cliente NOT IN(400,200) - AND t.warehouse_id NOT IN (0,13) - GROUP BY m.Id_Article, Periodo, t.warehouse_id; - - END IF; -END$$ -DELIMITER ; diff --git a/db/routines/bi/procedures/comparativa_add_manual.sql b/db/routines/bi/procedures/comparativa_add_manual.sql deleted file mode 100644 index 281e15b23..000000000 --- a/db/routines/bi/procedures/comparativa_add_manual.sql +++ /dev/null @@ -1,40 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`comparativa_add_manual`(IN vStarted DATE, IN vEnded DATE) -BEGIN -/** - * Recalcula la tabla Comparativa para dos valores dados - * - * @param vStarted fecha desde - * @param vEnded fecha hasta - */ - - DECLARE periodStart INT; - DECLARE periodEnd INT; - - -- Seleccionamos la fecha minima/maxima del periodo que vamos a consultar - - SELECT t.period INTO periodStart - FROM vn.`time` t - WHERE t.dated = vStarted; - - SELECT t.period INTO periodEnd - FROM vn.`time` t - WHERE t.dated = vEnded; - - DELETE FROM vn2008.Comparativa - WHERE Periodo BETWEEN periodStart AND periodEnd; - - INSERT INTO vn2008.Comparativa(Periodo, Id_Article, warehouse_id, Cantidad,price) - SELECT tm.period as Periodo, m.Id_Article, t.warehouse_id, sum(m.Cantidad), sum(v.importe) - FROM bs.ventas v - JOIN vn2008.time tm ON tm.date = v.fecha - JOIN vn2008.Movimientos m ON m.Id_Movimiento = v.Id_Movimiento - JOIN vn2008.Tipos tp ON tp.tipo_id = v.tipo_id - JOIN vn2008.reinos r ON r.id = tp.reino_id - JOIN vn2008.Tickets t ON t.Id_Ticket = m.Id_Ticket - WHERE tm.period BETWEEN periodStart AND periodEnd - AND t.Id_Cliente NOT IN(400,200) - AND t.warehouse_id NOT IN (0,13) - GROUP BY m.Id_Article, Periodo, t.warehouse_id; -END$$ -DELIMITER ; diff --git a/db/routines/bs/procedures/sale_add.sql b/db/routines/bs/procedures/sale_add.sql new file mode 100644 index 000000000..64beb4776 --- /dev/null +++ b/db/routines/bs/procedures/sale_add.sql @@ -0,0 +1,72 @@ +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 ; diff --git a/db/routines/bs/procedures/ventas_add_launcher.sql b/db/routines/bs/procedures/sales_addLauncher.sql similarity index 56% rename from db/routines/bs/procedures/ventas_add_launcher.sql rename to db/routines/bs/procedures/sales_addLauncher.sql index 0d9e89a89..38cb5e219 100644 --- a/db/routines/bs/procedures/ventas_add_launcher.sql +++ b/db/routines/bs/procedures/sales_addLauncher.sql @@ -1,13 +1,12 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`ventas_add_launcher`() +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`sales_addLauncher`() BEGIN /** * Añade las ventas a la tabla bs.sale que se realizaron desde hace un mes hasta hoy * */ - DECLARE vCurDate DATE DEFAULT util.VN_CURDATE(); - CALL ventas_add(vCurDate - INTERVAL 1 MONTH, vCurDate); - + + CALL sale_add(vCurDate - INTERVAL 1 MONTH, vCurDate); END$$ DELIMITER ; diff --git a/db/routines/bs/procedures/ventas_add.sql b/db/routines/bs/procedures/ventas_add.sql deleted file mode 100644 index fcb00e092..000000000 --- a/db/routines/bs/procedures/ventas_add.sql +++ /dev/null @@ -1,78 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`ventas_add`( - IN vStarted DATETIME, - IN vEnded DATETIME) -BEGIN -/** -* Añade las ventas que se realizaron entre -* vStarted y vEnded -* -* @param vStarted Fecha de inicio -* @param vEnded Fecha de finalizacion -* -**/ - DECLARE vStartingDate DATETIME; - DECLARE vEndingDate DATETIME; - - IF vStarted < TIMESTAMPADD(YEAR,-5,util.VN_CURDATE()) - OR vEnded < TIMESTAMPADD(YEAR,-5,util.VN_CURDATE()) THEN - CALL util.throw('fechaDemasiadoAntigua'); - END IF; - - SET vEnded = util.dayEnd(vEnded); - SET vStartingDate = vStarted ; - SET vEndingDate = util.dayEnd(vStartingDate); - - DELETE - FROM sale - WHERE dated BETWEEN vStartingDate AND vEnded; - - WHILE vEndingDate <= vEnded DO - - REPLACE ventas(Id_Movimiento, importe, recargo, fecha, tipo_id, Id_Cliente, empresa_id) - SELECT saleFk, - SUM(IF(ct.isBase, s.quantity * sc.value, 0)) importe, - SUM(IF(ct.isBase, 0, s.quantity * sc.value)) recargo, - vStartingDate, - i.typeFk, - a.clientFk, - t.companyFk - 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 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.ticket t ON t.id = s.ticketFk - JOIN vn.address a ON a.id = t.addressFk - JOIN vn.client cl ON cl.id = a.clientFk - WHERE t.shipped BETWEEN vStartingDate AND vEndingDate - AND s.quantity <> 0 - AND s.discount <> 100 - AND ic.merchandise - GROUP BY sc.saleFk - HAVING IFNULL(importe,0) <> 0 OR IFNULL(recargo,0) <> 0; - - UPDATE sale s - JOIN ( - SELECT s.id, - SUM(s.quantity * sc.value ) margen, - s.quantity * s.price * (100 - s.discount ) / 100 pvp - FROM vn.sale s - JOIN vn.ticket t ON t.id = s.ticketFk - 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 vStartingDate AND vEndingDate - AND ct.isMargin = TRUE - GROUP BY s.id) sub ON sub.id = s.saleFk - SET s.margin = sub.margen + s.amount + s.surcharge - sub.pvp; - - SET vStartingDate = TIMESTAMPADD(DAY,1, vStartingDate); - SET vEndingDate = util.dayEnd(vStartingDate); - - END WHILE; - -END$$ -DELIMITER ; diff --git a/db/versions/11001-blackPalmetto/00-firstScript.sql b/db/versions/11001-blackPalmetto/00-firstScript.sql new file mode 100644 index 000000000..e69de29bb diff --git a/db/versions/11031-aquaPalmetto/00-firstScript.sql b/db/versions/11031-aquaPalmetto/00-firstScript.sql new file mode 100644 index 000000000..5ef37e8f0 --- /dev/null +++ b/db/versions/11031-aquaPalmetto/00-firstScript.sql @@ -0,0 +1,4 @@ + +UPDATE bs.nightTask + SET `procedure` = 'sales_addLauncher' + WHERE `procedure` = 'ventas_add_launcher'; \ No newline at end of file