103 lines
2.8 KiB
SQL
103 lines
2.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bs`.`ventas_contables_add`(IN vYear INT, IN vMonth INT)
|
|
BEGIN
|
|
|
|
/**
|
|
* Reemplaza las ventas contables del último año.
|
|
* Es el origen de datos para el balance de Entradas
|
|
*
|
|
* @param vYear Año a reemplazar
|
|
* @param vMonth Mes a reemplazar
|
|
*
|
|
**/
|
|
|
|
DECLARE TIPO_PATRIMONIAL INT DEFAULT 188;
|
|
|
|
DELETE FROM bs.ventas_contables
|
|
WHERE year = vYear
|
|
AND month = vMonth;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_list;
|
|
CREATE TEMPORARY TABLE tmp.ticket_list
|
|
(PRIMARY KEY (Id_Ticket))
|
|
ENGINE = MEMORY
|
|
SELECT Id_Ticket
|
|
FROM vn2008.Tickets t
|
|
JOIN vn.invoiceOut io ON io.id = t.Factura
|
|
WHERE year(io.issued) = vYear
|
|
AND month(io.issued) = vMonth;
|
|
|
|
INSERT INTO bs.ventas_contables(year
|
|
, month
|
|
, venta
|
|
, grupo
|
|
, reino_id
|
|
, tipo_id
|
|
, empresa_id
|
|
, gasto)
|
|
|
|
SELECT vYear
|
|
, vMonth
|
|
, round(sum(Cantidad * Preu * (100 - m.Descuento)/100))
|
|
, IF(
|
|
e.empresa_grupo = e2.empresa_grupo
|
|
,1
|
|
,IF(e2.empresa_grupo,2,0)
|
|
) as grupo
|
|
, tp.reino_id
|
|
, a.tipo_id
|
|
, t.empresa_id
|
|
, a.expenseFk
|
|
+ IF(e.empresa_grupo = e2.empresa_grupo
|
|
,1
|
|
,IF(e2.empresa_grupo,2,0)
|
|
) * 100000
|
|
+ tp.reino_id * 1000 as Gasto
|
|
FROM vn2008.Movimientos m
|
|
JOIN vn2008.Tickets t on t.Id_Ticket = m.Id_Ticket
|
|
JOIN vn2008.Consignatarios cs on cs.Id_Consigna = t.Id_Consigna
|
|
JOIN vn2008.Clientes c on c.Id_Cliente = cs.Id_Cliente
|
|
JOIN tmp.ticket_list tt on tt.Id_Ticket = t.Id_Ticket
|
|
JOIN vn2008.Articles a on m.Id_Article = a.Id_Article
|
|
JOIN vn2008.empresa e on e.id = t.empresa_id
|
|
LEFT JOIN vn2008.empresa e2 on e2.Id_Cliente = c.Id_Cliente
|
|
JOIN vn2008.Tipos tp on tp.tipo_id = a.tipo_id
|
|
WHERE Cantidad <> 0
|
|
AND Preu <> 0
|
|
AND m.Descuento <> 100
|
|
AND a.tipo_id != TIPO_PATRIMONIAL
|
|
GROUP BY grupo, reino_id, tipo_id, empresa_id, Gasto;
|
|
|
|
INSERT INTO bs.ventas_contables(year
|
|
, month
|
|
, venta
|
|
, grupo
|
|
, reino_id
|
|
, tipo_id
|
|
, empresa_id
|
|
, gasto)
|
|
SELECT vYear
|
|
, vMonth
|
|
, sum(ts.quantity * ts.price)
|
|
, IF(
|
|
c.companyGroupFk = c2.companyGroupFk
|
|
,1
|
|
,IF(c2.companyGroupFk, 2, 0)
|
|
) as grupo
|
|
, NULL
|
|
, NULL
|
|
, t.companyFk
|
|
, 7050000000
|
|
FROM vn.ticketService ts
|
|
JOIN vn.ticket t ON ts.ticketFk = t.id
|
|
JOIN vn.address a on a.id = t.addressFk
|
|
JOIN vn.client cl on cl.id = a.clientFk
|
|
JOIN tmp.ticket_list tt on tt.Id_Ticket = t.id
|
|
JOIN vn.company c on c.id = t.companyFk
|
|
LEFT JOIN vn.company c2 on c2.clientFk = cl.id
|
|
GROUP BY grupo, t.companyFk ;
|
|
|
|
DROP TEMPORARY TABLE tmp.ticket_list;
|
|
END$$
|
|
DELIMITER ;
|