<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.0 Transitional//EN">
<HTML xmlns="http://www.w3.org/TR/REC-html40" 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"><HEAD>
<META http-equiv=Content-Type content="text/html; charset=us-ascii">
<META content="MSHTML 6.00.6000.16414" name=GENERATOR>
<STYLE>@font-face {
font-family: Cambria Math;
}
@font-face {
font-family: Calibri;
}
@page Section1 {size: 612.0pt 792.0pt; margin: 70.85pt 3.0cm 70.85pt 3.0cm; }
P.MsoNormal {
FONT-SIZE: 11pt; MARGIN: 0cm 0cm 0pt; FONT-FAMILY: "Calibri","sans-serif"
}
LI.MsoNormal {
FONT-SIZE: 11pt; MARGIN: 0cm 0cm 0pt; FONT-FAMILY: "Calibri","sans-serif"
}
DIV.MsoNormal {
FONT-SIZE: 11pt; MARGIN: 0cm 0cm 0pt; FONT-FAMILY: "Calibri","sans-serif"
}
A:link {
COLOR: blue; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.MsoHyperlink {
COLOR: blue; TEXT-DECORATION: underline; mso-style-priority: 99
}
A:visited {
COLOR: purple; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.MsoHyperlinkFollowed {
COLOR: purple; TEXT-DECORATION: underline; mso-style-priority: 99
}
SPAN.EmailStyle17 {
COLOR: windowtext; FONT-FAMILY: "Calibri","sans-serif"; mso-style-type: personal-compose
}
..MsoChpDefault {
mso-style-type: export-only
}
DIV.Section1 {
page: Section1
}
</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=PT vLink=purple link=blue>
<DIV dir=ltr align=left><SPAN class=493073412-02042007><FONT face=Arial
color=#0000ff size=2>I'm not sure how slow this would be depending on how many
line segments you have by name, but it seems the most speedy to write.
Basically I think you want to collect all your roads of N17 into a single
geometry so that you can then apply a single distance check
call.</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=493073412-02042007><FONT face=Arial
color=#0000ff size=2></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=493073412-02042007><FONT face=Arial
color=#0000ff size=2>So something like</FONT></SPAN></DIV>
<DIV dir=ltr align=left><SPAN class=493073412-02042007><FONT face=Arial
color=#0000ff size=2></FONT></SPAN> </DIV>
<DIV dir=ltr align=left><SPAN class=493073412-02042007><FONT size=2>
<P class=MsoNormal><SPAN lang=EN-US><FONT color=#0000ff>select u.friendly_name,
distance(transform(u.curr_location, 32628), <o:p></o:p></FONT></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><FONT color=#0000ff>transform(<SPAN
class=493073412-02042007>rc.agg_</SPAN>geometry,32628)) as thedistance
<o:p></o:p></FONT></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><FONT color=#0000ff>from <SPAN
class=493073412-02042007>(SELECT collect(r.geometry) as agg_geometry FROM
</SPAN>pt_mainland_roads r<SPAN class=493073412-02042007> WHERE r.name = 'N17')
rc</SPAN>, units as u <o:p></o:p></FONT></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><FONT color=#0000ff>where r<SPAN
class=493073412-02042007>c</SPAN>.<SPAN
class=493073412-02042007>agg_</SPAN>geometry <SPAN
class=493073412-02042007>&& </SPAN>u.curr_location order by thedistance
LIMIT 1<SPAN class=493073412-02042007>0</SPAN>;</FONT></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><FONT color=#0000ff></FONT></SPAN> </P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff>If you have some units that are not in the bounding box of a road
that would be in the top 10, then you may want to change your where clause
to</FONT></SPAN></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff></FONT></SPAN></o:p></SPAN> </P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff>expand(r<SPAN class=493073412-02042007>c</SPAN>.<SPAN
class=493073412-02042007>agg_</SPAN>geometry, <somevalue>) <SPAN
class=493073412-02042007>&& </SPAN>u.curr_location
</FONT></SPAN></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff></FONT></SPAN></o:p></SPAN> </P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff>Hope that helps,</FONT></SPAN></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p><SPAN class=493073412-02042007><FONT
color=#0000ff>Regina</FONT></SPAN></o:p></SPAN></P></FONT></SPAN></DIV><BR>
<DIV class=OutlookMessageHeader lang=en-us dir=ltr align=left>
<HR tabIndex=-1>
<FONT face=Tahoma size=2><B>From:</B>
postgis-users-bounces@postgis.refractions.net
[mailto:postgis-users-bounces@postgis.refractions.net] <B>On Behalf Of </B>Pedro
Doria Meunier<BR><B>Sent:</B> Sunday, April 01, 2007 9:50 PM<BR><B>To:</B>
'PostGIS Users Discussion'<BR><B>Subject:</B> [postgis-users] 10 closest
units<BR><B>Importance:</B> High<BR></FONT><BR></DIV>
<DIV></DIV>
<DIV class=Section1>
<P class=MsoNormal>Hi All,<o:p></o:p></P>
<P class=MsoNormal><o:p> </o:p></P>
<P class=MsoNormal><SPAN lang=EN-US>@Regina:<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Remember you helped me with the 10 closest
units to a given point? This was it:<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>(original layers srid==4326 – I want
*<B>meters</B>* so the transform at play)<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>SELECT u.id, u.friendly_name,
u.curr_location, t.oid, distance(transform(u.curr_location,32628),
transform(t.geometry, 32628)) AS thedistance, u.mobile FROM units AS u, (SELECT
roads.oid, roads.geometry FROM roads WHERE name=’N17’ LIMIT 1) AS t
<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>ORDER BY thedistance LIMIT
10;<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>(this query returns the 1<SUP>st</SUP> found
line segment labelled ‘N17’ which is 68Kms away when the unit is actually 1.8
meters away from the closest line segment of the same
label)<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>@All<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>This actually returns the FIRST occurrence
of ‘N17’ (the sample).<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>This is *<B>NOT</B>* necessarily the closest
road to the unit’s current location.<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>I’ve melted half-a-dozen neurons (mainly due
to tiredness at the time of this writing :] )trying to figure out how can I
implement the distance bit in the sub-query…<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Given example for ONE
unit:<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>select u.friendly_name,
distance(transform(u.curr_location, 32628), <o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>transform(geometry,32628)) as thedistance
<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>from pt_mainland_roads as r, units as u
<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>where name='N17' AND u.curr_location
&& r.geometry order by thedistance LIMIT 1;<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>(this returns the correct
result)<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>So to summarize
things:<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>I need help with a query that returns the
*<B>FIRST TEN</B>* units to the *<B>closest given</B>* road.
<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>(Keep in mind that multiple line segments
with the same name exist – I need the closest)<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Will try again tomorrow with a clear head
but in the meantime:<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Any help would be most
appreciated!<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US><o:p> </o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Best regards,<o:p></o:p></SPAN></P>
<P class=MsoNormal><SPAN lang=EN-US>Pedro Doria
Meunier.<o:p></o:p></SPAN></P></DIV></BODY></HTML>
<HTML><BODY><P><hr size=1></P><br>
<P><STRONG><br>
The substance of this message, including any attachments, may be<br>
confidential, legally privileged and/or exempt from disclosure<br>
pursuant to Massachusetts law. It is intended solely for the<br>
addressee. If you received this in error, please contact the sender<br>
and delete the material from any computer.<br>
</STRONG></P></BODY></HTML>