mirror of https://github.com/itflow-org/itflow
Add collections report
This commit is contained in:
parent
f18bb340bf
commit
73e14c164b
|
|
@ -0,0 +1,118 @@
|
|||
<?php
|
||||
require_once "inc_all_reports.php";
|
||||
|
||||
validateAccountantRole();
|
||||
|
||||
// Fetch Accounts and their balances
|
||||
$sql_client_balance_report = "
|
||||
SELECT
|
||||
clients.client_id,
|
||||
clients.client_name,
|
||||
IFNULL(SUM(invoices.invoice_amount), 0) - IFNULL(SUM(payments.payment_amount), 0) AS balance,
|
||||
contacts.contact_phone AS billing_contact_phone,
|
||||
IFNULL(recurring_totals.recurring_monthly_total, 0) AS recurring_monthly_total,
|
||||
(IFNULL(SUM(invoices.invoice_amount), 0) - IFNULL(SUM(payments.payment_amount), 0) - IFNULL(recurring_totals.recurring_monthly_total, 0)) AS behind_amount,
|
||||
CASE
|
||||
WHEN IFNULL(recurring_totals.recurring_monthly_total, 0) > 0 THEN
|
||||
(IFNULL(SUM(invoices.invoice_amount), 0) - IFNULL(SUM(payments.payment_amount), 0) - IFNULL(recurring_totals.recurring_monthly_total, 0)) / recurring_totals.recurring_monthly_total
|
||||
ELSE
|
||||
0
|
||||
END AS months_behind
|
||||
FROM
|
||||
clients
|
||||
LEFT JOIN
|
||||
invoices
|
||||
ON
|
||||
clients.client_id = invoices.invoice_client_id
|
||||
AND invoices.invoice_status NOT LIKE 'Draft'
|
||||
AND invoices.invoice_status NOT LIKE 'Cancelled'
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
payment_invoice_id,
|
||||
SUM(payment_amount) as payment_amount
|
||||
FROM payments
|
||||
GROUP BY payment_invoice_id) as payments
|
||||
ON
|
||||
invoices.invoice_id = payments.payment_invoice_id
|
||||
LEFT JOIN
|
||||
contacts
|
||||
ON
|
||||
clients.client_id = contacts.contact_client_id AND contacts.contact_billing = 1
|
||||
LEFT JOIN
|
||||
(SELECT
|
||||
recurring_client_id,
|
||||
SUM(recurring_amount) AS recurring_monthly_total
|
||||
FROM recurring
|
||||
WHERE recurring_status = 1 AND recurring_frequency = 'month'
|
||||
GROUP BY recurring_client_id) as recurring_totals
|
||||
ON
|
||||
clients.client_id = recurring_totals.recurring_client_id
|
||||
GROUP BY
|
||||
clients.client_id,
|
||||
clients.client_name,
|
||||
contacts.contact_phone,
|
||||
recurring_totals.recurring_monthly_total
|
||||
HAVING
|
||||
balance > 0 AND months_behind >= 2
|
||||
ORDER BY
|
||||
months_behind DESC;";
|
||||
$result_client_balance_report = mysqli_query($mysqli, $sql_client_balance_report);
|
||||
?>
|
||||
|
||||
<div class="card card-dark">
|
||||
<div class="card-header py-2">
|
||||
<h3 class="card-title mt-2"><i class="fas fa-fw fa-balance-scale mr-2"></i>Collections</h3>
|
||||
<div class="card-tools">
|
||||
<button type="button" class="btn btn-primary d-print-none" onclick="window.print();"><i class="fas fa-fw fa-print mr-2"></i>Print</button>
|
||||
</div>
|
||||
</div>
|
||||
<div class="card-body p-0">
|
||||
<div>
|
||||
<div class="table-responsive-sm">
|
||||
<table class="table table-sm">
|
||||
<thead class="text-dark">
|
||||
<tr>
|
||||
<th>Client Name</th>
|
||||
<th>Balance</th>
|
||||
<th>Billing Contact Phone</th>
|
||||
<th>Monthly Recurring Amount</th>
|
||||
<th>Past Due Balance</th>
|
||||
<th>Months Past Due</th>
|
||||
</tr>
|
||||
</thead>
|
||||
<tbody>
|
||||
<?php
|
||||
while ($row = mysqli_fetch_assoc($result_client_balance_report)) {
|
||||
$client_id = $row['client_id'];
|
||||
$client_name = nullable_htmlentities($row['client_name']);
|
||||
$balance = $row['balance'];
|
||||
$billing_contact_phone = nullable_htmlentities($row['billing_contact_phone']);
|
||||
$recurring_monthly_total = $row['recurring_monthly_total'];
|
||||
$behind_amount = $row['behind_amount'];
|
||||
$months_behind = $row['months_behind'];
|
||||
|
||||
$formatted_balance = numfmt_format_currency($currency_format, $balance, $config_currency_code);
|
||||
$formatted_recurring_monthly_total = numfmt_format_currency($currency_format, $recurring_monthly_total, $config_currency_code);
|
||||
$formatted_behind_amount = numfmt_format_currency($currency_format, $behind_amount, $config_currency_code);
|
||||
|
||||
echo "<tr>";
|
||||
echo "<td><a href='client_details.php?client_id=$client_id'>$client_name</a></td>";
|
||||
echo "<td class='text-right'>$formatted_balance</td>";
|
||||
echo "<td>$billing_contact_phone</td>";
|
||||
echo "<td class='text-right'>$formatted_recurring_monthly_total</td>";
|
||||
echo "<td class='text-right'>$formatted_behind_amount</td>";
|
||||
echo "<td class='text-right'>$months_behind</td>";
|
||||
echo "</tr>";
|
||||
}
|
||||
?>
|
||||
</tbody>
|
||||
</table>
|
||||
</div>
|
||||
</div>
|
||||
</div>
|
||||
</div>
|
||||
|
||||
<?php require_once "footer.php";
|
||||
|
||||
|
||||
?>
|
||||
|
|
@ -54,7 +54,7 @@
|
|||
</li>
|
||||
<li class="nav-item">
|
||||
<a href="report_budget.php" class="nav-link <?php if (basename($_SERVER["PHP_SELF"]) == "report_budget.php") { echo "active"; } ?>">
|
||||
<i class="fas fa-balance-scale nav-icon"></i>
|
||||
<i class="fas fa-list nav-icon"></i>
|
||||
<p>Budget</p>
|
||||
</a>
|
||||
</li>
|
||||
|
|
@ -66,7 +66,7 @@
|
|||
</li>
|
||||
<li class="nav-item">
|
||||
<a href="report_profit_loss.php" class="nav-link <?php if (basename($_SERVER["PHP_SELF"]) == "report_profit_loss.php") { echo "active"; } ?>">
|
||||
<i class="fas fa-balance-scale nav-icon"></i>
|
||||
<i class="fas fa-file-invoice-dollar nav-icon"></i>
|
||||
<p>Profit & Loss</p>
|
||||
</a>
|
||||
</li>
|
||||
|
|
@ -76,6 +76,12 @@
|
|||
<p>Balance Sheet</p>
|
||||
</a>
|
||||
</li>
|
||||
<li class="nav-item">
|
||||
<a href="report_collections.php" class="nav-link <?php if (basename($_SERVER["PHP_SELF"]) == "report_collections.php") { echo "active"; } ?>">
|
||||
<i class="fas fa-search-dollar nav-icon"></i>
|
||||
<p>Collections</p>
|
||||
</a>
|
||||
</li>
|
||||
<?php } // End financial reports IF statement ?>
|
||||
|
||||
<?php if ($session_user_role == 2 || $session_user_role == 3) { ?>
|
||||
|
|
|
|||
Loading…
Reference in New Issue