From: Regina Obe Date: Thu, 11 Aug 2011 16:35:13 +0000 (+0000) Subject: change reverse_geocode back to using addr table and also use cousub for location X-Git-Tag: 2.0.0alpha1~1118 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=dff685ce27bf247be6772b1b49f2ed33c244623f;p=postgis change reverse_geocode back to using addr table and also use cousub for location git-svn-id: http://svn.osgeo.org/postgis/trunk@7729 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql b/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql index e38f0c6a5..d610ca7a5 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql @@ -59,21 +59,30 @@ BEGIN RAISE NOTICE 'Get matching counties start: %', clock_timestamp(); END IF; -- locate county - SELECT countyfp, name INTO var_countyfp, var_county FROM county WHERE statefp = var_state AND ST_Intersects(the_geom, var_pt) LIMIT 1; - + var_stmt := 'SELECT countyfp, name FROM county WHERE statefp = $1 AND ST_Intersects(the_geom, $2) LIMIT 1;'; + EXECUTE var_stmt USING var_state, var_pt INTO var_countyfp, var_county; + --locate zip - SELECT zcta5ce INTO var_zip FROM zcta5 WHERE statefp = var_state AND ST_Intersects(the_geom, var_pt) LIMIT 1; - + var_stmt := 'SELECT zcta5ce FROM zcta5 WHERE statefp = $1 AND ST_Intersects(the_geom, $2) LIMIT 1;'; + EXECUTE var_stmt USING var_state, var_pt INTO var_zip; -- locate city IF var_zip > '' THEN var_addy.zip := var_zip ; END IF; - --SELECT z.name INTO var_place FROM place As z WHERE z.statefp = var_state AND ST_Intersects(the_geom, var_pt) LIMIT 1; + + var_stmt := 'SELECT z.name FROM place As z WHERE z.statefp = $1 AND ST_Intersects(the_geom, $2) LIMIT 1;'; + EXECUTE var_stmt USING var_state, var_pt INTO var_place; IF var_place > '' THEN - var_addy.location := var_place; - ELSIF var_zip > '' THEN - SELECT z.city INTO var_place FROM zip_lookup_base As z WHERE z.statefp = var_state AND z.county = var_county AND z.zip = var_zip LIMIT 1; - var_addy.location := var_place; + var_addy.location := var_place; + ELSE + var_stmt := 'SELECT z.name FROM cousub As z WHERE z.statefp = $1 AND ST_Intersects(the_geom, $2) LIMIT 1;'; + EXECUTE var_stmt USING var_state, var_pt INTO var_place; + IF var_place > '' THEN + var_addy.location := var_place; + -- ELSIF var_zip > '' THEN + -- SELECT z.city INTO var_place FROM zip_lookup_base As z WHERE z.statefp = var_state AND z.county = var_county AND z.zip = var_zip LIMIT 1; + -- var_addy.location := var_place; + END IF; END IF; IF var_debug THEN @@ -101,28 +110,30 @@ BEGIN AND ST_Intersects(faces.the_geom, ref_geom) ), e AS - ( SELECT edges.* , CASE WHEN edges.tfidr = f.tfid THEN ''R'' WHEN edges.tfidl = f.tfid THEN ''L'' ELSE NULL END::varchar As eside, - CASE WHEN edges.tfidr = f.tfid THEN rfromadd ELSE lfromadd END As fromhn, CASE WHEN edges.tfidr = f.tfid THEN rtoadd ELSE ltoadd END As tohn, - CASE WHEN edges.tfidr = f.tfid THEN zipr ELSE zipl END As zip, + ( SELECT edges.tlid , edges.statefp, edges.the_geom, CASE WHEN edges.tfidr = f.tfid THEN ''R'' WHEN edges.tfidl = f.tfid THEN ''L'' ELSE NULL END::varchar As eside, ST_ClosestPoint(edges.the_geom,ref_geom) As center_pt, ref_geom FROM edges INNER JOIN f ON (f.statefp = edges.statefp AND (edges.tfidr = f.tfid OR edges.tfidl = f.tfid)) CROSS JOIN ref WHERE edges.statefp = ' || quote_literal(var_state) || ' AND edges.countyfp = ' || quote_literal(var_countyfp) || ' AND ST_DWithin(edges.the_geom, ref.ref_geom, 0.01) AND (edges.mtfcc LIKE ''S%'') --only consider streets and roads - ) + ) , + ea AS + (SELECT e.statefp, e.tlid, a.fromhn, a.tohn, e.center_pt, ref_geom, a.zip, a.side, e.the_geom + FROM e LEFT JOIN addr As a ON (a.statefp = ' || quote_literal(var_state) || ' AND e.tlid = a.tlid and e.eside = a.side) + ) SELECT * - FROM (SELECT DISTINCT ON(tlid,eside) foo.fullname, foo.streetname, foo.streettypeabbrev, foo.zip, foo.center_pt, - eside, to_number(fromhn, ''999999'') As fromhn, to_number(tohn, ''999999'') As tohn, ST_GeometryN(ST_Multi(line),1) As line, + FROM (SELECT DISTINCT ON(tlid,side) foo.fullname, foo.streetname, foo.streettypeabbrev, foo.zip, foo.center_pt, + side, to_number(fromhn, ''999999'') As fromhn, to_number(tohn, ''999999'') As tohn, ST_GeometryN(ST_Multi(line),1) As line, dist FROM - (SELECT e.tlid, e.the_geom As line, COALESCE(n.fullname,e.fullname) As fullname, COALESCE(n.prequalabr || '' '','''') || n.name AS streetname, n.predirabrv, COALESCE(suftypabrv, pretypabrv) As streettypeabbrev, - n.sufdirabrv, e.zip, e.eside, e.fromhn, e.tohn , e.center_pt, + (SELECT e.tlid, e.the_geom As line, n.fullname, COALESCE(n.prequalabr || '' '','''') || n.name AS streetname, n.predirabrv, COALESCE(suftypabrv, pretypabrv) As streettypeabbrev, + n.sufdirabrv, e.zip, e.side, e.fromhn, e.tohn , e.center_pt, ST_Distance_Sphere(e.center_pt,ref_geom) As dist - FROM e + FROM ea AS e LEFT JOIN (SELECT featnames.* FROM featnames - WHERE featnames.statefp = ' || quote_literal(var_state) ||' AND featnames.mtfcc LIKE ''S%'' ) AS n ON (n.statefp = e.statefp AND n.tlid = e.tlid) + WHERE featnames.statefp = ' || quote_literal(var_state) ||' ) AS n ON (n.statefp = e.statefp AND n.tlid = e.tlid) ORDER BY dist LIMIT 50 ) As foo - ORDER BY foo.tlid, foo.eside, foo.fullname ASC NULLS LAST, dist LIMIT 50) As f ORDER BY f.dist '; + ORDER BY foo.tlid, foo.side, foo.fullname ASC NULLS LAST, dist LIMIT 50) As f ORDER BY f.dist '; IF var_debug = true THEN RAISE NOTICE 'Statement 1: %', var_stmt; @@ -217,7 +228,7 @@ BEGIN var_addy_alt.streettypeabbrev := var_addy.streettypeabbrev; addy[1] := var_addy_alt; END IF; - IF var_debug THEN + IF var_debug THEN RAISE NOTICE 'End Get matching edges loop: %', clock_timestamp(); END IF; diff --git a/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress b/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress index 6bd6ed03c..044915d10 100644 --- a/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress +++ b/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress @@ -1,5 +1,5 @@ -I- 90, Wellesley, MA 02493|{"(,,90,I-,,,Wellesley,MA,02493,)"} -I- 90, Worcester, MA 01501|{"(,,90,I-,,,Worcester,MA,01501,)"} +I- 90, Weston, MA 02493|{"(,,90,I-,,,Weston,MA,02493,)"} +I- 90, Auburn, MA 01501|{"(,,90,I-,,,Auburn,MA,01501,)"} 158 Washington St, Boston, MA 02108|{"(158,,Washington,St,,,Boston,MA,02108,)"} 32 Capen St, Medford, MA 02155|{"(32,,Capen,St,,,Medford,MA,02155,)","(3,,Edison,Ave,,,Medford,MA,02155,)"} 58 Massachusetts Ave, Cambridge, MA 02139|{"(58,,Massachusetts,Ave,,,Cambridge,MA,02139,)","(7,,Wellesley,St,,,Cambridge,MA,02139,)","(7,,Massachusetts,Ave,,,Cambridge,MA,02139,)"} diff --git a/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress.sql b/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress.sql index 1d906c28e..19629262a 100644 --- a/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress.sql +++ b/extras/tiger_geocoder/tiger_2010/regress/reverse_geocode_regress.sql @@ -1,7 +1,7 @@ \timing -SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.27593,42.33891)); -- I 90 Exit 14 -SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.85335,42.19262)); -- I 90 Exit 10, Worcester MA +SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.27593,42.33891)); -- I 90 Exit 14, Weston MA +SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.85335,42.19262)); -- I 90 Exit 10, Auburn, MA 01501 SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.057811,42.358274)); -- 1 Devonshire Place (washington st area) -SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.123848,42.41115)); --30 capen -SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.09436,42.35981)); -- 77 Massachusetts Ave +SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.123848,42.41115)); -- 30 capen, Medford, MA 02155 +SELECT pprint_addy(addy[1]), addy FROM reverse_geocode(ST_Point(-71.09436,42.35981)); -- 77 Massachusetts Ave, Cambridge, MA 02139 \timing \ No newline at end of file