feat: refs #8119 itemCampaignQuantity
gitea/salix/pipeline/pr-master There was a failure building this commit Details

This commit is contained in:
Guillermo Bonet 2024-10-17 10:08:27 +02:00
parent 15622a3e68
commit 999cb2dbb4
3 changed files with 113 additions and 0 deletions

View File

@ -0,0 +1,8 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` EVENT `vn`.`itemCampaignQuantity_add`
ON SCHEDULE EVERY 5 MINUTE
STARTS '2024-10-18 03:00:00.000'
ON COMPLETION PRESERVE
ENABLE
DO CALL itemCampaignQuantity_add(NULL, NULL, NULL)$$
DELIMITER ;

View File

@ -0,0 +1,81 @@
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 vYesterday INT;
DECLARE vDefaultCampaign VARCHAR(100);
DECLARE vPreviousDaysToInsert INT;
DECLARE vDateSumFrom DATE;
DECLARE vDateSumTo DATE;
DECLARE vScopeDays DATE;
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 > util.VN_CURDATE()
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 util.VN_CURDATE() BETWEEN vDateSumTo - INTERVAL vPreviousDaysToInsert DAY
AND vDateSumTo THEN
LEAVE proc;
END IF;
SET vDateSumFrom = vDateSumTo - INTERVAL vScopeDays DAY;
INSERT INTO itemCampaignQuantity(dated, itemFk, quantity, campaign)
SELECT DATE(s.created),
s.itemFk,
CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
THEN SUM(s.quantity)
END quantity,
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 ;

View File

@ -0,0 +1,24 @@
CREATE TABLE IF NOT EXISTS vn.itemCampaignQuantity (
dated date NOT NULL,
itemFk int(11) NOT NULL,
quantity decimal(10,2) NOT NULL,
campaign varchar(100) NOT NULL,
CONSTRAINT itemCampaignQuantity_pk PRIMARY KEY (dated,itemFk),
CONSTRAINT itemCampaignQuantity_item_FK FOREIGN KEY (itemFk) REFERENCES vn.item(id) ON DELETE RESTRICT ON UPDATE CASCADE
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8mb3
COLLATE=utf8mb3_unicode_ci;
CREATE TABLE IF NOT EXISTS vn.itemCampaignQuantityConfig (
id int(10) unsigned NOT NULL PRIMARY,
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)
VALUES (1, 'allSaints', 90);