diff --git a/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.config.js b/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.config.js
index 6984740435..1af8ce562b 100644
--- a/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.config.js
+++ b/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.config.js
@@ -25,6 +25,14 @@ function UnbalancedInvoicePaymentsConfigController($sce, Notify, SavedReports, A
delete vm.reportDetails.debtorGroupUuid;
};
+ vm.clear = (key) => {
+ delete vm.reportDetails[key];
+ };
+
+ vm.onSelectService = service => {
+ vm.reportDetails.serviceId = service.id;
+ };
+
vm.clearPreview = function clearPreview() {
vm.previewGenerated = false;
vm.previewResult = null;
diff --git a/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.html b/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.html
index d41e5c0f0d..325f936263 100644
--- a/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.html
+++ b/client/src/modules/reports/generate/unpaid-invoice-payments/unpaid-invoice-payments.html
@@ -39,6 +39,15 @@
REPORT.UNPAID_INVOICE_PAYMENTS_REPORT.TITL
+
+
+
+
+
+
+
REPORT.UTIL.PREVIEW
diff --git a/server/controllers/finance/reports/unpaid-invoice-payments/index.js b/server/controllers/finance/reports/unpaid-invoice-payments/index.js
index c97e13c1c0..5dea1f1757 100644
--- a/server/controllers/finance/reports/unpaid-invoice-payments/index.js
+++ b/server/controllers/finance/reports/unpaid-invoice-payments/index.js
@@ -51,7 +51,11 @@ async function getUnbalancedInvoices(options) {
new Date(options.dateTo),
];
- const wherePart = options.debtorGroupName ? `WHERE debtorGroupName = ${db.escape(options.debtorGroupName)}` : '';
+ const { debtorGroupName, serviceId } = options;
+ let wherePart = debtorGroupName ? `WHERE debtorGroupName = ${db.escape(debtorGroupName)}` : '';
+ if (serviceId) {
+ wherePart = (wherePart.length < 2) ? `WHERE serviceID=${serviceId}` : `${wherePart} AND serviceId=${serviceId}`;
+ }
const rows = await db.transaction()
.addQuery('CALL UnbalancedInvoicePaymentsTable(?, ?);', params)
@@ -101,7 +105,6 @@ async function getUnbalancedInvoices(options) {
if (!row.debtorGroupName) {
row.isGroupTotalRow = true;
}
-
// add pretty debtor names
const debtor = debtorNameMap[row.debtorUuid];
if (debtor) {
diff --git a/server/models/migrations/next/migrations.sql b/server/models/migrations/next/migrations.sql
new file mode 100644
index 0000000000..52331e6d99
--- /dev/null
+++ b/server/models/migrations/next/migrations.sql
@@ -0,0 +1,190 @@
+delimiter $$
+
+-- this Procedure help to make quick analyse about unbalanced invoice
+-- it create a table name 'unbalancedInvoices' that can be used by the analyser
+DROP PROCEDURE IF EXISTS UnbalancedInvoicePaymentsTable$$
+CREATE PROCEDURE UnbalancedInvoicePayments(
+ IN dateFrom DATE,
+ IN dateTo DATE
+) BEGIN
+
+ -- this holds all the invoices that were made during the period
+ -- two copies are needed for the UNION ALL query.
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoices_1;
+ CREATE TEMPORARY TABLE tmp_invoices_1 (INDEX uuid (uuid)) AS
+ SELECT invoice.uuid, invoice.debtor_uuid, invoice.date
+ FROM invoice
+ WHERE
+ DATE(invoice.date) BETWEEN DATE(dateFrom) AND DATE(dateTo)
+ AND reversed = 0
+ ORDER BY invoice.date;
+
+ DROP TABLE IF EXISTS tmp_invoices_2;
+ CREATE TEMPORARY TABLE tmp_invoices_2 AS SELECT * FROM tmp_invoices_1;
+
+ -- This holds the invoices from the PJ/GL
+ DROP TEMPORARY TABLE IF EXISTS tmp_records;
+ CREATE TEMPORARY TABLE tmp_records AS
+ SELECT ledger.record_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
+ FROM (
+ SELECT pj.record_uuid, pj.debit_equiv, pj.credit_equiv
+ FROM posting_journal pj
+ JOIN tmp_invoices_1 i ON i.uuid = pj.record_uuid
+ AND pj.entity_uuid = i.debtor_uuid
+
+ UNION ALL
+
+ SELECT gl.record_uuid, gl.debit_equiv, gl.credit_equiv
+ FROM general_ledger gl
+ JOIN tmp_invoices_2 i ON i.uuid = gl.record_uuid
+ AND gl.entity_uuid = i.debtor_uuid
+ ) AS ledger;
+
+ -- this holds the references/payments against the invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_references;
+ CREATE TEMPORARY TABLE tmp_references AS
+ SELECT ledger.reference_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
+ FROM (
+ SELECT pj.reference_uuid, pj.debit_equiv, pj.credit_equiv
+ FROM posting_journal pj
+ JOIN tmp_invoices_1 i ON i.uuid = pj.reference_uuid
+ AND pj.entity_uuid = i.debtor_uuid
+
+ UNION ALL
+
+ SELECT gl.reference_uuid, gl.debit_equiv, gl.credit_equiv
+ FROM general_ledger gl
+ JOIN tmp_invoices_2 i ON i.uuid = gl.reference_uuid
+ AND gl.entity_uuid = i.debtor_uuid
+ ) AS ledger;
+
+ -- combine invoices and references to get the balance of each invoice.
+ -- note that we filter out balanced invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoice_balances;
+ CREATE TEMPORARY TABLE tmp_invoice_balances AS
+ SELECT z.uuid, SUM(z.debit_equiv) AS debit_equiv,
+ SUM(z.credit_equiv) AS credit_equiv,
+ SUM(z.debit_equiv) - SUM(z.credit_equiv) AS balance
+ FROM (
+ SELECT i.uuid, i.debit_equiv, i.credit_equiv FROM tmp_records i
+ UNION ALL
+ SELECT p.uuid, p.debit_equiv, p.credit_equiv FROM tmp_references p
+ )z
+ GROUP BY z.uuid
+ HAVING balance <> 0;
+
+ -- even though this column is called "balance", it is actually the amount remaining
+ -- on the invoice.
+ SELECT em.text AS debtorReference, debtor.text AS debtorName, balances.debit_equiv AS debit,
+ balances.credit_equiv AS credit, iv.date AS creation_date, balances.balance,
+ (balances.credit_equiv / IF(balances.debit_equiv = 0, 1, balances.debit_equiv )) AS paymentPercentage,
+ dm.text AS reference
+ FROM tmp_invoices_1 AS iv
+ JOIN tmp_invoice_balances AS balances ON iv.uuid = balances.uuid
+ LEFT JOIN document_map AS dm ON dm.uuid = iv.uuid
+ JOIN debtor ON debtor.uuid = iv.debtor_uuid
+ LEFT JOIN entity_map AS em ON em.uuid = iv.debtor_uuid
+ ORDER BY iv.date;
+END$$
+
+
+-- this Procedure help to make quick analyse about unbalanced invoice
+-- it create a table name 'unbalancedInvoices' that can be used by the analyser
+DROP PROCEDURE IF EXISTS UnbalancedInvoicePaymentsTable$$
+CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
+ IN dateFrom DATE,
+ IN dateTo DATE
+) BEGIN
+
+ -- this holds all the invoices that were made during the period
+ -- two copies are needed for the UNION ALL query.
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoices_1;
+ CREATE TEMPORARY TABLE tmp_invoices_1 (INDEX uuid (uuid)) AS
+ SELECT invoice.uuid, invoice.debtor_uuid, invoice.date
+ FROM invoice
+ WHERE
+ DATE(invoice.date) BETWEEN DATE(dateFrom) AND DATE(dateTo)
+ AND reversed = 0
+ ORDER BY invoice.date;
+
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoices_2;
+ CREATE TEMPORARY TABLE tmp_invoices_2 AS SELECT * FROM tmp_invoices_1;
+
+ DROP TEMPORARY TABLE IF EXISTS tmp_records;
+ -- This holds the invoices from the PJ/GL
+ CREATE TEMPORARY TABLE tmp_records AS
+ SELECT ledger.record_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
+ FROM (
+ SELECT pj.record_uuid, pj.debit_equiv, pj.credit_equiv
+ FROM posting_journal pj
+ JOIN tmp_invoices_1 i ON i.uuid = pj.record_uuid
+ AND pj.entity_uuid = i.debtor_uuid
+
+ UNION ALL
+
+ SELECT gl.record_uuid, gl.debit_equiv, gl.credit_equiv
+ FROM general_ledger gl
+ JOIN tmp_invoices_2 i ON i.uuid = gl.record_uuid
+ AND gl.entity_uuid = i.debtor_uuid
+ ) AS ledger;
+
+ -- this holds the references/payments against the invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_references;
+ CREATE TEMPORARY TABLE tmp_references AS
+ SELECT ledger.reference_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
+ FROM (
+ SELECT pj.reference_uuid, pj.debit_equiv, pj.credit_equiv
+ FROM posting_journal pj
+ JOIN tmp_invoices_1 i ON i.uuid = pj.reference_uuid
+ AND pj.entity_uuid = i.debtor_uuid
+
+ UNION ALL
+
+ SELECT gl.reference_uuid, gl.debit_equiv, gl.credit_equiv
+ FROM general_ledger gl
+ JOIN tmp_invoices_2 i ON i.uuid = gl.reference_uuid
+ AND gl.entity_uuid = i.debtor_uuid
+ ) AS ledger;
+
+ -- combine invoices and references to get the balance of each invoice.
+ -- note that we filter out balanced invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoice_balances;
+ CREATE TEMPORARY TABLE tmp_invoice_balances AS
+ SELECT z.uuid, SUM(z.debit_equiv) AS debit_equiv,
+ SUM(z.credit_equiv) AS credit_equiv,
+ SUM(z.debit_equiv) - SUM(z.credit_equiv) AS balance
+ FROM (
+ SELECT i.uuid, i.debit_equiv, i.credit_equiv FROM tmp_records i
+ UNION ALL
+ SELECT p.uuid, p.debit_equiv, p.credit_equiv FROM tmp_references p
+ )z
+ GROUP BY z.uuid
+ HAVING balance <> 0;
+
+ -- even though this column is called "balance", it is actually the amount remaining
+ -- on the invoice.
+
+ DROP TEMPORARY TABLE IF EXISTS unbalanced_invoices;
+ CREATE TEMPORARY TABLE `unbalanced_invoices` AS (
+ SELECT BUID(ivc.uuid) as invoice_uuid , em.text AS debtorReference, debtor.text AS debtorName,
+ BUID(debtor.uuid) as debtorUuid,
+ balances.debit_equiv AS debit,
+ balances.credit_equiv AS credit, iv.date AS creation_date, balances.balance,
+ dm.text AS reference, ivc.project_id, p.name as 'projectName', dbtg.name as 'debtorGroupName',
+ s.name as 'serviceName', s.id as 'serviceId',
+ ((balances.credit_equiv / IF(balances.debit_equiv = 0, 1, balances.debit_equiv )*100)) AS paymentPercentage
+ FROM tmp_invoices_1 AS iv
+ JOIN invoice ivc ON ivc.uuid = iv.uuid
+ JOIN service s On s.id = ivc.service_id
+ JOIN debtor dbt ON ivc.debtor_uuid = dbt.uuid
+ JOIN debtor_group dbtg ON dbtg.uuid = dbt.group_uuid
+ JOIN project p ON p.id = ivc.project_id
+ JOIN tmp_invoice_balances AS balances ON iv.uuid = balances.uuid
+ LEFT JOIN document_map AS dm ON dm.uuid = iv.uuid
+ JOIN debtor ON debtor.uuid = iv.debtor_uuid
+ LEFT JOIN entity_map AS em ON em.uuid = iv.debtor_uuid
+ ORDER BY iv.date
+ );
+END$$
+
+DELIMITER ;
\ No newline at end of file
diff --git a/server/models/procedures/analysis.sql b/server/models/procedures/analysis.sql
index 9223cfc746..c5944ad062 100644
--- a/server/models/procedures/analysis.sql
+++ b/server/models/procedures/analysis.sql
@@ -11,30 +11,34 @@ CREATE PROCEDURE Pivot(
IN pivot_col VARCHAR(64), -- name of column to put across the top
IN tally_col VARCHAR(64), -- name of column to SUM up
IN where_clause VARCHAR(99), -- empty string or "WHERE ..."
- IN order_by VARCHAR(99) -- empty string or "ORDER BY ..."; usually the base_cols
+ IN order_by VARCHAR(99) -- empty string or "ORDER BY ..."; usually the base_cols
)
DETERMINISTIC
SQL SECURITY INVOKER
BEGIN
+
-- Find the distinct values
-- Build the SUM()s
SET @subq = CONCAT('SELECT DISTINCT ', pivot_col, ' AS val ',
- ' FROM ', tbl_name, ' ', where_clause, ' ORDER BY 1');
+ ' FROM ', tbl_name, ' ', where_clause, ' ORDER BY 1') COLLATE utf8mb4_unicode_ci;
-- select @subq;
- SET @cc1 = "CONCAT('SUM(IF(&p = ', &v, ', &t, 0)) AS ', &v)";
- SET @cc2 = REPLACE(@cc1, '&p', pivot_col);
- SET @cc3 = REPLACE(@cc2, '&t', tally_col);
+ SET @cc1 = "CONCAT('SUM(IF(&p = ', &v, ', &t, 0)) AS ', &v)" COLLATE utf8mb4_unicode_ci;
+
+ SET @cc2 = REPLACE(@cc1, '&p' , pivot_col) COLLATE utf8mb4_unicode_ci;
+
+ SET @cc3 = REPLACE(@cc2, '&t', tally_col) COLLATE utf8mb4_unicode_ci;
-- select @cc2, @cc3;
- SET @qval = CONCAT("'\"', val, '\"'");
+ SET @qval = CONCAT("'\"', val, '\"'") COLLATE utf8mb4_unicode_ci;
-- select @qval;
- SET @cc4 = REPLACE(@cc3, '&v', @qval);
+ SET @cc4 = REPLACE(@cc3, '&v', @qval) COLLATE utf8mb4_unicode_ci;
-- select @cc4;
SET SESSION group_concat_max_len = 10000; -- just in case
SET @stmt = CONCAT(
'SELECT GROUP_CONCAT(', @cc4, ' SEPARATOR ",\n") INTO @sums',
- ' FROM ( ', @subq, ' ) AS top');
+ ' FROM ( ', @subq, ' ) AS top') COLLATE utf8mb4_unicode_ci;
+
SELECT @stmt;
PREPARE _sql FROM @stmt;
EXECUTE _sql; -- Intermediate step: build SQL for columns
@@ -50,7 +54,8 @@ BEGIN
' GROUP BY ', base_cols,
'\n WITH ROLLUP',
'\n', order_by
- );
+ ) COLLATE utf8mb4_unicode_ci;
+
SELECT @stmt2; -- The statement that generates the result
PREPARE _sql FROM @stmt2;
EXECUTE _sql; -- The resulting pivot table ouput
diff --git a/server/models/procedures/invoicing.sql b/server/models/procedures/invoicing.sql
index 776ef5671c..713db57d43 100644
--- a/server/models/procedures/invoicing.sql
+++ b/server/models/procedures/invoicing.sql
@@ -800,7 +800,7 @@ CREATE PROCEDURE UnbalancedInvoicePayments(
-- this holds all the invoices that were made during the period
-- two copies are needed for the UNION ALL query.
DROP TABLE IF EXISTS tmp_invoices_1;
- CREATE TABLE tmp_invoices_1 (INDEX uuid (uuid)) AS
+ CREATE TEMPORARY TABLE tmp_invoices_1 (INDEX uuid (uuid)) AS
SELECT invoice.uuid, invoice.debtor_uuid, invoice.date
FROM invoice
WHERE
@@ -809,10 +809,10 @@ CREATE PROCEDURE UnbalancedInvoicePayments(
ORDER BY invoice.date;
DROP TABLE IF EXISTS tmp_invoices_2;
- CREATE TABLE tmp_invoices_2 AS SELECT * FROM tmp_invoices_1;
+ CREATE TEMPORARY TABLE tmp_invoices_2 AS SELECT * FROM tmp_invoices_1;
-- This holds the invoices from the PJ/GL
- DROP TABLE IF EXISTS tmp_records;
+ DROP TEMPORARY TABLE IF EXISTS tmp_records;
CREATE TABLE tmp_records AS
SELECT ledger.record_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
FROM (
@@ -831,7 +831,7 @@ CREATE PROCEDURE UnbalancedInvoicePayments(
-- this holds the references/payments against the invoices
DROP TABLE IF EXISTS tmp_references;
- CREATE TABLE tmp_references AS
+ CREATE TEMPORARY TABLE tmp_references AS
SELECT ledger.reference_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
FROM (
SELECT pj.reference_uuid, pj.debit_equiv, pj.credit_equiv
@@ -850,7 +850,7 @@ CREATE PROCEDURE UnbalancedInvoicePayments(
-- combine invoices and references to get the balance of each invoice.
-- note that we filter out balanced invoices
DROP TABLE IF EXISTS tmp_invoice_balances;
- CREATE TABLE tmp_invoice_balances AS
+ CREATE TEMPORARY TABLE tmp_invoice_balances AS
SELECT z.uuid, SUM(z.debit_equiv) AS debit_equiv,
SUM(z.credit_equiv) AS credit_equiv,
SUM(z.debit_equiv) - SUM(z.credit_equiv) AS balance
@@ -887,6 +887,7 @@ CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
-- this holds all the invoices that were made during the period
-- two copies are needed for the UNION ALL query.
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoices_1;
CREATE TEMPORARY TABLE tmp_invoices_1 (INDEX uuid (uuid)) AS
SELECT invoice.uuid, invoice.debtor_uuid, invoice.date
FROM invoice
@@ -895,8 +896,10 @@ CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
AND reversed = 0
ORDER BY invoice.date;
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoices_2;
CREATE TEMPORARY TABLE tmp_invoices_2 AS SELECT * FROM tmp_invoices_1;
-
+
+ DROP TEMPORARY TABLE IF EXISTS tmp_records;
-- This holds the invoices from the PJ/GL
CREATE TEMPORARY TABLE tmp_records AS
SELECT ledger.record_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
@@ -915,6 +918,7 @@ CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
) AS ledger;
-- this holds the references/payments against the invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_references;
CREATE TEMPORARY TABLE tmp_references AS
SELECT ledger.reference_uuid AS uuid, ledger.debit_equiv, ledger.credit_equiv
FROM (
@@ -933,6 +937,7 @@ CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
-- combine invoices and references to get the balance of each invoice.
-- note that we filter out balanced invoices
+ DROP TEMPORARY TABLE IF EXISTS tmp_invoice_balances;
CREATE TEMPORARY TABLE tmp_invoice_balances AS
SELECT z.uuid, SUM(z.debit_equiv) AS debit_equiv,
SUM(z.credit_equiv) AS credit_equiv,
@@ -948,13 +953,14 @@ CREATE PROCEDURE UnbalancedInvoicePaymentsTable(
-- even though this column is called "balance", it is actually the amount remaining
-- on the invoice.
+ DROP TEMPORARY TABLE IF EXISTS unbalanced_invoices;
CREATE TEMPORARY TABLE `unbalanced_invoices` AS (
SELECT BUID(ivc.uuid) as invoice_uuid , em.text AS debtorReference, debtor.text AS debtorName,
BUID(debtor.uuid) as debtorUuid,
balances.debit_equiv AS debit,
balances.credit_equiv AS credit, iv.date AS creation_date, balances.balance,
dm.text AS reference, ivc.project_id, p.name as 'projectName', dbtg.name as 'debtorGroupName',
- s.name as 'serviceName',
+ s.name as 'serviceName', s.id as 'serviceId',
((balances.credit_equiv / IF(balances.debit_equiv = 0, 1, balances.debit_equiv )*100)) AS paymentPercentage
FROM tmp_invoices_1 AS iv
JOIN invoice ivc ON ivc.uuid = iv.uuid