salix/db/routines/vn/procedures/greuge_notifyEvents.sql

73 lines
1.7 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`greuge_notifyEvents`()
BEGIN
/**
* Notify to detect wrong greuges.
*/
DECLARE vTimeStart DATETIME;
DECLARE vTimeEnd DATETIME;
DECLARE vMaxPercentToWrong DECIMAL(10,2);
DECLARE vJSON JSON;
DECLARE vArray JSON;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vHasData BOOL DEFAULT FALSE;
DECLARE vCounter INT DEFAULT 0;
DECLARE myCur CURSOR FOR
SELECT JSON_OBJECT(
'ticketId', g.ticketFk,
'clientId', g.clientFk,
'description', g.description,
'amount', g.amount
)
FROM greuge g
JOIN greugeType gt ON gt.id = g.greugeTypeFk
JOIN ticket t ON t.id = g.ticketFk
WHERE g.created BETWEEN vTimeStart AND util.dayEnd(vTimeEnd)
AND g.amount > (t.totalWithVat * (vMaxPercentToWrong / 100))
AND gt.code = 'freightDifference'
AND SIGN(t.totalWithVat)
ORDER BY g.clientFk;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
SELECT IFNULL(DATE(lastNotifyCheck), util.VN_CURDATE()) INTO vTimeStart
FROM greugeConfig;
SET vTimeEnd = util.VN_NOW();
SELECT maxPercentToWrong INTO vMaxPercentToWrong
FROM greugeConfig
LIMIT 1;
IF vMaxPercentToWrong IS NULL THEN
CALL util.throw('Greuge max percent to wrong is not configured');
END IF;
SET vArray = JSON_ARRAY();
OPEN myCur;
myCur: LOOP
FETCH myCur INTO vJSON;
IF vDone THEN
LEAVE myCur;
END IF;
SET vArray = JSON_MERGE(vArray, vJSON);
SET vCounter = vCounter + 1;
SET vHasData = TRUE;
END LOOP;
CLOSE myCur;
IF vHasData THEN
SELECT util.notification_send(
'greuge-wrong',
JSON_OBJECT('tickets', JSON_EXTRACT(vArray, '$')),
account.myUser_getId()
);
END IF;
UPDATE greugeConfig
SET lastNotifyCheck = vTimeEnd;
END$$
DELIMITER ;