2024-01-15 11:31:03 +00:00
|
|
|
DELIMITER $$
|
|
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`balance_create`(
|
|
|
|
IN vStartingMonth INT,
|
|
|
|
IN vEndingMonth INT,
|
|
|
|
IN vCompany INT,
|
|
|
|
IN vIsConsolidated BOOLEAN,
|
|
|
|
IN vInterGroupSalesIncluded BOOLEAN)
|
|
|
|
BEGIN
|
|
|
|
DECLARE intGAP INT DEFAULT 7;
|
|
|
|
DECLARE vYears INT DEFAULT 2;
|
|
|
|
DECLARE vYear TEXT;
|
|
|
|
DECLARE vOneYearAgo TEXT;
|
|
|
|
DECLARE vTwoYearsAgo TEXT;
|
|
|
|
DECLARE vQuery TEXT;
|
|
|
|
DECLARE vConsolidatedGroup INT;
|
|
|
|
DECLARE vStartingDate DATE DEFAULT '2020-01-01';
|
|
|
|
DECLARE vCurYear INT DEFAULT YEAR(util.VN_CURDATE());
|
|
|
|
DECLARE vStartingYear INT DEFAULT vCurYear - 2;
|
|
|
|
DECLARE vTable TEXT;
|
|
|
|
|
|
|
|
SET vTable = util.quoteIdentifier('balance_nest_tree');
|
|
|
|
SET vYear = util.quoteIdentifier(vCurYear);
|
|
|
|
SET vOneYearAgo = util.quoteIdentifier(vCurYear-1);
|
|
|
|
SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2);
|
|
|
|
|
|
|
|
-- Solicitamos la tabla tmp.nest, como base para el balance
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.nest;
|
|
|
|
|
|
|
|
EXECUTE IMMEDIATE CONCAT(
|
|
|
|
'CREATE TEMPORARY TABLE tmp.nest
|
|
|
|
SELECT node.id
|
|
|
|
,CONCAT( REPEAT(REPEAT(" ",?), COUNT(parent.id) - 1), node.name) AS name
|
|
|
|
,node.lft
|
|
|
|
,node.rgt
|
|
|
|
,COUNT(parent.id) - 1 as depth
|
|
|
|
,cast((node.rgt - node.lft - 1) / 2 as DECIMAL) as sons
|
|
|
|
FROM ', vTable, ' AS node,
|
|
|
|
', vTable, ' AS parent
|
|
|
|
WHERE node.lft BETWEEN parent.lft AND parent.rgt
|
|
|
|
GROUP BY node.id
|
|
|
|
ORDER BY node.lft')
|
|
|
|
USING intGAP;
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.balance;
|
|
|
|
CREATE TEMPORARY TABLE tmp.balance
|
|
|
|
SELECT * FROM tmp.nest;
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_receptoras;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_emisoras;
|
|
|
|
|
|
|
|
SELECT empresa_grupo INTO vConsolidatedGroup
|
|
|
|
FROM empresa
|
|
|
|
WHERE id = vCompany;
|
|
|
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.empresas_receptoras
|
|
|
|
SELECT id as empresa_id
|
|
|
|
FROM vn2008.empresa
|
|
|
|
WHERE id = vCompany
|
|
|
|
OR empresa_grupo = IF(vIsConsolidated, vConsolidatedGroup, NULL);
|
|
|
|
|
|
|
|
CREATE TEMPORARY TABLE tmp.empresas_emisoras
|
|
|
|
SELECT Id_Proveedor as empresa_id FROM vn2008.Proveedores p;
|
|
|
|
|
|
|
|
IF vInterGroupSalesIncluded = FALSE THEN
|
|
|
|
|
|
|
|
DELETE ee.*
|
|
|
|
FROM tmp.empresas_emisoras ee
|
|
|
|
JOIN vn2008.empresa e on e.id = ee.empresa_id
|
|
|
|
WHERE e.empresa_grupo = vConsolidatedGroup;
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
-- Se calculan las facturas que intervienen, para luego poder servir el desglose desde aqui
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.balance_desglose;
|
|
|
|
CREATE TEMPORARY TABLE tmp.balance_desglose
|
|
|
|
SELECT er.empresa_id receptora_id,
|
|
|
|
ee.empresa_id emisora_id,
|
|
|
|
year(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `year`,
|
|
|
|
month(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `month`,
|
|
|
|
gastos_id Id_Gasto,
|
|
|
|
SUM(bi) importe
|
|
|
|
FROM recibida r
|
|
|
|
JOIN recibida_iva ri on ri.recibida_id = r.id
|
|
|
|
JOIN tmp.empresas_receptoras er on er.empresa_id = r.empresa_id
|
|
|
|
JOIN tmp.empresas_emisoras ee ON ee.empresa_id = r.proveedor_id
|
|
|
|
WHERE IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha)) >= vStartingDate
|
|
|
|
AND r.contabilizada
|
|
|
|
GROUP BY Id_Gasto, year, month, emisora_id, receptora_id;
|
|
|
|
|
|
|
|
INSERT INTO tmp.balance_desglose(
|
|
|
|
receptora_id,
|
|
|
|
emisora_id,
|
|
|
|
year,
|
|
|
|
month,
|
|
|
|
Id_Gasto,
|
|
|
|
importe)
|
|
|
|
SELECT gr.empresa_id,
|
|
|
|
gr.empresa_id,
|
|
|
|
year,
|
|
|
|
month,
|
|
|
|
Id_Gasto,
|
|
|
|
SUM(importe)
|
|
|
|
FROM gastos_resumen gr
|
|
|
|
JOIN tmp.empresas_receptoras er on gr.empresa_id = er.empresa_id
|
|
|
|
WHERE year >= vStartingYear
|
|
|
|
AND month BETWEEN vStartingMonth AND vEndingMonth
|
|
|
|
GROUP BY Id_Gasto, year, month, gr.empresa_id;
|
|
|
|
|
|
|
|
DELETE FROM tmp.balance_desglose
|
|
|
|
WHERE month < vStartingMonth
|
|
|
|
OR month > vEndingMonth;
|
|
|
|
|
|
|
|
-- Ahora el balance
|
|
|
|
EXECUTE IMMEDIATE CONCAT(
|
|
|
|
'ALTER TABLE tmp.balance
|
|
|
|
ADD COLUMN ', vTwoYearsAgo ,' INT(10) NULL ,
|
|
|
|
ADD COLUMN ', vOneYearAgo ,' INT(10) NULL ,
|
|
|
|
ADD COLUMN ', vYear,' INT(10) NULL ,
|
|
|
|
ADD COLUMN Id_Gasto VARCHAR(10) NULL,
|
|
|
|
ADD COLUMN Gasto VARCHAR(45) NULL');
|
|
|
|
|
|
|
|
-- Añadimos los gastos, para facilitar el formulario
|
|
|
|
UPDATE tmp.balance b
|
|
|
|
JOIN vn2008.balance_nest_tree bnt on bnt.id = b.id
|
2024-02-05 08:02:31 +00:00
|
|
|
JOIN (SELECT id Id_Gasto, name Gasto
|
|
|
|
FROM vn.expense
|
|
|
|
GROUP BY id) g ON g.Id_Gasto = bnt.Id_Gasto COLLATE utf8_general_ci
|
2024-01-15 11:31:03 +00:00
|
|
|
SET b.Id_Gasto = g.Id_Gasto COLLATE utf8_general_ci
|
|
|
|
, b.Gasto = g.Gasto COLLATE utf8_general_ci ;
|
|
|
|
|
|
|
|
-- Rellenamos los valores de primer nivel, los que corresponden a los gastos simples
|
|
|
|
WHILE vYears >= 0 DO
|
|
|
|
SET vQuery = CONCAT(
|
|
|
|
'UPDATE tmp.balance b
|
|
|
|
JOIN
|
|
|
|
(SELECT Id_Gasto, SUM(Importe) as Importe
|
|
|
|
FROM tmp.balance_desglose
|
|
|
|
WHERE year = ?
|
|
|
|
GROUP BY Id_Gasto
|
|
|
|
) sub on sub.Id_Gasto = b.Id_Gasto COLLATE utf8_general_ci
|
|
|
|
SET ', util.quoteIdentifier(vCurYear - vYears), ' = - Importe');
|
|
|
|
|
|
|
|
EXECUTE IMMEDIATE vQuery
|
|
|
|
USING vCurYear - vYears;
|
|
|
|
|
|
|
|
SET vYears = vYears - 1;
|
|
|
|
END WHILE;
|
|
|
|
|
|
|
|
-- Añadimos las ventas
|
|
|
|
EXECUTE IMMEDIATE CONCAT(
|
|
|
|
'UPDATE tmp.balance b
|
|
|
|
JOIN (
|
|
|
|
SELECT SUM(IF(year = ?, venta, 0)) y2,
|
|
|
|
SUM(IF(year = ?, venta, 0)) y1,
|
|
|
|
SUM(IF(year = ?, venta, 0)) y0,
|
|
|
|
c.Gasto
|
|
|
|
FROM bs.ventas_contables c
|
|
|
|
JOIN tmp.empresas_receptoras er on er.empresa_id = c.empresa_id
|
|
|
|
WHERE month BETWEEN ? AND ?
|
|
|
|
GROUP BY c.Gasto
|
|
|
|
) sub ON sub.Gasto = b.Id_Gasto COLLATE utf8_general_ci
|
|
|
|
SET b.', vTwoYearsAgo, '= IFNULL(b.', vTwoYearsAgo, ', 0) + sub.y2,
|
|
|
|
b.', vOneYearAgo, '= IFNULL(b.', vOneYearAgo, ', 0) + sub.y1,
|
|
|
|
b.', vYear, '= IFNULL(b.', vYear, ', 0) + sub.y0')
|
|
|
|
USING vCurYear-2,
|
|
|
|
vCurYear-1,
|
|
|
|
vCurYear,
|
|
|
|
vStartingMonth,
|
|
|
|
vEndingMonth;
|
|
|
|
|
|
|
|
-- Ventas intra grupo
|
|
|
|
IF NOT vInterGroupSalesIncluded THEN
|
|
|
|
|
|
|
|
SELECT lft, rgt INTO @grupoLft, @grupoRgt
|
|
|
|
FROM tmp.balance b
|
|
|
|
WHERE TRIM(b.`name`) = 'Grupo';
|
|
|
|
|
|
|
|
DELETE
|
|
|
|
FROM tmp.balance
|
|
|
|
WHERE lft BETWEEN @grupoLft AND @grupoRgt;
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
-- Rellenamos el valor de los padres con la suma de los hijos
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.balance_aux;
|
|
|
|
CREATE TEMPORARY TABLE tmp.balance_aux
|
|
|
|
SELECT * FROM tmp.balance;
|
|
|
|
|
|
|
|
EXECUTE IMMEDIATE
|
|
|
|
CONCAT('UPDATE tmp.balance b
|
|
|
|
JOIN (
|
|
|
|
SELECT b1.id,
|
|
|
|
b1.name,
|
|
|
|
SUM(b2.', vYear,') thisYear,
|
|
|
|
SUM(b2.', vOneYearAgo,') oneYearAgo,
|
|
|
|
SUM(b2.', vTwoYearsAgo,') twoYearsAgo
|
|
|
|
FROM tmp.nest b1
|
|
|
|
JOIN tmp.balance_aux b2 on b2.lft BETWEEN b1.lft and b1.rgt
|
|
|
|
GROUP BY b1.id)sub ON sub.id = b.id
|
|
|
|
SET b.', vYear, ' = thisYear,
|
|
|
|
b.', vOneYearAgo, ' = oneYearAgo,
|
|
|
|
b.', vTwoYearsAgo, ' = twoYearsAgo');
|
|
|
|
|
|
|
|
SELECT *, CONCAT('',ifnull(Id_Gasto,'')) newgasto
|
|
|
|
FROM tmp.balance;
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|