From a4873493df86c4ab5f31c8980960cf2042f2974d Mon Sep 17 00:00:00 2001 From: Sudo-Ivan Date: Fri, 2 Jan 2026 17:28:27 -0600 Subject: [PATCH] feat(MessageHandler): optimize conversation fetching using window functions for improved performance and add unread message filtering capability --- meshchatx/src/backend/message_handler.py | 47 +++++++++++++++++------- 1 file changed, 33 insertions(+), 14 deletions(-) diff --git a/meshchatx/src/backend/message_handler.py b/meshchatx/src/backend/message_handler.py index 38199b6..2bdd495 100644 --- a/meshchatx/src/backend/message_handler.py +++ b/meshchatx/src/backend/message_handler.py @@ -57,33 +57,52 @@ class MessageHandler: return self.db.provider.fetchall(query, params) def get_conversations(self, local_hash, filter_unread=False): - # Implementation moved from get_conversations DAO but with local_hash filter + # Implementation using window functions for better performance + # This requires SQLite 3.25+ query = """ - SELECT m1.* FROM lxmf_messages m1 - JOIN ( - SELECT - CASE WHEN source_hash = ? THEN destination_hash ELSE source_hash END as peer_hash, - MAX(timestamp) as max_ts + WITH RankedMessages AS ( + SELECT *, + CASE WHEN source_hash = ? THEN destination_hash ELSE source_hash END as peer_hash, + ROW_NUMBER() OVER ( + PARTITION BY CASE WHEN source_hash = ? THEN destination_hash ELSE source_hash END + ORDER BY timestamp DESC + ) as rn FROM lxmf_messages WHERE source_hash = ? OR destination_hash = ? - GROUP BY peer_hash - ) m2 ON (CASE WHEN m1.source_hash = ? THEN m1.destination_hash ELSE m1.source_hash END = m2.peer_hash - AND m1.timestamp = m2.max_ts) - WHERE (m1.source_hash = ? OR m1.destination_hash = ?) + ) + SELECT * FROM RankedMessages WHERE rn = 1 """ params = [ local_hash, local_hash, local_hash, local_hash, - local_hash, - local_hash, ] if filter_unread: - query += " AND EXISTS (SELECT 1 FROM lxmf_messages m3 WHERE (m3.source_hash = m2.peer_hash AND m3.destination_hash = ?) AND m3.state = 'received' AND m3.is_incoming = 1)" + # For filtering unread, we need to check if there are any received messages from that peer + query = """ + WITH RankedMessages AS ( + SELECT *, + CASE WHEN source_hash = ? THEN destination_hash ELSE source_hash END as peer_hash, + ROW_NUMBER() OVER ( + PARTITION BY CASE WHEN source_hash = ? THEN destination_hash ELSE source_hash END + ORDER BY timestamp DESC + ) as rn + FROM lxmf_messages + WHERE source_hash = ? OR destination_hash = ? + ) + SELECT * FROM RankedMessages WHERE rn = 1 + AND EXISTS ( + SELECT 1 FROM lxmf_messages m3 + WHERE m3.source_hash = peer_hash + AND m3.destination_hash = ? + AND m3.state = 'received' + AND m3.is_incoming = 1 + ) + """ params.append(local_hash) - query += " ORDER BY m1.timestamp DESC" + query += " ORDER BY timestamp DESC" return self.db.provider.fetchall(query, params)