diff --git a/db/routines/vn/events/itemCampaign_add.sql b/db/routines/vn/events/itemCampaign_add.sql new file mode 100644 index 000000000..efb2aeb11 --- /dev/null +++ b/db/routines/vn/events/itemCampaign_add.sql @@ -0,0 +1,8 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` EVENT `vn`.`itemCampaig_add` + ON SCHEDULE EVERY 1 DAY + STARTS '2024-10-18 03:00:00.000' + ON COMPLETION PRESERVE + ENABLE +DO CALL itemCampaign_add()$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/itemCampaign_add.sql b/db/routines/vn/procedures/itemCampaign_add.sql new file mode 100644 index 000000000..8fb40df67 --- /dev/null +++ b/db/routines/vn/procedures/itemCampaign_add.sql @@ -0,0 +1,54 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemCampaign_add`() +proc: BEGIN +/** + * Añade registros a tabla itemCampaign. + * + * @param vDateFrom Fecha desde + * @param vDateTo Fecha hasta + * @param vCampaign Código de la campaña + */ + DECLARE vYesterday DATE; + DECLARE vCampaign VARCHAR(100); + DECLARE vScopeDays INT; + DECLARE vPreviousDays INT; + DECLARE vDateSumFrom DATE; + DECLARE vDateSumTo DATE; + + SET vYesterday = util.yesterday(); + + SELECT dated, code, scopeDays, previousDays + INTO vDateSumTo, vCampaign, vScopeDays, vPreviousDays + FROM campaign + WHERE dated >= vYesterday + ORDER BY dated + LIMIT 1; + + IF vCampaign IS NULL THEN + CALL util.throw('Missing data in campaign table'); + END IF; + + IF NOT vYesterday BETWEEN vDateSumTo - INTERVAL vPreviousDays DAY + AND vDateSumTo THEN + LEAVE proc; + END IF; + + SET vDateSumFrom = vDateSumTo - INTERVAL vScopeDays DAY; + SET vDateSumTo = vDateSumTo - INTERVAL 1 DAY; + + INSERT INTO itemCampaign(dated, itemFk, quantity, total, campaign) + SELECT vYesterday, + s.itemFk, + SUM(s.quantity) quantity, + SUM((s.quantity * s.price) * (100 - s.discount) / 100) total, + vCampaign + FROM sale s + JOIN ticket t ON t.id = s.ticketFk + JOIN client c ON c.id = t.clientFk + WHERE t.shipped BETWEEN vDateSumFrom AND util.dayEnd(vDateSumTo) + AND c.typeFk = 'normal' + AND NOT t.isDeleted + GROUP BY s.itemFk + HAVING quantity; +END$$ +DELIMITER ; diff --git a/db/versions/11308-redCymbidium/00-firstScript.sql b/db/versions/11308-redCymbidium/00-firstScript.sql new file mode 100644 index 000000000..fe76cb600 --- /dev/null +++ b/db/versions/11308-redCymbidium/00-firstScript.sql @@ -0,0 +1,25 @@ +CREATE TABLE IF NOT EXISTS `vn`.`itemCampaign` ( + `id` int(11) NOT NULL PRIMARY KEY AUTO_INCREMENT, + dated date NOT NULL, + itemFk int(11) NOT NULL, + quantity decimal(10,2) NOT NULL, + total decimal(10,2) NOT NULL, + campaign varchar(100) NOT NULL, + UNIQUE KEY `itemCampaign_UNIQUE` (`dated`,`itemFk`), + CONSTRAINT itemCampaign_item_FK FOREIGN KEY (itemFk) REFERENCES vn.item(id) ON DELETE RESTRICT ON UPDATE CASCADE +) +ENGINE=InnoDB +DEFAULT CHARSET=utf8mb3 +COLLATE=utf8mb3_unicode_ci +COMMENT='Tallos confirmados por día en los días de más producción de una campaña. La tabla está pensada para que sea una foto.'; + +ALTER TABLE vn.campaign + ADD previousDays int(10) unsigned DEFAULT 30 NOT NULL COMMENT 'Días previos para calcular e insertar en la tabla itemCampaign'; + +UPDATE vn.campaign + SET previousDays = 90 + WHERE code = 'allSaints'; + +UPDATE vn.campaign + SET previousDays = 60 + WHERE code IN ('valentinesDay', 'mothersDay');