DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE vn.supplier_statementWithEntries( vSupplierFk INT, vCurrencyFk INT, vCompanyFk INT, vOrderBy VARCHAR(15), vIsConciliated BOOL, vHasEntries BOOL ) BEGIN /** * Creates a supplier statement, calculating balances in euros and the specified currency. * * @param vSupplierFk Supplier ID * @param vCurrencyFk Currency ID * @param vCompanyFk Company ID * @param vOrderBy Order by criteria * @param vIsConciliated Indicates whether it is reconciled or not * @param vHasEntries Indicates if future entries must be shown * @return tmp.supplierStatement */ DECLARE vBalanceStartingDate DATETIME; SET @euroBalance:= 0; SET @currencyBalance:= 0; SELECT balanceStartingDate INTO vBalanceStartingDate FROM invoiceInConfig; CREATE OR REPLACE TEMPORARY TABLE tmp.supplierStatement ENGINE = MEMORY SELECT *, @euroBalance:= ROUND( @euroBalance + IFNULL(paymentEuros, 0) - IFNULL(invoiceEuros, 0), 2 ) euroBalance, @currencyBalance:= ROUND( @currencyBalance + IFNULL(paymentCurrency, 0) - IFNULL(invoiceCurrency, 0), 2 ) currencyBalance FROM ( SELECT NULL bankFk, ii.companyFk, ii.serial, ii.id, CASE WHEN vOrderBy = 'issued' THEN ii.issued WHEN vOrderBy = 'bookEntried' THEN ii.bookEntried WHEN vOrderBy = 'booked' THEN ii.booked WHEN vOrderBy = 'dueDate' THEN iid.dueDated END dated, CONCAT('S/Fra ', ii.supplierRef) sref, IF(ii.currencyFk > 1, ROUND(SUM(iid.foreignValue) / SUM(iid.amount), 3), NULL ) changeValue, CAST(SUM(iid.amount) AS DECIMAL(10,2)) invoiceEuros, CAST(SUM(iid.foreignValue) AS DECIMAL(10,2)) invoiceCurrency, NULL paymentEuros, NULL paymentCurrency, ii.currencyFk, ii.isBooked, c.code, 'invoiceIn' statementType FROM invoiceIn ii JOIN invoiceInDueDay iid ON iid.invoiceInFk = ii.id JOIN currency c ON c.id = ii.currencyFk WHERE ii.issued >= vBalanceStartingDate AND ii.supplierFk = vSupplierFk AND vCurrencyFk IN (ii.currencyFk, 0) AND vCompanyFk IN (ii.companyFk, 0) AND (vIsConciliated = ii.isBooked OR NOT vIsConciliated) GROUP BY iid.id UNION ALL SELECT p.bankFk, p.companyFk, NULL, p.id, CASE WHEN vOrderBy = 'issued' THEN p.received WHEN vOrderBy = 'bookEntried' THEN p.received WHEN vOrderBy = 'booked' THEN p.received WHEN vOrderBy = 'dueDate' THEN p.dueDated END, CONCAT(IFNULL(pm.name, ''), IF(pn.concept <> '', CONCAT(' : ', pn.concept), '') ), IF(p.currencyFk > 1, p.divisa / p.amount, NULL), NULL, NULL, p.amount, p.divisa, p.currencyFk, p.isConciliated, c.code, 'payment' FROM payment p LEFT JOIN currency c ON c.id = p.currencyFk LEFT JOIN accounting a ON a.id = p.bankFk LEFT JOIN payMethod pm ON pm.id = p.payMethodFk LEFT JOIN promissoryNote pn ON pn.paymentFk = p.id WHERE p.received >= vBalanceStartingDate AND p.supplierFk = vSupplierFk AND vCurrencyFk IN (p.currencyFk, 0) AND vCompanyFk IN (p.companyFk, 0) AND (vIsConciliated = p.isConciliated OR NOT vIsConciliated) UNION ALL SELECT NULL, companyFk, NULL, se.id, CASE WHEN vOrderBy = 'issued' THEN se.dated WHEN vOrderBy = 'bookEntried' THEN se.dated WHEN vOrderBy = 'booked' THEN se.dated WHEN vOrderBy = 'dueDate' THEN se.dueDated END, se.description, 1, amount, NULL, NULL, NULL, currencyFk, isConciliated, c.`code`, 'expense' FROM supplierExpense se JOIN currency c ON c.id = se.currencyFk WHERE se.supplierFk = vSupplierFk AND vCurrencyFk IN (se.currencyFk,0) AND vCompanyFk IN (se.companyFk,0) AND (vIsConciliated = se.isConciliated OR NOT vIsConciliated) UNION ALL SELECT NULL bankFk, e.companyFk, 'E' serial, e.invoiceNumber id, tr.landed dated, CONCAT('Ent. ',e.id) sref, 1 / ((e.commission/100)+1) changeValue, e.invoiceAmount * (1 + (e.commission/100)), e.invoiceAmount, NULL, NULL, e.currencyFk, FALSE isBooked, c.code, 'order' FROM entry e JOIN travel tr ON tr.id = e.travelFk JOIN currency c ON c.id = e.currencyFk WHERE e.supplierFk = vSupplierFk AND tr.landed >= CURDATE() AND e.invoiceInFk IS NULL AND vHasEntries ORDER BY (dated IS NULL AND NOT isBooked), dated, IF(vOrderBy = 'dueDate', id, NULL) LIMIT 10000000000000000000 ) t; END$$ DELIMITER ;