feat: refs #8119 Requested changes
This commit is contained in:
parent
5162c2037b
commit
1afb33c306
|
@ -1,8 +1,8 @@
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`vn`@`localhost` EVENT `vn`.`itemCampaignQuantity_add`
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` EVENT `vn`.`itemCampaig_add`
|
||||||
ON SCHEDULE EVERY 1 DAY
|
ON SCHEDULE EVERY 1 DAY
|
||||||
STARTS '2024-10-18 03:00:00.000'
|
STARTS '2024-10-18 03:00:00.000'
|
||||||
ON COMPLETION PRESERVE
|
ON COMPLETION PRESERVE
|
||||||
ENABLE
|
ENABLE
|
||||||
DO CALL itemCampaignQuantity_add(NULL, NULL, NULL)$$
|
DO CALL itemCampaign_add()$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -1,86 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemCampaignQuantity_add`(
|
|
||||||
vDateFrom DATE,
|
|
||||||
vDateTo DATE,
|
|
||||||
vCampaign VARCHAR(100)
|
|
||||||
)
|
|
||||||
proc: BEGIN
|
|
||||||
/**
|
|
||||||
* Añade registros a tabla itemCampaignQuantity.
|
|
||||||
*
|
|
||||||
* @param vDateFrom Fecha desde
|
|
||||||
* @param vDateTo Fecha hasta
|
|
||||||
* @param vCampaign Código de la campaña
|
|
||||||
*/
|
|
||||||
DECLARE vCurdate DATE;
|
|
||||||
DECLARE vYesterday DATE;
|
|
||||||
DECLARE vDefaultCampaign VARCHAR(100);
|
|
||||||
DECLARE vPreviousDaysToInsert INT;
|
|
||||||
DECLARE vDateSumFrom DATE;
|
|
||||||
DECLARE vDateSumTo DATE;
|
|
||||||
DECLARE vScopeDays INT;
|
|
||||||
|
|
||||||
SET vCurdate = util.VN_CURDATE();
|
|
||||||
SET vYesterday = util.yesterday();
|
|
||||||
|
|
||||||
IF vDateFrom IS NULL THEN
|
|
||||||
SET vDateFrom = vYesterday;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
IF vDateTo IS NULL THEN
|
|
||||||
SET vDateTo = vYesterday;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
IF vDateFrom > vDateTo THEN
|
|
||||||
CALL util.throw('Start date cannot be later than end date');
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
SELECT defaultCampaign, previousDaysToInsert
|
|
||||||
INTO vDefaultCampaign, vPreviousDaysToInsert
|
|
||||||
FROM itemCampaignQuantityConfig;
|
|
||||||
|
|
||||||
IF vCampaign IS NULL THEN
|
|
||||||
SET vCampaign = vDefaultCampaign;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
IF vCampaign IS NULL OR vPreviousDaysToInsert IS NULL THEN
|
|
||||||
CALL util.throw('Missing values in the configuration table');
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
SELECT dated, scopeDays INTO vDateSumTo, vScopeDays
|
|
||||||
FROM campaign
|
|
||||||
WHERE dated > vCurdate
|
|
||||||
AND code = vCampaign
|
|
||||||
ORDER BY dated
|
|
||||||
LIMIT 1;
|
|
||||||
|
|
||||||
IF vDateSumTo IS NULL OR vScopeDays IS NULL THEN
|
|
||||||
CALL util.throw('Missing data in campaign table');
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
IF NOT vCurdate BETWEEN vDateSumTo - INTERVAL vPreviousDaysToInsert DAY
|
|
||||||
AND vDateSumTo THEN
|
|
||||||
LEAVE proc;
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
SET vDateSumFrom = vDateSumTo - INTERVAL vScopeDays DAY;
|
|
||||||
|
|
||||||
REPLACE itemCampaignQuantity(dated, itemFk, quantity, total, campaign)
|
|
||||||
SELECT DATE(s.created),
|
|
||||||
s.itemFk,
|
|
||||||
SUM(CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
|
|
||||||
THEN s.quantity
|
|
||||||
END) quantity,
|
|
||||||
SUM(CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
|
|
||||||
THEN s.total
|
|
||||||
END) total,
|
|
||||||
vCampaign
|
|
||||||
FROM sale s
|
|
||||||
JOIN ticket t ON t.id = s.ticketFk
|
|
||||||
JOIN client c ON c.id = t.clientFk
|
|
||||||
WHERE s.created BETWEEN vDateFrom AND util.dayEnd(vDateTo)
|
|
||||||
AND c.businessTypeFk <> 'worker'
|
|
||||||
GROUP BY DATE(s.created), s.itemFk
|
|
||||||
HAVING quantity;
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -0,0 +1,58 @@
|
||||||
|
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 vCurdate DATE;
|
||||||
|
DECLARE vYesterday DATE;
|
||||||
|
DECLARE vCampaign VARCHAR(100);
|
||||||
|
DECLARE vPreviousDays INT;
|
||||||
|
DECLARE vDateSumFrom DATE;
|
||||||
|
DECLARE vDateSumTo DATE;
|
||||||
|
DECLARE vScopeDays INT;
|
||||||
|
|
||||||
|
SET vCurdate = util.VN_CURDATE();
|
||||||
|
|
||||||
|
SELECT dated, code, scopeDays, previousDays
|
||||||
|
INTO vDateSumTo, vCampaign, vScopeDays, vPreviousDays
|
||||||
|
FROM campaign
|
||||||
|
WHERE dated > vCurdate
|
||||||
|
ORDER BY dated
|
||||||
|
LIMIT 1;
|
||||||
|
|
||||||
|
IF vCampaign IS NULL THEN
|
||||||
|
CALL util.throw('Missing data in campaign table');
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF NOT vCurdate BETWEEN vDateSumTo - INTERVAL vPreviousDays DAY
|
||||||
|
AND vDateSumTo THEN
|
||||||
|
LEAVE proc;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SET vDateSumFrom = vDateSumTo - INTERVAL vScopeDays DAY;
|
||||||
|
SET vYesterday = util.yesterday();
|
||||||
|
|
||||||
|
REPLACE itemCampaign(dated, itemFk, quantity, total, campaign)
|
||||||
|
SELECT DATE(s.created),
|
||||||
|
s.itemFk,
|
||||||
|
SUM(CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
|
||||||
|
THEN s.quantity
|
||||||
|
END) quantity,
|
||||||
|
SUM(CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
|
||||||
|
THEN (s.quantity * s.price) * (100 - s.discount) / 100
|
||||||
|
END) total,
|
||||||
|
vCampaign
|
||||||
|
FROM sale s
|
||||||
|
JOIN ticket t ON t.id = s.ticketFk
|
||||||
|
JOIN client c ON c.id = t.clientFk
|
||||||
|
WHERE s.created BETWEEN vYesterday AND util.dayEnd(vYesterday)
|
||||||
|
AND c.typeFk = 'normal'
|
||||||
|
GROUP BY DATE(s.created), s.itemFk
|
||||||
|
HAVING quantity;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -1,27 +1,25 @@
|
||||||
CREATE TABLE IF NOT EXISTS `vn`.`itemCampaignQuantity` (
|
CREATE TABLE IF NOT EXISTS `vn`.`itemCampaign` (
|
||||||
`id` int(11) NOT NULL PRIMARY KEY AUTO_INCREMENT,
|
`id` int(11) NOT NULL PRIMARY KEY AUTO_INCREMENT,
|
||||||
dated date NOT NULL,
|
dated date NOT NULL,
|
||||||
itemFk int(11) NOT NULL,
|
itemFk int(11) NOT NULL,
|
||||||
quantity decimal(10,2) NOT NULL,
|
quantity decimal(10,2) NOT NULL,
|
||||||
total decimal(10,2) NOT NULL,
|
total decimal(10,2) NOT NULL,
|
||||||
campaign varchar(100) NOT NULL,
|
campaign varchar(100) NOT NULL,
|
||||||
UNIQUE KEY `itemCampaignQuantity_UNIQUE` (`dated`,`itemFk`),
|
UNIQUE KEY `itemCampaign_UNIQUE` (`dated`,`itemFk`),
|
||||||
CONSTRAINT itemCampaignQuantity_item_FK FOREIGN KEY (itemFk) REFERENCES vn.item(id) ON DELETE RESTRICT ON UPDATE CASCADE
|
CONSTRAINT itemCampaign_item_FK FOREIGN KEY (itemFk) REFERENCES vn.item(id) ON DELETE RESTRICT ON UPDATE CASCADE
|
||||||
)
|
)
|
||||||
ENGINE=InnoDB
|
ENGINE=InnoDB
|
||||||
DEFAULT CHARSET=utf8mb3
|
DEFAULT CHARSET=utf8mb3
|
||||||
COLLATE=utf8mb3_unicode_ci
|
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.';
|
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.';
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS `vn`.`itemCampaignQuantityConfig` (
|
ALTER TABLE vn.campaign
|
||||||
id int(10) unsigned NOT NULL PRIMARY KEY,
|
ADD previousDays int(10) unsigned DEFAULT 30 NOT NULL COMMENT 'Días previos para calcular e insertar en la tabla itemCampaign';
|
||||||
defaultCampaign varchar(100) NOT NULL COMMENT 'Campaña por defecto si se le pasa NULL',
|
|
||||||
previousDaysToInsert int(10) unsigned NOT NULL COMMENT 'Días anteriores a la fecha de fin de campaña para insertar',
|
|
||||||
CONSTRAINT `itemCampaignQuantityConfig_check` CHECK (`id` = 1)
|
|
||||||
)
|
|
||||||
ENGINE=InnoDB
|
|
||||||
DEFAULT CHARSET=utf8mb3
|
|
||||||
COLLATE=utf8mb3_unicode_ci;
|
|
||||||
|
|
||||||
INSERT IGNORE INTO `vn`.`itemCampaignQuantityConfig` (id, defaultCampaign, previousDaysToInsert)
|
UPDATE vn.campaign
|
||||||
VALUES (1, 'allSaints', 90);
|
SET previousDays = 90
|
||||||
|
WHERE code = 'allSaints';
|
||||||
|
|
||||||
|
UPDATE vn.campaign
|
||||||
|
SET previousDays = 60
|
||||||
|
WHERE code IN ('valentinesDay', 'mothersDay');
|
||||||
|
|
Loading…
Reference in New Issue