TEST_4825-intrastat #1221
|
@ -0,0 +1,225 @@
|
||||||
|
DROP PROCEDURE IF EXISTS `vn`.`invoiceOut_new`;
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceOut_new`(
|
||||||
|
vSerial VARCHAR(255),
|
||||||
|
vInvoiceDate DATETIME,
|
||||||
|
vTaxArea VARCHAR(25),
|
||||||
|
OUT vNewInvoiceId INT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Creación de facturas emitidas.
|
||||||
|
* requiere previamente tabla ticketToInvoice(id).
|
||||||
|
*
|
||||||
|
* @param vSerial serie a la cual se hace la factura
|
||||||
|
* @param vInvoiceDate fecha de la factura
|
||||||
|
* @param vTaxArea tipo de iva en relacion a la empresa y al cliente
|
||||||
|
* @param vNewInvoiceId id de la factura que se acaba de generar
|
||||||
|
* @return vNewInvoiceId
|
||||||
|
*/
|
||||||
|
DECLARE vSpainCountryCode INT DEFAULT 1;
|
||||||
|
DECLARE vIsAnySaleToInvoice BOOL;
|
||||||
|
DECLARE vIsAnyServiceToInvoice BOOL;
|
||||||
|
DECLARE vNewRef VARCHAR(255);
|
||||||
|
DECLARE vWorker INT DEFAULT account.myUser_getId();
|
||||||
|
DECLARE vCompany INT;
|
||||||
|
DECLARE vSupplier INT;
|
||||||
|
DECLARE vClient INT;
|
||||||
|
DECLARE vCplusStandardInvoiceTypeFk INT DEFAULT 1;
|
||||||
|
DECLARE vCplusCorrectingInvoiceTypeFk INT DEFAULT 6;
|
||||||
|
DECLARE vCplusSimplifiedInvoiceTypeFk INT DEFAULT 2;
|
||||||
|
DECLARE vCorrectingSerial VARCHAR(1) DEFAULT 'R';
|
||||||
|
DECLARE vSimplifiedSerial VARCHAR(1) DEFAULT 'S';
|
||||||
|
DECLARE vNewInvoiceInId INT;
|
||||||
|
DECLARE vIsInterCompany BOOL;
|
||||||
|
|
||||||
|
SET vInvoiceDate = IFNULL(vInvoiceDate,CURDATE());
|
||||||
|
|
||||||
|
SELECT t.clientFk, t.companyFk
|
||||||
|
INTO vClient, vCompany
|
||||||
|
FROM ticketToInvoice tt
|
||||||
|
JOIN ticket t ON t.id = tt.id
|
||||||
|
LIMIT 1;
|
||||||
|
|
||||||
|
-- Eliminem de ticketToInvoice els tickets que no han de ser facturats
|
||||||
|
DELETE ti.*
|
||||||
|
FROM ticketToInvoice ti
|
||||||
|
JOIN ticket t ON t.id = ti.id
|
||||||
|
JOIN sale s ON s.ticketFk = t.id
|
||||||
|
JOIN item i ON i.id = s.itemFk
|
||||||
|
JOIN supplier su ON su.id = t.companyFk
|
||||||
|
JOIN client c ON c.id = t.clientFk
|
||||||
|
LEFT JOIN itemTaxCountry itc ON itc.itemFk = i.id AND itc.countryFk = su.countryFk
|
||||||
|
WHERE YEAR(t.shipped) < 2001
|
||||||
|
OR c.isTaxDataChecked = FALSE
|
||||||
|
OR t.isDeleted
|
||||||
|
OR c.hasToInvoice = FALSE
|
||||||
|
OR itc.id IS NULL;
|
||||||
|
|
||||||
|
SELECT SUM(s.quantity * s.price * (100 - s.discount)/100), ts.id
|
||||||
|
INTO vIsAnySaleToInvoice, vIsAnyServiceToInvoice
|
||||||
|
FROM ticketToInvoice t
|
||||||
|
LEFT JOIN sale s ON s.ticketFk = t.id
|
||||||
|
LEFT JOIN ticketService ts ON ts.ticketFk = t.id;
|
||||||
|
|
||||||
|
IF (vIsAnySaleToInvoice OR vIsAnyServiceToInvoice)
|
||||||
|
AND (vCorrectingSerial = vSerial OR NOT hasAnyNegativeBase())
|
||||||
|
THEN
|
||||||
|
|
||||||
|
-- el trigger añade el siguiente Id_Factura correspondiente a la vSerial
|
||||||
|
INSERT INTO invoiceOut
|
||||||
|
(
|
||||||
|
ref,
|
||||||
|
serial,
|
||||||
|
issued,
|
||||||
|
clientFk,
|
||||||
|
dued,
|
||||||
|
companyFk,
|
||||||
|
cplusInvoiceType477Fk
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
1,
|
||||||
|
vSerial,
|
||||||
|
vInvoiceDate,
|
||||||
|
vClient,
|
||||||
|
getDueDate(vInvoiceDate, dueDay),
|
||||||
|
vCompany,
|
||||||
|
IF(vSerial = vCorrectingSerial,
|
||||||
|
vCplusCorrectingInvoiceTypeFk,
|
||||||
|
IF(vSerial = vSimplifiedSerial,
|
||||||
|
vCplusSimplifiedInvoiceTypeFk,
|
||||||
|
vCplusStandardInvoiceTypeFk))
|
||||||
|
FROM client
|
||||||
|
WHERE id = vClient;
|
||||||
|
|
||||||
|
|
||||||
|
SET vNewInvoiceId = LAST_INSERT_ID();
|
||||||
|
|
||||||
|
SELECT `ref`
|
||||||
|
INTO vNewRef
|
||||||
|
FROM invoiceOut
|
||||||
|
WHERE id = vNewInvoiceId;
|
||||||
|
|
||||||
|
UPDATE ticket t
|
||||||
|
JOIN ticketToInvoice ti ON ti.id = t.id
|
||||||
|
SET t.refFk = vNewRef;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.updateInter;
|
||||||
|
CREATE TEMPORARY TABLE tmp.updateInter ENGINE = MEMORY
|
||||||
|
SELECT s.id,ti.id ticket_id,vWorker Id_Trabajador
|
||||||
|
FROM ticketToInvoice ti
|
||||||
|
LEFT JOIN ticketState ts ON ti.id = ts.ticket
|
||||||
|
JOIN state s
|
||||||
|
WHERE IFNULL(ts.alertLevel,0) < 3 and s.`code` = getAlert3State(ti.id);
|
||||||
|
|
||||||
|
INSERT INTO vncontrol.inter(state_id,Id_Ticket,Id_Trabajador)
|
||||||
|
SELECT * FROM tmp.updateInter;
|
||||||
|
|
||||||
|
INSERT INTO ticketLog (action, userFk, originFk, description)
|
||||||
|
SELECT 'UPDATE', account.myUser_getId(), ti.id, CONCAT('Crea factura ', vNewRef)
|
||||||
|
FROM ticketToInvoice ti;
|
||||||
|
|
||||||
|
CALL invoiceExpenceMake(vNewInvoiceId);
|
||||||
|
CALL invoiceTaxMake(vNewInvoiceId,vTaxArea);
|
||||||
|
|
||||||
|
UPDATE invoiceOut io
|
||||||
|
JOIN (
|
||||||
|
SELECT SUM(amount) AS total
|
||||||
|
FROM invoiceOutExpence
|
||||||
|
WHERE invoiceOutFk = vNewInvoiceId
|
||||||
|
) base
|
||||||
|
JOIN (
|
||||||
|
SELECT SUM(vat) AS total
|
||||||
|
FROM invoiceOutTax
|
||||||
|
WHERE invoiceOutFk = vNewInvoiceId
|
||||||
|
) vat
|
||||||
|
SET io.amount = base.total + vat.total
|
||||||
|
WHERE io.id = vNewInvoiceId;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE tmp.updateInter;
|
||||||
|
|
||||||
|
SELECT ios.isCEE INTO vIsInterCompany
|
||||||
|
FROM vn.ticket t
|
||||||
|
JOIN vn.invoiceOut io ON io.`ref` = t.refFk
|
||||||
|
JOIN vn.invoiceOutSerial ios ON ios.code = io.serial
|
||||||
|
WHERE t.refFk = vNewRef
|
||||||
|
LIMIT 1;
|
||||||
|
|
||||||
|
IF (vIsInterCompany) THEN
|
||||||
|
|
||||||
|
SELECT vCompany INTO vSupplier;
|
||||||
|
SELECT id INTO vCompany FROM company WHERE clientFk = vClient;
|
||||||
|
|
||||||
|
INSERT INTO invoiceIn(supplierFk, supplierRef, issued, companyFk)
|
||||||
|
SELECT vSupplier, vNewRef, vInvoiceDate, vCompany;
|
||||||
|
|
||||||
|
SET vNewInvoiceInId = LAST_INSERT_ID();
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket;
|
||||||
|
CREATE TEMPORARY TABLE tmp.ticket
|
||||||
|
(KEY (ticketFk))
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT id ticketFk
|
||||||
|
FROM ticketToInvoice;
|
||||||
|
|
||||||
|
CALL `ticket_getTax`('NATIONAL');
|
||||||
|
|
||||||
|
SET @vTaxableBaseServices := 0.00;
|
||||||
|
SET @vTaxCodeGeneral := NULL;
|
||||||
|
|
||||||
|
INSERT INTO vn.invoiceInTax(invoiceInFk, taxableBase, expenceFk, taxTypeSageFk, transactionTypeSageFk)
|
||||||
|
SELECT vNewInvoiceInId, @vTaxableBaseServices, sub.expenceFk, sub.taxTypeSageFk , sub.transactionTypeSageFk
|
||||||
|
FROM (
|
||||||
|
SELECT @vTaxableBaseServices := SUM(tst.taxableBase) taxableBase, i.expenceFk, i.taxTypeSageFk , i.transactionTypeSageFk, @vTaxCodeGeneral := i.taxClassCodeFk
|
||||||
|
FROM tmp.ticketServiceTax tst
|
||||||
|
JOIN vn.invoiceOutTaxConfig i ON i.taxClassCodeFk = tst.code
|
||||||
|
WHERE i.isService
|
||||||
|
HAVING taxableBase
|
||||||
|
) sub;
|
||||||
|
|
||||||
|
INSERT INTO vn.invoiceInTax(invoiceInFk, taxableBase, expenceFk, taxTypeSageFk, transactionTypeSageFk)
|
||||||
|
SELECT vNewInvoiceInId, SUM(tt.taxableBase) - IF(tt.code = @vTaxCodeGeneral, @vTaxableBaseServices, 0) taxableBase, i.expenceFk, i.taxTypeSageFk , i.transactionTypeSageFk
|
||||||
|
FROM tmp.ticketTax tt
|
||||||
|
JOIN vn.invoiceOutTaxConfig i ON i.taxClassCodeFk = tt.code
|
||||||
|
WHERE !i.isService
|
||||||
|
GROUP BY tt.pgcFk
|
||||||
|
HAVING taxableBase
|
||||||
|
ORDER BY tt.priority;
|
||||||
|
|
||||||
|
CALL invoiceInDueDay_calculate(vNewInvoiceInId);
|
||||||
|
|
||||||
|
INSERT INTO invoiceInIntrastat (
|
||||||
|
invoiceInFk,
|
||||||
|
intrastatFk,
|
||||||
|
amount,
|
||||||
|
stems,
|
||||||
|
countryFk,
|
||||||
|
net)
|
||||||
|
SELECT
|
||||||
|
vNewInvoiceInId invoiceInFk,
|
||||||
|
i.intrastatFk,
|
||||||
|
CAST(SUM((s.quantity * s.price * (100 - s.discount) / 100 )) AS DECIMAL(10,2)) subtotal,
|
||||||
|
CAST(SUM(IFNULL(i.stems, 1) * s.quantity) AS DECIMAL(10,2)) stems,
|
||||||
|
su.countryFk,
|
||||||
|
CAST(SUM(IFNULL(i.stems, 1)
|
||||||
|
* s.quantity
|
||||||
|
* IF(ic.grams, ic.grams, i.weightByPiece) / 1000) AS DECIMAL(10,2)) netKg
|
||||||
|
FROM sale s
|
||||||
|
JOIN ticket t ON s.ticketFk = t.id
|
||||||
|
JOIN supplier su ON su.id = t.companyFk
|
||||||
|
JOIN item i ON i.id = s.itemFk
|
||||||
|
JOIN vn.itemCost ic ON ic.itemFk = i.id AND ic.warehouseFk = t.warehouseFk
|
||||||
|
JOIN intrastat ir ON ir.id = i.intrastatFk
|
||||||
|
WHERE t.refFk = vNewRef;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE tmp.ticket;
|
||||||
|
DROP TEMPORARY TABLE tmp.ticketAmount;
|
||||||
|
DROP TEMPORARY TABLE tmp.ticketTax;
|
||||||
|
DROP TEMPORARY TABLE tmp.ticketServiceTax;
|
||||||
|
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE `ticketToInvoice`;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -82,7 +82,7 @@ module.exports = {
|
||||||
return this.rawSqlFromDef(`taxes`, [reference]);
|
return this.rawSqlFromDef(`taxes`, [reference]);
|
||||||
},
|
},
|
||||||
fetchIntrastat(reference) {
|
fetchIntrastat(reference) {
|
||||||
return this.rawSqlFromDef(`intrastat`, [reference, reference, reference, reference, reference]);
|
return this.rawSqlFromDef(`intrastat`, [reference, reference, reference]);
|
||||||
},
|
},
|
||||||
fetchRectified(reference) {
|
fetchRectified(reference) {
|
||||||
return this.rawSqlFromDef(`rectified`, [reference]);
|
return this.rawSqlFromDef(`rectified`, [reference]);
|
||||||
|
|
|
@ -1,39 +1,26 @@
|
||||||
SELECT *
|
SELECT *
|
||||||
FROM invoiceOut io
|
FROM invoiceOut io
|
||||||
JOIN invoiceOutSerial ios ON io.serial = ios.code
|
JOIN invoiceOutSerial ios ON io.serial = ios.code
|
||||||
JOIN
|
JOIN(
|
||||||
(SELECT
|
SELECT ir.id code,
|
||||||
t.refFk,
|
ir.description,
|
||||||
ir.id code,
|
iii.stems,
|
||||||
ir.description description,
|
iii.net netKg,
|
||||||
CAST(SUM(IFNULL(i.stems, 1) * s.quantity) AS DECIMAL(10,2)) stems,
|
iii.amount subtotal
|
||||||
CAST(SUM(CAST(IFNULL(i.stems, 1) * s.quantity * IF(ic.grams, ic.grams, i.density * ic.cm3delivery / 1000) / 1000 AS DECIMAL(10,2)) *
|
FROM vn.invoiceInIntrastat iii
|
||||||
IF(sub.weight, sub.weight / vn.invoiceOut_getWeight(?), 1)) AS DECIMAL(10,2)) netKg,
|
LEFT JOIN vn.invoiceIn ii ON ii.id = iii.invoiceInFk
|
||||||
CAST(SUM((s.quantity * s.price * (100 - s.discount) / 100 )) AS DECIMAL(10,2)) subtotal
|
LEFT JOIN vn.invoiceOut io ON io.ref = ii.supplierRef
|
||||||
FROM vn.ticket t
|
LEFT JOIN vn.intrastat ir ON ir.id = iii.intrastatFk
|
||||||
JOIN vn.sale s ON s.ticketFk = t.id
|
WHERE io.`ref` = ?
|
||||||
JOIN vn.item i ON i.id = s.itemFk
|
UNION ALL
|
||||||
JOIN vn.itemCost ic ON ic.itemFk = i.id AND ic.warehouseFk = t.warehouseFk
|
SELECT NULL code,
|
||||||
JOIN vn.intrastat ir ON ir.id = i.intrastatFk
|
'Servicios' description,
|
||||||
LEFT JOIN (
|
0 stems,
|
||||||
SELECT t2.weight
|
0 netKg,
|
||||||
FROM vn.ticket t2
|
IF(CAST(SUM((ts.quantity * ts.price)) AS DECIMAL(10,2)), CAST(SUM((ts.quantity * ts.price)) AS DECIMAL(10,2)), 0) subtotal
|
||||||
WHERE refFk = ? AND weight
|
FROM vn.ticketService ts
|
||||||
LIMIT 1
|
JOIN vn.ticket t ON ts.ticketFk = t.id
|
||||||
) sub ON TRUE
|
WHERE t.refFk = ?
|
||||||
WHERE t.refFk = ?
|
) sub
|
||||||
AND i.intrastatFk
|
WHERE io.ref = ? AND ios.isCEE
|
||||||
GROUP BY i.intrastatFk
|
ORDER BY sub.code;
|
||||||
UNION ALL
|
|
||||||
SELECT
|
|
||||||
NULL AS refFk,
|
|
||||||
NULL AS code,
|
|
||||||
NULL AS description,
|
|
||||||
0 AS stems,
|
|
||||||
0 AS netKg,
|
|
||||||
IF(CAST(SUM((ts.quantity * ts.price)) AS DECIMAL(10,2)), CAST(SUM((ts.quantity * ts.price)) AS DECIMAL(10,2)), 0) AS subtotal
|
|
||||||
FROM vn.ticketService ts
|
|
||||||
JOIN vn.ticket t ON ts.ticketFk = t.id
|
|
||||||
WHERE t.refFk = ?) sub
|
|
||||||
WHERE io.`ref` = ? AND ios.isCEE
|
|
||||||
ORDER BY sub.code;
|
|
||||||
|
|
Loading…
Reference in New Issue