Add receivable/payable filtering with database-level query optimization
Add account type filtering to Recent Transactions table and fix pagination issue where filters were applied after fetching results, causing incomplete data display.
Database layer (crud.py):
- Add get_journal_entries_by_user_and_account_type() to filter entries by
both user_id and account_type at SQL query level
- Add count_journal_entries_by_user_and_account_type() for accurate counts
- Filters apply before pagination, ensuring all matching records are fetched
API layer (views_api.py):
- Add filter_account_type parameter ('asset' for receivable, 'liability' for payable)
- Refactor filtering logic to use new database-level filter functions
- Support filter combinations: user only, account_type only, user+account_type, or all
- Enrich entries with account_type metadata for UI display
Frontend (index.js):
- Add account_type to transactionFilter state
- Add accountTypeOptions computed property with receivable/payable choices
- Reorder table columns to show User before Date
- Update loadTransactions to send account_type filter parameter
- Update clearTransactionFilter to clear both user and account_type filters
UI (index.html):
- Add second filter dropdown for account type (Receivable/Payable)
- Show clear button when either filter is active
- Update button label from "Clear Filter" to "Clear Filters"
This fixes the critical bug where filtering for receivables would only show a subset of results (e.g., 2 out of 20 entries fetched) instead of all matching receivables. Now filters are applied at the database level before pagination, ensuring users see all relevant transactions.
This commit is contained in:
parent
f3d0d8652b
commit
3af93c3479
4 changed files with 163 additions and 22 deletions
86
crud.py
86
crud.py
|
|
@ -395,6 +395,92 @@ async def count_journal_entries_by_user(user_id: str) -> int:
|
|||
return result["total"] if result else 0
|
||||
|
||||
|
||||
async def get_journal_entries_by_user_and_account_type(
|
||||
user_id: str, account_type: str, limit: int = 100, offset: int = 0
|
||||
) -> list[JournalEntry]:
|
||||
"""Get journal entries that affect the user's accounts filtered by account type"""
|
||||
# Get all user-specific accounts of the specified type
|
||||
user_accounts = await db.fetchall(
|
||||
"SELECT id FROM accounts WHERE user_id = :user_id AND account_type = :account_type",
|
||||
{"user_id": user_id, "account_type": account_type},
|
||||
)
|
||||
|
||||
if not user_accounts:
|
||||
return []
|
||||
|
||||
account_ids = [acc["id"] for acc in user_accounts]
|
||||
|
||||
# Get all journal entries that have lines affecting these accounts
|
||||
placeholders = ','.join([f":account_{i}" for i in range(len(account_ids))])
|
||||
params = {f"account_{i}": acc_id for i, acc_id in enumerate(account_ids)}
|
||||
params["limit"] = limit
|
||||
params["offset"] = offset
|
||||
|
||||
entries_data = await db.fetchall(
|
||||
f"""
|
||||
SELECT DISTINCT je.*
|
||||
FROM journal_entries je
|
||||
JOIN entry_lines el ON je.id = el.journal_entry_id
|
||||
WHERE el.account_id IN ({placeholders})
|
||||
ORDER BY je.entry_date DESC, je.created_at DESC
|
||||
LIMIT :limit OFFSET :offset
|
||||
""",
|
||||
params,
|
||||
)
|
||||
|
||||
entries = []
|
||||
for entry_data in entries_data:
|
||||
# Parse flag and meta from database
|
||||
from .models import JournalEntryFlag
|
||||
flag = JournalEntryFlag(entry_data.get("flag", "*"))
|
||||
meta = json.loads(entry_data.get("meta", "{}")) if entry_data.get("meta") else {}
|
||||
|
||||
entry = JournalEntry(
|
||||
id=entry_data["id"],
|
||||
description=entry_data["description"],
|
||||
entry_date=entry_data["entry_date"],
|
||||
created_by=entry_data["created_by"],
|
||||
created_at=entry_data["created_at"],
|
||||
reference=entry_data["reference"],
|
||||
flag=flag,
|
||||
meta=meta,
|
||||
lines=[],
|
||||
)
|
||||
entry.lines = await get_entry_lines(entry.id)
|
||||
entries.append(entry)
|
||||
|
||||
return entries
|
||||
|
||||
|
||||
async def count_journal_entries_by_user_and_account_type(user_id: str, account_type: str) -> int:
|
||||
"""Count journal entries that affect the user's accounts filtered by account type"""
|
||||
# Get all user-specific accounts of the specified type
|
||||
user_accounts = await db.fetchall(
|
||||
"SELECT id FROM accounts WHERE user_id = :user_id AND account_type = :account_type",
|
||||
{"user_id": user_id, "account_type": account_type},
|
||||
)
|
||||
|
||||
if not user_accounts:
|
||||
return 0
|
||||
|
||||
account_ids = [acc["id"] for acc in user_accounts]
|
||||
|
||||
# Count journal entries that have lines affecting these accounts
|
||||
placeholders = ','.join([f":account_{i}" for i in range(len(account_ids))])
|
||||
params = {f"account_{i}": acc_id for i, acc_id in enumerate(account_ids)}
|
||||
|
||||
result = await db.fetchone(
|
||||
f"""
|
||||
SELECT COUNT(DISTINCT je.id) as total
|
||||
FROM journal_entries je
|
||||
JOIN entry_lines el ON je.id = el.journal_entry_id
|
||||
WHERE el.account_id IN ({placeholders})
|
||||
""",
|
||||
params,
|
||||
)
|
||||
return result["total"] if result else 0
|
||||
|
||||
|
||||
# ===== BALANCE AND REPORTING =====
|
||||
|
||||
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue