Working on aggregate charts

This commit is contained in:
David Bomba 2024-06-25 14:58:18 +10:00
parent 702d8992e5
commit 96766d33b8
5 changed files with 262 additions and 29 deletions

View File

@ -43,17 +43,19 @@ trait ChartQueries
return DB::select("
SELECT
sum(expenses.amount / IFNULL(CAST(JSON_UNQUOTE(JSON_EXTRACT(clients.settings, '$.currency_id')) AS SIGNED), :company_currency2)) as amount,
IFNULL(expenses.currency_id, :company_currency) as currency_id
SUM(
CASE
WHEN expenses.currency_id = :company_currency THEN amount
ELSE expenses.amount * expenses.exchange_rate
END
) AS amount
FROM expenses
JOIN clients
ON expenses.client_id=clients.id
WHERE expenses.is_deleted = 0
AND expenses.company_id = :company_id
AND (expenses.date BETWEEN :start_date AND :end_date)
{$user_filter}
GROUP BY currency_id
", ['company_currency2' => $this->company->settings->currency_id, 'company_currency' => $this->company->settings->currency_id, 'company_id' => $this->company->id, 'start_date' => $start_date, 'end_date' => $end_date]);
GROUP BY expenses.company_id
", ['company_currency' => $this->company->settings->currency_id, 'company_id' => $this->company->id, 'start_date' => $start_date, 'end_date' => $end_date]);
}
public function getAggregateExpenseChartQuery($start_date, $end_date)
@ -63,11 +65,14 @@ trait ChartQueries
return DB::select("
SELECT
sum(expenses.amount / IFNULL(CAST(JSON_UNQUOTE(JSON_EXTRACT(clients.settings, '$.currency_id')) AS SIGNED), :company_currency)) as total,
SUM(
CASE
WHEN expenses.currency_id = :company_currency THEN amount
ELSE expenses.amount * expenses.exchange_rate
END
) AS amount,
expenses.date
FROM expenses
JOIN clients
ON expenses.client_id=clients.id
WHERE (expenses.date BETWEEN :start_date AND :end_date)
AND expenses.company_id = :company_id
AND expenses.is_deleted = 0
@ -268,15 +273,17 @@ trait ChartQueries
return DB::select("
SELECT
sum((payments.amount - payments.refunded) * payments.exchange_rate) as paid_to_date,
payments.currency_id AS currency_id
sum((payments.amount - payments.refunded) / payments.exchange_rate) as paid_to_date
FROM payments
JOIN clients
ON payments.client_id=clients.id
WHERE payments.company_id = :company_id
AND payments.is_deleted = 0
AND clients.is_deleted = 0
{$user_filter}
AND payments.status_id IN (1,4,5,6)
AND (payments.date BETWEEN :start_date AND :end_date)
GROUP BY payments.currency_id
GROUP BY payments.company_id
", ['company_id' => $this->company->id, 'start_date' => $start_date, 'end_date' => $end_date]);
}
@ -290,8 +297,11 @@ trait ChartQueries
sum(payments.amount - payments.refunded) as paid_to_date,
payments.currency_id AS currency_id
FROM payments
JOIN clients
ON payments.client_id=clients.id
WHERE payments.company_id = :company_id
AND payments.is_deleted = 0
AND clients.is_deleted = 0
{$user_filter}
AND payments.status_id IN (1,4,5,6)
AND (payments.date BETWEEN :start_date AND :end_date)

View File

@ -134,10 +134,10 @@ class ChartService
$aggregate_expenses = $this->getAggregateExpenseQuery($start_date, $end_date);
$aggregate_invoices = $this->getAggregateInvoicesQuery($start_date, $end_date);
$data[999]['invoices'] = $aggregate_invoices !== false ? $aggregate_invoices : new \stdClass();
$data[999]['expense'] = $aggregate_expenses !== false ? $aggregate_expenses : new \stdClass();
$data[999]['outstanding'] = $aggregate_outstanding !== false ? $aggregate_outstanding : new \stdClass();
$data[999]['revenue'] = $aggregate_revenue !== false ? $aggregate_revenue : new \stdClass();
$data[999]['invoices'] = $aggregate_invoices !== false ? reset($aggregate_invoices) : new \stdClass();
$data[999]['expense'] = $aggregate_expenses !== false ? reset($aggregate_expenses) : new \stdClass();
$data[999]['outstanding'] = $aggregate_outstanding !== false ? reset($aggregate_outstanding) : new \stdClass();
$data[999]['revenue'] = $aggregate_revenue !== false ? reset($aggregate_revenue) : new \stdClass();
return $data;

View File

@ -660,7 +660,7 @@ class HtmlEngine
}
$data['$contact.signature_raw'] = ['value' => $this->invitation->signature_base64, 'label' => ctrans('texts.signature')];
$data['$contact.signature_date'] = ['value' => $this->translateDate($this->invitation->signature_date, $this->client->date_format(), $this->client->locale()), 'label' => ctrans('texts.date')];
$data['$contact.signature_date'] = ['value' => $this->translateDate($this->invitation->signature_date ?? '1970-01-01', $this->client->date_format(), $this->client->locale()), 'label' => ctrans('texts.date')];
$data['$contact.signature_ip'] = ['value' => $this->invitation->signature_ip ?? '', 'label' => ctrans('texts.address')];
$data['$thanks'] = ['value' => '', 'label' => ctrans('texts.thanks')];

View File

@ -78,7 +78,7 @@ trait MakesDates
*/
public function formatDatetime($date, string $format): string
{
return Carbon::createFromTimestamp((int)$date)->format($format.' g:i a');
return Carbon::createFromTimestamp((int) ($date ?? 0))->format($format.' g:i a');
}
/**

View File

@ -19,6 +19,7 @@ use App\Models\Currency;
use Tests\MockAccountData;
use App\DataMapper\ClientSettings;
use App\DataMapper\CompanySettings;
use App\Models\Expense;
use App\Services\Chart\ChartService;
use Illuminate\Foundation\Testing\DatabaseTransactions;
@ -86,30 +87,156 @@ class ChartCurrencyTest extends TestCase
]);
Invoice::factory()->create([
$i1 = Invoice::factory()->create([
'client_id' => $usd->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 0,
'paid_to_date' => 100,
'status_id' => 4,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()
]);
Invoice::factory()->create([
$i2 = Invoice::factory()->create([
'client_id' => $gbp->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 0,
'paid_to_date' => 100,
'status_id' => 4,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()
]);
$i1->service()->markPaid()->save();
$i2->service()->markPaid()->save();
$cs = new ChartService($company, $this->user, true);
$results = $cs->totals('1970-01-01', '2050-01-01');
$this->assertCount(2, $results['currencies']);
// nlog($results);
$this->assertEquals('USD', $results['currencies'][1]);
$this->assertEquals('GBP', $results['currencies'][2]);
$this->assertEquals(100, $results[1]['invoices']->invoiced_amount);
$this->assertEquals(100, $results[2]['invoices']->invoiced_amount);
$this->assertEquals(150, $results[999]['invoices']->invoiced_amount);
$this->assertEquals(150, $results[999]['revenue']->paid_to_date);
$usd->forceDelete();
$gbp->forceDelete();
}
public function testAggregateOutstanding()
{
$settings = CompanySettings::defaults();
$settings->company_logo = 'https://pdf.invoicing.co/favicon-v2.png';
$settings->website = 'www.invoiceninja.com';
$settings->address1 = 'Address 1';
$settings->address2 = 'Address 2';
$settings->city = 'City';
$settings->state = 'State';
$settings->postal_code = 'Postal Code';
$settings->phone = '555-343-2323';
$settings->email = '';
$settings->country_id = '840';
$settings->vat_number = 'vat number';
$settings->id_number = 'id number';
$settings->use_credits_payment = 'always';
$settings->timezone_id = '1';
$settings->entity_send_time = 0;
$company = Company::factory()->create([
'account_id' => $this->account->id,
'settings' => $settings,
]);
$settings = ClientSettings::defaults();
$settings->currency_id = '1'; //USD
$usd = Client::factory()->create([
'user_id' => $this->user->id,
'company_id' => $company->id,
'settings' => $settings,
]);
Currency::query()->where('id', 1)->update(['exchange_rate' => 1]);
Currency::query()->where('id', 2)->update(['exchange_rate' => 0.5]);
$settings = ClientSettings::defaults();
$settings->currency_id = '2'; //GBP
$gbp = Client::factory()->create([
'user_id' => $this->user->id,
'company_id' => $company->id,
'settings' => $settings,
]);
$i1 = Invoice::factory()->create([
'client_id' => $usd->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()
]);
$i1_overdue = Invoice::factory()->create([
'client_id' => $usd->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()->subDays(10)
]);
$i2 = Invoice::factory()->create([
'client_id' => $gbp->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()
]);
$i2_overdue = Invoice::factory()->create([
'client_id' => $gbp->id,
'user_id' => $this->user->id,
'company_id' => $company->id,
'amount' => 100,
'balance' => 100,
'paid_to_date' => 0,
'status_id' => 2,
'date' => now(),
'due_date' => now()->subDays(10)
]);
$i1->service()->markPaid()->save();
$i2->service()->markPaid()->save();
$cs = new ChartService($company, $this->user, true);
$results = $cs->totals('1970-01-01', '2050-01-01');
@ -121,13 +248,109 @@ class ChartCurrencyTest extends TestCase
$this->assertEquals('USD', $results['currencies'][1]);
$this->assertEquals('GBP', $results['currencies'][2]);
$this->assertEquals(200, $results[1]['invoices']->invoiced_amount);
$this->assertEquals(200, $results[2]['invoices']->invoiced_amount);
nlog(array_sum(array_column($results['currencies'][1]['invoices'],'invoiced_amount')));
$this->assertEquals(100, array_sum(array_column($results['currencies'][1]['invoices'],'invoiced_amount')));
$this->assertEquals(300, $results[999]['invoices']->invoiced_amount);
$this->assertEquals(150, $results[999]['revenue']->paid_to_date);
$this->assertEquals(150, $results[999]['outstanding']->amount);
$this->assertEquals(2, $results[999]['outstanding']->outstanding_count);
$usd->forceDelete();
$gbp->forceDelete();
}
public function testAggregateExpenses()
{
$settings = CompanySettings::defaults();
$settings->company_logo = 'https://pdf.invoicing.co/favicon-v2.png';
$settings->website = 'www.invoiceninja.com';
$settings->address1 = 'Address 1';
$settings->address2 = 'Address 2';
$settings->city = 'City';
$settings->state = 'State';
$settings->postal_code = 'Postal Code';
$settings->phone = '555-343-2323';
$settings->email = '';
$settings->country_id = '840';
$settings->vat_number = 'vat number';
$settings->id_number = 'id number';
$settings->use_credits_payment = 'always';
$settings->timezone_id = '1';
$settings->entity_send_time = 0;
$company = Company::factory()->create([
'account_id' => $this->account->id,
'settings' => $settings,
]);
$settings = ClientSettings::defaults();
$settings->currency_id = '1'; //USD
$usd = Client::factory()->create([
'user_id' => $this->user->id,
'company_id' => $company->id,
'settings' => $settings,
]);
Currency::query()->where('id', 1)->update(['exchange_rate' => 1]);
Currency::query()->where('id', 2)->update(['exchange_rate' => 0.5]);
$settings = ClientSettings::defaults();
$settings->currency_id = '2'; //GBP
$gbp = Client::factory()->create([
'user_id' => $this->user->id,
'company_id' => $company->id,
'settings' => $settings,
]);
$usd_e = Expense::factory()->create([
'company_id' => $company->id,
'user_id' => $this->user->id,
'client_id' => $usd->id,
'amount' => 100,
]);
$gbp_e = Expense::factory()->create([
'company_id' => $company->id,
'user_id' => $this->user->id,
'client_id' => $usd->id,
'amount' => 100,
]);
$cs = new ChartService($company, $this->user, true);
$results = $cs->totals('1970-01-01', '2050-01-01');
$this->assertCount(2, $results['currencies']);
nlog($results);
// $this->assertEquals('USD', $results['currencies'][1]);
// $this->assertEquals('GBP', $results['currencies'][2]);
// $this->assertEquals(200, $results[1]['invoices']->invoiced_amount);
// $this->assertEquals(200, $results[2]['invoices']->invoiced_amount);
// $this->assertEquals(300, $results[999]['invoices']->invoiced_amount);
// $this->assertEquals(150, $results[999]['revenue']->paid_to_date);
// $this->assertEquals(150, $results[999]['outstanding']->amount);
// $this->assertEquals(2, $results[999]['outstanding']->outstanding_count);
$usd->forceDelete();
$gbp->forceDelete();
}
public function testRevenueValues()
{
Invoice::factory()->create([