salix/db/changes/10110-postCampaign/00-clientGetMana.sql

76 lines
1.9 KiB
SQL

DROP function IF EXISTS `vn`.`clientGetMana`;
DELIMITER $$
CREATE DEFINER=`root`@`%` FUNCTION `vn`.`clientGetMana`(vClient INT) RETURNS decimal(10,2)
DETERMINISTIC
BEGIN
/**
* Devuelve el mana del cliente.
*
* @param vClient Id del cliente
* @return Mana del cliente
*/
DECLARE vMana DECIMAL(10,2);
DECLARE vFromDated DATE;
DECLARE vHasMana BOOLEAN;
DECLARE vManaComponent INT;
DECLARE vAutoManaComponent INT;
DECLARE vManaBank INT;
DECLARE vManaGreugeType INT;
SELECT id INTO vManaGreugeType FROM greugeType WHERE code = 'mana';
SELECT id INTO vManaBank FROM bank WHERE code = 'mana';
SELECT id INTO vManaComponent FROM component WHERE code = 'mana';
SELECT id INTO vAutoManaComponent FROM component WHERE code = 'autoMana';
SELECT COUNT(*) INTO vHasMana
FROM `client` c
WHERE c.id = vClient AND c.typeFk = 'normal';
IF NOT vHasMana THEN
RETURN 0;
END IF;
SELECT max(dated) INTO vFromDated
FROM clientManaCache;
SELECT sum(mana) INTO vMana
FROM
(
SELECT mana
FROM clientManaCache
WHERE clientFk = vClient
AND dated = vFromDated
UNION ALL
SELECT s.quantity * value
FROM ticket t
JOIN address a ON a.id = t.addressFk
JOIN sale s on s.ticketFk = t.id
JOIN saleComponent sc on sc.saleFk = s.id
WHERE sc.componentFk IN (vManaComponent, vAutoManaComponent)
AND t.shipped > vFromDated
AND t.shipped < TIMESTAMPADD(DAY,1,CURDATE())
AND a.clientFk = vClient
UNION ALL
SELECT - amountPaid
FROM receipt r
JOIN `client` c ON c.id = r.clientFk
WHERE r.bankFk = vManaBank
AND r.payed > vFromDated
AND r.payed <= CURDATE()
AND c.id = vClient
UNION ALL
SELECT g.amount
FROM greuge g
JOIN `client` c ON c.id = g.clientFk
WHERE g.greugeTypeFk = vManaGreugeType
AND g.shipped > vFromDated
AND g.shipped <= CURDATE()
AND c.id = vClient
) sub;
RETURN IFNULL(vMana,0);
END$$
DELIMITER ;