intranet-queries/2011-10-20-view_ventas_con_recaudo.sql

43 lines
1.6 KiB
SQL

-- Documentos de venta que han sido cruzados con uno o más recaudos
-- No se detalla el documento recaudo
-- La fecha de pago debería coincidir con la fecha del último pago
CREATE
ALGORITHM = TEMPTABLE
VIEW view_ventas_con_recaudo
AS SELECT
suc.nombre_sucursal AS Branch_Office,
dv.id_documento AS Invoice_No,
dv.fecha AS Invoice_Date,
rec.fecha_vencimiento AS Invoice_Due_Date,
MAX(rec.fecha) AS Payment_Date,
cs.id_cliente AS ID_Customer,
cs.nombre_cliente AS Customer_Name,
SUM(dvi.cantidad * i.peso * (IF(dvi.valor>0,1,-1))) AS Invoice_qty_Kg,
SUM(dvi.valor) AS Amount,
"COP" AS Currency,
rec.id_documento AS Payment_Doc,
SUM(rec.valor) / COUNT(dvi.id_item) AS Payed_value,
MAX(rec.valor) AS Payed_value_confirmation
FROM
documento_ventas_has_item dvi
JOIN documento_ventas dv
ON ( dv.id_documento=dvi.id_documento AND dv.id_sucursal=dvi.id_sucursal )
JOIN recaudo rec
ON ( dv.id_documento = rec.id_documento_cruce AND dv.id_sucursal = rec.id_sucursal )
JOIN item i
ON ( dvi.id_item=i.id_item AND dvi.id_sucursal=i.id_sucursal )
JOIN cliente_has_sucursal cs
ON ( dv.id_sucursal=cs.id_sucursal AND dv.id_cliente=cs.id_cliente )
JOIN forma_pago fp
ON ( dv.id_formapago = fp.id_formapago AND dv.id_sucursal = fp.id_sucursal )
JOIN sucursal suc
ON ( dv.id_sucursal = suc.id_sucursal )
WHERE
YEAR(dv.fecha) >= 2008
AND LEFT(dv.id_documento,2) RLIKE 'F|D[^0-9MP]'
AND NOT (dv.id_cliente LIKE "999")
AND (rec.id_documento <> rec.id_documento_cruce)
GROUP BY
Branch_Office, Invoice_No