<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=utf-8"><meta name=Generator content="Microsoft Word 15 (filtered medium)"><style><!--
/* Font Definitions */
@font-face
{font-family:"Cambria Math";
panose-1:2 4 5 3 5 4 6 3 2 4;}
@font-face
{font-family:Calibri;
panose-1:2 15 5 2 2 2 4 3 2 4;}
/* Style Definitions */
p.MsoNormal, li.MsoNormal, div.MsoNormal
{margin:0in;
margin-bottom:.0001pt;
font-size:12.0pt;
font-family:"Times New Roman",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;}
span.EmailStyle17
{mso-style-type:personal-reply;
font-family:"Calibri",sans-serif;
color:#1F497D;}
.MsoChpDefault
{mso-style-type:export-only;
font-family:"Calibri",sans-serif;}
@page WordSection1
{size:8.5in 11.0in;
margin:1.0in 1.0in 1.0in 1.0in;}
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-US link=blue vlink=purple><div class=WordSection1><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'>Side note if you are using PostGIS >= 2.2 + PostgreSQL 9.5+, then no need to compute distance twice because <-> would give you true distance. So you can shorten a bit (and should improve speed slightly) with<o:p></o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'><o:p> </o:p></span></p><p class=MsoNormal>SELECT<o:p></o:p></p><p class=MsoNormal> <a href="http://p1.id" target="_blank">p1.id</a>,<o:p></o:p></p><p class=MsoNormal> <a href="http://t.id" target="_blank">t.id</a> AS id2,<o:p></o:p></p><p class=MsoNormal> t.dist<o:p></o:p></p><p class=MsoNormal>FROM parc p1<o:p></o:p></p><p class=MsoNormal> CROSS JOIN LATERAL<o:p></o:p></p><p class=MsoNormal> (SELECT<o:p></o:p></p><p class=MsoNormal> <a href="http://p2.id" target="_blank">p2.id</a>,<o:p></o:p></p><p class=MsoNormal> p1.geom <-> p2.geom AS dist<o:p></o:p></p><p class=MsoNormal> FROM parc p2<o:p></o:p></p><p class=MsoNormal> WHERE <a href="http://p1.id" target="_blank">p1.id</a> <> <a href="http://p2.id" target="_blank">p2.id</a><o:p></o:p></p><p class=MsoNormal> ORDER BY dist<o:p></o:p></p><p class=MsoNormal> LIMIT 1) AS t<o:p></o:p></p><p class=MsoNormal>ORDER BY <a href="http://p1.id" target="_blank">p1.id</a>, t.dist;<o:p></o:p></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'><o:p> </o:p></span></p><p class=MsoNormal><span style='font-size:11.0pt;font-family:"Calibri",sans-serif;color:#1F497D'><o:p> </o:p></span></p><div style='border:none;border-left:solid blue 1.5pt;padding:0in 0in 0in 4.0pt'><div><div style='border:none;border-top:solid #E1E1E1 1.0pt;padding:3.0pt 0in 0in 0in'><p class=MsoNormal><b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif'>From:</span></b><span style='font-size:11.0pt;font-family:"Calibri",sans-serif'> postgis-users [mailto:postgis-users-bounces@lists.osgeo.org] <b>On Behalf Of </b>Vispo Leblanc<br><b>Sent:</b> Thursday, May 31, 2018 12:05 PM<br><b>To:</b> postgis-users@lists.osgeo.org<br><b>Subject:</b> Re: [postgis-users] Increase KNN efficiency<o:p></o:p></span></p></div></div><p class=MsoNormal><o:p> </o:p></p><div><div><p class=MsoNormal>Thanks Nicolas, this is <b><u>way better</u></b>, I guess my previous query was calculating all distance between all elements. <o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>Thanks again! <o:p></o:p></p></div><p class=MsoNormal><o:p> </o:p></p><div><div><p class=MsoNormal>On Thu, May 31, 2018 at 2:47 AM Nicolas Ribot <<a href="mailto:nicolas.ribot@gmail.com">nicolas.ribot@gmail.com</a>> wrote:<o:p></o:p></p></div><blockquote style='border:none;border-left:solid #CCCCCC 1.0pt;padding:0in 0in 0in 6.0pt;margin-left:4.8pt;margin-right:0in'><div><p class=MsoNormal>Hi,<o:p></o:p></p><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>Put the KNN operator in a LATERAL subquery, using LIMIT x to limit NN to x elements:<o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><div><p class=MsoNormal>SELECT<o:p></o:p></p></div><div><p class=MsoNormal> <a href="http://p1.id" target="_blank">p1.id</a>,<o:p></o:p></p></div><div><p class=MsoNormal> <a href="http://t.id" target="_blank">t.id</a> AS id2,<o:p></o:p></p></div><div><p class=MsoNormal> t.dist<o:p></o:p></p></div><div><p class=MsoNormal>FROM parc p1<o:p></o:p></p></div><div><p class=MsoNormal> CROSS JOIN LATERAL<o:p></o:p></p></div><div><p class=MsoNormal> (SELECT<o:p></o:p></p></div><div><p class=MsoNormal> <a href="http://p2.id" target="_blank">p2.id</a>,<o:p></o:p></p></div><div><p class=MsoNormal> st_distance(p1.geom, p2.geom) AS dist<o:p></o:p></p></div><div><p class=MsoNormal> FROM parc p2<o:p></o:p></p></div><div><p class=MsoNormal> WHERE <a href="http://p1.id" target="_blank">p1.id</a> <> <a href="http://p2.id" target="_blank">p2.id</a><o:p></o:p></p></div><div><p class=MsoNormal> ORDER BY p1.geom <-> p2.geom<o:p></o:p></p></div><div><p class=MsoNormal> LIMIT 1) AS t<o:p></o:p></p></div><div><p class=MsoNormal>ORDER BY <a href="http://p1.id" target="_blank">p1.id</a>, t.dist;<o:p></o:p></p></div></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>Nicolas<o:p></o:p></p></div></div><div><p class=MsoNormal><o:p> </o:p></p><div><p class=MsoNormal>On 30 May 2018 at 23:07, Vispo Leblanc <<a href="mailto:vispoleblanc@gmail.com" target="_blank">vispoleblanc@gmail.com</a>> wrote:<o:p></o:p></p><blockquote style='border:none;border-left:solid #CCCCCC 1.0pt;padding:0in 0in 0in 6.0pt;margin-left:4.8pt;margin-right:0in'><div><div><p class=MsoNormal>Hello PostGIS users, <o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>I am looking for a way to increase the speed of my query with KNN. <o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>I have two tables with millions of points in each table. I would like to find the nearest neighbor (only one) of my points in table A with my points in table B.<o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>I wrote the following query: <o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>WITH index_query as (<br> SELECT<br> <a href="http://t1.id" target="_blank">t1.id</a>,<br> t1.geom AS geom,<br> t2.geom AS geom2, <br> t1.geom <-> t2.geom AS distance<br> FROM research_scrapper.table1 t1, <br> research_scrapper.table2 t2<br> ORDER BY t1.geom <-> t2.geom<br>)<br>SELECT tbl.cas_id, tbl.geom <br>FROM index_query tbl<br>INNER JOIN<br> (<br> SELECT geom2, <br> MIN(distance) as distance<br> FROM index_query <br> GROUP BY geom2<br> )tbl1<br> ON tbl1.geom_generated=tbl.geom_generated<br> AND tbl1.distance = tbl.distance<o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>This is taking forever, would you have any suggestions on how to increase the efficiency?<o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div><div><p class=MsoNormal>Thanks for your help,<o:p></o:p></p></div><div><p class=MsoNormal><o:p> </o:p></p></div></div><p class=MsoNormal><br>_______________________________________________<br>postgis-users mailing list<br><a href="mailto:postgis-users@lists.osgeo.org" target="_blank">postgis-users@lists.osgeo.org</a><br><a href="https://lists.osgeo.org/mailman/listinfo/postgis-users" target="_blank">https://lists.osgeo.org/mailman/listinfo/postgis-users</a><o:p></o:p></p></blockquote></div><p class=MsoNormal><o:p> </o:p></p></div><p class=MsoNormal>_______________________________________________<br>postgis-users mailing list<br><a href="mailto:postgis-users@lists.osgeo.org" target="_blank">postgis-users@lists.osgeo.org</a><br><a href="https://lists.osgeo.org/mailman/listinfo/postgis-users" target="_blank">https://lists.osgeo.org/mailman/listinfo/postgis-users</a><o:p></o:p></p></blockquote></div></div></div></div></body></html>