71 lines
2.5 KiB
SQL
71 lines
2.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`quadre_clientes_detalle`(IN idC INT, IN idE INT, IN datFEC DATETIME)
|
|
BEGIN
|
|
|
|
DECLARE datSTART DATE;
|
|
|
|
SET datSTART = util.firstDayOfYear(datFEC);
|
|
SET datFEC = TIMESTAMP(datFEC,'23:59:59');
|
|
|
|
-- Creamos una tabla para almacenar las facturas del cliente, junto con el numero de veces que se repite.
|
|
DROP TEMPORARY TABLE IF EXISTS qFACTURAS;
|
|
|
|
CREATE TEMPORARY TABLE qFACTURAS
|
|
(Fecha DATETIME,
|
|
TPVcount INT,
|
|
Factura DECIMAL(10,2) SIGNED,
|
|
Recibo DECIMAL(10,2) SIGNED,
|
|
CPcount INT,
|
|
Debe DECIMAL(10,2) SIGNED,
|
|
Haber DECIMAL(10,2) SIGNED,
|
|
Control INT DEFAULT 0,
|
|
PRIMARY KEY(Fecha, TPVcount, Factura, Recibo, CPcount, Debe, Haber))
|
|
ENGINE = InnoDB
|
|
;
|
|
|
|
-- Insertamos las facturas y los recibos de gestion.
|
|
INSERT INTO qFACTURAS
|
|
|
|
SELECT Fecha, COUNT(*) as TPVcount, round(Importe,2) as Factura, 0 as Recibo, COUNT(*)as CPcount,round(Importe,2) as Debe, 0 as Haber, 1 as Control
|
|
FROM Facturas
|
|
WHERE Id_Cliente = idC AND empresa_id = idE AND Fecha BETWEEN datSTART AND datFEC
|
|
GROUP BY Fecha, round(Importe,2)
|
|
UNION ALL
|
|
SELECT Fechacobro as Fecha, COUNT(*) as TPVcount, 0 as Factura, round(Entregado,2) as Recibo,COUNT(*) as CPCount, 0 as Debe, round(Entregado,2) as Haber, 3 as Control
|
|
FROM Recibos
|
|
WHERE Id_Cliente = idC AND empresa_id = idE AND Fechacobro BETWEEN datSTART AND datFEC
|
|
GROUP BY Fechacobro, round(Entregado,2);
|
|
|
|
-- Insertamos los asientos de contabilidad, marcando con control = -1 las repetidas.
|
|
INSERT INTO qFACTURAS
|
|
SELECT *
|
|
FROM (
|
|
SELECT Fecha, COUNT(*) as TPVcount, round(Eurodebe,2) as Factura, round(Eurohaber,2) as Recibo, COUNT(*) as CPcount, round(Eurodebe,2) as Debe, round(Eurohaber,2) as Haber, 2 as Control
|
|
FROM bi.XDiario_ALL XD
|
|
JOIN Clientes C ON C.Cuenta = XD.SUBCTA
|
|
WHERE Id_Cliente = idC AND empresa_id = idE AND Fecha BETWEEN datSTART AND datFEC
|
|
AND (Eurodebe <> 0 OR Eurohaber <>0)
|
|
GROUP BY Fecha, round(Eurodebe,2), round(Eurohaber,2)
|
|
) sub
|
|
|
|
ON DUPLICATE KEY UPDATE Control = -1;
|
|
|
|
|
|
|
|
-- Eliminamos las repetidas
|
|
-- DELETE FROM qFACTURAS WHERE Control = -1;
|
|
|
|
-- Arreglamos las buenas
|
|
UPDATE qFACTURAS SET TPVcount = 0, Factura = 0, Recibo = 0 WHERE Control = 2;
|
|
UPDATE qFACTURAS SET CPcount = 0, Debe = 0, Haber = 0 WHERE Control IN (1,3);
|
|
|
|
-- Mostramos el resultado
|
|
SELECT *, @saldo := @saldo + TPVcount * (Factura + Recibo) - CPCount * ( Debe + Haber ) as Saldo
|
|
FROM qFACTURAS
|
|
JOIN (SELECT @saldo := 0) truqui ;
|
|
DROP TEMPORARY TABLE IF EXISTS qFACTURAS;
|
|
|
|
|
|
END$$
|
|
DELIMITER ;
|