**/\r
-- This function given a point try to determine the approximate street address (norm_addy form)\r
-- and array of cross streets, as well as interpolated points along the streets\r
--- Use case example: SELECT pprint_addy(r.addy[1]) As st1, array_to_string(r.street, ',') FROM reverse_geocode(ST_GeomFromText('POINT(-71.057811 42.358274)',4269)) As r;\r
-set search_path=tiger,public;\r
+-- Use case example an address at the intersection of 3 streets: SELECT pprint_addy(r.addy[1]) As st1, pprint_addy(r.addy[2]) As st2, pprint_addy(r.addy[3]) As st3, array_to_string(r.street, ',') FROM reverse_geocode(ST_GeomFromText('POINT(-71.057811 42.358274)',4269)) As r;\r
+--set search_path=tiger,public;\r
CREATE OR REPLACE FUNCTION reverse_geocode(\r
IN pt geometry,\r
IN include_strnum_range boolean,\r
OUT intpt geometry[],\r
OUT addy NORM_ADDY[],\r
- OUT street text[]\r
+ OUT street varchar[]\r
) RETURNS RECORD\r
AS $_$\r
DECLARE\r
var_redge RECORD;\r
var_states text[];\r
var_addy NORM_ADDY;\r
+ var_strnum varchar;\r
+ var_primary_line geometry := NULL;\r
+ var_primary_dist numeric(10,2) ;\r
BEGIN\r
IF pt IS NULL THEN\r
RETURN;\r
RETURN;\r
END IF;\r
\r
- -- Find the street edges that this point is closest to with tolerance of 500 meters (width of road)\r
+ -- Find the street edges that this point is closest to with tolerance of 0.005 but only consider the edge if the point is contained in the right or left face\r
+ -- Then order addresses by proximity to road\r
FOR var_redge IN\r
- SELECT DISTINCT ON(fullname) foo.gid, foo.fullname, foo.stusps, foo.zip, \r
+ SELECT * \r
+ FROM (SELECT DISTINCT ON(fullname) 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
+ side, to_number(fromhn, '999999') As fromhn, to_number(tohn, '999999') As tohn, ST_GeometryN(ST_Multi(line),1) As line, foo.dist\r
FROM \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
+ (SELECT e.the_geom As line, e.fullname, a.zip, s.stusps, ST_ClosestPoint(e.the_geom, pt) As intpt, e.statefp, a.side, a.fromhn, a.tohn, ST_Distance_Sphere(e.the_geom, pt) As dist\r
FROM edges AS e INNER JOIN state As s ON (e.statefp = s.statefp AND s.statefp = ANY(var_states) )\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
+ ( ( 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, 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
+ ORDER BY ST_Distance_Sphere(e.the_geom, pt) LIMIT 4) As foo \r
+ WHERE dist < 150 --less than 150 m\r
+ ORDER BY foo.fullname, foo.dist) As f ORDER BY f.dist LOOP\r
+ IF var_primary_line IS NULL THEN --this is the first time in the loop and our primary guess\r
+ var_primary_line := var_redge.line;\r
+ var_primary_dist := var_redge.dist;\r
END IF;\r
+ -- We only consider other edges as matches if they intersect our primary edge -- that would mean we are at a corner place\r
+ IF ST_Intersects(var_redge.line, var_primary_line) THEN\r
+ intpt := array_append(intpt,var_redge.intpt); \r
+ IF var_redge.fullname IS NOT NULL THEN\r
+ street := array_append(street, (CASE WHEN include_strnum_range THEN COALESCE(var_redge.fromhn::varchar, '')::varchar || ' - ' || COALESCE(var_redge.tohn::varchar,'')::varchar || ' '::varchar ELSE '' END::varchar || var_redge.fullname::varchar)::varchar);\r
+ --interploate the number -- note that if fromhn > tohn we will be subtracting which is what we want\r
+ -- We only consider differential distances are reeally close from our primary pt\r
+ IF var_redge.dist < var_primary_dist*1.1 THEN \r
+ var_strnum := (var_redge.fromhn + ST_Line_Locate_Point(var_redge.line, pt)*(var_redge.tohn - var_redge.fromhn))::numeric(10)::varchar;\r
+ var_addy := normalize_address( COALESCE(var_strnum::varchar || ' ', '') || var_redge.fullname || ', ' || var_redge.place || ', ' || var_redge.stusps || ' ' || var_redge.zip);\r
+ addy := array_append(addy, var_addy);\r
+ END IF;\r
+ END IF;\r
+ END IF;\r
END LOOP;\r
\r
RETURN; \r
\r
CREATE OR REPLACE FUNCTION reverse_geocode(IN pt geometry, OUT intpt geometry[],\r
OUT addy NORM_ADDY[],\r
- OUT street text[]) RETURNS RECORD\r
+ OUT street varchar[]) RETURNS RECORD\r
AS \r
$$\r
-- default to not including street range in cross streets\r