From 3bf2b46689e49d07e55ae5fcb413cb53b88d469b Mon Sep 17 00:00:00 2001 From: vicent Date: Wed, 30 Mar 2022 10:09:01 +0200 Subject: [PATCH] feat(ticket_line): update workerMana if check claimMana option --- .../10440-fallas/00-manaCustomerUpdate.sql | 106 ++++++++++++++++++ .../10440-fallas/00-manaSpellersRequery.sql | 75 +++++++++++++ 2 files changed, 181 insertions(+) create mode 100644 db/changes/10440-fallas/00-manaCustomerUpdate.sql create mode 100644 db/changes/10440-fallas/00-manaSpellersRequery.sql diff --git a/db/changes/10440-fallas/00-manaCustomerUpdate.sql b/db/changes/10440-fallas/00-manaCustomerUpdate.sql new file mode 100644 index 000000000..6a714f81e --- /dev/null +++ b/db/changes/10440-fallas/00-manaCustomerUpdate.sql @@ -0,0 +1,106 @@ +DROP PROCEDURE IF EXISTS `bs`.`manaCustomerUpdate`; + +DELIMITER $$ +$$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `bs`.`manaCustomerUpdate`() +BEGIN + DECLARE vToDated DATE; + DECLARE vFromDated DATE; + DECLARE vForDeleteDated DATE; + DECLARE vManaId INT; + DECLARE vManaAutoId INT; + DECLARE vClaimManaId INT; + DECLARE vManaBankId INT; + DECLARE vManaGreugeTypeId INT; + + SELECT id INTO vManaId + FROM `component` WHERE code = 'mana'; + + SELECT id INTO vManaAutoId + FROM `component` WHERE code = 'autoMana'; + + SELECT id INTO vClaimManaId + FROM `component` WHERE code = 'mana claim'; + + SELECT id INTO vManaBankId + FROM `bank` WHERE code = 'mana'; + + SELECT id INTO vManaGreugeTypeId + FROM `greugeType` WHERE code = 'mana'; + + SELECT IFNULL(max(dated), '2016-01-01') + INTO vFromDated + FROM bs.manaCustomer; + + DELETE + FROM bs.manaCustomer + WHERE dated = vFromDated; + + SELECT IFNULL(max(dated), '2016-01-01') + INTO vFromDated + FROM bs.manaCustomer; + + WHILE timestampadd(DAY,30,vFromDated) < CURDATE() DO + + SELECT + timestampadd(DAY,30,vFromDated), + timestampadd(DAY,-90,vFromDated) + INTO + vToDated, + vForDeleteDated; + + DELETE FROM bs.manaCustomer + WHERE dated <= vForDeleteDated; + + + INSERT INTO bs.manaCustomer(Id_Cliente, Mana, dated) + + SELECT + Id_Cliente, + cast(sum(mana) as decimal(10,2)) as mana, + vToDated as dated + FROM + + ( + SELECT cs.Id_Cliente, Cantidad * Valor as mana + FROM vn2008.Tickets t + JOIN vn2008.Consignatarios cs using(Id_Consigna) + JOIN vn2008.Movimientos m on m.Id_Ticket = t.Id_Ticket + JOIN vn2008.Movimientos_componentes mc on mc.Id_Movimiento = m.Id_Movimiento + WHERE Id_Componente IN (vManaAutoId, vManaId, vClaimManaId) + AND t.Fecha > vFromDated + AND date(t.Fecha) <= vToDated + + + UNION ALL + + SELECT r.Id_Cliente, - Entregado + FROM vn2008.Recibos r + WHERE Id_Banco = vManaBankId + AND Fechacobro > vFromDated + AND Fechacobro <= vToDated + + UNION ALL + + SELECT g.Id_Cliente, g.Importe + FROM vn2008.Greuges g + WHERE Greuges_type_id = vManaGreugeTypeId + AND Fecha > vFromDated + AND Fecha <= vToDated + + UNION ALL + + SELECT Id_Cliente, mana + FROM bs.manaCustomer + WHERE dated = vFromDated + ) sub + + GROUP BY Id_Cliente + HAVING Id_Cliente; + + SET vFromDated = vToDated; + + END WHILE; + +END$$ +DELIMITER ; diff --git a/db/changes/10440-fallas/00-manaSpellersRequery.sql b/db/changes/10440-fallas/00-manaSpellersRequery.sql new file mode 100644 index 000000000..1a0a03ddb --- /dev/null +++ b/db/changes/10440-fallas/00-manaSpellersRequery.sql @@ -0,0 +1,75 @@ +DROP PROCEDURE IF EXISTS `vn`.`manaSpellersRequery`; + +DELIMITER $$ +$$ +CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`manaSpellersRequery`(vWorkerFk INTEGER) +BEGIN +/** + * Recalcula el mana consumido por un trabajador + * + * @param vWorkerFk Id Trabajador + */ + DECLARE vWorkerIsExcluded BOOLEAN; + DECLARE vFromDated DATE; + DECLARE vToDated DATE DEFAULT TIMESTAMPADD(DAY,1,CURDATE()); + DECLARE vMana INT; + DECLARE vAutoMana INT; + DECLARE vClaimMana INT; + DECLARE vManaBank INT; + DECLARE vManaGreugeType INT; + + SELECT COUNT(*) INTO vWorkerIsExcluded + FROM workerManaExcluded + WHERE workerFk = vWorkerFk; + + IF NOT vWorkerIsExcluded THEN + SELECT id INTO vMana + FROM `component` WHERE code = 'mana'; + + SELECT id INTO vAutoMana + FROM `component` WHERE code = 'autoMana'; + + SELECT id INTO vClaimMana + FROM `component` WHERE code = 'mana claim'; + + SELECT id INTO vManaBank + FROM `bank` WHERE code = 'mana'; + + SELECT id INTO vManaGreugeType + FROM `greugeType` WHERE code = 'mana'; + + SELECT max(dated) INTO vFromDated + FROM clientManaCache; + + REPLACE workerMana (workerFk, amount) + SELECT vWorkerFk, sum(mana) FROM + ( + SELECT s.quantity * sc.value as mana + FROM ticket t + JOIN address a ON a.id = t.addressFk + JOIN client c ON c.id = a.clientFk + JOIN sale s ON s.ticketFk = t.id + JOIN saleComponent sc ON sc.saleFk = s.id + WHERE c.salesPersonFk = vWorkerFk AND sc.componentFk IN (vMana, vAutoMana, vClaimMana) + AND t.shipped > vFromDated AND t.shipped < vToDated + UNION ALL + SELECT - r.amountPaid + FROM receipt r + JOIN client c ON c.id = r.clientFk + WHERE c.salesPersonFk = vWorkerFk AND bankFk = vManaBank + AND payed > vFromDated + UNION ALL + SELECT g.amount + FROM greuge g + JOIN client c ON c.id = g.clientFk + WHERE c.salesPersonFk = vWorkerFk AND g.greugeTypeFk = vManaGreugeType + AND g.shipped > vFromDated and g.shipped < CURDATE() + UNION ALL + SELECT cc.mana + FROM clientManaCache cc + JOIN client c ON c.id = cc.clientFk + WHERE c.salesPersonFk = vWorkerFk AND cc.dated = vFromDated + ) sub; + END IF; +END$$ +DELIMITER ;