From ce55d44fb75dbd7130259835ca865ff444fc35cd Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Mon, 27 May 2024 16:27:12 +0200 Subject: [PATCH] feat: salesPersonFk to saleDepartmentFk refs #6802 --- .../bi/procedures/analisis_ventas_update.sql | 2 + .../bi/procedures/defaultersFromDate.sql | 61 +++++--- .../bs/procedures/campaignComparative.sql | 42 ------ db/routines/bs/procedures/clean.sql | 3 + db/routines/bs/procedures/clientDied_calc.sql | 61 ++++++++ .../bs/procedures/clientDied_recalc.sql | 4 +- .../bs/procedures/comparativeCampaign.sql | 39 +++++ .../bs/procedures/manaCustomerUpdate.sql | 4 +- .../bs/procedures/manaSpellers_actualize.sql | 6 +- .../bs/procedures/manaSpellers_recalc.sql | 29 ++++ db/routines/bs/procedures/portfolio_add.sql | 27 ++++ .../bs/procedures/salePersonEvolutionAdd.sql | 20 --- .../salesByClientDepartment_add.sql | 46 ++++++ .../salesDepartmentEvolution_add.sql | 64 ++++++++ .../bs/procedures/vendedores_add_launcher.sql | 2 +- ...sql => client_unassignSalesDepartment.sql} | 4 +- db/routines/vn/events/clientsDisable.sql | 2 +- .../vn/functions/catalog_componentReverse.sql | 6 +- .../functions/client_getSalesPersonCode.sql | 26 ---- .../procedures/catalog_componentCalculate.sql | 6 +- db/routines/vn/procedures/clientDebtSpray.sql | 3 +- .../vn/procedures/clientGreugeSpray.sql | 93 ++++++------ .../vn/procedures/clientRemoveWorker.sql | 30 ++-- .../client_unassignSalesDepartment.sql | 52 +++++++ .../vn/procedures/collection_getTickets.sql | 66 +++++---- db/routines/vn/procedures/itemSale_byWeek.sql | 5 +- .../vn/procedures/manaSpellers_requery.sql | 38 +++++ .../vn/procedures/productionControl.sql | 2 + .../vn/procedures/route_getTickets.sql | 5 +- .../procedures/sectorCollection_getSale.sql | 3 +- .../vn/procedures/ticket_canAdvance.sql | 8 +- .../vn/procedures/ticket_cloneWeekly.sql | 44 ++++-- db/routines/vn/procedures/workerDisable.sql | 39 ++--- .../vn/procedures/zone_getAddresses.sql | 3 + .../vn/triggers/client_beforeInsert.sql | 2 + .../vn/triggers/client_beforeUpdate.sql | 23 ++- db/routines/vn/views/newBornSales.sql | 44 +++--- db/routines/vn2008/views/Clientes.sql | 1 + .../11032-blackRose/00-firstScript.sql | 139 ++++++++++++++++++ 39 files changed, 778 insertions(+), 276 deletions(-) delete mode 100644 db/routines/bs/procedures/campaignComparative.sql create mode 100644 db/routines/bs/procedures/clientDied_calc.sql create mode 100644 db/routines/bs/procedures/comparativeCampaign.sql create mode 100644 db/routines/bs/procedures/manaSpellers_recalc.sql create mode 100644 db/routines/bs/procedures/portfolio_add.sql delete mode 100644 db/routines/bs/procedures/salePersonEvolutionAdd.sql create mode 100644 db/routines/bs/procedures/salesByClientDepartment_add.sql create mode 100644 db/routines/bs/procedures/salesDepartmentEvolution_add.sql rename db/routines/vn/events/{client_unassignSalesPerson.sql => client_unassignSalesDepartment.sql} (73%) delete mode 100644 db/routines/vn/functions/client_getSalesPersonCode.sql create mode 100644 db/routines/vn/procedures/client_unassignSalesDepartment.sql create mode 100644 db/routines/vn/procedures/manaSpellers_requery.sql create mode 100644 db/versions/11032-blackRose/00-firstScript.sql diff --git a/db/routines/bi/procedures/analisis_ventas_update.sql b/db/routines/bi/procedures/analisis_ventas_update.sql index ef3e165a0..4a9746ebf 100644 --- a/db/routines/bi/procedures/analisis_ventas_update.sql +++ b/db/routines/bi/procedures/analisis_ventas_update.sql @@ -12,6 +12,7 @@ BEGIN INSERT INTO analisis_ventas ( Familia, Reino, + salesDepartmentFk, Comercial, Comprador, Provincia, @@ -25,6 +26,7 @@ BEGIN SELECT it.name, ic.name, + c.salesDepartmentFk, w.code, w2.code, p.name, diff --git a/db/routines/bi/procedures/defaultersFromDate.sql b/db/routines/bi/procedures/defaultersFromDate.sql index bfe133750..ee2c791db 100644 --- a/db/routines/bi/procedures/defaultersFromDate.sql +++ b/db/routines/bi/procedures/defaultersFromDate.sql @@ -1,24 +1,45 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`defaultersFromDate`(IN vDate DATE) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`defaultersFromDate`( + IN vDated DATE +) BEGIN - - SELECT t1.*, c.name Cliente, w.code workerCode, c.payMethodFk pay_met_id, c.dueDay Vencimiento - FROM ( - -- Filtramos aquellos clientes cuyo saldo se ha incrementado de ayer a hoy - select * from( - select today.client, today.amount todayAmount, yesterday.amount yesterdayAmount, round(yesterday.amount - today.amount,2) as difference, defaulterSince - from - (select client, amount, defaulterSince - from defaulters - where date = vDate and hasChanged) today - join - (select client, amount - from defaulters - where date = TIMESTAMPADD(DAY,-1,vDate)) yesterday using(client) - - having today.amount > 0 and difference <> 0 - ) newDefaulters - )t1 left join vn.client c ON c.id = t1.client - left join vn.worker w ON w.id = c.salesPersonFk; +/** + * Retorna la info de clientes morosos a una fecha + * + * @param vDated Fecha a comprobar + */ + WITH todayDefaulters AS( + SELECT client, amount, defaulterSince + FROM bi.defaulters + WHERE date = vDated + AND hasChanged + ), yesterdayDefaulters AS( + SELECT client, amount + FROM bi.defaulters + WHERE date = vDated - INTERVAL 1 DAY + ), newDefaulters AS( + SELECT td.client, + td.amount todayAmount, + yd.amount yesterdayAmount, + ROUND(yd.amount - td.amount, 2) difference, + defaulterSince + FROM todayDefaulters td + JOIN yesterdayDefaulters yd ON yd.client = td.client + WHERE td.amount > 0 + HAVING difference <> 0 + ) SELECT nd.client, + nd.todayAmount, + nd.yesterdayAmount, + nd.difference, + nd.defaulterSince, + c.name Cliente, + w.code workerCode, + d.name salesDepartmentName, + c.payMethodFk pay_met_id, + c.dueDay Vencimiento + FROM newDefaulters nd + LEFT JOIN vn.client c ON c.id = nd.client + LEFT JOIN vn.worker w ON w.id = c.salesPersonFk + LEFT JOIN vn.department d ON d.id = c.salesDepartmentFk; END$$ DELIMITER ; diff --git a/db/routines/bs/procedures/campaignComparative.sql b/db/routines/bs/procedures/campaignComparative.sql deleted file mode 100644 index 6b4b983b5..000000000 --- a/db/routines/bs/procedures/campaignComparative.sql +++ /dev/null @@ -1,42 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`campaignComparative`(vDateFrom DATE, vDateTo DATE) -BEGIN - SELECT - workerName, - id, - name, - CAST(SUM(previousAmmount) AS DECIMAL(10, 0)) AS previousAmmount, - CAST(SUM(currentAmmount) AS DECIMAL(10, 0)) AS currentAmmount - FROM ( - (SELECT - CONCAT(w.firstname, ' ', w.lastName) AS workerName, - c.id, - c.name, - SUM(v.importe) AS previousAmmount, - 0 currentAmmount - FROM bs.ventas v - INNER JOIN vn.`client` c ON v.Id_Cliente = c.id - INNER JOIN vn.worker w ON c.salesPersonFk = w.id - WHERE v.fecha BETWEEN DATE_ADD(vDateFrom, INTERVAL - 1 YEAR) - AND DATE_ADD(vDateTo, INTERVAL - 1 YEAR) - GROUP BY w.id, v.Id_Cliente) - UNION ALL - (SELECT - CONCAT(w.firstname, ' ', w.lastName) AS workerName, - c.id, - c.name, - 0 AS previousAmmount, - SUM(s.quantity * s.price) AS currentAmmount - FROM vn.sale s - JOIN vn.ticket t ON t.id = s.ticketFk - JOIN vn.client c ON c.id = t.clientFk - JOIN vn.worker w ON c.salesPersonFk = w.id - WHERE t.shipped BETWEEN vDateFrom - AND vDateTo - GROUP BY w.id, c.id) - ) comparative - GROUP BY workerName, id - HAVING (previousAmmount <> 0 OR currentAmmount <> 0) - ORDER BY workerName, id; -END$$ -DELIMITER ; diff --git a/db/routines/bs/procedures/clean.sql b/db/routines/bs/procedures/clean.sql index eff2faadb..030622a3e 100644 --- a/db/routines/bs/procedures/clean.sql +++ b/db/routines/bs/procedures/clean.sql @@ -23,6 +23,9 @@ BEGIN DELETE FROM salesByclientSalesPerson WHERE dated < vFourYearsAgo; + DELETE FROM salesByClientDepartment + WHERE dated < vFourYearsAgo; + DELETE FROM m3 WHERE fecha < vTwoYearAgo; diff --git a/db/routines/bs/procedures/clientDied_calc.sql b/db/routines/bs/procedures/clientDied_calc.sql new file mode 100644 index 000000000..3cb93e74a --- /dev/null +++ b/db/routines/bs/procedures/clientDied_calc.sql @@ -0,0 +1,61 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`clientDied_calc`( + vDays INT, + vCountryCode VARCHAR(2) +) +BEGIN +/** + * Recalcula los clientes inactivos y hace insert en la tabla clientDied + * estableciendo hasta 3 avisos en función del periodo y el código de país. + * + * @param vDays El número de días a considerar para la inactividad del cliente + * @param vCountryCode El código del país para filtrar los clientes + */ + DECLARE vFirstPeriod , vSecondPeriod, vThridPeriod DATE; + SET vFirstPeriod = util.VN_CURDATE() - INTERVAL vDays DAY; + SET vSecondPeriod = util.VN_CURDATE() - INTERVAL vDays * 2 DAY; + SET vThridPeriod = util.VN_CURDATE() - INTERVAL vDays * 3 DAY; + + DELETE cd.* FROM clientDied cd + JOIN ( + SELECT c.id FROM vn.client c + JOIN vn.country co ON co.id = c.countryFk + WHERE co.code = vCountryCode + ) sub ON sub.id = cd.clientFk; + + INSERT INTO clientDied (clientFk, lastInvoiced, warning) + SELECT c.id, + sub.lastShipped, + CASE + WHEN lastShipped < vThridPeriod OR lastShipped IS NULL THEN 'third' + WHEN lastShipped < vSecondPeriod THEN 'second' + WHEN lastShipped < vFirstPeriod THEN 'first' + END + FROM vn.client c + JOIN vn.country co ON co .id = c.countryFk + JOIN vn.department w ON w.id = c.salesDepartmentFk + JOIN vn.departmentMana dm ON dm.salesDepartmentFk = c.salesDepartmentFk + LEFT JOIN ( + SELECT c.id, DATE(MAX(t.shipped)) lastShipped + FROM vn.client c + LEFT JOIN vn.ticket t ON t.clientFk = c.id + LEFT JOIN vn.country co ON co.id = c.countryFk + WHERE co.code = vCountryCode + AND (t.shipped <= util.VN_CURDATE() OR t.shipped IS NULL) + GROUP BY c.id + ) sub ON sub.id = c.id + LEFT JOIN vn.clientObservation cob ON cob.clientFk = c.id + AND cob.created > vThridPeriod + WHERE (sub.lastShipped < vFirstPeriod OR sub.lastShipped IS NULL) + AND c.created < vThridPeriod + AND co.code = vCountryCode + AND cob.`text` IS NULL + AND c.id NOT IN ( + SELECT DISTINCT clientFk + FROM vn.ticket + WHERE refFk IS NULL + AND shipped >= vFirstPeriod + ) + GROUP BY c.id; +END$$ +DELIMITER ; diff --git a/db/routines/bs/procedures/clientDied_recalc.sql b/db/routines/bs/procedures/clientDied_recalc.sql index 1b5cb5ac8..89e82b7fb 100644 --- a/db/routines/bs/procedures/clientDied_recalc.sql +++ b/db/routines/bs/procedures/clientDied_recalc.sql @@ -33,9 +33,7 @@ BEGIN END FROM vn.client c JOIN vn.country co ON co .id = c.countryFk - JOIN vn.worker w ON w.id = c.salesPersonFk - JOIN vn.worker b ON b.id = w.bossFk - JOIN vn.workerMana wm ON wm.workerFk = c.salesPersonFk + JOIN vn.departmentMana dm ON dm.salesDepartmentFk = c.salesDepartmentFk LEFT JOIN ( SELECT c.id, DATE(MAX(t.shipped)) lastShipped FROM vn.client c diff --git a/db/routines/bs/procedures/comparativeCampaign.sql b/db/routines/bs/procedures/comparativeCampaign.sql new file mode 100644 index 000000000..c05b20921 --- /dev/null +++ b/db/routines/bs/procedures/comparativeCampaign.sql @@ -0,0 +1,39 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root``localhost` PROCEDURE `bs`.`comparativeCampaign`(vDateFrom DATE, vDateTo DATE) +BEGIN + SELECT deparmentName, + id clientFk, + name clientName, + CAST(SUM(previousAmmount) AS DECIMAL(10, 0)) previousAmmount, + CAST(SUM(currentAmmount) AS DECIMAL(10, 0)) currentAmmount + FROM ((SELECT + d.name deparmentName, + c.id, + c.name, + SUM(s.amount) previousAmmount, + 0 currentAmmount + FROM sale s + JOIN vn.`client` c ON s.clientFk = c.id + JOIN vn.department d ON d.id = c.salesDepartmentFk + WHERE s.dated BETWEEN DATE_ADD(vDateFrom, INTERVAL - 1 YEAR) + AND DATE_ADD(vDateTo, INTERVAL - 1 YEAR) + GROUP BY d.id, s.clientFk) + UNION ALL + (SELECT + d.name deparmentName, + c.id, + c.name, + 0 AS previousAmmount, + SUM(s.quantity * s.price) currentAmmount + FROM vn.sale s + JOIN vn.ticket t ON t.id = s.ticketFk + JOIN vn.client c ON c.id = t.clientFk + JOIN vn.department d ON d.id = c.salesDepartmentFk + WHERE t.shipped BETWEEN vDateFrom AND vDateTo + GROUP BY d.id, c.id) + ) comparative + GROUP BY deparmentName, id + HAVING previousAmmount OR currentAmmount + ORDER BY deparmentName, id; +END$$ +DELIMITER ; diff --git a/db/routines/bs/procedures/manaCustomerUpdate.sql b/db/routines/bs/procedures/manaCustomerUpdate.sql index b77ddc1fd..d3a06427d 100644 --- a/db/routines/bs/procedures/manaCustomerUpdate.sql +++ b/db/routines/bs/procedures/manaCustomerUpdate.sql @@ -29,7 +29,7 @@ BEGIN SELECT manaFromDays, manaToDays INTO vManaFromDays, vManaToDays - FROM vn.salespersonConfig; + FROM vn.salesDepartmentConfig; SELECT MAX(dated) INTO vFromDated @@ -46,7 +46,7 @@ BEGIN IF ISNULL(vFromDated) THEN SELECT manaDateFrom INTO vFromDated - FROM vn.salespersonConfig; + FROM vn.salesDepartmentConfig; END IF; WHILE vFromDated + INTERVAL vManaToDays DAY < util.VN_CURDATE() DO diff --git a/db/routines/bs/procedures/manaSpellers_actualize.sql b/db/routines/bs/procedures/manaSpellers_actualize.sql index 20b0f84f8..e774bf12b 100644 --- a/db/routines/bs/procedures/manaSpellers_actualize.sql +++ b/db/routines/bs/procedures/manaSpellers_actualize.sql @@ -14,13 +14,13 @@ BEGIN WHERE s.dated BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE() GROUP BY c.lastSalesPersonFk )avgPortfolioWeight ON avgPortfolioWeight.lastSalesPersonFk = wm.workerFk - JOIN vn.salespersonConfig spc + JOIN vn.salesDepartmentConfig sdc SET wm.pricesModifierRate = IFNULL( GREATEST( - spc.manaMinRate, + sdc.manaMinRate, LEAST( - spc.manaMaxRate, + sdc.manaMaxRate, ROUND( - wm.amount / avgPortfolioWeight.amount, 3) ) ) diff --git a/db/routines/bs/procedures/manaSpellers_recalc.sql b/db/routines/bs/procedures/manaSpellers_recalc.sql new file mode 100644 index 000000000..414e54109 --- /dev/null +++ b/db/routines/bs/procedures/manaSpellers_recalc.sql @@ -0,0 +1,29 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`manaSpellers_recalc`() +BEGIN +/** + * Recalcula el valor del campo con el modificador de precio + * para el componente de maná automático. + */ + UPDATE vn.departmentMana dm + JOIN ( + SELECT c.lastSalesDepartmentFk, + FLOOR(SUM(s.amount) / 12) amount + FROM salesByClientDepartment s + JOIN vn.client c ON c.id = s.clientFk + WHERE s.dated BETWEEN util.VN_CURDATE() - INTERVAL 1 YEAR AND util.VN_CURDATE() + GROUP BY c.lastSalesDepartmentFk + )avgPortfolioWeight ON avgPortfolioWeight.lastSalesDepartmentFk = dm.salesDepartmentFk + JOIN vn.salesDepartmentConfig sdc + SET dm.pricesModifierRate = + IFNULL( + GREATEST( + sdc.manaMinRate, + LEAST( + sdc.manaMaxRate, + ROUND( - dm.amount / avgPortfolioWeight.amount, 3) + ) + ) + ,0); +END$$ +DELIMITER ; diff --git a/db/routines/bs/procedures/portfolio_add.sql b/db/routines/bs/procedures/portfolio_add.sql new file mode 100644 index 000000000..0269e1fe3 --- /dev/null +++ b/db/routines/bs/procedures/portfolio_add.sql @@ -0,0 +1,27 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`portfolio_add`() +BEGIN +/** + * Inserta en la tabla @bs.portfolio las ventas desde el año pasado + * agrupadas por equipo, año y mes + */ + DECLARE vYear INT DEFAULT YEAR(util.VN_CURDATE()) - 1; + + CALL util.time_generate( + MAKEDATE(vYear, 1), + (SELECT MAX(dated) FROM sale) + ); + + INSERT INTO portfolio(yeared, monthed , saleDepartmentFk, Amount) + SELECT t.`year`, t.`month`, w.code, SUM(s.amount) + FROM tmp.time t + JOIN sale s on t.dated = s.dated + JOIN vn.client c on c.id = s.clientFk + JOIN vn.department d ON d.id = c.salesDepartmentFk + GROUP BY d.id, t.`year`, t.`month`; + + DROP TEMPORARY TABLE tmp.time; +END$$ +DELIMITER ; + + diff --git a/db/routines/bs/procedures/salePersonEvolutionAdd.sql b/db/routines/bs/procedures/salePersonEvolutionAdd.sql deleted file mode 100644 index 33e31b699..000000000 --- a/db/routines/bs/procedures/salePersonEvolutionAdd.sql +++ /dev/null @@ -1,20 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`salePersonEvolutionAdd`(IN vDateStart DATETIME) -BEGIN - DELETE FROM bs.salePersonEvolution - WHERE dated <= DATE_SUB(util.VN_CURDATE(), INTERVAL 1 YEAR); - - - INSERT INTO bs.salePersonEvolution (dated, amount, equalizationTax, salesPersonFk) - SELECT fecha dated, - CAST(SUM(importe) AS DECIMAL(10,2) ) amount, - CAST(SUM(recargo) AS DECIMAL(10,2) ) equalizationTax , - IFNULL(salesPersonFk,0) salesPersonFk - FROM bs.ventas v - JOIN vn.client c ON v.Id_Cliente = c.id - JOIN vn.company co ON co.id = v.empresa_id - WHERE co.code = "VNL" AND fecha >= vDateStart - GROUP BY v.fecha,c.salesPersonFk - ORDER BY salesPersonFk,dated ASC; -END$$ -DELIMITER ; diff --git a/db/routines/bs/procedures/salesByClientDepartment_add.sql b/db/routines/bs/procedures/salesByClientDepartment_add.sql new file mode 100644 index 000000000..96b5ec7b0 --- /dev/null +++ b/db/routines/bs/procedures/salesByClientDepartment_add.sql @@ -0,0 +1,46 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`salesByClientDepartments_add`(vDatedFrom DATE) +BEGIN +/** + * Agrupa las ventas por cliente/departamento/fecha en la tabla bs.salesByClientDepartment + * El asociación cliente/comercial/fecha, se mantiene correcta en el tiempo + * + * @param vDatedFrom el cálculo se realizará desde la fecha introducida hasta ayer + */ + + IF vDatedFrom IS NULL THEN + SET vDatedFrom = util.VN_CURDATE() - INTERVAL 1 MONTH; + END IF; + + UPDATE salesByClientDepartment + SET amount = 0, + equalizationTax = 0, + amountNewBorn = 0 + WHERE dated BETWEEN vDatedFrom AND util.yesterday(); + + INSERT INTO salesByClientDepartment( + dated, + salesDepartmentFk, + clientFk, + amount, + equalizationTax) + SELECT s.dated, + c.salesDepartmentFk, + s.clientFk, + SUM(s.amount), + SUM(s.surcharge) + FROM sale s + JOIN vn.client c on s.clientFk = c.id + WHERE s.dated BETWEEN vDatedFrom AND util.yesterday() + GROUP BY s.dated, c.salesDepartmentFk, s.clientFk + ON DUPLICATE KEY UPDATE amount= VALUES(amount), + equalizationTax= VALUES(equalizationTax); + + UPDATE salesByClientDepartment s + JOIN vn.newBornSales n ON n.dated = s.dated AND + n.clientFk = s.clientFk + SET s.amountNewBorn = n.amount + WHERE n.dated BETWEEN vDatedFrom AND util.yesterday(); + +END$$ +DELIMITER ; diff --git a/db/routines/bs/procedures/salesDepartmentEvolution_add.sql b/db/routines/bs/procedures/salesDepartmentEvolution_add.sql new file mode 100644 index 000000000..b0bd7b3ea --- /dev/null +++ b/db/routines/bs/procedures/salesDepartmentEvolution_add.sql @@ -0,0 +1,64 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`salesDepartmentEvolution_add`() +BEGIN +/** + * Calcula los datos para los gráficos de evolución agrupado por salesDepartmentFk y día. + * Recalcula automáticamente los 3 últimos meses para comprobar si hay algún cambio. + */ + DECLARE vDated DATE; + + SELECT MAX(dated) - INTERVAL 3 MONTH INTO vDated + FROM salesDepartmentEvolution; + + DELETE FROM salesDepartmentEvolution + WHERE dated >= vDated; + + IF ISNULL(vDated) THEN + SELECT MIN(dated) INTO vDated + FROM salesByClientDepartment; + + INSERT INTO salesByClientDepartment( + salesDepartmentFk, + dated, + amount, + equalizationTax, + amountNewBorn + ) + SELECT salesDepartmentFk, + dated, + amount, + equalizationTax, + amountNewBorn + FROM salesByClientDepartment + WHERE dated = vDated + GROUP BY salesDepartmentFk; + + SET vDated = vDated + INTERVAL 1 DAY; + END IF; + + WHILE vDated < util.VN_CURDATE() DO + + REPLACE salesByClientDepartment(salesDepartmentFk, dated, amount) + SELECT salesDepartmentFk, vDated, amount + FROM(SELECT salesDepartmentFk, SUM(amount) amount + FROM(SELECT salesDepartmentFk, amount + FROM salesByClientDepartment + WHERE dated = vDated - INTERVAL 1 DAY + UNION ALL + SELECT salesDepartmentFk, amount + FROM salesByClientDepartment + WHERE dated = vDated + UNION ALL + SELECT salesDepartmentFk, - amount + FROM salesByClientDepartment + WHERE dated = vDated - INTERVAL 1 YEAR + )sub + GROUP BY salesDepartmentFk + )sub + GROUP BY salesDepartmentFk; + + SET vDated = vDated + INTERVAL 1 DAY; + + END WHILE; +END$$ +DELIMITER ; diff --git a/db/routines/bs/procedures/vendedores_add_launcher.sql b/db/routines/bs/procedures/vendedores_add_launcher.sql index c0718a659..eb87e7969 100644 --- a/db/routines/bs/procedures/vendedores_add_launcher.sql +++ b/db/routines/bs/procedures/vendedores_add_launcher.sql @@ -2,7 +2,7 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`vendedores_add_launcher`() BEGIN - CALL bs.salesByclientSalesPerson_add(util.VN_CURDATE()- INTERVAL 45 DAY); + CALL bs.salesByclientSalesDepartment_add(util.VN_CURDATE()- INTERVAL 45 DAY); END$$ DELIMITER ; diff --git a/db/routines/vn/events/client_unassignSalesPerson.sql b/db/routines/vn/events/client_unassignSalesDepartment.sql similarity index 73% rename from db/routines/vn/events/client_unassignSalesPerson.sql rename to db/routines/vn/events/client_unassignSalesDepartment.sql index 46ad414b1..558ac4194 100644 --- a/db/routines/vn/events/client_unassignSalesPerson.sql +++ b/db/routines/vn/events/client_unassignSalesDepartment.sql @@ -1,8 +1,8 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` EVENT `vn`.`client_unassignSalesPerson` +CREATE OR REPLACE DEFINER=`root`@`localhost` EVENT `vn`.`client_unassignSalesDepartment` ON SCHEDULE EVERY 1 DAY STARTS '2023-06-01 03:30:00.000' ON COMPLETION PRESERVE ENABLE -DO CALL client_unassignSalesPerson$$ +DO CALL client_unassignSalesDepartment$$ DELIMITER ; diff --git a/db/routines/vn/events/clientsDisable.sql b/db/routines/vn/events/clientsDisable.sql index 238e060dd..66517b40d 100644 --- a/db/routines/vn/events/clientsDisable.sql +++ b/db/routines/vn/events/clientsDisable.sql @@ -13,7 +13,7 @@ DO BEGIN SELECT DISTINCT c.id FROM client c LEFT JOIN ticket t ON t.clientFk = c.id - WHERE c.salesPersonFk IS NOT NULL + WHERE c.salesDepartmentFk IS NOT NULL OR t.created > util.VN_CURDATE() - INTERVAL 2 MONTH OR shipped > util.VN_CURDATE() - INTERVAL 2 MONTH ); diff --git a/db/routines/vn/functions/catalog_componentReverse.sql b/db/routines/vn/functions/catalog_componentReverse.sql index f37b20890..e4bac208f 100644 --- a/db/routines/vn/functions/catalog_componentReverse.sql +++ b/db/routines/vn/functions/catalog_componentReverse.sql @@ -69,10 +69,10 @@ BEGIN -- Componente de maná automático, en función del maná acumulado por el comercial. INSERT INTO tmp.catalog_component (warehouseFk, itemFk, componentFk, cost) - SELECT vWarehouse, vItem, vComponentMana, ROUND(wm.pricesModifierRate, 3) + SELECT vWarehouse, vItem, vComponentMana, ROUND(dm.pricesModifierRate, 3) FROM client c - JOIN vn.workerMana wm ON c.salesPersonFk = wm.workerFk - WHERE wm.isPricesModifierActivated AND c.id = vCustomer LIMIT 1; + JOIN vn.departmentMana dm ON c.salesDepartmentFk = dm.salesDepartmentFk + WHERE dm.isPricesModifierActivated AND c.id = vCustomer LIMIT 1; -- Reparto INSERT INTO tmp.catalog_component (warehouseFk, itemFk, componentFk, cost) diff --git a/db/routines/vn/functions/client_getSalesPersonCode.sql b/db/routines/vn/functions/client_getSalesPersonCode.sql deleted file mode 100644 index 69b8424d8..000000000 --- a/db/routines/vn/functions/client_getSalesPersonCode.sql +++ /dev/null @@ -1,26 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`client_getSalesPersonCode`(vClientFk INT, vDated DATE) - RETURNS varchar(3) CHARSET utf8mb3 COLLATE utf8mb3_general_ci - DETERMINISTIC -BEGIN -/** - * Dado un id cliente y una fecha, devuelve su comercial. - * Para más información ir a client_getSalesPerson() - * - * @param vClientFk El id del cliente - * @param vDated Fecha a comprobar - * @return El código del comercial para la fecha dada - **/ - DECLARE vWorkerCode CHAR(3); - DECLARE vSalesPersonFk INT; - - SET vSalesPersonFk = client_getSalesPerson(vClientFk, vDated); - - SELECT code - INTO vWorkerCode - FROM worker - WHERE id = vSalesPersonFk; - - RETURN vWorkerCode; -END$$ -DELIMITER ; diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index 4b860103d..64c08dfdf 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -138,12 +138,12 @@ BEGIN SELECT tcb.warehouseFk, tcb.itemFk, c2.id, - ROUND(base * wm.pricesModifierRate, 3) manaAuto + ROUND(base * dm.pricesModifierRate, 3) manaAuto FROM tmp.ticketComponentBase tcb JOIN `client` c on c.id = vClientFk - JOIN workerMana wm ON c.salesPersonFk = wm.workerFk + JOIN departmentMana dm ON c.salesDepartmentFk = dm.salesDepartmentFk JOIN vn.component c2 ON c2.code = 'autoMana' - WHERE wm.isPricesModifierActivated + WHERE dm.isPricesModifierActivated HAVING manaAuto <> 0; -- Precios especiales diff --git a/db/routines/vn/procedures/clientDebtSpray.sql b/db/routines/vn/procedures/clientDebtSpray.sql index 687c08fe2..2aafe904c 100644 --- a/db/routines/vn/procedures/clientDebtSpray.sql +++ b/db/routines/vn/procedures/clientDebtSpray.sql @@ -22,7 +22,8 @@ BEGIN WHERE clientFk = vClientFk; UPDATE vn.client - SET salesPersonFk = NULL + SET salesPersonFk = NULL, + salesDepartmentFk = NULL WHERE id = vClientFk; END$$ diff --git a/db/routines/vn/procedures/clientGreugeSpray.sql b/db/routines/vn/procedures/clientGreugeSpray.sql index c337e2dd3..70a5e4105 100644 --- a/db/routines/vn/procedures/clientGreugeSpray.sql +++ b/db/routines/vn/procedures/clientGreugeSpray.sql @@ -1,7 +1,11 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`clientGreugeSpray`(IN vClientFk INT, IN onlyForHisOwner BOOL, IN vWorkerCode VARCHAR(3), IN vWithMana BOOLEAN) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`clientGreugeSpray`( + IN vClientFk INT, + IN vIsOnlyForHisOwner BOOL, + IN vDepartmentCode VARCHAR(45), + IN vWithMana BOOLEAN +) BEGIN - DECLARE vGreuge DECIMAL(10,2); DECLARE vOwner INT; DECLARE vTotalSale INT; @@ -9,65 +13,62 @@ BEGIN DECLARE vGreugeTypeMana INT DEFAULT 3;-- Maná DECLARE vMana DECIMAL(10,2); - SELECT vn.clientGetMana(vClientFk) INTO vMana; + SELECT clientGetMana(vClientFk) INTO vMana; IF vWithMana AND vMana THEN - - INSERT INTO vn.greuge( clientFk, - description, - amount, - shipped, - greugeTypeFk) - VALUES( vClientFk, - 'Desasignación', - -1 * vMana, - util.VN_CURDATE(), - vGreugeTypeMana); - + INSERT INTO greuge + SET clientFk = vClientFk, + description = 'Desasignación', + amount = - vMana, + shipped = util.VN_CURDATE(), + greugeTypeFk = vGreugeTypeMana; END IF; - SELECT sum(amount) INTO vGreuge - FROM vn.greuge + SELECT SUM(amount) INTO vGreuge + FROM greuge WHERE clientFk = vClientFk; - IF vGreuge != 0 THEN - - IF LENGTH(vWorkerCode) = 0 THEN - - SELECT salesPersonFk INTO vOwner - FROM vn.client + IF vGreuge THEN + IF LENGTH(vDepartmentCode) THEN + SELECT salesDepartmentFk INTO vOwner + FROM client WHERE id = vClientFk; - ELSE - SELECT id INTO vOwner - FROM vn.worker - WHERE code = vWorkerCode COLLATE utf8_general_ci; - + FROM department + WHERE code = vDepartmentCode; END IF; - DROP TEMPORARY TABLE IF EXISTS tmp.clientList; - CREATE TEMPORARY TABLE tmp.clientList - SELECT DISTINCT t.clientFk, floor(cr.yearSale / 12) monthSale + IF vOwner IS NULL THEN + CALL util.throw('The department is incorrect'); + END IF; + + INSERT INTO greuge(clientFk, description, amount, shipped, greugeTypeFk) + WITH greuges AS( + SELECT DISTINCT t.clientFk, FLOOR(cr.yearSale / 12) monthSale FROM vn.ticket t JOIN vn.client c ON c.id = t.clientFk - JOIN vn.workerMana wm ON wm.workerFk = c.salesPersonFk + JOIN vn.departmentMana dm ON dm.salesDepartmentFk = c.salesDepartmentFk JOIN vn.claimRatio cr ON cr.clientFk = c.id - WHERE wm.workerFk = IF(onlyForHisOwner, vOwner, wm.workerFk) - AND t.shipped >= TIMESTAMPADD(MONTH,-1,util.VN_CURDATE()) - AND c.id != vClientFk - HAVING monthSale > 100; - - SELECT SUM(monthSale) INTO vTotalSale - FROM tmp.clientList; - - INSERT INTO vn.greuge(clientFk, description, amount, shipped, greugeTypeFk) - SELECT clientFk, CONCAT('Cliente: ',vClientFk), vGreuge * monthSale / vTotalSale, util.VN_CURDATE(), vGreugeTypeFk - FROM tmp.clientList + WHERE dm.salesDepartmentFk = IF(vIsOnlyForHisOwner, vOwner, dm.salesDepartmentFk) + AND t.shipped >= util.VN_CURDATE() - INTERVAL 1 MONTH + AND c.id <> vClientFk + HAVING monthSale > 100 + ), totalGreuge AS( + SELECT SUM(monthSale) totalSale FROM greuges + )SELECT g.clientFk, + CONCAT('Cliente: ', vClientFk), + vGreuge * g.monthSale / tgtotalSale, + util.VN_CURDATE(), + vGreugeTypeFk + FROM greuges g + JOIN totalGreuge tg UNION ALL - SELECT vClientFk, 'Reparto greuge', -vGreuge, util.VN_CURDATE(), vGreugeTypeFk; - + SELECT vClientFk, + 'Reparto greuge', + -vGreuge, + util.VN_CURDATE(), + vGreugeTypeFk; END IF; - END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/clientRemoveWorker.sql b/db/routines/vn/procedures/clientRemoveWorker.sql index 15d247c67..53582a7f6 100644 --- a/db/routines/vn/procedures/clientRemoveWorker.sql +++ b/db/routines/vn/procedures/clientRemoveWorker.sql @@ -8,7 +8,7 @@ BEGIN FROM tmp.clientGetDebt c LEFT JOIN clientRisk r ON r.clientFk = c.clientFk GROUP BY c.clientFk - HAVING SUM(IFNULL(r.amount,0)) = 0; + HAVING SUM(IFNULL(r.amount, 0)) = 0; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; @@ -16,22 +16,28 @@ BEGIN CREATE TEMPORARY TABLE tmp.clientGetDebt SELECT cd.clientFk FROM bs.clientDied cd - LEFT JOIN clientProtected cp ON cp.clientFk = cd.clientFk - JOIN client c ON c.id = cd.clientFk - JOIN province p ON p.id = c.provinceFk - LEFT JOIN autonomy a ON a.id = p.autonomyFk - JOIN country co ON co.id = p.countryFk - WHERE cd.warning = 'third' - AND cp.clientFk IS NULL - AND co.code NOT IN ('PT') - AND a.name <> 'Canarias' - AND c.salesPersonFk IS NOT NULL; + LEFT JOIN clientProtected cp ON cp.clientFk = cd.clientFk + JOIN client c ON c.id = cd.clientFk + JOIN province p ON p.id = c.provinceFk + LEFT JOIN autonomy a ON a.id = p.autonomyFk + JOIN country co ON co.id = p.countryFk + WHERE cd.warning = 'third' + AND cp.clientFk IS NULL + AND co.code NOT IN ('PT') + AND a.name <> 'Canarias' + AND c.salesPersonFk IS NOT NULL + AND c.salesDepartmentFk IS NOT NULL; OPEN rs; FETCH rs INTO vClientFk; WHILE NOT vDone DO CALL vn.clientGreugeSpray(vClientFk, TRUE, '',TRUE); - UPDATE vn.client SET salesPersonFk = NULL WHERE id = vClientFk; + + UPDATE vn.client + SET salesPersonFk = NULL, + salesDepartmentFk = NULL + WHERE id = vClientFk; + FETCH rs INTO vClientFk; END WHILE; CLOSE rs; diff --git a/db/routines/vn/procedures/client_unassignSalesDepartment.sql b/db/routines/vn/procedures/client_unassignSalesDepartment.sql new file mode 100644 index 000000000..6db64cfcc --- /dev/null +++ b/db/routines/vn/procedures/client_unassignSalesDepartment.sql @@ -0,0 +1,52 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`client_unassignSalesDepartment`() +BEGIN +/** + * Elimina la asignación de salesDepartmentFk de la ficha del clientes + * que no han realizado una compra en los últimos 3 meses y reparte + * su greuge entre el resto de clientes + */ + DECLARE vDone BOOL DEFAULT FALSE; + DECLARE vClientFk INT; + DECLARE vCursor CURSOR FOR + SELECT c.clientFk + FROM tClientList c + LEFT JOIN clientRisk r ON r.clientFk = c.clientFk + GROUP BY c.clientFk + HAVING NOT SUM(IFNULL(r.amount, 0)); + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + CREATE OR REPLACE TEMPORARY TABLE tClientList + SELECT c.id clientFk + FROM bs.clientDied cd + JOIN client c ON c.id = cd.clientFk + LEFT JOIN clientProtected cp ON cp.clientFk = c.id + LEFT JOIN salesPersonProtected sp ON sp.salesPersonFk = c.salesPersonFk + LEFT JOIN salesDepartmentProtected sd ON sp.salesDepartmentFk = c.salesDepartmentFk + JOIN province p ON p.id = c.provinceFk + LEFT JOIN autonomy a ON a.id = p.autonomyFk + JOIN country co ON co.id = p.countryFk + WHERE cd.warning = 'third' + AND cp.clientFk IS NULL + AND sp.salesPersonFk IS NULL + AND a.name <> 'Canarias' + AND c.salesDepartmentFk IS NOT NULL; + + OPEN vCursor; + l: LOOP + SET vDone = FALSE; + FETCH vCursor INTO vClientFk; + IF vDone THEN + LEAVE l; + END IF; + CALL clientGreugeSpray(vClientFk, TRUE, '', TRUE); + UPDATE client + SET salesDepartmentFk = NULL + WHERE id = vClientFk; + END LOOP; + CLOSE vCursor; + + DROP TEMPORARY TABLE tClientList; +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/collection_getTickets.sql b/db/routines/vn/procedures/collection_getTickets.sql index 0a71ada78..ce4a661eb 100644 --- a/db/routines/vn/procedures/collection_getTickets.sql +++ b/db/routines/vn/procedures/collection_getTickets.sql @@ -1,62 +1,68 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getTickets`(vParamFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getTickets`( + vParamFk INT +) BEGIN /** * Selecciona los tickets de una colección/ticket * @param vParamFk ticketFk/collectionFk - * @return Retorna ticketFk, level, agencyName, warehouseFk, salesPersonFk, observaciones + * @return Retorna (ticketFk, level, agencyName, warehouseFk, salesPersonFk, + * observaciones, rgb, salesDepartmentFk) */ DECLARE vItemPackingTypeFk VARCHAR(1); -- Si los sacadores son los de pruebas, pinta los colores SELECT itemPackingTypeFk INTO vItemPackingTypeFk - FROM vn.collection + FROM collection WHERE id = vParamFk; SELECT t.id ticketFk, - IF (!(vItemPackingTypeFk <=> 'V'), cc.code,CONCAT(SUBSTRING('ABCDEFGH',tc.wagon, 1),'-',tc.`level` )) `level`, + IF (NOT(vItemPackingTypeFk <=> 'V'), + cc.code, + CONCAT(SUBSTRING('ABCDEFGH',tc.wagon, 1),'-',tc.`level` )) `level`, am.name agencyName, t.warehouseFk, - w.id salesPersonFk, + c.salesPersonFk, IFNULL(tob.description,'') observaciones, - cc.rgb - FROM vn.ticket t - LEFT JOIN vn.ticketCollection tc ON t.id = tc.ticketFk - LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk -- PAK 23/12/21 - LEFT JOIN vn.collectionColors cc + cc.rgb, + c.salesDepartmentFk + FROM ticket t + LEFT JOIN ticketCollection tc ON t.id = tc.ticketFk + LEFT JOIN collection c2 ON c2.id = tc.collectionFk + LEFT JOIN collectionColors cc ON cc.wagon = tc.wagon AND cc.shelve = tc.`level` - AND cc.trainFk = c2.trainFk -- PAK 23/12/21 - LEFT JOIN vn.zone z ON z.id = t.zoneFk - LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk - LEFT JOIN vn.client c ON c.id = t.clientFk - LEFT JOIN vn.worker w ON w.id = c.salesPersonFk - LEFT JOIN vn.ticketObservation tob ON tob.ticketFk = t.id + AND cc.trainFk = c2.trainFk + LEFT JOIN zone z ON z.id = t.zoneFk + LEFT JOIN agencyMode am ON am.id = z.agencyModeFk + LEFT JOIN client c ON c.id = t.clientFk + LEFT JOIN ticketObservation tob ON tob.ticketFk = t.id AND tob.observationTypeFk = 1 WHERE t.id = vParamFk AND t.shipped >= util.yesterday() UNION ALL SELECT t.id ticketFk, - IF(!(vItemPackingTypeFk <=> 'V'), cc.code, CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`, + IF(NOT(vItemPackingTypeFk <=> 'V'), + cc.code, + CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`, am.name agencyName, t.warehouseFk, - w.id salesPersonFk, + c.salesPersonFk, IFNULL(tob.description, '') observaciones, - IF(!(vItemPackingTypeFk <=> 'V'), cc.rgb, NULL) `rgb` - FROM vn.ticket t - JOIN vn.ticketCollection tc ON t.id = tc.ticketFk - LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk -- PAK 23/12/21 - LEFT JOIN vn.collectionColors cc + IF(NOT(vItemPackingTypeFk <=> 'V'), cc.rgb, NULL) `rgb`, + c.salesDepartmentFk + FROM ticket t + JOIN ticketCollection tc ON t.id = tc.ticketFk + LEFT JOIN collection c2 ON c2.id = tc.collectionFk + LEFT JOIN collectionColors cc ON cc.wagon = tc.wagon AND cc.shelve = tc.`level` - AND cc.trainFk = c2.trainFk -- PAK 23/12/21 - LEFT JOIN vn.zone z ON z.id = t.zoneFk - LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk - LEFT JOIN vn.client c ON c.id = t.clientFk - LEFT JOIN vn.worker w ON w.id = c.salesPersonFk - LEFT JOIN vn.ticketObservation tob ON tob.ticketFk = t.id + AND cc.trainFk = c2.trainFk + LEFT JOIN zone z ON z.id = t.zoneFk + LEFT JOIN agencyMode am ON am.id = z.agencyModeFk + LEFT JOIN client c ON c.id = t.clientFk + LEFT JOIN ticketObservation tob ON tob.ticketFk = t.id AND tob.observationTypeFk = 1 WHERE tc.collectionFk = vParamFk; - END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/itemSale_byWeek.sql b/db/routines/vn/procedures/itemSale_byWeek.sql index bc43b7b16..f5b293a50 100644 --- a/db/routines/vn/procedures/itemSale_byWeek.sql +++ b/db/routines/vn/procedures/itemSale_byWeek.sql @@ -24,7 +24,9 @@ BEGIN tls.name stateName, sb.buyFk, s.id saleFk, - wk.id salesPersonFk + wk.id salesPersonFk, + d.id salesDepartmentFk, + d.name salesDepartment FROM sale s JOIN ticket t ON t.id = s.ticketFk JOIN warehouse w ON w.id = t.warehouseFk @@ -32,6 +34,7 @@ BEGIN LEFT JOIN agencyMode am ON am.id = t.agencyModeFk JOIN `client` c ON c.id = a.clientFk LEFT JOIN worker wk ON wk.id = c.salesPersonFk + LEFT JOIN department d ON d.id = c.salesDepartmentFk LEFT JOIN ticketLastState tls ON tls.ticketFk = t.id LEFT JOIN saleBuy sb ON sb.saleFk = s.id LEFT JOIN buy b ON b.id = sb.buyFk diff --git a/db/routines/vn/procedures/manaSpellers_requery.sql b/db/routines/vn/procedures/manaSpellers_requery.sql new file mode 100644 index 000000000..3b90fc1b2 --- /dev/null +++ b/db/routines/vn/procedures/manaSpellers_requery.sql @@ -0,0 +1,38 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`manaSpellers_requery`( + vDepartmentFk INTEGER +) +`whole_proc`: +BEGIN +/** + * Guarda en departmentMana el mana consumido por un departamento + * + * @param vDepartmentFk Id department + */ + DECLARE vIsDepartmentExcluded BOOLEAN; + + SELECT COUNT(*) INTO vIsDepartmentExcluded + FROM departmentManaExcluded + WHERE departmentFk = vSalesDepartmentFk; + + IF vIsDepartmentExcluded THEN + LEAVE whole_proc; + END IF; + + CREATE OR REPLACE TEMPORARY TABLE tmp.client + SELECT id + FROM client + WHERE salesDepartmentFk = vDepartmentFk; + + CALL client_getMana(); + + INSERT INTO departmentMana (departmentFk, amount) + SELECT vDepartmentFk, SUM(mana) + FROM tmp.clientMana + ON DUPLICATE KEY UPDATE amount = VALUES(amount); + + DROP TEMPORARY TABLE + tmp.client, + tmp.clientMana; +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/productionControl.sql b/db/routines/vn/procedures/productionControl.sql index b42645d1e..2b896f395 100644 --- a/db/routines/vn/procedures/productionControl.sql +++ b/db/routines/vn/procedures/productionControl.sql @@ -65,6 +65,7 @@ proc: BEGIN w.code workerCode, DATE(t.shipped) shipped, wk.code salesPersonCode, + d.code salesDepartmentCode, p.id provinceFk, tls.productionOrder, IFNULL(tls.alertLevel, 0) alertLevel, @@ -84,6 +85,7 @@ proc: BEGIN LEFT JOIN ticketStateToday tst ON tst.ticketFk = t.id LEFT JOIN `state` st ON st.id = tst.state LEFT JOIN client c ON c.id = t.clientFk + LEFT JOIN department d ON d.id = c.salesDepartmentFk LEFT JOIN worker wk ON wk.id = c.salesPersonFk JOIN address a ON a.id = t.addressFk LEFT JOIN province p ON p.id = a.provinceFk diff --git a/db/routines/vn/procedures/route_getTickets.sql b/db/routines/vn/procedures/route_getTickets.sql index 55b08208f..addb69e27 100644 --- a/db/routines/vn/procedures/route_getTickets.sql +++ b/db/routines/vn/procedures/route_getTickets.sql @@ -8,7 +8,7 @@ BEGIN * @param vRouteFk * @select Información de los tickets */ -SELECT t.id Id, + SELECT t.id Id, t.clientFk Client, a.id Address, a.nickname ClientName, @@ -24,6 +24,7 @@ SELECT t.id Id, d.longitude Longitude, d.latitude Latitude, wm.mediaValue SalePersonPhone, + CONCAT_WS(' - ', 'adfa', de.pbxQueue ) salesDepartmentPhone, tob.description Note, t.isSigned Signed, t.priority, @@ -31,6 +32,8 @@ SELECT t.id Id, FROM ticket t JOIN client c ON t.clientFk = c.id JOIN address a ON t.addressFk = a.id + LEFT JOIN vn.department de ON de.id = c.salesDepartmentFk + LEFT JOIN vn.company co ON co.`code` = 'VNL' LEFT JOIN workerMedia wm ON wm.workerFk = c.salesPersonFk LEFT JOIN ( SELECT t.addressFk, MAX(d.ticketFk) lastTicketFk diff --git a/db/routines/vn/procedures/sectorCollection_getSale.sql b/db/routines/vn/procedures/sectorCollection_getSale.sql index e1636895b..4a44c3e5c 100644 --- a/db/routines/vn/procedures/sectorCollection_getSale.sql +++ b/db/routines/vn/procedures/sectorCollection_getSale.sql @@ -15,7 +15,8 @@ BEGIN w.code workerCode, sgd.saleFk, iss.quantity pickedQuantity, - c.salesPersonFk + c.salesPersonFk, + c.salesDepartmentFk FROM vn.sale s JOIN item i ON i.id = s.itemFk JOIN saleGroupDetail sgd ON sgd.saleFk = s.id diff --git a/db/routines/vn/procedures/ticket_canAdvance.sql b/db/routines/vn/procedures/ticket_canAdvance.sql index d1ca7b5e2..c01542e32 100644 --- a/db/routines/vn/procedures/ticket_canAdvance.sql +++ b/db/routines/vn/procedures/ticket_canAdvance.sql @@ -1,5 +1,9 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_canAdvance`(vDateFuture DATE, vDateToAdvance DATE, vWarehouseFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_canAdvance`( + vDateFuture DATE, + vDateToAdvance DATE, + vWarehouseFk INT +) BEGIN /** * Devuelve los tickets y la cantidad de lineas de venta que se pueden adelantar. @@ -27,6 +31,7 @@ BEGIN origin.futureIpt, dest.ipt, origin.workerFk, + origin.departmentFk, origin.futureLiters, origin.futureLines, dest.shipped, @@ -56,6 +61,7 @@ BEGIN SELECT s.ticketFk, c.salesPersonFk workerFk, + c.salesDepartmentFk departmentFk, t.shipped, t.totalWithVat, st.name futureState, diff --git a/db/routines/vn/procedures/ticket_cloneWeekly.sql b/db/routines/vn/procedures/ticket_cloneWeekly.sql index 6bceb2fdf..6c755ab27 100644 --- a/db/routines/vn/procedures/ticket_cloneWeekly.sql +++ b/db/routines/vn/procedures/ticket_cloneWeekly.sql @@ -12,21 +12,21 @@ BEGIN DECLARE vAgencyModeFk INT; DECLARE vNewTicket INT; DECLARE vYear INT; - DECLARE vSalesPersonFK INT; + DECLARE vObservationTypeFkForSalesPerson INT; DECLARE vItemPicker INT; DECLARE rsTicket CURSOR FOR - SELECT tt.ticketFk, - t.clientFk, - t.warehouseFk, - t.companyFk, - t.addressFk, - tt.agencyModeFk, - ti.dated - FROM ticketWeekly tt - JOIN ticket t ON tt.ticketFk = t.id - JOIN tmp.time ti - WHERE WEEKDAY(ti.dated) = tt.weekDay; + SELECT tt.ticketFk, + t.clientFk, + t.warehouseFk, + t.companyFk, + t.addressFk, + tt.agencyModeFk, + ti.dated + FROM ticketWeekly tt + JOIN ticket t ON tt.ticketFk = t.id + JOIN tmp.time ti + WHERE WEEKDAY(ti.dated) = tt.weekDay; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vIsDone = TRUE; @@ -36,6 +36,7 @@ BEGIN myLoop: LOOP BEGIN DECLARE vSalesPersonEmail VARCHAR(150); + DECLARE vSalesDepartmentEmail VARCHAR(150); DECLARE vIsDuplicateMail BOOL; DECLARE vSubject VARCHAR(150); DECLARE vMessage TEXT; @@ -138,7 +139,7 @@ BEGIN FROM ticketRequest WHERE ticketFk =vTicketFk; - SELECT id INTO vSalesPersonFK + SELECT id INTO vObservationTypeFkForSalesPerson FROM observationType WHERE code = 'salesPerson'; @@ -152,7 +153,7 @@ BEGIN description) VALUES( vNewTicket, - vSalesPersonFK, + vObservationTypeFkForSalesPerson, CONCAT('turno desde ticket: ',vTicketFk)) ON DUPLICATE KEY UPDATE description = CONCAT(ticketObservation.description,VALUES(description),' '); @@ -169,9 +170,10 @@ BEGIN IF (vLanding IS NULL) THEN - SELECT e.email INTO vSalesPersonEmail + SELECT e.email, d.notificationEmail INTO vSalesPersonEmail, vSalesDepartmentEmail FROM client c - JOIN account.emailUser e ON e.userFk = c.salesPersonFk + LEFT JOIN account.emailUser e ON e.userFk = c.salesPersonFk + LEFT JOIN department d ON d.id = c.saleDepartmentFk WHERE c.id = vClientFk; SET vSubject = CONCAT('Turnos - No se ha podido clonar correctamente el ticket ', @@ -189,6 +191,16 @@ BEGIN IF NOT vIsDuplicateMail THEN CALL mail_insert(vSalesPersonEmail, NULL, vSubject, vMessage); END IF; + + SELECT COUNT(*) INTO vIsDuplicateMail + FROM mail + WHERE receiver = vSalesDepartmentEmail + AND subject = vSubject; + + IF NOT vIsDuplicateMail THEN + CALL mail_insert(vSalesDepartmentEmail, NULL, vSubject, vMessage); + END IF; + CALL ticketStateUpdate (vNewTicket, 'FIXING'); ELSE CALL ticketCalculateClon(vNewTicket, vTicketFk); diff --git a/db/routines/vn/procedures/workerDisable.sql b/db/routines/vn/procedures/workerDisable.sql index 4b10cb7fa..0f9814990 100644 --- a/db/routines/vn/procedures/workerDisable.sql +++ b/db/routines/vn/procedures/workerDisable.sql @@ -1,32 +1,37 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`workerDisable`(vUserId int) -mainLabel:BEGIN +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`workerDisable`(vUserFk INT) +l:BEGIN - IF (SELECT COUNT(*) FROM workerDisableExcluded WHERE workerFk = vUserId AND (dated > util.VN_CURDATE() OR dated IS NULL)) > 0 THEN - LEAVE mainLabel; + IF (SELECT COUNT(*) + FROM workerDisableExcluded + WHERE workerFk = vUserFk + AND (dated > util.VN_CURDATE() OR dated IS NULL)) > 0 THEN + LEAVE l; END IF; - DELETE cp FROM clientProtected cp - JOIN client c ON c.id = cp.clientFk - WHERE c.salesPersonFk = vUserId; + DELETE cp + FROM clientProtected cp + JOIN client c ON c.id = cp.clientFk + WHERE c.salesPersonFk = vUserFk; - DELETE FROM account.account - WHERE id = vUserId; + DELETE FROM account.account WHERE id = vUserFk; UPDATE account.user SET role = 2 - WHERE id = vUserId; + WHERE id = vUserFk; - DELETE FROM pbx.sip - WHERE user_id = vUserId; + DELETE FROM pbx.sip WHERE user_id = vUserFk; UPDATE `client` c - JOIN payMethod p ON p.name = 'CONTADO' - SET c.credit = 0, c.payMethodFk = p.id, hasCoreVnl = FALSE - WHERE c.id = vUserId; + JOIN payMethod p ON p.name = 'CONTADO' + SET c.credit = 0, + c.payMethodFk = p.id, + hasCoreVnl = FALSE + WHERE c.id = vUserFk; UPDATE `client` c - SET c.salesPersonFk = null - WHERE c.salesPersonFk = vUserId; + SET c.salesPersonFk = NULL, + c.salesDepartmentFk = NULL + WHERE c.salesPersonFk = vUserFk; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/zone_getAddresses.sql b/db/routines/vn/procedures/zone_getAddresses.sql index ce7b0204e..93037e5a3 100644 --- a/db/routines/vn/procedures/zone_getAddresses.sql +++ b/db/routines/vn/procedures/zone_getAddresses.sql @@ -31,11 +31,14 @@ BEGIN bt.description, c.salesPersonFk, u.name username, + d.salesDepartmentFk, + d.name departmentName, aai.invoiced, cnb.lastShipped FROM vn.client c JOIN notHasTicket ON notHasTicket.id = c.id LEFT JOIN account.`user` u ON u.id = c.salesPersonFk + LEFT JOIN vn.department d ON d.id = c.salesDepartmentFk JOIN vn.`address` a ON a.clientFk = c.id JOIN vn.postCode pc ON pc.code = a.postalCode JOIN vn.town t ON t.id = pc.townFk AND t.provinceFk = a.provinceFk diff --git a/db/routines/vn/triggers/client_beforeInsert.sql b/db/routines/vn/triggers/client_beforeInsert.sql index 75b69c7dd..44b3f79ae 100644 --- a/db/routines/vn/triggers/client_beforeInsert.sql +++ b/db/routines/vn/triggers/client_beforeInsert.sql @@ -17,5 +17,7 @@ BEGIN SET NEW.accountingAccount = 4300000000 + NEW.id; SET NEW.lastSalesPersonFk = NEW.salesPersonFk; + + SET NEW.lastSalesDepartmentFk = NEW.salesDepartmentFk ; END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/client_beforeUpdate.sql b/db/routines/vn/triggers/client_beforeUpdate.sql index 2f384c535..142f95880 100644 --- a/db/routines/vn/triggers/client_beforeUpdate.sql +++ b/db/routines/vn/triggers/client_beforeUpdate.sql @@ -46,7 +46,7 @@ BEGIN THEN INSERT INTO mail(receiver, replyTo, `subject`, body) SELECT - CONCAT(IF(ac.id,u.name, 'jgallego'), '@verdnatura.es'), + CONCAT(IF(ac.id, u.name, 'jgallego'), '@verdnatura.es'), 'administracion@verdnatura.es', CONCAT('Cliente ', NEW.id), CONCAT('Recibida la documentación: ', vText) @@ -54,6 +54,14 @@ BEGIN LEFT JOIN account.user u ON w.id = u.id AND u.active LEFT JOIN account.account ac ON ac.id = u.id WHERE w.id = NEW.salesPersonFk; + + INSERT INTO mail(receiver, replyTo, `subject`, body) + SELECT IFNULL(d.notificationEmail, CONCAT('jgallego', '@verdnatura.es')), + 'administracion@verdnatura.es', + CONCAT('Cliente ', NEW.id), + CONCAT('Recibida la documentación: ', vText) + FROM department d + WHERE d.id = NEW.salesDepartmentFk; END IF; IF NEW.salespersonFk IS NULL AND OLD.salespersonFk IS NOT NULL THEN @@ -65,10 +73,23 @@ BEGIN END IF; END IF; + IF NEW.salesDepartmentFk IS NULL AND OLD.salesDepartmentFk IS NOT NULL THEN + IF (SELECT COUNT(clientFk) + FROM clientProtected + WHERE clientFk = NEW.id + ) > 0 THEN + CALL util.throw("HAS_CLIENT_PROTECTED"); + END IF; + END IF; + IF !(NEW.salesPersonFk <=> OLD.salesPersonFk) THEN SET NEW.lastSalesPersonFk = IFNULL(NEW.salesPersonFk, OLD.salesPersonFk); END IF; + IF !(NEW.salesDepartmentFk <=> OLD.salesDepartmentFk) THEN + SET NEW.lastSalesDepartmentFk = IFNULL(NEW.salesDepartmentFk, OLD.salesDepartmentFk); + END IF; + IF !(NEW.businessTypeFk <=> OLD.businessTypeFk) AND (NEW.businessTypeFk = 'individual' OR OLD.businessTypeFk = 'individual') THEN SET NEW.isTaxDataChecked = 0; END IF; diff --git a/db/routines/vn/views/newBornSales.sql b/db/routines/vn/views/newBornSales.sql index d34eff4ef..d011f8757 100644 --- a/db/routines/vn/views/newBornSales.sql +++ b/db/routines/vn/views/newBornSales.sql @@ -1,26 +1,24 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `vn`.`newBornSales` -AS SELECT `v`.`importe` AS `amount`, - `v`.`Id_Cliente` AS `clientFk`, - `c`.`salesPersonFk` AS `userFk`, - `v`.`fecha` AS `dated`, - `cn`.`firstShipped` AS `firstShipped` -FROM ( - ( - ( - ( - `bs`.`clientNewBorn` `cn` - JOIN `bs`.`ventas` `v` ON( - `cn`.`firstShipped` + INTERVAL 1 year > `v`.`fecha` - AND `v`.`Id_Cliente` = `cn`.`clientFk` - ) - ) - JOIN `vn`.`client` `c` ON(`c`.`id` = `v`.`Id_Cliente`) - ) - JOIN `account`.`user` `u` ON(`u`.`id` = `c`.`salesPersonFk`) - ) - JOIN `account`.`role` `r` ON(`r`.`id` = `u`.`role`) - ) -WHERE `r`.`name` = 'salesPerson' - AND `u`.`name` NOT IN ('ismaelalcolea', 'ruben') +AS SELECT + `v`.`importe` AS `amount`, + `v`.`Id_Cliente` AS `clientFk`, + `c`.`salesPersonFk` AS `userFk`, + `c`.`salesDepartmentFk` AS `departmentFk`, + `v`.`fecha` AS `dated`, + `cn`.`firstShipped` AS `firstShipped` +FROM + ((((`bs`.`clientNewBorn` `cn` +JOIN `bs`.`ventas` `v`ON + (`cn`.`firstShipped` + INTERVAL 1 YEAR > `v`.`fecha` + AND `v`.`Id_Cliente` = `cn`.`clientFk`)) +JOIN `vn`.`client` `c`ON + (`c`.`id` = `v`.`Id_Cliente`)) +LEFT JOIN `account`.`user` `u`ON + (`u`.`id` = `c`.`salesPersonFk`)) +JOIN `account`.`role` `r`ON + (`r`.`id` = `u`.`role`)) +WHERE + `r`.`name` = 'salesPerson' + AND `u`.`name` NOT IN ('ismaelalcolea', 'ruben'); \ No newline at end of file diff --git a/db/routines/vn2008/views/Clientes.sql b/db/routines/vn2008/views/Clientes.sql index 153d875bc..f60f65670 100644 --- a/db/routines/vn2008/views/Clientes.sql +++ b/db/routines/vn2008/views/Clientes.sql @@ -41,6 +41,7 @@ AS SELECT `c`.`id` AS `id_cliente`, `c`.`isCreatedAsServed` AS `isCreatedAsServed`, `c`.`hasInvoiceSimplified` AS `hasInvoiceSimplified`, `c`.`salesPersonFk` AS `Id_Trabajador`, + `c`.`salesDepartmentFk` AS `salesDepartmentFk`, `c`.`isVies` AS `vies`, `c`.`bankEntityFk` AS `bankEntityFk`, `c`.`typeFk` AS `typeFk` diff --git a/db/versions/11032-blackRose/00-firstScript.sql b/db/versions/11032-blackRose/00-firstScript.sql new file mode 100644 index 000000000..daca97ace --- /dev/null +++ b/db/versions/11032-blackRose/00-firstScript.sql @@ -0,0 +1,139 @@ +ALTER TABLE vn.client + ADD IF NOT EXISTS salesDepartmentFk INT(11) DEFAULT NULL NULL; + +ALTER TABLE vn.client + ADD IF NOT EXISTS lastSalesDepartmentFk INT(11) DEFAULT NULL NULL; + +ALTER TABLE vn.client + ADD CONSTRAINT client_department_FK FOREIGN KEY IF NOT EXISTS (salesDepartmentFk) + REFERENCES vn.department(id) ON DELETE RESTRICT ON UPDATE CASCADE; + +ALTER TABLE vn.client + ADD CONSTRAINT client_lastDepartment_FK FOREIGN KEY IF NOT EXISTS (lastSalesDepartmentFk) + REFERENCES vn.department(id) ON DELETE RESTRICT ON UPDATE CASCADE; + +UPDATE vn.client c + JOIN vn.worker w ON w.id = c.salesPersonFk + JOIN vn.business b ON b.id = w.businessFk + SET c.salesDepartmentFk = b.departmentFk; + +UPDATE vn.client c + JOIN vn.worker w ON w.id = c.lastSalesPersonFk + JOIN vn.business b ON b.id = w.businessFk + SET c.lastSalesDepartmentFk = b.departmentFk; + +-- Hi ha que vore en els que no fan JOIN perque no tenen business actiu que department/lastDepartment ficar + + +DROP TABLE IF EXISTS vn.departmentMana; + +CREATE TABLE `vn`.`departmentMana` ( + `salesDepartmentFk` int(10) NOT NULL, + `size` int(11) NOT NULL DEFAULT 300, + `amount` int(11) NOT NULL DEFAULT 0, + `pricesModifierRate` double NOT NULL DEFAULT 0, + `isPricesModifierActivated` tinyint(1) NOT NULL DEFAULT 1, + PRIMARY KEY (`salesDepartmentFk`), + KEY `departmentMana_idx` (`salesDepartmentFk`), + CONSTRAINT `departmentMana_salesDepartment_FK` FOREIGN KEY (`salesDepartmentFk`) + REFERENCES `vn`.`department` (`id`) ON DELETE CASCADE ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + +-- Actualizar el valor con la suma de amount y valor medio de pricesModifierRate // Inicializar ¿? + +DROP TABLE IF EXISTS bs.salesByClientDepartment; +CREATE TABLE `bs`.`salesByClientDepartment` ( + `dated` date NOT NULL DEFAULT '0000-00-00', + `salesDepartmentFk` int(10) DEFAULT NULL, + `clientFk` int(11) NOT NULL, + `amount` decimal(10,3) NOT NULL DEFAULT 0.000, + `equalizationTax` decimal(10,3) NOT NULL DEFAULT 0.000, + `amountNewBorn` decimal(10,3) NOT NULL DEFAULT 0.000, + PRIMARY KEY (`dated`,`clientFk`), + KEY `salesByClientDepartment_clientFk` (`clientFk`), + KEY `salesByClientDepartment_salesDepartmentFk` (`salesDepartmentFk`), + KEY `salesByClientDepartment_dated` (`dated`,`clientFk`,`amount`), + CONSTRAINT `salesByClientDepartment_clientFk_FK` + FOREIGN KEY (`clientFk`) REFERENCES `vn`.`client` (`id`) ON UPDATE CASCADE, + CONSTRAINT `salesByClientDepartment_department_FK` + FOREIGN KEY (`salesDepartmentFk`) REFERENCES `vn`.`department` (`id`) ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Ventas diarias por cliente y departamento'; + + +INSERT INTO bs.salesByClientDepartment( + dated, + salesDepartmentFk, + clientFk, + amount, + equalizationTax, + amountNewBorn) + SELECT ss.dated, b.departmentFk, ss.clientFk, ss.amount, ss.equalizationTax, ss.amountNewBorn + FROM bs.salesByclientSalesPerson ss + JOIN vn.worker w ON w.id = ss.salesPersonFk + JOIN vn.business b ON b.id = w.businessFk; + +DROP TABLE IF EXISTS `vn`.`salesDepartmentProtected`; + +CREATE TABLE `vn`.`salesDepartmentProtected` ( + `salesDepartmentFk` int(10) NOT NULL, + PRIMARY KEY (`salesDepartmentFk`), + CONSTRAINT `salesDepartmentProtected_FK` FOREIGN KEY (`salesDepartmentFk`) REFERENCES `vn`.`department` (`id`) ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci + COMMENT='Lista de departamentos comerciales que no se desasignarán automáticamente sus clientes'; + +-- Inicializar valores a mano? +UPDATE vn.observationType + SET description='Dto. Comercial',code='salesDepartment' + WHERE code = 'salesPerson'; + +DROP TABLE IF EXISTS `bs`.`portfolio`; + +CREATE TABLE `bs`.`portfolio` ( + `salesDepartmentFk` int(10) NOT NULL, + `yeared` int(4) NOT NULL, + `monthed` int(2) NOT NULL, + `amount` decimal(10,2) DEFAULT NULL, + PRIMARY KEY (`salesDepartmentFk`,`yeared`,`monthed`), + KEY `portfolio_salesDepartmentFk` (`salesDepartmentFk`), + CONSTRAINT `portfolio_salesDepartment_department_FK` + FOREIGN KEY (`salesDepartmentFk`) REFERENCES `vn`.`department` (`id`) ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + + +CREATE TABLE `bs`.`salesDepartmentEvolution` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `dated` date NOT NULL DEFAULT '0000-00-00', + `salesDepartmentFk` int(10) DEFAULT NULL, + `amount` decimal(10,3) NOT NULL DEFAULT 0.000, + `equalizationTax` decimal(10,3) NOT NULL DEFAULT 0.000, + `amountNewBorn` decimal(10,3) NOT NULL DEFAULT 0.000, + PRIMARY KEY (`id`), + KEY `salesDepartmentEvolution_salesDepartment` (`salesDepartmentFk`), + CONSTRAINT `salesDepartmentEvolution_salesDepartment_department_FK` FOREIGN KEY (`salesDepartmentFk`) + REFERENCES `vn`.`department` (`id`) ON UPDATE CASCADE +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci; + +RENAME TABLE vn.salespersonConfig TO vn.salesDepartmentConfig; + + +ALTER TABLE vn.company ADD IF NOT EXISTS phone varchar(15) DEFAULT NULL NULL; + +/* +- bs.clientDied_recalc está calculandose con workerMana se empezará a calcular por departmentMana +- HAY COMERCIALES QUE NO ESTAN EN LA TABLA WORKERMANA, ESTO IMPLICA QUE SE DESACTIVARANA AUNQUE DEJEN DE COMPRAR +- bs.carteras -> bs.portfolio +- bs.manaSpellers_actulize --> bs.manaSpellers_recalc +- vn.manaSpellersRequery --> vn.manaSpellers_requery +- bs.salesByclientSalesPerson_add --> bs.salesByClientDepartments_add // CALL en bs.vendedores_add_launcher +- revisar evento vn.clientsDisable hay que modificarlo para que mire el salesDepartmentFk y no el salesPersonFk +- Funciones, revisar donde se utilizan y eliminar su uso vn.client_getSalesPerson y vn.client_getSalesPersonByTicket +- vn.catalog_componentCalculate -> cambiar el calculo del componente mana, está calculandose con workerMana hay que cambiarlo para departmentMana +- crear evento vn.client_unassignSalesPerson que llame al proc vn.client_unassignSalesPerson y eliminar el evento y proc client_unassignSalesPerson +- vn.clientGreugeSpray está calculandose con workerMana hay que cambiarlo para departmentMana +- vn.workerDisable revisar el DELETE de clientProtected +- vn.newBornSales revisar vista +- vn.observationType revisar como insertar desde el fichero de version de myt y revisar todos los usos de salesPerson -> salesDepartment + +clientGreugeSpray -> revisar el número de parámetros. Es posible que se puedan eliminar los boleanos + +*/ \ No newline at end of file