118 lines
3.5 KiB
SQL
118 lines
3.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`supplierStatement`(vSupplierFk INT, vCurrencyFk INT, vCompanyFk INT, vOrderBy VARCHAR(15), vOnlyConciliated BIT)
|
|
BEGIN
|
|
SET @saldo_eur:= 0;
|
|
SET @saldo_div:= 0;
|
|
select vOnlyConciliated;
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.supplierStatement;
|
|
|
|
CREATE TEMPORARY TABLE tmp.supplierStatement ENGINE = MEMORY
|
|
SELECT
|
|
*,
|
|
@saldo_eur:= round(@saldo_eur + IFNULL(Pago_Euros, 0) - IFNULL(Fac_Euros, 0) ,2 ) AS saldo_eur,
|
|
@saldo_div:= round(@saldo_div + IFNULL(Pago_Divisas, 0) - IFNULL(Fac_Divisas, 0) ,2 ) AS saldo_div
|
|
FROM
|
|
(SELECT * FROM
|
|
(SELECT
|
|
NULL as banco_id,
|
|
r.empresa_id,
|
|
r.serie,
|
|
r.id,
|
|
CASE
|
|
WHEN vOrderBy = 'issued' THEN r.fecha
|
|
WHEN vOrderBy = 'bookEntried' THEN r.bookEntried
|
|
WHEN vOrderBy = 'booked' THEN r.dateBooking
|
|
WHEN vOrderBy = 'dueDate' THEN rv.fecha
|
|
END AS fecha,
|
|
CONCAT('S/Fra ', r.sref) sref,
|
|
if(r.moneda_id > 1,round(sum(divisa) / sum(cantidad),3),NULL) val_cambio,
|
|
CAST(sum(cantidad) as DECIMAL(10,2)) as Fac_Euros,
|
|
CAST(sum(divisa) as DECIMAL(10,2)) as Fac_Divisas,
|
|
NULL AS Pago_Euros,
|
|
NULL AS Pago_Divisas,
|
|
r.moneda_id,
|
|
r.contabilizada,
|
|
Moneda,
|
|
NULL as pago_sdc_id,
|
|
'invoiceIn' statementType
|
|
FROM
|
|
recibida r
|
|
JOIN recibida_vencimiento rv on rv.recibida_id = r.id
|
|
JOIN Monedas m on m.Id_Moneda = r.moneda_id
|
|
WHERE
|
|
r.fecha > '2014-12-31'
|
|
AND r.proveedor_id = vSupplierFk
|
|
AND vCurrencyFk IN (r.moneda_id, 0)
|
|
AND vCompanyFk IN (r.empresa_id,0)
|
|
AND (vOnlyConciliated = r.contabilizada OR NOT vOnlyConciliated)
|
|
GROUP BY rv.id
|
|
|
|
UNION ALL
|
|
SELECT
|
|
p.id_banco,
|
|
p.empresa_id,
|
|
NULL,
|
|
p.id,
|
|
CASE
|
|
WHEN vOrderBy = 'issued' THEN p.Fecha
|
|
WHEN vOrderBy = 'bookEntried' THEN p.Fecha
|
|
WHEN vOrderBy = 'booked' THEN p.Fecha
|
|
WHEN vOrderBy = 'dueDate' THEN p.dueDated
|
|
END AS fecha,
|
|
CONCAT(IFNULL(name, ''), IF(pre.concepto <> '', CONCAT(' : ', pre.concepto), '')),
|
|
if(p.id_moneda > 1, p.divisa / importe, NULL) tip_cambio,
|
|
NULL,
|
|
NULL,
|
|
p.importe,
|
|
p.divisa,
|
|
p.id_moneda,
|
|
p.conciliado,
|
|
Moneda,
|
|
NULL as pago_sdc_id,
|
|
'payment' statementType
|
|
FROM
|
|
pago p
|
|
LEFT JOIN Monedas ON Monedas.Id_Moneda = p.id_moneda
|
|
LEFT JOIN Bancos ON p.id_banco = Bancos.Id_banco
|
|
LEFT JOIN pay_met pm ON p.pay_met_id = pm.id
|
|
LEFT JOIN Pagares pre ON pre.pago_id = p.id
|
|
WHERE
|
|
Fecha > '2014-12-31'
|
|
AND p.Id_Proveedor = vSupplierFk
|
|
AND vCurrencyFk IN (p.id_moneda,0)
|
|
AND vCompanyFk IN (p.empresa_id,0)
|
|
AND (vOnlyConciliated = p.conciliado OR NOT vOnlyConciliated)
|
|
UNION ALL
|
|
SELECT
|
|
NULL,
|
|
companyFk,
|
|
NULL,
|
|
se.id,
|
|
CASE
|
|
WHEN vOrderBy = 'issued' THEN se.dated
|
|
WHEN vOrderBy = 'bookEntried' THEN se.dated
|
|
WHEN vOrderBy = 'booked' THEN se.dated
|
|
WHEN vOrderBy = 'dueDate' THEN se.dueDated
|
|
END AS fecha,
|
|
se.description,
|
|
1 tip_cambio,
|
|
amount,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
currencyFk,
|
|
isConciliated,
|
|
c.`code`,
|
|
NULL,
|
|
'expense' statementType
|
|
FROM vn.supplierExpense se
|
|
JOIN vn.currency c on c.id= se.currencyFk
|
|
WHERE se.supplierFk = vSupplierFk
|
|
AND vCurrencyFk IN (se.currencyFk,0)
|
|
AND vCompanyFk IN (se.companyFk,0)
|
|
AND (vOnlyConciliated = se.isConciliated OR NOT vOnlyConciliated)
|
|
) AS SUB
|
|
ORDER BY (fecha is null and NOT contabilizada),fecha, IF(vOrderBy = 'dueDate', id, NULL) LIMIT 10000000000000000000) t;
|
|
END$$
|
|
DELIMITER ;
|