55 lines
1.4 KiB
SQL
55 lines
1.4 KiB
SQL
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 ;
|