48

I'm trying to achieve exactly what's explained here: Creating a threaded private messaging system like facebook and gmail, however i don't completly understand Joel Brown's answer. can any one please explain.

This is what my db tables look like with sample data (I assume i filled it in correctly for demo purposes): enter image description here

  1. I need to display a list of threads based on LoginId (newest on top) what would the query look like in LINQ? (what i'm asking is in a a group of message threads, give me the 1 newest message in each thread) - just like this is done on facebook.

  2. I need to display ALL the messages in a message thread (LINQ) -> just like it's done on facebook where you click the message and you would see the whole "conversation" in a tread.

Please help! thanks

EDIT -> continuation Joel, is this correct??

enter image description here

Joel, i'm a bit confused, can you please explain (comments/questions in bold):

The idea here is that every time a user starts a brand new thread/message, it starts with a new record in the THREAD table. The user is then added as a THREAD_PARTICIPANT and the content of the message is added to MESSAGE which points back to the containing THREAD. The FK from MESSAGE to USER indicates the author of the message.

LoginId 1 sends a message to LoginId2 => new record is inserted to MessageThread table. Also a record is inserted to MessageThreadParticipant record with MessageThreadId = 1, LoginId = 1 (the sender). And a new record is inserted into Message table with MessageId =1, MessageThreadid =1, SenderLoginId = 1 (correct??)

this is what i have after that iteration: enter image description here

I think i'm confused because there is no way for Loginid 2 to know that there is a message for him. ?? OR maybe I need to insert 2 records into MessageThreadParticipant?? (the sender and the receiver)-> this way both can see the whole "conversation"??

EDIT2: Joe, I think I could do this:

SELECT
  Message.MessageId, Message.CreateDate, Message.Body, Login.Username, Message.SenderLoginId
, (SELECT MessageReadState.ReadDate 
   FROM MessageReadState 
   WHERE MessageReadState.MessageId = Message.MessageId 
     ) as ReadDate
FROM Message 
    INNER JOIN Login ON Message.SenderLoginId = Login.LoginId
    INNER JOIN MessageThreadParticipant mtp on mtp.MessageThreadId = Message.MessageThreadId 
AND ( Message.MessageId in 
        ( SELECT Max(Message.MessageId)
          FROM MessageThreadParticipant INNER JOIN Message 
            ON MessageThreadParticipant.MessageThreadId = Message.MessageThreadId
          GROUP BY MessageThreadParticipant.MessageThreadId
        )
      )
Where mtp.LoginId = 2
ORDER BY Message.CreateDate DESC;

Please correct me if i'm wrong :)

Community
  • 1
  • 1
ShaneKm
  • 20,823
  • 43
  • 167
  • 296
  • Shane, I think you've got it. Have a look at my edited answer for expanded example data. – Joel Brown Jul 01 '11 at 11:46
  • 1
    Shane, I don't think you can get it to work using your query from Edit 2. There are two issues that I see. One is that you will only see messages that are read by the user in question, since you're inner joining to MTP. The other is that you are trying to do a sub-select in your FROM (...Message.MessageId in ( SELECT Max(Message.MessageId) ...) which is highly unconventional, if it works at all, which I don't think it will because you can't join to a multi-valued equality. The sub-select belongs in a WHERE clause. – Joel Brown Jul 04 '11 at 11:22

2 Answers2

89

Well why don't you just ask? :)

Let me try to pin down my understanding of your requirement. It seems to me that you are looking at a thread being a linear list (not a tree) of messages between two people. I would think that you might want to allow more people in than just two. That would be like Facebook insofar as someone posts a message and then any number of people can read it and then start adding comments. When you add a comment it puts you into the thread and you start getting status updates and e-mails telling you about activity in the thread and so forth. Assuming that is what you're after, then the schema I suggested to Big Mike is not exactly what you're looking for.

Consider instead the following:

Schema

The idea here is that every time a user starts a brand new thread/message, it starts with a new record in the THREAD table. The user is then added as a THREAD_PARTICIPANT and the content of the message is added to MESSAGE which points back to the containing THREAD. The FK from MESSAGE to USER indicates the author of the message.

When a user reads a message, they get an entry in the MESSAGE_READ_STATE table to indicate that they have marked the message read, either explicitly or implicitly, depending on how your requirements go.

When someone comments on the initial message in the thread, a second MESSAGE is added with an FK back to the original THREAD and the reply author (user) gets added to the THREAD_PARTICIPANT table. And so it goes as messages are added to the thread by one, two or even more participants.

To get the most recent message in any thread, just take the top 1 from MESSAGE sorted descending on create date (or an identity key) where the message FK is to the thread of interest.

To get the most recently updated thread for a user, get the THREAD related to the top 1 from message sorted descending on create date where the message is in a thread in which the user is a THREAD_PARTICIPANT.

I'm afraid I can never state these things in LINQ without breaking out LinqPad. If you are having trouble catching my drift from the above, I could flesh out the answer with table definitions and some SQL. Just ask in the comments.

EDIT: Clarification of Requirements and Implementation

Clarifying the requirements: Initially I was thinking about publicly posted messages with the opportunity for commenting, whereas Shane is after more of the direct message feature. In which case the initial recipient needs to be included in the THREAD_PARTICIPANT table at the outset.

For some clarity, let's put a few rows in tables. Here is the scenario, (in honour of Canada Day): User 1 DMs User 2 to ask about meeting for a beer. User 2 replies with a question about where to meet and User 1 answers. The tables would look something like this: (probably oversimplified)

Sample Data Part 1 Sample Data Part 2

EDIT #2: Access SQL for list of all messages in a thread, with read state...

Using @OP's schema, this SQL will get a list of messages in a given thread with an indication of whether a given user has read each message or not. Messages are in most recent first order.

SELECT 
  Message.MessageId
, Message.CreateDate
, Message.Body
, Login.Username
, (SELECT MessageReadState.ReadDate 
   FROM MessageReadState 
   WHERE MessageReadState.MessageId = Message.MessageId 
     and MessageReadState.LoginId = 2) as ReadState
FROM (Message INNER JOIN Login ON Message.SenderLoginId = Login.LoginId) 
WHERE (((Message.MessageThreadId)=10))
ORDER BY Message.CreateDate DESC;

Note that the trick, if it's fair to call it that, is that the read state is picked up with a sub-select. This is necessary because part of the criteria for getting the read state requires a where clause that can't be satisfied with an outer join. Therefore you use the subselect to pin down which (possibly missing) value you want from the MessageReadState child table.

EDIT 3: SQL for getting all threads with latest message in each for a given user...

To get a list of all of the threads in which a given user has participated, sorted by most recent message first, with only the most recent message being displayed (1 message per thread) then you would use a similar query to the one above, except instead of filtering messages by their FK to the thread of interest, you filter the messages by a subquery that finds the latest message in each thread that the user of interest participated in. It would look like this:

SELECT
  Message.MessageId
, Message.CreateDate
, Message.Body
, Login.Username
, (SELECT MessageReadState.ReadDate 
   FROM MessageReadState 
   WHERE MessageReadState.MessageId = Message.MessageId 
     and MessageReadState.LoginId = 2) AS ReadState
FROM Message INNER JOIN Login ON Message.SenderLoginId = Login.LoginId
WHERE ( Message.MessageId in 
        ( SELECT Max(Message.MessageId)
          FROM MessageThreadParticipant INNER JOIN Message 
            ON MessageThreadParticipant.MessageThreadId = Message.MessageThreadId
          WHERE MessageThreadParticipant.LoginId=2
          GROUP BY MessageThreadParticipant.MessageThreadId
        )
      )
ORDER BY Message.CreateDate DESC;
Community
  • 1
  • 1
Joel Brown
  • 14,123
  • 4
  • 52
  • 64
  • Joel, please see my comments/questions in "edited" section above – ShaneKm Jul 01 '11 at 07:14
  • Joel, i assume i would use this query to get the list of messages (in a conversation) for loginId 1. Select m.*, mrs.* from Message m inner join MessageThreadParticipant mtp on mtp.MessageThreadId = m.MessageThreadId and mtp.LoginId = 1 left join MessageReadState mrs on mrs.MessageId = m.MessageId Where m.MessageThreadId = 1. However when LoginId 2 reads the message the records are duplicated. What would be the correct way to pull the records – ShaneKm Jul 01 '11 at 17:55
  • What i'm trying to do is to have: 1) a list of all Threads (top 1 newest message in a thread) for a given LoginId. 2) A list of all messages for a given ThreadId and LoginId with info telling me if it's a NEW message or Not – ShaneKm Jul 01 '11 at 18:09
  • Shane, I've edited above to show the SQL for getting a list of all messages in a given thread with info about whether a particular user has read each message or not. The messages are shown in most recent first order. I wasn't clear on what the other query was that you were looking for. Is it a list of all threads for a given user with each thread's most recent message in it? If you clear up what you're looking for I can probably suggest some SQL for it. – Joel Brown Jul 01 '11 at 19:10
  • Is it a list of all threads for a given user with each thread's most recent message in it? - YES. – ShaneKm Jul 03 '11 at 16:38
  • Joel, I believe this works too.. this way I can create a view with all those joins. This then becomes as easy as calling Where LoginId =.. (Please see edit 2) – ShaneKm Jul 04 '11 at 06:12
  • The model breaks if the users should be able to delete a message, but that mesage should still show up in the other participants threads. – Spock Jun 05 '12 at 09:20
  • What would the models look like to create this using Code First? – Shane LeBlanc Jun 30 '12 at 05:35
  • 2
    @Spock - OP's requirements didn't say anything about users deleting messages, but the model can be easily enhanced to accomodate individual users choosing to "delete" a message while leaving the message there for other users to view. This could be done at the thread level by deleting the `THREAD_PARTICIPANT` record for that user or at the message level by adding a code or flag to `MESSAGE_READ_STATE` to indicate that the user has soft-deleted the message. – Joel Brown Jun 30 '12 at 12:08
  • @user1066133 - Despite the fact that you don't have to do it this way, I don't think that there is any particular reason to model classes to tables on a 1:1 basis. If you wanted to build code first (I don't see the attraction, frankly) then just make a class for each table in the ERD. – Joel Brown Jun 30 '12 at 12:10
  • Are you implying code first as a bad method for development? I started learning MVC using EF Code First and am attempting to get a better grasp, just wondering if I'm wasting my time. – Shane LeBlanc Jun 30 '12 at 15:28
  • 1
    @user1066133 - I think code first has its place, especially as a prototyping tool or for building small or niche systems. I personally feel that code first was a concession to some programmers who aren't data-centric. In my experience, a very well considered (i.e. deliberately designed) database is a strong foundation for an application of any size or importance. If your project allows it, I would start with model first. If you have to work code first, you just have to make sure that you don't paint yourself into a very bad corner by skipping the data design step. – Joel Brown Jun 30 '12 at 17:53
  • It's a personal project so I'm free to choose any design I wish. Although I do have the beginning of it done using Code First, I guess I'll take a look into Model First. – Shane LeBlanc Jun 30 '12 at 18:58
  • @JoelBrown: How does user 2 see the message? I assume user 2 (being a recipient) gets added to `Thread_Particiapant` at the very onset when the message is first created? – Mrchief Jun 13 '13 at 05:37
  • @Mrchief - Yes. Notice how in the sample data the `MESSAGE` table has a foreign key to `THREAD` but nothing like `RECIPIENT_USER_ID`. The sender and recipient are both added to `THREAD_PARTICIPANT` when the message is created. Everyone in `THREAD_PARTICIPANT` can see all of the messages in the thread given by `THREAD_PARTICIPANT.THREAD_ID`. – Joel Brown Jun 13 '13 at 11:31
  • @JoelBrown for soft-deleting the message at the MESSAGE_READ_STATE, wouldn't this only delete a single message out of the whole thread? Or would the system function such that if a single message from a thread has been marked as delete, the user shouldn't see any of the messages from that thread? – compguy24 Dec 29 '13 at 00:53
  • @compguy24 - If a user wants to delete one message they can do a soft delete at the `MESSAGE_READ_STATE` level. If they want to soft delete the whole thread, they can remove themselves at the `THREAD_PARTICIPANT` level, or, probably better, they could soft delete all messages in the thread at the `MESSAGE_READ_STATE` level. This preserves the information for users in the thread who haven't deleted the message yet. You could have application logic to hard delete threads which are soft deleted by all thread participants, if that's what you want to do. – Joel Brown Dec 29 '13 at 14:48
  • @JoelBrown If I wanted to exclude messages sent by the user who is logged in that have not been replied to from the inbox, how might I do that? In other words, if I have sent a message to Bill, I don't want to see that message in my inbox until I get a reply. Instead, I should only see this in my sent mail until there is a reply. Any idea on how the TOP_MESSAGE query could exclude such messages? Maybe it would be something like: exclude messages if (sender_user_id = me AND thread_participants.id ONLY = me) – compguy24 Feb 07 '14 at 18:09
  • 2
    @compguy24 the usual way to exclude something based on information being missing is to use a **sub-select** with `WHERE NOT IN ...`. So for example you could take the base query and add to its where clause `AND WHERE Message.MessageID NOT IN ({select clause that pulls out the message ids of the thing that you're waiting for})` – Joel Brown Feb 07 '14 at 21:57
  • @JoelBrown, Is it possible to factor in BCC functionality with this arrangement (where the bcc recipients do not see others and their replies)? http://stackoverflow.com/questions/22916588/threaded-messaging-system-with-bcc-like-functionality – Mrchief Apr 07 '14 at 18:28
  • @Mrchief - I'm not sure that I follow what you're trying to do. BCC typically means that other people don't know that someone is able to see the thread. It sounds to me like you want to kind of flip that and say that BCC recipients can't see other peoples' replies??? In any case I don't think BCC and threaded conversations go together very easily. Maybe if had an `is_visible` flag on the `THREAD_PARTICIPANT` table? That would allow people to watch threads in a stealth/lurker mode. It wouldn't allow them to post, mind you. – Joel Brown Apr 07 '14 at 21:28
  • Your understanding is right. If you use GMail, then you can see the behavior I'm talking about. Only the creator sees the replies of everyone else, whereas the recipients do not see other's reply, just theirs. To them, its as if there is a one-to-one correspondence between the creator and them. If you see my question on this topic, I'm thinking along same lines. Just not sure if that is the best way to go. – Mrchief Apr 08 '14 at 14:32
  • Hey @JoelBrown - this is great, I just have one question. How would you suggest handling a "delete" of a message given this schema? Would that be handled on message_read_state? Ideally if the recipient deletes a message, it won't affect the senders' data at all. – Dave Harding Nov 09 '15 at 14:00
  • 2
    @DaveHarding - Yes, if you wanted to distinguish between message _read_ and message _deleted_, you could expand the `MESSAGE_READ_STATE` table to include either a deleted flag or, perhaps preferably, a deleted date. This would provide a soft-delete feature (so that you can _undelete_ if you want to) and it allows one participant in a thread to hide something without disrupting the data of other thread participants. – Joel Brown Nov 10 '15 at 14:23
  • 1
    How to check weather a thread is already exist between 2 users, suppose a thread id=10 already exist for user 1 and user 2 so no need to create a new thread. – azhar_SE_nextbridge Feb 07 '16 at 17:57
  • 1
    In other words how we get a thread that is already associated between two or among more than 2 users. @JoelBrown Sir need your guidance – azhar_SE_nextbridge Feb 07 '16 at 18:06
  • 1
    @azhar_SE_nextbridge - You join `THREAD_PARTICIPANT` to itself, selecting `THREAD_ID` from one (either) copy of the table where one copy has the `USER_ID` of the first user you are looking for and the other copy has the `USER_ID` of the second user you are looking for. If you find one (or more) then you can continue that thread. If you don't find any, then you need a new thread. If you find multiple matching threads you need a rule for which one to pick, such as the one with the highest `THREAD_ID` or the one which joins to `MESSAGE` with the most recent `SENT_DATE` (whatever makes sense). – Joel Brown Feb 08 '16 at 04:36
  • @JoelBrown right sir, thank you for guidance I got it what you explained.. stay blessed – azhar_SE_nextbridge Feb 08 '16 at 07:30
  • @JoelBrown please take a look at my query is it good to proceed with that in term of query performance select tp.threadid from [ThreadParticipant] tp inner join [ThreadParticipant] tp2 on tp.threadid = tp2.threadid and (tp2.userid = 2 and (select count(*) from [ThreadParticipant] tp3 where tp3.threadid = tp2.threadid ) = 2 ) where tp.userid = 1 It is for user1 & user2 – azhar_SE_nextbridge Feb 09 '16 at 07:10
  • @azhar_SE_nextbridge - I think you're going about it the hard way. Try something more like this: select top 1 tp1.threadid from ThreadParticipant tp1 inner join TreadParticipant tp2 on tp1.threadid = tp2.threadid inner join Message m on tp1.threadid = m.threadid where tp1.userid = 1 and tp2.userid = 2 and not exists (select tp3.threadid from ThreadParticipant tp3 where tp3.userid not in (1,2) -- order by m.sentdate desc – Joel Brown Feb 09 '16 at 18:17
  • @azhar_SE_nextbridge - Note that the above presumes that you are looking for the most recently modified thread that is exclusively between the two specified users, as opposed to any thread that includes those two users. – Joel Brown Feb 09 '16 at 18:18
  • how to count the unread messages of a thread in EDIT #3 query? – Mohammad Olfatmiri Mar 31 '16 at 20:29
  • @Oli - You just have to count the records in `MESSAGE` that are related to the user and thread you want with a `WHERE NOT IN` subselect to `MESSAGE_READ_STATE`. If you wanted to jam this all in to the query in edit #3 it would need to be a new subselect. – Joel Brown Mar 31 '16 at 22:08
  • @JoelBrown How would you get a thread between 2 users? E.g if I wanted to find the DM between the 2 users, what would the sql query look like? I'm using this design & am having trouble getting the thread between 2 users. I added a question here (maybe you could help): https://stackoverflow.com/questions/44880380/how-can-i-select-where-receive-other-results-connected-to-the-found-primary – James111 Jul 04 '17 at 01:34
3

According to Joel Brown'answer, you can add LAST_MESSAGE_ID column into THREAD table then getting all threads with last messages SQL is become very simple. You must update this column when every message send.

Getting all threads with latest message in each for a given user

SELECT *
FROM THREAD T
INNER JOIN MESSAGE M ON T.LAST_MESSAGE_ID=M.MESSAGE_ID
INNER JOIN USER SENDER ON M.USER_ID=SENDER.USER_ID
LEFT JOIN MessageReadState MRS ON M.MESSAGE_ID=MRS.MESSAGE_ID AND MRS.USER_ID=2
Himanshu
  • 31,810
  • 31
  • 111
  • 133
Alexander
  • 1,720
  • 4
  • 22
  • 40
  • how to get thread_id for given two users ? do i need this sort of query -SELECT * FROM `message_thread_has_user` as t1 join `message_thread_has_user` as t2 on t1.message_thread_id=t2.message_thread_id where (t1.user_id = 1 || t2.user_id = 1) and (t1.user_id = 2 || t2.user_id = 2) group by t1.message_thread_id – vivex Jun 20 '16 at 09:00
  • 1
    @Vivek you should add a unique char field = "unique_field" in MessageThread table . It stores users ids which ordered from min user id to max user id and joined with a seperator. example : user1=15, user2=9 and unique_field will be "9_15" and sql will be select * from MessageThread where unique_field="9_15" – Alexander Jun 20 '16 at 12:37
  • @Alaxander that does make sense , this will avoid joins. thanks. – vivex Jun 20 '16 at 19:00
  • @Vivek you can also use ThreadName field instead of creating "unique_field" for one to one message threads – Alexander Jun 21 '16 at 05:07