Skip to content
Permalink
Browse files

MDL-45594 simplify message_get_recent_conversations SQL

I am pretty sure that this new SQL is logically equivalent to
the original, and it passes Mark's unit tests. However, it is
hard to be 100% sure.
  • Loading branch information...
timhunt authored and markn86 committed Jun 26, 2014
1 parent 22ffc39 commit ca0074bf895e4c98e433ed493bd4e15d2c4a7324
Showing with 47 additions and 61 deletions.
  1. +47 −61 message/lib.php
@@ -707,70 +707,56 @@ function message_print_search($advancedsearch = false, $user1=null) {
function message_get_recent_conversations($user, $limitfrom=0, $limitto=100) {
global $DB;
$userfields = user_picture::fields('u', array('lastaccess'));
//This query retrieves the last message received from and sent to each user
//It unions that data then, within that set, it finds the most recent message you've exchanged with each user over all
//It then joins with some other tables to get some additional data we need
//message ID is used instead of timecreated as it should sort the same and will be much faster
//There is a separate query for read and unread queries as they are stored in different tables
//They were originally retrieved in one query but it was so large that it was difficult to be confident in its correctness
$sql = "SELECT $userfields, mr.id as mid, mr.notification, mr.smallmessage, mr.fullmessage, mr.fullmessagehtml, mr.fullmessageformat, mr.timecreated, mc.id as contactlistid, mc.blocked
FROM {message_read} mr
JOIN (
SELECT messages.userid AS userid, MAX(messages.mid) AS mid
FROM (
SELECT mr1.useridto AS userid, MAX(mr1.id) AS mid
FROM {message_read} mr1
WHERE mr1.useridfrom = :userid1
AND mr1.notification = 0
GROUP BY mr1.useridto
UNION
SELECT mr2.useridfrom AS userid, MAX(mr2.id) AS mid
FROM {message_read} mr2
WHERE mr2.useridto = :userid2
AND mr2.notification = 0
GROUP BY mr2.useridfrom
) messages
GROUP BY messages.userid
) messages2 ON mr.id = messages2.mid AND (mr.useridto = messages2.userid OR mr.useridfrom = messages2.userid)
JOIN {user} u ON u.id = messages2.userid
LEFT JOIN {message_contacts} mc ON mc.userid = :userid3 AND mc.contactid = u.id
WHERE u.deleted = '0'
ORDER BY mr.id DESC";
$params = array('userid1' => $user->id, 'userid2' => $user->id, 'userid3' => $user->id);
$read = $DB->get_records_sql($sql, $params, $limitfrom, $limitto);
$sql = "SELECT $userfields, m.id as mid, m.notification, m.smallmessage, m.fullmessage, m.fullmessagehtml, m.fullmessageformat, m.timecreated, mc.id as contactlistid, mc.blocked
FROM {message} m
JOIN (
SELECT messages.userid AS userid, MAX(messages.mid) AS mid
FROM (
SELECT m1.useridto AS userid, MAX(m1.id) AS mid
FROM {message} m1
WHERE m1.useridfrom = :userid1
AND m1.notification = 0
GROUP BY m1.useridto
UNION
SELECT m2.useridfrom AS userid, MAX(m2.id) AS mid
FROM {message} m2
WHERE m2.useridto = :userid2
AND m2.notification = 0
GROUP BY m2.useridfrom
) messages
GROUP BY messages.userid
) messages2 ON m.id = messages2.mid AND (m.useridto = messages2.userid OR m.useridfrom = messages2.userid)
JOIN {user} u ON u.id = messages2.userid
LEFT JOIN {message_contacts} mc ON mc.userid = :userid3 AND mc.contactid = u.id
WHERE u.deleted = '0'
ORDER BY m.id DESC";
$unread = $DB->get_records_sql($sql, $params, $limitfrom, $limitto);
$userfields = user_picture::fields('otheruser', array('lastaccess'));
// This query retrieves the most recent message received from or sent to
// seach other user.
//
// If two messages have the same timecreated, we take the one with the
// larger id.
//
// There is a separate query for read and unread messages as they are stored
// in different tables. They were originally retrieved in one query but it
// was so large that it was difficult to be confident in its correctness.
$sql = "SELECT $userfields,
message.id as mid, message.notification, message.smallmessage, message.fullmessage,
message.fullmessagehtml, message.fullmessageformat, message.timecreated,
contact.id as contactlistid, contact.blocked
FROM {message_read} message
JOIN {user} otheruser ON otheruser.id = CASE
WHEN message.useridto = :userid1 THEN message.useridfrom
ELSE message.useridto END
LEFT JOIN {message_contacts} contact ON contact.userid = :userid2 AND contact.contactid = otheruser.id
WHERE otheruser.deleted = 0
AND (message.useridto = :userid3 OR message.useridfrom = :userid4)
AND message.notification = 0
AND NOT EXISTS (
SELECT 1
FROM {message_read} othermessage
WHERE ((othermessage.useridto = :userid5 AND othermessage.useridfrom = otheruser.id) OR
(othermessage.useridfrom = :userid6 AND othermessage.useridto = otheruser.id))
AND (othermessage.timecreated > message.timecreated OR (
othermessage.timecreated = message.timecreated AND othermessage.id > message.id))
)
ORDER BY message.timecreated DESC";
$params = array('userid1' => $user->id, 'userid2' => $user->id, 'userid3' => $user->id,
'userid4' => $user->id, 'userid5' => $user->id, 'userid6' => $user->id);
$read = $DB->get_records_sql($sql, $params, $limitfrom, $limitto);
// We want to get the messages that have not been read. These are stored in the 'message' table. It is the
// exact same query as the one above, except for the table we are querying. So, simply replace references to
// the 'message_read' table with the 'message' table.
$sql = str_replace('{message_read}', '{message}', $sql);
$unread = $DB->get_records_sql($sql, $params, $limitfrom, $limitto);
$conversations = array();
//Union the 2 result sets together looking for the message with the most recent timecreated for each other user
//$conversation->id (the array key) is the other user's ID
// Union the 2 result sets together looking for the message with the most
// recent timecreated for each other user.
// $conversation->id (the array key) is the other user's ID.
$conversation_arrays = array($unread, $read);
foreach ($conversation_arrays as $conversation_array) {
foreach ($conversation_array as $conversation) {

0 comments on commit ca0074b

Please sign in to comment.
You can’t perform that action at this time.