You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

AccountService.php 17KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439
  1. <?php
  2. namespace App\Services;
  3. use App\Enums\Accounting\AccountCategory;
  4. use App\Models\Accounting\Account;
  5. use App\Models\Accounting\Bill;
  6. use App\Models\Accounting\Invoice;
  7. use App\Models\Accounting\Transaction;
  8. use App\Models\Common\Client;
  9. use App\Models\Common\Vendor;
  10. use App\Repositories\Accounting\JournalEntryRepository;
  11. use App\Utilities\Currency\CurrencyAccessor;
  12. use App\ValueObjects\Money;
  13. use Closure;
  14. use Illuminate\Database\Eloquent\Builder;
  15. use Illuminate\Database\Query\JoinClause;
  16. use Illuminate\Support\Facades\DB;
  17. class AccountService
  18. {
  19. public function __construct(
  20. protected JournalEntryRepository $journalEntryRepository
  21. ) {}
  22. public function getDebitBalance(Account $account, string $startDate, string $endDate): Money
  23. {
  24. $query = $this->getAccountBalances($startDate, $endDate, [$account->id])->first();
  25. return new Money($query->total_debit, $account->currency_code);
  26. }
  27. public function getCreditBalance(Account $account, string $startDate, string $endDate): Money
  28. {
  29. $query = $this->getAccountBalances($startDate, $endDate, [$account->id])->first();
  30. return new Money($query->total_credit, $account->currency_code);
  31. }
  32. public function getNetMovement(Account $account, string $startDate, string $endDate): Money
  33. {
  34. $query = $this->getAccountBalances($startDate, $endDate, [$account->id])->first();
  35. $netMovement = $this->calculateNetMovementByCategory(
  36. $account->category,
  37. $query->total_debit ?? 0,
  38. $query->total_credit ?? 0
  39. );
  40. return new Money($netMovement, $account->currency_code);
  41. }
  42. public function getStartingBalance(Account $account, string $startDate, bool $override = false): ?Money
  43. {
  44. if ($override === false && $account->category->isNominal()) {
  45. return null;
  46. }
  47. $query = $this->getAccountBalances($startDate, $startDate, [$account->id])->first();
  48. return new Money($query->starting_balance ?? 0, $account->currency_code);
  49. }
  50. public function getEndingBalance(Account $account, string $startDate, string $endDate): ?Money
  51. {
  52. $query = $this->getAccountBalances($startDate, $endDate, [$account->id])->first();
  53. $netMovement = $this->calculateNetMovementByCategory(
  54. $account->category,
  55. $query->total_debit ?? 0,
  56. $query->total_credit ?? 0
  57. );
  58. if ($account->category->isNominal()) {
  59. return new Money($netMovement, $account->currency_code);
  60. }
  61. $endingBalance = ($query->starting_balance ?? 0) + $netMovement;
  62. return new Money($endingBalance, $account->currency_code);
  63. }
  64. public function calculateNetMovementByCategory(AccountCategory $category, int $debitBalance, int $creditBalance): int
  65. {
  66. if ($category->isNormalDebitBalance()) {
  67. return $debitBalance - $creditBalance;
  68. } else {
  69. return $creditBalance - $debitBalance;
  70. }
  71. }
  72. public function getBalances(Account $account, string $startDate, string $endDate): array
  73. {
  74. $query = $this->getAccountBalances($startDate, $endDate, [$account->id])->first();
  75. $needStartingBalances = $account->category->isReal();
  76. $netMovement = $this->calculateNetMovementByCategory(
  77. $account->category,
  78. $query->total_debit ?? 0,
  79. $query->total_credit ?? 0
  80. );
  81. $balances = [
  82. 'debit_balance' => $query->total_debit,
  83. 'credit_balance' => $query->total_credit,
  84. 'net_movement' => $netMovement,
  85. 'starting_balance' => $needStartingBalances ? ($query->starting_balance ?? 0) : null,
  86. 'ending_balance' => $needStartingBalances
  87. ? ($query->starting_balance ?? 0) + $netMovement
  88. : $netMovement, // For nominal accounts, ending balance is just the net movement
  89. ];
  90. // Return balances, filtering out any null values
  91. return array_filter($balances, static fn ($value) => $value !== null);
  92. }
  93. public function getTransactionDetailsSubquery(string $startDate, string $endDate, ?string $entityId = null): Closure
  94. {
  95. return static function ($query) use ($startDate, $endDate, $entityId) {
  96. $query->select(
  97. 'journal_entries.id',
  98. 'journal_entries.account_id',
  99. 'journal_entries.transaction_id',
  100. 'journal_entries.type',
  101. 'journal_entries.amount',
  102. 'journal_entries.description',
  103. DB::raw("journal_entries.amount * CASE WHEN journal_entries.type = 'debit' THEN 1 ELSE -1 END AS signed_amount")
  104. )
  105. ->whereBetween('transactions.posted_at', [$startDate, $endDate])
  106. ->join('transactions', 'transactions.id', '=', 'journal_entries.transaction_id')
  107. ->orderBy('transactions.posted_at')
  108. ->with('transaction:id,type,description,posted_at,is_payment,payeeable_id,payeeable_type');
  109. if ($entityId) {
  110. $entityId = (int) $entityId;
  111. if ($entityId < 0) {
  112. $query->whereHas('transaction', function ($query) use ($entityId) {
  113. $query->where('payeeable_type', Vendor::class)
  114. ->where('payeeable_id', abs($entityId));
  115. });
  116. } else {
  117. $query->whereHas('transaction', function ($query) use ($entityId) {
  118. $query->where('payeeable_type', Client::class)
  119. ->where('payeeable_id', $entityId);
  120. });
  121. }
  122. }
  123. };
  124. }
  125. public function getAccountBalances(string $startDate, string $endDate, array $accountIds = []): Builder
  126. {
  127. $accountIds = array_map('intval', $accountIds);
  128. $query = Account::query()
  129. ->select([
  130. 'accounts.id',
  131. 'accounts.name',
  132. 'accounts.category',
  133. 'accounts.type',
  134. 'accounts.subtype_id',
  135. 'accounts.currency_code',
  136. 'accounts.code',
  137. ])
  138. ->addSelect([
  139. DB::raw("
  140. COALESCE(
  141. CASE
  142. WHEN accounts.category IN ('asset', 'expense') THEN
  143. SUM(CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END) -
  144. SUM(CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END)
  145. ELSE
  146. SUM(CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END) -
  147. SUM(CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END)
  148. END, 0
  149. ) AS starting_balance
  150. "),
  151. DB::raw("
  152. COALESCE(SUM(
  153. CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at BETWEEN ? AND ? THEN journal_entries.amount ELSE 0 END
  154. ), 0) AS total_debit
  155. "),
  156. DB::raw("
  157. COALESCE(SUM(
  158. CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at BETWEEN ? AND ? THEN journal_entries.amount ELSE 0 END
  159. ), 0) AS total_credit
  160. "),
  161. ])
  162. ->join('journal_entries', 'journal_entries.account_id', '=', 'accounts.id')
  163. ->join('transactions', function (JoinClause $join) use ($endDate) {
  164. $join->on('transactions.id', '=', 'journal_entries.transaction_id')
  165. ->where('transactions.posted_at', '<=', $endDate);
  166. })
  167. ->groupBy([
  168. 'accounts.id',
  169. 'accounts.name',
  170. 'accounts.category',
  171. 'accounts.type',
  172. 'accounts.subtype_id',
  173. 'accounts.currency_code',
  174. 'accounts.code',
  175. ])
  176. ->with(['subtype:id,name,inverse_cash_flow']);
  177. if (! empty($accountIds)) {
  178. $query->whereIn('accounts.id', $accountIds);
  179. }
  180. $query->addBinding([$startDate, $startDate, $startDate, $startDate, $startDate, $endDate, $startDate, $endDate], 'select');
  181. return $query;
  182. }
  183. public function getCashFlowAccountBalances(string $startDate, string $endDate, array $accountIds = []): Builder
  184. {
  185. $accountIds = array_map('intval', $accountIds);
  186. $query = Account::query()
  187. ->select([
  188. 'accounts.id',
  189. 'accounts.name',
  190. 'accounts.category',
  191. 'accounts.type',
  192. 'accounts.subtype_id',
  193. 'accounts.currency_code',
  194. 'accounts.code',
  195. ])
  196. ->addSelect([
  197. DB::raw("
  198. COALESCE(
  199. CASE
  200. WHEN accounts.category IN ('asset', 'expense') THEN
  201. SUM(CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END) -
  202. SUM(CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END)
  203. ELSE
  204. SUM(CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END) -
  205. SUM(CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at < ? THEN journal_entries.amount ELSE 0 END)
  206. END, 0
  207. ) AS starting_balance
  208. "),
  209. DB::raw("
  210. COALESCE(SUM(
  211. CASE WHEN journal_entries.type = 'debit' AND transactions.posted_at BETWEEN ? AND ? THEN journal_entries.amount ELSE 0 END
  212. ), 0) AS total_debit
  213. "),
  214. DB::raw("
  215. COALESCE(SUM(
  216. CASE WHEN journal_entries.type = 'credit' AND transactions.posted_at BETWEEN ? AND ? THEN journal_entries.amount ELSE 0 END
  217. ), 0) AS total_credit
  218. "),
  219. ])
  220. ->join('journal_entries', 'journal_entries.account_id', '=', 'accounts.id')
  221. ->join('transactions', function (JoinClause $join) use ($endDate) {
  222. $join->on('transactions.id', '=', 'journal_entries.transaction_id')
  223. ->where('transactions.posted_at', '<=', $endDate);
  224. })
  225. ->whereExists(function (\Illuminate\Database\Query\Builder $subQuery) {
  226. $subQuery->select(DB::raw(1))
  227. ->from('journal_entries as je')
  228. ->join('bank_accounts', 'bank_accounts.account_id', '=', 'je.account_id') // Join bank_accounts on account_id
  229. ->whereNotNull('bank_accounts.id') // Ensure there is a linked BankAccount
  230. ->whereColumn('je.transaction_id', 'journal_entries.transaction_id');
  231. })
  232. ->groupBy([
  233. 'accounts.id',
  234. 'accounts.name',
  235. 'accounts.category',
  236. 'accounts.type',
  237. 'accounts.subtype_id',
  238. 'accounts.currency_code',
  239. 'accounts.code',
  240. ])
  241. ->with(['subtype:id,name,inverse_cash_flow']);
  242. if (! empty($accountIds)) {
  243. $query->whereIn('accounts.id', $accountIds);
  244. }
  245. $query->addBinding([$startDate, $startDate, $startDate, $startDate, $startDate, $endDate, $startDate, $endDate], 'select');
  246. return $query;
  247. }
  248. public function getTotalBalanceForAllBankAccounts(string $startDate, string $endDate): Money
  249. {
  250. $accountIds = Account::whereHas('bankAccount')
  251. ->pluck('id')
  252. ->toArray();
  253. if (empty($accountIds)) {
  254. return new Money(0, CurrencyAccessor::getDefaultCurrency());
  255. }
  256. $result = DB::table('journal_entries')
  257. ->join('transactions', function (JoinClause $join) use ($endDate) {
  258. $join->on('transactions.id', '=', 'journal_entries.transaction_id')
  259. ->where('transactions.posted_at', '<=', $endDate);
  260. })
  261. ->whereIn('journal_entries.account_id', $accountIds)
  262. ->selectRaw('
  263. SUM(CASE
  264. WHEN transactions.posted_at < ? AND journal_entries.type = \'debit\' THEN journal_entries.amount
  265. WHEN transactions.posted_at < ? AND journal_entries.type = \'credit\' THEN -journal_entries.amount
  266. ELSE 0
  267. END) AS totalStartingBalance,
  268. SUM(CASE
  269. WHEN transactions.posted_at BETWEEN ? AND ? AND journal_entries.type = \'debit\' THEN journal_entries.amount
  270. WHEN transactions.posted_at BETWEEN ? AND ? AND journal_entries.type = \'credit\' THEN -journal_entries.amount
  271. ELSE 0
  272. END) AS totalNetMovement
  273. ', [
  274. $startDate,
  275. $startDate,
  276. $startDate,
  277. $endDate,
  278. $startDate,
  279. $endDate,
  280. ])
  281. ->first();
  282. $totalBalance = $result->totalStartingBalance + $result->totalNetMovement;
  283. return new Money($totalBalance, CurrencyAccessor::getDefaultCurrency());
  284. }
  285. public function getStartingBalanceForAllBankAccounts(string $startDate): Money
  286. {
  287. $accountIds = Account::whereHas('bankAccount')
  288. ->pluck('id')
  289. ->toArray();
  290. if (empty($accountIds)) {
  291. return new Money(0, CurrencyAccessor::getDefaultCurrency());
  292. }
  293. $result = DB::table('journal_entries')
  294. ->join('transactions', function (JoinClause $join) use ($startDate) {
  295. $join->on('transactions.id', '=', 'journal_entries.transaction_id')
  296. ->where('transactions.posted_at', '<', $startDate);
  297. })
  298. ->whereIn('journal_entries.account_id', $accountIds)
  299. ->selectRaw("
  300. SUM(CASE
  301. WHEN transactions.posted_at < ? AND journal_entries.type = 'debit' THEN journal_entries.amount
  302. WHEN transactions.posted_at < ? AND journal_entries.type = 'credit' THEN -journal_entries.amount
  303. ELSE 0
  304. END) AS totalStartingBalance
  305. ", [
  306. $startDate,
  307. $startDate,
  308. ])
  309. ->first();
  310. return new Money($result->totalStartingBalance ?? 0, CurrencyAccessor::getDefaultCurrency());
  311. }
  312. public function getBankAccountBalances(string $startDate, string $endDate): Builder | array
  313. {
  314. $accountIds = Account::whereHas('bankAccount')
  315. ->pluck('id')
  316. ->toArray();
  317. if (empty($accountIds)) {
  318. return [];
  319. }
  320. return $this->getAccountBalances($startDate, $endDate, $accountIds);
  321. }
  322. public function getEarliestTransactionDate(): string
  323. {
  324. $earliestDate = Transaction::min('posted_at');
  325. return $earliestDate ?? company_today()->toDateTimeString();
  326. }
  327. public function getUnpaidClientInvoices(?string $asOfDate = null): Builder
  328. {
  329. $asOfDate = $asOfDate ?? company_today()->toDateString();
  330. $driver = DB::getDriverName();
  331. switch ($driver) {
  332. case 'pgsql':
  333. $datediff = '(?::date - invoices.due_date::date)';
  334. break;
  335. case 'sqlite':
  336. $datediff = 'JULIANDAY(?) - JULIANDAY(invoices.due_date)';
  337. break;
  338. default:
  339. $datediff = 'DATEDIFF(?, invoices.due_date)';
  340. break;
  341. }
  342. return Invoice::query()
  343. ->select([
  344. 'invoices.id',
  345. 'invoices.client_id',
  346. 'invoices.due_date',
  347. 'invoices.amount_due',
  348. 'invoices.currency_code',
  349. DB::raw("{$datediff} as days_overdue"),
  350. ])
  351. ->addBinding([$asOfDate], 'select')
  352. ->unpaid()
  353. ->where('amount_due', '>', 0);
  354. }
  355. public function getUnpaidVendorBills(?string $asOfDate = null): Builder
  356. {
  357. $asOfDate = $asOfDate ?? company_today()->toDateString();
  358. $driver = DB::getDriverName();
  359. switch ($driver) {
  360. case 'pgsql':
  361. $datediff = '(?::date - bills.due_date::date)';
  362. break;
  363. case 'sqlite':
  364. $datediff = 'JULIANDAY(?) - JULIANDAY(bills.due_date)';
  365. break;
  366. default:
  367. $datediff = 'DATEDIFF(?, bills.due_date)';
  368. break;
  369. }
  370. return Bill::query()
  371. ->select([
  372. 'bills.id',
  373. 'bills.vendor_id',
  374. 'bills.due_date',
  375. 'bills.amount_due',
  376. 'bills.currency_code',
  377. DB::raw("{$datediff} as days_overdue"),
  378. ])
  379. ->addBinding([$asOfDate], 'select')
  380. ->unpaid()
  381. ->where('amount_due', '>', 0);
  382. }
  383. }