<html xmlns:v="urn:schemas-microsoft-com:vml" xmlns:o="urn:schemas-microsoft-com:office:office" xmlns:w="urn:schemas-microsoft-com:office:word" xmlns:m="http://schemas.microsoft.com/office/2004/12/omml" xmlns="http://www.w3.org/TR/REC-html40">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=us-ascii">
<meta name="Generator" content="Microsoft Word 14 (filtered medium)">
<style><!--
/* Font Definitions */
@font-face
        {font-family:"MS Mincho";
        panose-1:2 2 6 9 4 2 5 8 3 4;}
@font-face
        {font-family:"MS Mincho";
        panose-1:2 2 6 9 4 2 5 8 3 4;}
@font-face
        {font-family:Calibri;
        panose-1:2 15 5 2 2 2 4 3 2 4;}
@font-face
        {font-family:Tahoma;
        panose-1:2 11 6 4 3 5 4 4 2 4;}
@font-face
        {font-family:"\@MS Mincho";
        panose-1:2 2 6 9 4 2 5 8 3 4;}
/* Style Definitions */
p.MsoNormal, li.MsoNormal, div.MsoNormal
        {margin:0cm;
        margin-bottom:.0001pt;
        font-size:11.0pt;
        font-family:"Calibri","sans-serif";}
a:link, span.MsoHyperlink
        {mso-style-priority:99;
        color:blue;
        text-decoration:underline;}
a:visited, span.MsoHyperlinkFollowed
        {mso-style-priority:99;
        color:purple;
        text-decoration:underline;}
p.MsoPlainText, li.MsoPlainText, div.MsoPlainText
        {mso-style-priority:99;
        mso-style-link:"Plain Text Char";
        margin:0cm;
        margin-bottom:.0001pt;
        font-size:11.0pt;
        font-family:"Calibri","sans-serif";}
span.PlainTextChar
        {mso-style-name:"Plain Text Char";
        mso-style-priority:99;
        mso-style-link:"Plain Text";
        font-family:"Calibri","sans-serif";}
span.EmailStyle19
        {mso-style-type:personal-reply;
        font-family:"Calibri","sans-serif";
        color:#1F497D;}
.MsoChpDefault
        {mso-style-type:export-only;
        font-size:10.0pt;}
@page WordSection1
        {size:612.0pt 792.0pt;
        margin:72.0pt 72.0pt 72.0pt 72.0pt;}
div.WordSection1
        {page:WordSection1;}
--></style><!--[if gte mso 9]><xml>
<o:shapedefaults v:ext="edit" spidmax="1026" />
</xml><![endif]--><!--[if gte mso 9]><xml>
<o:shapelayout v:ext="edit">
<o:idmap v:ext="edit" data="1" />
</o:shapelayout></xml><![endif]-->
</head>
<body lang="EN-GB" link="blue" vlink="purple">
<div class="WordSection1">
<p class="MsoNormal"><span style="color:#1F497D">Sorry hit the wrong button on that last mail…<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">If I reduce down to a single join condition the tuple estimates become sensible. Note that the right branch shows a consistent set of tuples all the way.<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">SELECT count(*)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">FROM comms c<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"> LEFT JOIN researcher r ON c.launch_id = r.researcher_id AND c.launch_type in (0,2)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">Executing . . .<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">********************************************************************<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D">QUERY PLAN 7,2, no timeout, of simple aggregate
<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"> aggregate expression -> count(*)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> right join<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Hash Join(launch_id)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Heap<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Pages 79 Tups 52520<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> D85 C1232<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> / \<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Proj-rest Proj-rest<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Sorted(NU) Sorted(NU)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> Pages 25 Tups 6117 Pages 221 Tups 52520<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D"> D9 C61 D76 C525<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D">/ /<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D">researcher_id_idx comms_launch_indx<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D">I(r) I(c)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D">B-Tree(NU) B-Tree(NU)<o:p></o:p></span></p>
<p class="MsoNormal"><span style="font-family:"Courier New";color:#1F497D">Pages 36 Tups 6117 Pages 305 Tups 52520<o:p></o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<p class="MsoNormal"><span style="color:#1F497D"><o:p> </o:p></span></p>
<div>
<div style="border:none;border-top:solid #B5C4DF 1.0pt;padding:3.0pt 0cm 0cm 0cm">
<p class="MsoNormal"><b><span lang="EN-US" style="font-size:10.0pt;font-family:"Tahoma","sans-serif"">From:</span></b><span lang="EN-US" style="font-size:10.0pt;font-family:"Tahoma","sans-serif""> Martin Bowes [mailto:martin.bowes@ndph.ox.ac.uk]
<br>
<b>Sent:</b> 01 February 2018 14:00<br>
<b>To:</b> Karl and Betty Schendel; info-ingres@lists.planetingres.org<br>
<b>Subject:</b> Re: [Info-ingres] Bad tuple estimate on left join<o:p></o:p></span></p>
</div>
</div>
<p class="MsoNormal"><o:p> </o:p></p>
<p class="MsoPlainText"><span style="color:black">Hi Karl,<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="color:black"><o:p> </o:p></span></p>
<p class="MsoPlainText"><span style="color:black">The Proj-rest node is indeed handling the WHERE clause.<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="color:black">If I simply count the number of rows in comms that satisfy WHERE c.active=1 AND c.comm_type=2 I get 745 as the QEP showed.<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="color:black"><o:p> </o:p></span></p>
<p class="MsoPlainText"><span style="color:black">Nonetheless I ran the query without the where clause. This changed the plan to a right join and the tuple counts are still weird.<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="color:black">See below.<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="color:black"><o:p> </o:p></span></p>
<p class="MsoPlainText">SELECT count(*)<o:p></o:p></p>
<p class="MsoPlainText">FROM comms c<o:p></o:p></p>
<p class="MsoPlainText"> LEFT JOIN researcher r ON c.launch_id = r.researcher_id AND c.launch_type in (0,2)<o:p></o:p></p>
<p class="MsoPlainText"> LEFT JOIN user_details ud ON ud.user_id = r.user_id<o:p></o:p></p>
<p class="MsoPlainText">Executing . . .<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText">********************************************************************<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText">QUERY PLAN 2,2, no timeout, of simple aggregate <o:p></o:p></p>
<p class="MsoPlainText"> aggregate expression -> count(*)<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> left join<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> K Join(user_id)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Heap<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Pages 2 Tups 786<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> D161 C1279<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> / \<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> right join user_details<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Hash Join(researcher_id)(ud)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Sort on(user_id) B-Tree(user_id)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Pages 4 Tups 786 Pages 29 Tups 6200<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> D109 C1248<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> / \<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Proj-rest Proj-rest<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Sorted(NU) Sorted(NU)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> Pages 28 Tups 6117 Pages 221 Tups 52520<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New""> D33 C61 D76 C525<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New"">/ /<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New"">researcher comms_launch_indx<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New"">(r) I(c)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New"">B-Tree(NU) B-Tree(NU)<o:p></o:p></span></p>
<p class="MsoPlainText"><span style="font-family:"Courier New"">Pages 33 Tups 6117 Pages 305 Tups 52520<o:p></o:p></span></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText"><span style="color:black"><o:p> </o:p></span></p>
<p class="MsoPlainText">I wonder if that Kjoin tuple estimate is including the where clause as well, since the where restriction has to be applied somewhere, and the cost tree (QEP) doesn't normally show a separate proj-rest above joins. (Maybe it should!)
Do you still get 11 if you take the where clause off?<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText">(although in this instance, the where restrictions can apply at the orig level, so maybe they're included at the proj-rest.)<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText">Karl<o:p></o:p></p>
<p class="MsoPlainText"><o:p> </o:p></p>
<p class="MsoPlainText">_______________________________________________<o:p></o:p></p>
<p class="MsoPlainText">Info-ingres mailing list<o:p></o:p></p>
<p class="MsoPlainText"><a href="mailto:Info-ingres@lists.planetingres.org"><span style="color:windowtext;text-decoration:none">Info-ingres@lists.planetingres.org</span></a><o:p></o:p></p>
<p class="MsoPlainText"><a href="http://lists.planetingres.org/mailman/listinfo/info-ingres"><span style="color:windowtext;text-decoration:none">http://lists.planetingres.org/mailman/listinfo/info-ingres</span></a><o:p></o:p></p>
</div>
</body>
</html>