151 lines
4.1 KiB
SQL
151 lines
4.1 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`indicatorsUpdate`(vDated DATE)
|
|
BEGIN
|
|
|
|
DECLARE oneYearBefore DATE DEFAULT TIMESTAMPADD(YEAR,-1, vDated);
|
|
DECLARE twoMonthsBefore DATE DEFAULT TIMESTAMPADD(DAY,-60, vDated);
|
|
DECLARE oneMonthBefore DATE DEFAULT TIMESTAMPADD(DAY,-30, vDated);
|
|
DECLARE vWeek INT;
|
|
|
|
REPLACE indicators(updated)
|
|
VALUES(vDated);
|
|
|
|
-- Ventas totales del ultimo año
|
|
UPDATE indicators
|
|
SET lastYearSales =
|
|
(SELECT SUM(importe + recargo)
|
|
FROM ventas v
|
|
JOIN vn2008.empresa e ON e.id = v.empresa_id
|
|
JOIN vn2008.empresa_grupo eg ON eg.empresa_grupo_id = e.empresa_grupo
|
|
WHERE fecha BETWEEN oneYearBefore AND vDated
|
|
AND eg.grupo = 'Verdnatura'
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Greuge total acumulado
|
|
UPDATE indicators
|
|
SET totalGreuge =
|
|
(SELECT SUM(amount)
|
|
FROM vn.greuge
|
|
WHERE shipped <= vDated
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Tasa de morosidad con respecto a las ventas del último mes
|
|
UPDATE indicators
|
|
SET latePaymentRate =
|
|
(SELECT SUM(amount)
|
|
FROM bi.defaulters
|
|
WHERE date = vDated AND amount > 0)
|
|
/
|
|
(SELECT SUM(importe + recargo)
|
|
FROM ventas
|
|
WHERE fecha BETWEEN oneMonthBefore AND vDated)
|
|
WHERE updated = vDated;
|
|
|
|
-- Número de trabajadores activos
|
|
UPDATE indicators
|
|
SET countEmployee =
|
|
(SELECT CAST(SUM(ct.hoursWeek) / 40 AS DECIMAL (10, 2))
|
|
FROM vn.business b
|
|
JOIN vn.calendarType ct ON ct.id = b.calendarTypeFk
|
|
WHERE vDated BETWEEN b.started AND IFNULL(b.ended, vDated)
|
|
AND b.companyCodeFk = 'VNL'
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Maná medio acumulado por comercial
|
|
UPDATE indicators
|
|
SET averageMana =
|
|
(SELECT AVG(amount)
|
|
FROM vn.workerMana
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Número de clientes que han comprado en los últimos 30 dias
|
|
UPDATE indicators
|
|
SET lastMonthActiveClients =
|
|
(SELECT COUNT(DISTINCT t.clientFk)
|
|
FROM vn.ticket t
|
|
WHERE t.shipped BETWEEN oneMonthBefore AND vDated
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Número de clientes que no han comprado en los últimos 30 dias, pero compraron en los 30 anteriores
|
|
UPDATE indicators
|
|
SET lastMonthLostClients =
|
|
(SELECT COUNT(lm.clientFk)
|
|
FROM
|
|
(SELECT DISTINCT t.clientFk
|
|
FROM vn.ticket t
|
|
WHERE t.shipped BETWEEN oneMonthBefore AND vDated
|
|
) cm
|
|
RIGHT JOIN
|
|
(SELECT DISTINCT t.clientFk
|
|
FROM vn.ticket t
|
|
WHERE t.shipped >= twoMonthsBefore
|
|
AND t.shipped < oneMonthBefore
|
|
) lm ON lm.clientFk = cm.clientFk
|
|
WHERE cm.clientFk IS NULL
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Número de clientes que han comprado en los últimos 30 dias, pero no compraron en los 30 anteriores
|
|
UPDATE indicators
|
|
SET lastMonthNewClients =
|
|
(SELECT COUNT(cm.clientFk)
|
|
FROM
|
|
(SELECT DISTINCT t.clientFk
|
|
FROM vn.ticket t
|
|
WHERE t.shipped BETWEEN oneMonthBefore AND vDated
|
|
) cm
|
|
LEFT JOIN
|
|
(SELECT DISTINCT t.clientFk
|
|
FROM vn.ticket t
|
|
WHERE t.shipped >= twoMonthsBefore
|
|
AND t.shipped < oneMonthBefore
|
|
) lm ON lm.clientFk = cm.clientFk
|
|
WHERE lm.clientFk IS NULL
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Porcentaje de autopedidos sobre los pedidos totales
|
|
UPDATE indicators
|
|
SET lastMonthWebBuyingRate =
|
|
(SELECT (SUM(source_app != '') - SUM(source_app = 'TPV')) / SUM(source_app != '')
|
|
FROM hedera.`order`
|
|
WHERE date_send BETWEEN oneMonthBefore AND vDated
|
|
)
|
|
WHERE updated = vDated;
|
|
|
|
-- Cálculo de las ventas agrupado por semanas
|
|
SELECT week INTO vWeek
|
|
FROM vn.time
|
|
WHERE dated = vDated;
|
|
|
|
TRUNCATE salesByWeek;
|
|
|
|
INSERT INTO salesByWeek (week, year, sales)
|
|
SELECT t.week, t.year, SUM(v.importe + v.recargo) sales
|
|
FROM ventas v
|
|
LEFT JOIN vn.time t ON t.dated = fecha
|
|
GROUP BY t.week, t.year
|
|
ORDER BY t.week, t.year;
|
|
|
|
-- Indicador Ventas semana actual
|
|
UPDATE indicators i
|
|
JOIN salesByWeek s ON s.week= vWeek
|
|
AND s.year = YEAR(vDated)
|
|
SET i.thisWeekSales = s.sales
|
|
WHERE updated = vDated;
|
|
|
|
-- Indicador ventas semana actual en el año pasado
|
|
UPDATE indicators i
|
|
JOIN salesByWeek s ON s.week = vWeek
|
|
AND s.year = YEAR(vDated)-1
|
|
SET i.lastYearWeekSales = s.sales
|
|
WHERE updated = vDated;
|
|
|
|
END$$
|
|
DELIMITER ;
|