refs #7400 feat: book ledger with counters

This commit is contained in:
Carlos Andrés 2024-05-15 12:46:57 +02:00
parent dcc943e82d
commit 70dda22d75
8 changed files with 482 additions and 388 deletions

View File

@ -1,5 +1,6 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`xdiario_new`(vAsiento INT,
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`xdiario_new`(
vBookNumber INT,
vDated DATE,
vSubaccount VARCHAR(12),
vAccount VARCHAR(12),
@ -12,33 +13,33 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`xdiario_new`(vAsient
vVat DOUBLE,
vRe DOUBLE,
vAux TINYINT,
vCompany INT
vCompanyFk INT
)
RETURNS int(11)
NOT DETERMINISTIC
NO SQL
BEGIN
IF vAsiento IS NULL THEN
CALL vn.ledger_next(vAsiento);
IF vBookNumber IS NULL THEN
CALL ledger_next(YEAR(vDated), vCompanyFk, vBookNumber);
END IF;
INSERT INTO XDiario
SET ASIEN = vAsiento,
FECHA = vDated,
SUBCTA = vSubaccount,
CONTRA = vAccount,
CONCEPTO = vConcept,
EURODEBE = vDebit,
EUROHABER = vCredit,
BASEEURO = vEuro,
SERIE = vSerie,
FACTURA = vInvoice,
IVA = vVat,
RECEQUIV = vRe,
AUXILIAR = IF(vAux = FALSE, NULL, '*'),
MONEDAUSO = 2,
empresa_id = vCompany;
SET ASIEN = vBookNumber,
FECHA = vDated,
SUBCTA = vSubaccount,
CONTRA = vAccount,
CONCEPTO = vConcept,
EURODEBE = vDebit,
EUROHABER = vCredit,
BASEEURO = vEuro,
SERIE = vSerie,
FACTURA = vInvoice,
IVA = vVat,
RECEQUIV = vRe,
AUXILIAR = IF(vAux = FALSE, NULL, '*'),
MONEDAUSO = 2,
empresa_id = vCompanyFk;
RETURN vAsiento;
RETURN vBookNumber;
END$$
DELIMITER ;

View File

@ -2,127 +2,122 @@ DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`duaTaxBooking`(vDuaFk INT)
BEGIN
DECLARE vBookNumber INT;
DECLARE vBookDated DATE;
DECLARE vDiff DECIMAL(10,2);
DECLARE vApunte BIGINT;
SELECT ASIEN, IFNULL(bookEntried, util.VN_CURDATE()) INTO vBookNumber, vBookDated
FROM dua
DECLARE vBookDated DATE;
DECLARE vDiff DECIMAL(10,2);
DECLARE vApunte BIGINT;
DECLARE vCompanyFk INT;
SELECT ASIEN, IFNULL(bookEntried, util.VN_CURDATE()), companyFk
INTO vBookNumber, vBookDated, vCompanyFk
FROM dua
WHERE id = vDuaFk;
IF vBookNumber IS NULL OR NOT vBookNumber THEN
CALL ledger_next(vBookNumber);
CALL ledger_next(YEAR(vBookDated), vCompanyFk, vBookNumber);
END IF;
-- Apunte de la aduana
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
CONCEPTO,
EUROHABER,
SERIE,
empresa_id,
CLAVE,
FACTURA)
ASIEN,
FECHA,
SUBCTA,
CONCEPTO,
EUROHABER,
SERIE,
empresa_id,
CLAVE,
FACTURA)
SELECT vBookNumber,
d.bookEntried,
'4700000999',
CONCAT('DUA ',d.`code`),
sum(dt.base * dt.rate / 100) EUROHABER,
'R',
vCompanyFk,
vDuaFk,
vDuaFk
FROM duaTax dt
JOIN dua d ON d.id = dt.duaFk
WHERE dt.duaFk = vDuaFk;
SELECT
vBookNumber,
d.bookEntried,
'4700000999',
CONCAT('DUA ',d.`code`),
sum(dt.base * dt.rate / 100) EUROHABER,
'R',
d.companyFk,
vDuaFk,
vDuaFk
FROM duaTax dt
JOIN dua d ON d.id = dt.duaFk
WHERE dt.duaFk = vDuaFk;
-- Apuntes por tipo de IVA y proveedor
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EURODEBE,
BASEEURO,
CONCEPTO,
FACTURA,
IVA,
AUXILIAR,
SERIE,
FECHA_EX,
FECHA_OP,
FACTURAEX,
NFACTICK,
L340,
LDIFADUAN,
TIPOCLAVE,
TIPOEXENCI,
TIPONOSUJE,
TIPOFACT,
TIPORECTIF,
TERIDNIF,
TERNIF,
TERNOM,
empresa_id,
FECREGCON
)
SELECT
vBookNumber ASIEN,
vBookDated FECHA,
tr.account SUBCTA,
'4330002067' CONTRA,
sum(dt.tax) EURODEBE,
sum(dt.base) BASEEURO,
CONCAT('DUA nº',d.code) CONCEPTO,
d.id FACTURA,
dt.rate IVA,
'*' AUXILIAR,
'D' SERIE,
d.issued FECHA_EX,
d.operated FECHA_OP,
d.code FACTURAEX,
1 NFACTICK,
1 L340,
TRUE LDIFADUAN,
1 TIPOCLAVE,
1 TIPOEXENCI,
1 TIPONOSUJE,
5 TIPOFACT,
1 TIPORECTIF,
IF(c.code = 'ES', 1, 4) TERIDNIF,
s.nif TERNIF,
s.name TERNOM,
d.companyFk,
d.booked FECREGCON
FROM duaTax dt
JOIN dua d ON dt.duaFk = d.id
JOIN (SELECT account, rate
FROM
(SELECT rate, account
FROM invoiceInTaxBookingAccount ta
WHERE ta.effectived <= vBookDated
AND taxAreaFk = 'WORLD'
ORDER BY ta.effectived DESC
LIMIT 10000000000000000000
) tba
GROUP BY rate
-- Apuntes por tipo de IVA y proveedor
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EURODEBE,
BASEEURO,
CONCEPTO,
FACTURA,
IVA,
AUXILIAR,
SERIE,
FECHA_EX,
FECHA_OP,
FACTURAEX,
NFACTICK,
L340,
LDIFADUAN,
TIPOCLAVE,
TIPOEXENCI,
TIPONOSUJE,
TIPOFACT,
TIPORECTIF,
TERIDNIF,
TERNIF,
TERNOM,
empresa_id,
FECREGCON)
SELECT vBookNumber ASIEN,
vBookDated FECHA,
tr.account SUBCTA,
'4330002067' CONTRA,
SUM(dt.tax) EURODEBE,
SUM(dt.base) BASEEURO,
CONCAT('DUA nº',d.code) CONCEPTO,
d.id FACTURA,
dt.rate IVA,
'*' AUXILIAR,
'D' SERIE,
d.issued FECHA_EX,
d.operated FECHA_OP,
d.code FACTURAEX,
1 NFACTICK,
1 L340,
TRUE LDIFADUAN,
1 TIPOCLAVE,
1 TIPOEXENCI,
1 TIPONOSUJE,
5 TIPOFACT,
1 TIPORECTIF,
IF(c.code = 'ES', 1, 4) TERIDNIF,
s.nif TERNIF,
s.name TERNOM,
vCompanyFk,
d.booked FECREGCON
FROM duaTax dt
JOIN dua d ON dt.duaFk = d.id
JOIN (SELECT account, rate
FROM
(SELECT rate, account
FROM invoiceInTaxBookingAccount ta
WHERE ta.effectived <= vBookDated
AND taxAreaFk = 'WORLD'
ORDER BY ta.effectived DESC
LIMIT 10000000000000000000
) tba
GROUP BY rate
) tr ON tr.rate = dt.rate
JOIN supplier s ON s.id = d.companyFk
JOIN country c ON c.id = s.countryFk
WHERE d.id = vDuaFk
GROUP BY dt.rate;
JOIN supplier s ON s.id = d.companyFk
JOIN country c ON c.id = s.countryFk
WHERE d.id = vDuaFk
GROUP BY dt.rate;
SELECT SUM(EURODEBE) -SUM(EUROHABER), MAX(id) INTO vDiff, vApunte
FROM XDiario
WHERE ASIEN = vBookNumber;
UPDATE XDiario
SET BASEEURO = 100 * (EURODEBE - vDiff) / IVA,
EURODEBE = EURODEBE - vDiff
@ -131,6 +126,5 @@ BEGIN
UPDATE dua
SET ASIEN = vBookNumber
WHERE id = vDuaFk;
END$$
DELIMITER ;

View File

@ -2,6 +2,8 @@ DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceIn_booking`(vSelf INT)
BEGIN
DECLARE vBookNumber INT;
DECLARE vFiscalYear INT;
DECLARE vCompanyFk INT;
CREATE OR REPLACE TEMPORARY TABLE tInvoiceIn
ENGINE = MEMORY
@ -56,7 +58,8 @@ BEGIN
LEFT JOIN sage.taxType tt ON tt.id = ti.CodigoIva
WHERE ii.id = vSelf;
CALL vn.ledger_next(vBookNumber);
SELECT YEAR(bookEntried), companyFk INTO vFiscalYear, vCompanyFk FROM tInvoiceIn;
CALL ledger_next(vFiscalYear, vCompanyFk, vBookNumber);
-- Apunte del proveedor
INSERT INTO XDiario(

View File

@ -1,22 +1,25 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceOutBooking`(IN vInvoice INT)
BEGIN
/* Asienta la factura emitida
*
* param vInvoice factura_id
*/
/**
* Asienta una factura emitida
*
* @param vInvoice Id invoiceOut
*/
DECLARE vBookNumber INT;
DECLARE vExpenseConcept VARCHAR(50);
DECLARE vSpainCountryFk INT;
DECLARE vOldBookNumber INT;
DECLARE vExpenseConcept VARCHAR(50);
DECLARE vSpainCountryFk INT;
DECLARE vOldBookNumber INT;
DECLARE vFiscalYear INT;
DECLARE vCompanyFk INT;
SELECT id INTO vSpainCountryFk FROM country WHERE code = 'ES';
SELECT id INTO vSpainCountryFk FROM country WHERE `code` = 'ES';
SELECT ASIEN
SELECT ASIEN
INTO vOldBookNumber
FROM XDiario x
JOIN invoiceOut io ON io.id = vInvoice
WHERE x.SERIE = io.serial
WHERE x.SERIE = io.serial
AND x.FACTURA = RIGHT(io.ref, LENGTH(io.ref) - 1)
LIMIT 1;
@ -26,140 +29,133 @@ BEGIN
DROP TEMPORARY TABLE IF EXISTS rs;
CREATE TEMPORARY TABLE rs
SELECT
c.accountingAccount AS clientBookingAccount,
io.amount as totalAmount,
CONCAT('n/fra ', io.ref) as simpleConcept,
CONCAT('n/fra ', io.ref, ' ', c.name) as Concept,
io.serial AS SERIE,
io.issued AS FECHA_EX,
io.issued AS FECHA_OP,
io.issued AS FECHA,
1 AS NFACTICK,
IF(ic.correctingFk,'D','') AS TIPOOPE,
io.siiTrascendencyInvoiceOutFk AS TIPOCLAVE,
io.cplusTaxBreakFk AS TIPOEXENCI,
io.cplusSubjectOpFk AS TIPONOSUJE,
io.siiTypeInvoiceOutFk AS TIPOFACT,
ic.cplusRectificationTypeFk AS TIPORECTIF,
SELECT c.accountingAccount clientBookingAccount,
io.amount totalAmount,
CONCAT('n/fra ', io.ref) simpleConcept,
CONCAT('n/fra ', io.ref, ' ', c.name) Concept,
io.serial SERIE,
io.issued FECHA_EX,
io.issued FECHA_OP,
io.issued FECHA,
1 NFACTICK,
IF(ic.correctingFk,'D','') TIPOOPE,
io.siiTrascendencyInvoiceOutFk TIPOCLAVE,
io.cplusTaxBreakFk TIPOEXENCI,
io.cplusSubjectOpFk TIPONOSUJE,
io.siiTypeInvoiceOutFk TIPOFACT,
ic.cplusRectificationTypeFk TIPORECTIF,
io.companyFk,
RIGHT(io.ref, LENGTH(io.ref) - 1) AS invoiceNum,
IF(c.countryFk = vSpainCountryFk, vSpainCountryFk, IF(ct.isUeeMember,2,4)) AS TERIDNIF,
CONCAT(IF(ct.isUeeMember AND c.countryFk <> vSpainCountryFk,ct.code,''),c.fi) AS TERNIF,
c.socialName AS TERNOM,
ior.serial AS SERIE_RT,
RIGHT(ior.ref, LENGTH(ior.ref) - 1) AS FACTU_RT,
ior.issued AS FECHA_RT,
IF(ior.id,TRUE,FALSE) AS RECTIFICA
RIGHT(io.ref, LENGTH(io.ref) - 1) invoiceNum,
IF(c.countryFk = vSpainCountryFk, vSpainCountryFk, IF(ct.isUeeMember,2,4)) TERIDNIF,
CONCAT(IF(ct.isUeeMember AND c.countryFk <> vSpainCountryFk,ct.code,''),c.fi) TERNIF,
c.socialName TERNOM,
ior.serial SERIE_RT,
RIGHT(ior.ref, LENGTH(ior.ref) - 1) FACTU_RT,
ior.issued FECHA_RT,
IF(ior.id,TRUE,FALSE) RECTIFICA
FROM invoiceOut io
JOIN invoiceOutSerial ios ON ios.code = io.serial
JOIN client c ON c.id = io.clientFk
JOIN country ct ON ct.id = c.countryFk
LEFT JOIN invoiceCorrection ic ON ic.correctingFk = io.id
LEFT JOIN invoiceOut ior ON ior.id = ic.correctedFk
LEFT JOIN invoiceOut ior ON ior.id = ic.correctedFk
WHERE io.id = vInvoice;
CALL vn.ledger_next(vBookNumber);
SELECT YEAR(FECHA), companyFk INTO vFiscalYear, vCompanyFk FROM rs;
CALL ledger_next(vFiscalYear, vCompanyFk, vBookNumber);
-- Linea del cliente
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
EURODEBE,
CONCEPTO,
FECHA_EX,
FECHA_OP,
empresa_id
)
SELECT
vBookNumber AS ASIEN,
ASIEN,
FECHA,
SUBCTA,
EURODEBE,
CONCEPTO,
FECHA_EX,
FECHA_OP,
empresa_id)
SELECT vBookNumber,
rs.FECHA,
rs.clientBookingAccount AS SUBCTA,
rs.totalAmount AS EURODEBE,
rs.simpleConcept AS CONCEPTO,
rs.clientBookingAccount,
rs.totalAmount,
rs.simpleConcept,
rs.FECHA_EX,
rs.FECHA_OP,
rs.companyFk AS empresa_id
vCompanyFk
FROM rs;
-- Lineas de gasto
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EUROHABER,
CONCEPTO,
FECHA_EX,
FECHA_OP,
empresa_id
)
SELECT
vBookNumber AS ASIEN,
rs.FECHA,
ioe.expenseFk AS SUBCTA,
rs.clientBookingAccount AS CONTRA,
ioe.amount AS EUROHABER,
rs.Concept AS CONCEPTO,
rs.FECHA_EX,
rs.FECHA_OP,
rs.companyFk AS empresa_id
FROM rs
JOIN invoiceOutExpense ioe
WHERE ioe.invoiceOutFk = vInvoice;
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EUROHABER,
CONCEPTO,
FECHA_EX,
FECHA_OP,
empresa_id)
SELECT vBookNumber,
rs.FECHA,
ioe.expenseFk,
rs.clientBookingAccount,
ioe.amount,
rs.Concept,
rs.FECHA_EX,
rs.FECHA_OP,
vCompanyFk
FROM rs
JOIN invoiceOutExpense ioe
WHERE ioe.invoiceOutFk = vInvoice;
SELECT GROUP_CONCAT(`name` SEPARATOR ',')
INTO vExpenseConcept
FROM expense e
JOIN invoiceOutExpense ioe ON ioe.expenseFk = e.id
WHERE ioe.invoiceOutFk = vInvoice;
SELECT GROUP_CONCAT(`name` SEPARATOR ',')
INTO vExpenseConcept
FROM expense e
JOIN invoiceOutExpense ioe ON ioe.expenseFk = e.id
WHERE ioe.invoiceOutFk = vInvoice;
-- Lineas de IVA
-- Lineas de IVA
INSERT INTO XDiario(
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EUROHABER,
BASEEURO,
CONCEPTO,
FACTURA,
IVA,
RECEQUIV,
AUXILIAR,
SERIE,
SERIE_RT,
FACTU_RT,
RECTIFICA,
FECHA_RT,
FECHA_OP,
FECHA_EX,
TIPOOPE,
NFACTICK,
TERIDNIF,
TERNIF,
TERNOM,
L340,
TIPOCLAVE,
TIPOEXENCI,
TIPONOSUJE,
TIPOFACT,
TIPORECTIF,
empresa_id
)
SELECT
vBookNumber AS ASIEN,
ASIEN,
FECHA,
SUBCTA,
CONTRA,
EUROHABER,
BASEEURO,
CONCEPTO,
FACTURA,
IVA,
RECEQUIV,
AUXILIAR,
SERIE,
SERIE_RT,
FACTU_RT,
RECTIFICA,
FECHA_RT,
FECHA_OP,
FECHA_EX,
TIPOOPE,
NFACTICK,
TERIDNIF,
TERNIF,
TERNOM,
L340,
TIPOCLAVE,
TIPOEXENCI,
TIPONOSUJE,
TIPOFACT,
TIPORECTIF,
empresa_id)
SELECT vBookNumber ASIEN,
rs.FECHA,
iot.pgcFk AS SUBCTA,
rs.clientBookingAccount AS CONTRA,
iot.vat AS EUROHABER,
iot.taxableBase AS BASEEURO,
CONCAT(vExpenseConcept,' : ',rs.Concept) AS CONCEPTO,
rs.invoiceNum AS FACTURA,
IF(pe2.equFk,0,pgc.rate) AS IVA,
IF(pe2.equFk,0,pgce.rate) AS RECEQUIV,
IF(pgc.mod347,'','*') AS AUXILIAR,
iot.pgcFk SUBCTA,
rs.clientBookingAccount CONTRA,
iot.vat EUROHABER,
iot.taxableBase BASEEURO,
CONCAT(vExpenseConcept,' : ',rs.Concept) CONCEPTO,
rs.invoiceNum FACTURA,
IF(pe2.equFk,0,pgc.rate) IVA,
IF(pe2.equFk,0,pgce.rate) RECEQUIV,
IF(pgc.mod347,'','*') AUXILIAR,
rs.SERIE,
rs.SERIE_RT,
rs.FACTU_RT,
@ -168,27 +164,27 @@ BEGIN
rs.FECHA_OP,
rs.FECHA_EX,
rs.TIPOOPE,
rs.NFACTICK,
rs.NFACTICK,
rs.TERIDNIF,
rs.TERNIF,
rs.TERNOM,
pgc.mod340 AS L340,
pgc.siiTrascendencyInvoiceOutFk AS TIPOCLAVE,
pgc.cplusTaxBreakFk as TIPOEXENCI,
pgc.mod340 L340,
pgc.siiTrascendencyInvoiceOutFk TIPOCLAVE,
pgc.cplusTaxBreakFk TIPOEXENCI,
rs.TIPONOSUJE,
rs.TIPOFACT,
rs.TIPORECTIF,
rs.companyFk AS empresa_id
vCompanyFk
FROM rs
JOIN invoiceOutTax iot
JOIN pgc ON pgc.code = iot.pgcFk
LEFT JOIN pgcEqu pe ON pe.vatFk = iot.pgcFk -- --------------- Comprueba si la linea es de iva con rec.equiv. asociado
LEFT JOIN pgc pgce ON pgce.code = pe.equFk
LEFT JOIN pgcEqu pe2 ON pe2.equFk = iot.pgcFk -- --------------- Comprueba si la linea es de rec.equiv.
LEFT JOIN pgcEqu pe2 ON pe2.equFk = iot.pgcFk -- --------------- Comprueba si la linea es de rec.equiv.
WHERE iot.invoiceOutFk = vInvoice;
UPDATE invoiceOut
SET booked = util.VN_CURDATE()
WHERE id = vInvoice;
UPDATE invoiceOut
SET booked = util.VN_CURDATE()
WHERE id = vInvoice;
END$$
DELIMITER ;

View File

@ -1,5 +1,13 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ledger_doCompensation`(vDated DATE, vCompensationAccount VARCHAR(10) , vBankFk VARCHAR(10), vConcept VARCHAR(255), vAmount DECIMAL(10,2), vCompanyFk INT, vOriginalAccount VARCHAR(10))
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ledger_doCompensation`(
vDated DATE,
vCompensationAccount VARCHAR(10),
vBankFk VARCHAR(10),
vConcept VARCHAR(255),
vAmount DECIMAL(10,2),
vCompanyFk INT,
vOriginalAccount VARCHAR(10)
)
BEGIN
/**
* Compensa un pago o un recibo insertando en contabilidad
@ -9,29 +17,31 @@ BEGIN
* @param vBankFk banco de la compensacion
* @param vConcept descripcion
* @param vAmount cantidad que se compensa
* @param vCompany empresa
* @param vCompanyFk empresa
* @param vOriginalAccount cuenta contable desde la cual se compensa
*
*/
*/
DECLARE vNewBookEntry INT;
DECLARE vIsClientCompensation INT;
DECLARE vIsClientCompensation INT;
DECLARE vClientFk INT;
DECLARE vSupplierFk INT;
DECLARE vIsOriginalAClient BOOL;
DECLARE vPayMethodCompensation INT;
CALL ledger_next(vNewBookEntry);
DECLARE vSupplierFk INT;
DECLARE vIsOriginalAClient BOOL;
DECLARE vPayMethodCompensation INT;
SELECT COUNT(id) INTO vIsOriginalAClient FROM client WHERE accountingAccount LIKE vOriginalAccount COLLATE utf8_general_ci;
CALL ledger_next(YEAR(vDated), vCompanyFk, vNewBookEntry);
SELECT COUNT(id) INTO vIsOriginalAClient
FROM client
WHERE accountingAccount LIKE vOriginalAccount COLLATE utf8_general_ci;
SELECT id, COUNT(id) INTO vClientFk, vIsClientCompensation
FROM client
WHERE accountingAccount LIKE vCompensationAccount COLLATE utf8_general_ci;
SET @vAmount1:= 0.0;
SET @vAmount2:= 0.0;
INSERT INTO XDiario (ASIEN, FECHA, SUBCTA, CONTRA, CONCEPTO, EURODEBE, EUROHABER, empresa_id)
INSERT INTO XDiario (ASIEN, FECHA, SUBCTA, CONTRA, CONCEPTO, EURODEBE, EUROHABER, empresa_id)
VALUES ( vNewBookEntry,
vDated,
vOriginalAccount,
@ -49,30 +59,51 @@ BEGIN
),
vCompanyFk
),
( vNewBookEntry,
vDated,
vCompensationAccount,
vOriginalAccount,
vConcept,
@vAmount2,
( vNewBookEntry,
vDated,
vCompensationAccount,
vOriginalAccount,
vConcept,
@vAmount2,
@vAmount1,
vCompanyFk);
IF vIsClientCompensation THEN
IF vIsOriginalAClient THEN
SET vAmount = -vAmount;
END IF;
INSERT INTO receipt(invoiceFk, amountPaid, payed, bankFk, companyFk, clientFk, isConciliate)
VALUES (vConcept, vAmount, vDated, vBankFk, vCompanyFk, vClientFk, TRUE);
ELSE
IF NOT vIsOriginalAClient THEN
SET vAmount = -vAmount;
END IF;
SELECT id INTO vSupplierFk FROM supplier WHERE `account` LIKE vCompensationAccount COLLATE utf8_general_ci;
SELECT id INTO vPayMethodCompensation FROM payMethod WHERE `code` = 'compensation';
INSERT INTO payment (received, dueDated, supplierFk, amount, bankFk, payMethodFk, concept, companyFk, isConciliated)
VALUES(vDated, vDated, vSupplierFk, vAmount, vBankFk, vPayMethodCompensation, vConcept, vCompanyFk, TRUE);
END IF;
vCompanyFk);
IF vIsClientCompensation THEN
IF vIsOriginalAClient THEN
SET vAmount = -vAmount;
END IF;
INSERT INTO receipt
SET invoiceFk = vConcept,
amountPaid = vAmount,
payed = vDated,
bankFk = vBankFk,
companyFk = vCompanyFk,
clientFk = vClientFk,
isConciliate = TRUE;
ELSE
IF NOT vIsOriginalAClient THEN
SET vAmount = -vAmount;
END IF;
SELECT id INTO vSupplierFk
FROM supplier
WHERE `account` LIKE vCompensationAccount COLLATE utf8_general_ci;
SELECT id INTO vPayMethodCompensation
FROM payMethod
WHERE `code` = 'compensation';
INSERT INTO payment
SET received = vDated,
dueDated = vDated,
supplierFk = vSupplierFk,
amount = vAmount,
bankFk = vBankFk,
payMethodFk = vPayMethodCompensation,
concept = vConcept,
companyFk = vCompanyFk,
isConciliated = TRUE;
END IF;
END$$
DELIMITER ;

View File

@ -1,9 +1,63 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ledger_next`(OUT vNewBookEntry INT)
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ledger_next`(
IN vFiscalYear INT,
IN vCompanyFk INT,
OUT vNewBookEntry INT
)
BEGIN
UPDATE vn.ledgerConfig SET lastBookEntry = LAST_INSERT_ID(lastBookEntry + 1);
SET vNewBookEntry = LAST_INSERT_ID();
DECLARE vLastBookEntry INT;
DECLARE vHasStarTransaction BOOLEAN;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
IF vHasStarTransaction THEN
ROLLBACK TO sp;
RESIGNAL;
ELSE
ROLLBACK;
CALL util.throw ('It has not been possible to generate a newt ledger')
END IF;
END;
IF vFiscalYear IS NULL OR vCompanyFk IS NULL THEN
CALL util.throw('Fiscal year and company are required');
END IF;
SELECT @@in_transaction INTO vHasStarTransaction;
IF NOT vHasStarTransaction THEN
START TRANSACTION;
ELSE
SAVEPOINT sp;
END IF;
SELECT bookEntry INTO vLastBookEntry
FROM ledgerCounter
WHERE fiscalYear = vFiscalYear
AND companyFk = vCompanyFk
FOR UPDATE;
IF vLastBookEntry IS NULL THEN
INSERT INTO ledgerCounter
SET fiscalYear = vFiscalYear,
companyFk = vCompanyFk,
bookEntry = 1;
SET vLastBookEntry = 0;
END IF;
SET vNewBookEntry = vLastBookEntry + 1;
UPDATE ledgerCounter
SET bookEntry = vNewBookEntry
WHERE fiscalYear = vFiscalYear
AND companyFk = vCompanyFk;
IF vHasStarTransaction THEN
RELEASE SAVEPOINT sp;
ELSE
COMMIT;
END IF;
END$$
DELIMITER ;

View File

@ -3,92 +3,92 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`payment_beforeInsert`
BEFORE INSERT ON `payment`
FOR EACH ROW
BEGIN
DECLARE cuenta_banco,cuenta_proveedor DOUBLE;
DECLARE vNewBookEntry INT;
DECLARE bolCASH BOOLEAN;
DECLARE isSupplierActive BOOLEAN;
DECLARE vBankAccount, vSupplierAccount DOUBLE;
DECLARE vNewBookEntry INT;
DECLARE vIsCash BOOLEAN;
DECLARE vIsSupplierActive BOOLEAN;
-- PAK 10/02/15 No se asientan los pagos directamente, salvo en el caso de las cajas de CASH
SELECT (at2.code = 'cash') INTO bolCASH
FROM accounting a
JOIN accountingType at2 ON at2.id = a.accountingTypeFk
WHERE a.id = NEW.bankFk;
-- PAK 10/02/15 No se asientan los pagos directamente, salvo en el caso de las cajas de CASH
SELECT (at2.code = 'cash') INTO vIsCash
FROM accounting a
JOIN accountingType at2 ON at2.id = a.accountingTypeFk
WHERE a.id = NEW.bankFk;
IF bolCASH THEN
SELECT account INTO cuenta_banco
FROM accounting
WHERE id = NEW.bankFk;
SELECT account INTO cuenta_proveedor
FROM supplier
WHERE id = NEW.supplierFk;
IF vIsCash THEN
SELECT account INTO vBankAccount
FROM accounting
WHERE id = NEW.bankFk;
CALL ledger_next(vNewBookEntry);
INSERT INTO XDiario ( ASIEN,
FECHA,
SUBCTA,
CONTRA,
CONCEPTO,
EURODEBE,
EUROHABER,
empresa_id)
SELECT vNewBookEntry,
NEW.received,
SUBCTA,
CONTRA,
NEW.concept,
EURODEBE,
EUROHABER,
NEW.companyFk
FROM ( SELECT cuenta_banco SUBCTA,
cuenta_proveedor CONTRA,
0 EURODEBE,
NEW.amount + NEW.bankingFees EUROHABER
UNION ALL
SELECT cuenta_proveedor SUBCTA,
cuenta_banco CONTRA,
NEW.amount EURODEBE,
0 EUROHABER) gf;
IF NEW.bankingFees <> 0 THEN
INSERT INTO XDiario ( ASIEN,
FECHA,
SUBCTA,
CONTRA,
CONCEPTO,
EURODEBE,
EUROHABER,
empresa_id)
SELECT vNewBookEntry,
NEW.received,
IF(c.id = 1,6260000002,
IF(CEE = 1,6260000003,6260000004)),
cuenta_banco,
NEW.concept,
NEW.bankingFees,
0,
NEW.companyFk
FROM supplier s
JOIN country c ON s.countryFk = c.id
WHERE s.id = NEW.supplierFk;
END IF;
END IF;
SET NEW.dueDated = IFNULL(NEW.dueDated, NEW.received);
SELECT isActive INTO isSupplierActive
SELECT account INTO vSupplierAccount
FROM supplier
WHERE id = NEW.supplierFk;
IF isSupplierActive = FALSE THEN
CALL util.throw('SUPPLIER_INACTIVE');
END IF;
IF ISNULL(NEW.workerFk) THEN
SET NEW.workerFk = account.myUser_getId();
END IF;
END$$
CALL ledger_next(YEAR(NEW.received), NEW.companyFk, vNewBookEntry);
INSERT INTO XDiario (
ASIEN,
FECHA,
SUBCTA,
CONTRA,
CONCEPTO,
EURODEBE,
EUROHABER,
empresa_id)
SELECT vNewBookEntry,
NEW.received,
SUBCTA,
CONTRA,
NEW.concept,
EURODEBE,
EUROHABER,
NEW.companyFk
FROM (SELECT vBankAccount SUBCTA,
vSupplierAccount CONTRA,
0 EURODEBE,
NEW.amount + NEW.bankingFees EUROHABER
UNION ALL
SELECT vSupplierAccount SUBCTA,
vBankAccount CONTRA,
NEW.amount EURODEBE,
0 EUROHABER) gf;
IF NEW.bankingFees <> 0 THEN
INSERT INTO XDiario (
ASIEN,
FECHA,
SUBCTA,
CONTRA,
CONCEPTO,
EURODEBE,
EUROHABER,
empresa_id)
SELECT vNewBookEntry,
NEW.received,
IF(c.id = 1,6260000002,
IF(CEE = 1,6260000003,6260000004)),
vBankAccount,
NEW.concept,
NEW.bankingFees,
0,
NEW.companyFk
FROM supplier s
JOIN country c ON s.countryFk = c.id
WHERE s.id = NEW.supplierFk;
END IF;
END IF;
SET NEW.dueDated = IFNULL(NEW.dueDated, NEW.received);
SELECT isActive INTO vIsSupplierActive
FROM supplier
WHERE id = NEW.supplierFk;
IF vIsSupplierActive = FALSE THEN
CALL util.throw('SUPPLIER_INACTIVE');
END IF;
IF ISNULL(NEW.workerFk) THEN
SET NEW.workerFk = account.myUser_getId();
END IF;
END$$
DELIMITER ;

View File

@ -0,0 +1,15 @@
CREATE OR REPLACE TABLE vn.ledgerCounter (
fiscalYear INT UNSIGNED NOT NULL COMMENT 'Año del ejercicio contable',
bookEntry INT UNSIGNED DEFAULT 1 NOT NULL COMMENT 'Contador asiento contable',
companyFk INT UNSIGNED DEFAULT 442 NOT NULL,
PRIMARY KEY (fiscalYear),
CONSTRAINT ledgerCounterCompanyFk_Fk FOREIGN KEY (companyFk)
REFERENCES vn.company (id) ON DELETE CASCADE ON UPDATE CASCADE
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8mb3
COLLATE=utf8mb3_unicode_ci
COMMENT='Contador para asientos contables';
CREATE INDEX ledgerCounter_fiscalYear_IDX
USING BTREE ON vn.ledgerCounter (fiscalYear);