112 lines
4.3 KiB
SQL
112 lines
4.3 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`comercialesCompleto`(IN vWorker INT, vDate DATE)
|
|
BEGIN
|
|
DECLARE vAYearAgoStarted DATE DEFAULT DATE_FORMAT(TIMESTAMPADD(YEAR, - 1, vDate), '%Y-%m-01');
|
|
DECLARE vAYearAgoEnded DATE DEFAULT TIMESTAMPADD(YEAR, - 1, LAST_DAY(vDate));
|
|
|
|
CALL vn.worker_GetHierarchy(vWorker);
|
|
|
|
INSERT IGNORE INTO tmp.workerHierarchyList (workerFk)
|
|
SELECT wd2.workerFk
|
|
FROM vn.workerDepartment wd2
|
|
WHERE wd2.workerFk = vWorker;
|
|
|
|
-- Falta que en algunos casos solo tenga en cuenta los tipos afectados.
|
|
SELECT
|
|
c.Id_Cliente id_cliente,
|
|
c.Cliente cliente,
|
|
cr.recobro * 100 tarifa,
|
|
c.Telefono telefono,
|
|
c.movil,
|
|
c.POBLACION poblacion,
|
|
p.`name` provincia,
|
|
ROUND(f.futur, 2) futur,
|
|
c.Credito credito,
|
|
pm.`name` forma_pago,
|
|
ROUND(c365 / 12, 2) consumo_medio365,
|
|
ROUND(c365, 2) consumo365,
|
|
ROUND(CmLy.peso, 2) peso_mes_año_pasado,
|
|
ROUND(CmLy.peso * 1.19, 2) objetivo,
|
|
tr.CodigoTrabajador,
|
|
ROUND(mes_actual.consumo, 2) consumoMes,
|
|
ROUND(IFNULL(mes_actual.consumo, 0) - IFNULL(CmLy.peso * 1.19, 0), 2) como_lo_llevo,
|
|
DATE(LastTicket) ultimo_ticket,
|
|
dead.muerto,
|
|
g.Greuge,
|
|
cr.recobro
|
|
FROM
|
|
vn2008.Clientes c
|
|
LEFT JOIN
|
|
(SELECT g.Id_Cliente, CAST( SUM(Importe) as DECIMAL(12,2)) AS Greuge
|
|
FROM vn2008.Greuges g
|
|
JOIN vn.`client` c ON c.id = g.Id_Cliente
|
|
LEFT JOIN vn.worker w ON c.salesPersonFk = w.id
|
|
WHERE (c.salesPersonFk = vWorker OR w.bossFk = vWorker)
|
|
GROUP BY Id_Cliente
|
|
) g ON g.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
vn2008.province p ON p.province_id = c.province_id
|
|
JOIN
|
|
vn2008.pay_met pm ON pm.id = c.pay_met_id
|
|
LEFT JOIN
|
|
vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
LEFT JOIN
|
|
bi.claims_ratio cr on cr.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
(SELECT v.Id_Cliente, SUM(importe) c365 -- optimizat de 6s /5.3s/ 4.7s a 0.3/0.4/0.3
|
|
FROM bs.ventas v
|
|
JOIN vn2008.Clientes c ON c.Id_Cliente = v.Id_Cliente
|
|
WHERE v.fecha BETWEEN TIMESTAMPADD(YEAR, - 1, vDate) AND vDate
|
|
GROUP BY v.Id_Cliente) c365 ON c365.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
(SELECT
|
|
Id_Cliente, SUM(importe) consumo
|
|
FROM
|
|
bs.ventas v
|
|
INNER JOIN vn2008.Clientes c USING (Id_Cliente)
|
|
LEFT JOIN vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
WHERE
|
|
(c.Id_Trabajador = vWorker OR tr.boss = vWorker)
|
|
AND (v.fecha BETWEEN TIMESTAMPADD(DAY, - DAY(vDate) + 1, vDate) AND TIMESTAMPADD(DAY, - 1, vDate))
|
|
GROUP BY Id_Cliente) mes_actual ON mes_actual.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
(SELECT t.Id_Cliente, SUM(m.preu * m.Cantidad * (1 - m.Descuento / 100)) futur
|
|
FROM vn2008.Tickets t
|
|
JOIN vn2008.Clientes c ON c.Id_Cliente = t.Id_Cliente
|
|
JOIN vn2008.Movimientos m ON m.Id_Ticket = t.Id_Ticket
|
|
LEFT JOIN vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
WHERE
|
|
(c.Id_Trabajador = vWorker OR tr.boss = vWorker)
|
|
AND t.Fecha BETWEEN vDate AND util.dayEnd(LAST_DAY(vDate))
|
|
GROUP BY Id_Cliente) f ON c.Id_Cliente = f.Id_Cliente
|
|
LEFT JOIN
|
|
(SELECT MAX(t.Fecha) LastTicket, c.Id_Cliente
|
|
FROM vn2008.Tickets t
|
|
JOIN vn2008.Clientes c ON c.Id_cliente = t.Id_Cliente
|
|
LEFT JOIN vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
WHERE
|
|
(c.Id_Trabajador = vWorker OR tr.boss = vWorker)
|
|
GROUP BY t.Id_Cliente) LastTicket ON LastTicket.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
(
|
|
SELECT SUM(importe) peso, c.Id_Cliente
|
|
FROM bs.ventas v
|
|
JOIN vn2008.Clientes c ON c.Id_Cliente = v.Id_Cliente
|
|
LEFT JOIN vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
WHERE fecha BETWEEN vAYearAgoStarted and vAYearAgoEnded
|
|
AND (c.Id_Trabajador = vWorker OR tr.boss = vWorker)
|
|
GROUP BY c.Id_Cliente) CmLy ON CmLy.Id_Cliente = c.Id_Cliente
|
|
LEFT JOIN
|
|
(SELECT c.Id_Cliente,
|
|
IF(MAX(Fecha) < DATE_FORMAT(TIMESTAMPADD(MONTH, - 1, vDate), '%Y- %m-01'), TRUE, FALSE) muerto
|
|
FROM vn2008.Facturas f
|
|
JOIN vn2008.Clientes c ON c.Id_cliente = f.Id_Cliente
|
|
LEFT JOIN vn2008.Trabajadores tr ON c.Id_Trabajador = tr.Id_Trabajador
|
|
WHERE (c.Id_Trabajador = vWorker OR tr.boss = vWorker)
|
|
GROUP BY Id_Cliente) dead ON dead.Id_Cliente = c.Id_Cliente
|
|
JOIN tmp.workerHierarchyList s ON s.workerFk = c.Id_Trabajador;
|
|
|
|
DROP TEMPORARY TABLE tmp.workerHierarchyList;
|
|
END$$
|
|
DELIMITER ;
|