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 15KB

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