salix/db/routines/bi/procedures/analisis_ventas_evolution_a...

233 lines
6.2 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`analisis_ventas_evolution_add`()
BEGIN
DECLARE vPreviousPeriod INT;
DECLARE vCurrentPeriod INT;
DECLARE vLastPeriod INT;
DECLARE vMinPeriod INT DEFAULT 201400;
DECLARE vMaxPeriod INT;
DECLARE vYear INT;
DECLARE vWeek INT;
SELECT t.period INTO vMaxPeriod
FROM vn.`time` t
WHERE t.dated = util.VN_CURDATE();
-- Almacen
SET vCurrentPeriod = IFNULL(vLastPeriod, vMinPeriod);
WHILE vCurrentPeriod < vMaxPeriod
DO
SELECT MAX(Periodo) INTO vPreviousPeriod
FROM analisis_ventas_almacen_evolution
WHERE Periodo < vMaxPeriod;
SELECT MIN(period) INTO vCurrentPeriod
FROM vn.time
WHERE period > vPreviousPeriod;
SET vYear = FLOOR(vCurrentPeriod / 100);
SET vWeek = vCurrentPeriod - (vYear * 100);
DELETE FROM analisis_ventas_almacen_evolution
WHERE Periodo = vCurrentPeriod;
REPLACE analisis_ventas_almacen_evolution(Almacen, Ventas, Semana,Año, Periodo)
SELECT Almacen, SUM(Ventas) AS Ventas, vWeek, vYear, vCurrentPeriod
FROM (
SELECT almacen, SUM(Importe) AS Ventas
FROM analisis_ventas
WHERE vYear = Año
AND vWeek = Semana
GROUP BY almacen
UNION ALL
SELECT almacen, - SUM(Importe) AS Ventas
FROM analisis_ventas
WHERE vYear - 1 = Año
AND vWeek = Semana
GROUP BY almacen
UNION ALL
SELECT Almacen, Ventas
FROM analisis_ventas_almacen_evolution
WHERE Periodo = vPreviousPeriod
) sub
GROUP BY Almacen;
END WHILE;
-- Reino
SET vCurrentPeriod = vMinPeriod;
WHILE vCurrentPeriod < vMaxPeriod
DO
SELECT MAX(periodo) INTO vPreviousPeriod
FROM analisis_ventas_reino_evolution
WHERE periodo < vMaxPeriod;
SELECT MIN(period) INTO vCurrentPeriod
FROM vn.time
WHERE period > vPreviousPeriod;
SET vYear = FLOOR(vCurrentPeriod / 100);
SET vWeek = vCurrentPeriod - (vYear * 100);
DELETE FROM analisis_ventas_reino_evolution
WHERE Periodo = vCurrentPeriod;
REPLACE analisis_ventas_reino_evolution(reino, ventas, semana,año, periodo)
SELECT reino, SUM(ventas) AS ventas, vWeek, vYear, vCurrentPeriod
FROM (
SELECT Reino, SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear = Año
AND vWeek = Semana
GROUP BY Reino
UNION ALL
SELECT Reino, - SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear - 1 = Año
AND vWeek = Semana
GROUP BY Reino
UNION ALL
SELECT reino, ventas
FROM analisis_ventas_reino_evolution
WHERE Periodo = vPreviousPeriod
) sub
GROUP BY reino;
END WHILE;
-- Provincia
SET vCurrentPeriod = vMinPeriod;
WHILE vCurrentPeriod < vMaxPeriod
DO
SELECT MAX(periodo) INTO vPreviousPeriod
FROM analisis_ventas_provincia_evolution
WHERE periodo < vMaxPeriod;
SELECT MIN(period) INTO vCurrentPeriod
FROM vn.time
WHERE period > vPreviousPeriod;
SET vYear = FLOOR(vCurrentPeriod / 100);
SET vWeek = vCurrentPeriod - (vYear * 100);
DELETE FROM analisis_ventas_provincia_evolution
WHERE Periodo = vCurrentPeriod;
REPLACE analisis_ventas_provincia_evolution(provincia, countryCode, ventas, semana,año, periodo)
SELECT Provincia, code, SUM(ventas) AS ventas, vWeek, vYear, vCurrentPeriod
FROM (
SELECT a.Provincia, c.code, SUM(a.Importe) AS ventas
FROM analisis_ventas a
JOIN vn.province p ON p.name= a.provincia
JOIN vn.country c ON c.id = p.countryFk
WHERE vYear = a.Año
AND vWeek = a.Semana
GROUP BY a.Provincia
UNION ALL
SELECT a.Provincia, c.code, - SUM(a.Importe) AS ventas
FROM analisis_ventas a
JOIN vn.province p ON p.name= a.provincia
JOIN vn.country c ON c.id = p.countryFk
WHERE vYear - 1 = a.Año
AND vWeek = a.Semana
GROUP BY a.Provincia
UNION ALL
SELECT a.provincia,a.countryCode, a.ventas
FROM analisis_ventas_provincia_evolution a
WHERE a.Periodo = vPreviousPeriod
) sub
GROUP BY Provincia;
END WHILE;
-- Vista
SET vCurrentPeriod = vMinPeriod;
WHILE vCurrentPeriod < vMaxPeriod
DO
SELECT MAX(periodo) INTO vPreviousPeriod
FROM analisis_ventas_vista_evolution
WHERE periodo < vMaxPeriod;
SELECT MIN(period) INTO vCurrentPeriod
FROM vn.time
WHERE period > vPreviousPeriod;
SET vYear = FLOOR(vCurrentPeriod / 100);
SET vWeek = vCurrentPeriod - (vYear * 100);
DELETE FROM analisis_ventas_vista_evolution
WHERE Periodo = vCurrentPeriod;
REPLACE analisis_ventas_vista_evolution(vista, ventas, semana,año, periodo)
SELECT vista, SUM(ventas) AS ventas, vWeek, vYear, vCurrentPeriod
FROM (
SELECT Vista, SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear = Año
AND vWeek = Semana
GROUP BY Vista
UNION ALL
SELECT Vista, - SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear - 1 = Año
AND vWeek = Semana
GROUP BY Vista
UNION ALL
SELECT vista, ventas
FROM analisis_ventas_vista_evolution
WHERE Periodo = vPreviousPeriod
) sub
GROUP BY Vista;
END WHILE;
-- Vendedor
SET vCurrentPeriod = vMinPeriod;
WHILE vCurrentPeriod < vMaxPeriod
DO
SELECT MAX(periodo) INTO vPreviousPeriod
FROM analisis_ventas_vendedor_evolution
WHERE periodo < vMaxPeriod;
SELECT MIN(period) INTO vCurrentPeriod
FROM vn.time
WHERE period > vPreviousPeriod;
SET vYear = FLOOR(vCurrentPeriod / 100);
SET vWeek = vCurrentPeriod - (vYear * 100);
DELETE FROM analisis_ventas_vendedor_evolution
WHERE Periodo = vCurrentPeriod;
REPLACE analisis_ventas_vendedor_evolution(vendedor, ventas, semana,año, periodo)
SELECT Comercial AS vendedor, SUM(ventas) AS ventas, vWeek, vYear, vCurrentPeriod
FROM (
SELECT Comercial, SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear = Año
AND vWeek = Semana
GROUP BY Comercial
UNION ALL
SELECT Comercial, - SUM(Importe) AS ventas
FROM analisis_ventas
WHERE vYear - 1 = Año
AND vWeek = Semana
GROUP BY Comercial
UNION ALL
SELECT vendedor, ventas
FROM analisis_ventas_vendedor_evolution
WHERE Periodo = vPreviousPeriod
) sub
GROUP BY vendedor;
END WHILE;
END$$
DELIMITER ;