選択できるのは25トピックまでです。 トピックは、先頭が英数字で、英数字とダッシュ('-')を使用した35文字以内のものにしてください。

AccountService.php 14KB

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