DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceOut_new`( vSerial VARCHAR(255), vInvoiceDate DATE, vTaxArea VARCHAR(25), OUT vNewInvoiceId INT) BEGIN /** * Creación de facturas emitidas. * requiere previamente tabla tmp.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 vIsAnySaleToInvoice BOOL; DECLARE vIsAnyServiceToInvoice BOOL; DECLARE vNewRef VARCHAR(255); DECLARE vWorker INT DEFAULT account.myUser_getId(); DECLARE vCompanyFk INT; DECLARE vInterCompanyFk INT; DECLARE vClientFk 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 vNewInvoiceInFk INT; DECLARE vIsInterCompany BOOL DEFAULT FALSE; DECLARE vIsCEESerial BOOL DEFAULT FALSE; DECLARE vIsCorrectInvoiceDate BOOL; DECLARE vMaxShipped DATE; DECLARE vDone BOOL; DECLARE vTicketFk INT; DECLARE vCursor CURSOR FOR SELECT id FROM tmp.ticketToInvoice; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; SET vInvoiceDate = IFNULL(vInvoiceDate, util.VN_CURDATE()); SELECT t.clientFk, t.companyFk, MAX(DATE(t.shipped)), DATE(vInvoiceDate) >= invoiceOut_getMaxIssued( vSerial, t.companyFk, YEAR(vInvoiceDate)) INTO vClientFk, vCompanyFk, vMaxShipped, vIsCorrectInvoiceDate FROM tmp.ticketToInvoice tt JOIN ticket t ON t.id = tt.id; IF(vMaxShipped > vInvoiceDate) THEN CALL util.throw("Invoice date can't be less than max date"); END IF; IF NOT vIsCorrectInvoiceDate THEN CALL util.throw('Exists an invoice with a previous date'); END IF; -- Eliminem de tmp.ticketToInvoice els tickets que no han de ser facturats DELETE ti.* FROM tmp.ticketToInvoice ti JOIN ticket t ON t.id = ti.id LEFT JOIN address a ON a.id = t.addressFk 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 AND t.isDeleted) OR c.isTaxDataChecked = FALSE OR t.isDeleted OR c.hasToInvoice = FALSE OR itc.id IS NULL OR a.id IS NULL OR (vTaxArea = 'WORLD' AND (a.customsAgentFk IS NULL OR a.incotermsFk IS NULL)); SELECT SUM(s.quantity * s.price * (100 - s.discount)/100) <> 0 INTO vIsAnySaleToInvoice FROM tmp.ticketToInvoice t JOIN sale s ON s.ticketFk = t.id; SELECT COUNT(*) > 0 INTO vIsAnyServiceToInvoice FROM tmp.ticketToInvoice t 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, siiTypeInvoiceOutFk ) SELECT 1, vSerial, vInvoiceDate, vClientFk, getDueDate(vInvoiceDate, dueDay), vCompanyFk, IF(vSerial = vCorrectingSerial, vCplusCorrectingInvoiceTypeFk, IF(vSerial = vSimplifiedSerial, vCplusSimplifiedInvoiceTypeFk, vCplusStandardInvoiceTypeFk)) FROM client WHERE id = vClientFk; SET vNewInvoiceId = LAST_INSERT_ID(); SELECT `ref` INTO vNewRef FROM invoiceOut WHERE id = vNewInvoiceId; OPEN vCursor; l: LOOP SET vDone = FALSE; FETCH vCursor INTO vTicketFk; IF vDone THEN LEAVE l; END IF; CALL ticket_recalc(vTicketFk, vTaxArea); END LOOP; CLOSE vCursor; UPDATE ticket t JOIN tmp.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 tmp.ticketToInvoice ti LEFT JOIN ticketState ts ON ti.id = ts.ticketFk JOIN state s WHERE IFNULL(ts.alertLevel, 0) < 3 and s.`code` = getAlert3State(ti.id); INSERT INTO ticketTracking(stateFk, ticketFk, userFk) SELECT * FROM tmp.updateInter; CALL invoiceExpenseMake(vNewInvoiceId); CALL invoiceTaxMake(vNewInvoiceId, vTaxArea); UPDATE invoiceOut io JOIN ( SELECT SUM(amount) total FROM invoiceOutExpense WHERE invoiceOutFk = vNewInvoiceId ) base JOIN ( SELECT SUM(vat) total FROM invoiceOutTax WHERE invoiceOutFk = vNewInvoiceId ) vat SET io.amount = base.total + vat.total WHERE io.id = vNewInvoiceId; DROP TEMPORARY TABLE tmp.updateInter; SELECT COUNT(*), id INTO vIsInterCompany, vInterCompanyFk FROM company WHERE clientFk = vClientFk; IF (vIsInterCompany) THEN INSERT INTO invoiceIn(supplierFk, supplierRef, issued, companyFk) SELECT vCompanyFk, vNewRef, vInvoiceDate, vInterCompanyFk; SET vNewInvoiceInFk = LAST_INSERT_ID(); DROP TEMPORARY TABLE IF EXISTS tmp.ticket; CREATE TEMPORARY TABLE tmp.ticket (KEY (ticketFk)) ENGINE = MEMORY SELECT id ticketFk FROM tmp.ticketToInvoice; CALL `ticket_getTax`('NATIONAL'); SET @vTaxableBaseServices := 0.00; SET @vTaxCodeGeneral := NULL; INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk) SELECT vNewInvoiceInFk, @vTaxableBaseServices, sub.expenseFk, sub.taxTypeSageFk, sub.transactionTypeSageFk FROM ( SELECT @vTaxableBaseServices := SUM(tst.taxableBase) taxableBase, i.expenseFk, i.taxTypeSageFk, i.transactionTypeSageFk, @vTaxCodeGeneral := i.taxClassCodeFk FROM tmp.ticketServiceTax tst JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tst.code WHERE i.isService HAVING taxableBase ) sub; INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk) SELECT vNewInvoiceInFk, SUM(tt.taxableBase) - IF(tt.code = @vTaxCodeGeneral, @vTaxableBaseServices, 0) taxableBase, i.expenseFk, i.taxTypeSageFk , i.transactionTypeSageFk FROM tmp.ticketTax tt JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tt.code WHERE !i.isService GROUP BY tt.pgcFk HAVING taxableBase ORDER BY tt.priority; CALL invoiceInDueDay_calculate(vNewInvoiceInFk); SELECT COUNT(*) INTO vIsCEESerial FROM invoiceOutSerial WHERE code = vSerial; IF vIsCEESerial THEN INSERT INTO invoiceInIntrastat ( invoiceInFk, intrastatFk, amount, stems, countryFk, net) SELECT vNewInvoiceInFk, i.intrastatFk, SUM(CAST((s.quantity * s.price * (100 - s.discount) / 100 ) AS DECIMAL(10, 2))), SUM(CAST(IFNULL(i.stems, 1) * s.quantity AS DECIMAL(10, 2))), su.countryFk, CAST(SUM(IFNULL(i.stems, 1) * s.quantity * IF(ic.grams, ic.grams, IFNULL(i.weightByPiece, 0)) / 1000) AS DECIMAL(10, 2)) 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 LEFT JOIN itemCost ic ON ic.itemFk = i.id AND ic.warehouseFk = t.warehouseFk WHERE t.refFk = vNewRef GROUP BY i.intrastatFk; END IF; 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 `tmp`.`ticketToInvoice`; END$$ DELIMITER ;