---$Id$\r
+--$Id$\r
/*** \r
* \r
* Copyright (C) 2011 Regina Obe and Leo Hsu (Paragon Corporation)\r
\r
-- Find the street edges that this point is closest to with tolerance of 500 meters (width of road)\r
FOR var_redge IN\r
- SELECT DISTINCT ON(fullname) foo.gid, foo.fullname, foo.stusps, foo.zip, (SELECT z.place FROM zip_state_loc AS z WHERE z.zip = foo.zip and z.statefp = foo.statefp) As place, foo.intpt \r
+ SELECT DISTINCT ON(fullname) foo.gid, foo.fullname, foo.stusps, foo.zip, \r
+ (SELECT z.place FROM zip_state_loc AS z WHERE z.zip = foo.zip and z.statefp = foo.statefp LIMIT 1) As place, foo.intpt,\r
+ side, fromhn, tohn\r
FROM \r
- (SELECT e.gid, e.fullname, a.zip, s.stusps, ST_ClosestPoint(e.the_geom, pt) As intpt, e.statefp\r
+ (SELECT e.gid, e.fullname, a.zip, s.stusps, ST_ClosestPoint(e.the_geom, pt) As intpt, e.statefp, a.side, a.fromhn, a.tohn\r
FROM edges AS e INNER JOIN state As s ON (e.statefp = s.statefp AND s.statefp = ANY(var_states) )\r
- INNER JOIN addr As a ON (e.tlid = a.tlid AND e.statefp = a.statefp) -- INNER JOIN zip_state_loc As z ON (a.statefp = z.statefp AND a.zip = z.zip) /** really slow with this join **/\r
+ INNER JOIN faces As fl ON (e.tfidl = fl.tfid AND e.statefp = fl.statefp)\r
+ INNER JOIN faces As fr ON (e.tfidr = fr.tfid AND e.statefp = fr.statefp)\r
+ INNER JOIN addr As a ON ( e.tlid = a.tlid AND e.statefp = a.statefp AND \r
+ ( ( ST_Contains(fl.the_geom, pt) AND a.side = 'L') OR ( ST_Contains(fr.the_geom, pt) AND a.side = 'R' ) ) )\r
+ -- INNER JOIN zip_state_loc As z ON (a.statefp = z.statefp AND a.zip = z.zip) /** really slow with this join **/\r
WHERE e.statefp = ANY(var_states) AND a.statefp = ANY(var_states) AND ST_DWithin(e.the_geom, pt, 0.005)\r
ORDER BY ST_Distance(e.the_geom, pt) LIMIT 4) As foo \r
WHERE ST_Distance_Sphere(foo.intpt, pt) < 150 --less than 150 m\r
ORDER BY foo.fullname, ST_Distance_Sphere(foo.intpt, pt) LOOP\r
intpt := array_append(intpt,var_redge.intpt); \r
IF var_redge.fullname IS NOT NULL THEN\r
- street := array_append(street,var_redge.fullname::text);\r
+ street := array_append(street, CASE WHEN include_strnum_range THEN COALESCE(var_redge.fromhn, '')::text || ' - ' || COALESCE(var_redge.tohn,'')::text || ' '::text ELSE '' END::text || var_redge.fullname::text);\r
var_addy := normalize_address(var_redge.fullname || ', ' || var_redge.place || ', ' || var_redge.stusps || ' ' || var_redge.zip);\r
addy := array_append(addy, var_addy);\r
END IF;\r