feat: refs #8119 itemCampaignQuantity #3117
|
@ -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 ;
|
|
@ -0,0 +1,81 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemCampaignQuantity_add`(
|
||||
vDateFrom DATE,
|
||||
guillermo marked this conversation as resolved
Outdated
|
||||
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,
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
vol guardar tallos y euros vol guardar tallos y euros
|
||||
CASE WHEN t.shipped BETWEEN vDateSumFrom AND vDateSumTo
|
||||
THEN SUM(s.quantity)
|
||||
END quantity,
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
jo crec que el case no cal, simplement, lo que torne el where es suma jo crec que el case no cal, simplement, lo que torne el where es suma
guillermo
commented
Si que fa falta, ja que volem sumar de vDateFrom y vDateTo soles de ixos rango de dies (vDateSumFrom y vDateSumTo). Si vols torna a vore el codi i si no comentem. Si que fa falta, ja que volem sumar de vDateFrom y vDateTo soles de ixos rango de dies (vDateSumFrom y vDateSumTo).
Si vols torna a vore el codi i si no comentem.
|
||||
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,24 @@
|
|||
CREATE TABLE IF NOT EXISTS vn.itemCampaignQuantity (
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
posali una definicio de que es guarda en esta taula posali una definicio de que es guarda en esta taula
|
||||
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),
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
posali un camp id, que a salix les claus primaries dobles no les gestiona be, despues ja poses una clau unique en item,quantity posali un camp id, que a salix les claus primaries dobles no les gestiona be, despues ja poses una clau unique en item,quantity
|
||||
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',
|
||||
guillermo marked this conversation as resolved
Outdated
jgallego
commented
açò deuria tindre una Fk a la taula campaing? açò deuria tindre una Fk a la taula campaing?
guillermo
commented
No se puede, ya que en la tabla campaign hay más de 1 registro con ese dato, y además es de tipo ENUM. No se puede, ya que en la tabla campaign hay más de 1 registro con ese dato, y además es de tipo ENUM.
|
||||
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);
|
Loading…
Reference in New Issue
que aporta que puguen pasar parametros a NULL? jo crec que no deixaria..i a mes el yesterday no comprenc per a que, ha de mirar fecha campaña menos x
Per a poder ficar-lo en el event i que siga lo mes sencill posible.
El yesterday se gasta perque el event se executa a les 3AM, pero volem vore ahir, ja que s'ha completat el día.