Re: Optimize query for listing un-read messages - Mailing list pgsql-general

From Alban Hertroys
Subject Re: Optimize query for listing un-read messages
Date
Msg-id 51091B6E-1EA2-4D11-A868-82FB6D570F07@gmail.com
Whole thread Raw
In response to Re: Optimize query for listing un-read messages  (Andreas Joseph Krogh <andreas@visena.com>)
Responses Re: Optimize query for listing un-read messages
List pgsql-general
On 03 May 2014, at 12:45, Andreas Joseph Krogh <andreas@visena.com> wrote:

> Do you really need to query message_property twice? I would think this would give the same results:
>
> SELECT
>     m.id                          AS message_id,
>     prop.person_id,
>     coalesce(prop.is_read, FALSE) AS is_read,
>     m.subject
> FROM message m
>     LEFT OUTER JOIN message_property prop ON prop.message_id = m.id AND prop.person_id = 1 AND prop.is_read = FALSE
> ;

Ah yes, of course that would match a bit too much. This however does give the same results:

SELECT
   m.id                          AS message_id,
   prop.person_id,
   coalesce(prop.is_read, FALSE) AS is_read,
   m.subject
FROM message m
   LEFT OUTER JOIN message_property prop ON prop.message_id = m.id AND prop.person_id = 1
WHERE prop.is_read IS NULL OR prop.is_read = FALSE
;

That shaves off half the time of the query here, namely one indexscan.

The remaining time appears to be spent finding the rows in “message" that do not have a corresponding
“message_property"for the given (message_id, person_id) tuple. It’s basically trying to find no needle in a haystack,
youwon’t know that there is no needle until you’ve searched the entire haystack. 

It does seem to help a bit to create separate indexes on message_property.message_id and  message_property.person_id;
thatreduces the sizes of the indexes that the database needs to match and merge other in order to find the missing
message_id’s.


Alban Hertroys
--
If you can't see the forest for the trees,
cut the trees and you'll find there is no forest.



pgsql-general by date:

Previous
From: Andreas Joseph Krogh
Date:
Subject: Re: Optimize query for listing un-read messages
Next
From: Andreas Joseph Krogh
Date:
Subject: Re: Optimize query for listing un-read messages