<refname>Geocode</refname>
<refpurpose>Takes in an address as a string (or other normalized address) and outputs a set of possible locations which include a point geometry in NAD 83 long lat, a normalized address for each, and the rating. The lower the rating the more likely the match.
- Results are sorted by lowest rating first.</refpurpose>
+ Results are sorted by lowest rating first. Can optionally pass in maximum results, defaults to 10, and restrict_region (defaults to NULL)</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcdef>setof record <function>geocode</function></funcdef>
<paramdef><type>varchar </type> <parameter>address</parameter></paramdef>
<paramdef><type choice='opt'>integer </type> <parameter>max_results=10</parameter></paramdef>
+ <paramdef><type choice='opt'>geometry </type> <parameter>restrict_region=NULL</parameter></paramdef>
<paramdef><type>norm_addy </type> <parameter>OUT addy</parameter></paramdef>
<paramdef><type>geometry </type> <parameter>OUT geomout</parameter></paramdef>
<paramdef><type>integer </type> <parameter>OUT rating</parameter></paramdef>
--$Id$
CREATE OR REPLACE FUNCTION geocode(
input VARCHAR, max_results integer DEFAULT 10,
+ restrict_geom geometry DEFAULT NULL,
OUT ADDY NORM_ADDY,
OUT GEOMOUT GEOMETRY,
OUT RATING INTEGER
RETURN NEXT;
END LOOP;*/
- RETURN QUERY SELECT g.addy, g.geomout, g.rating FROM geocode(ADDY, max_results) As g ORDER BY g.rating;
+ RETURN QUERY SELECT g.addy, g.geomout, g.rating FROM geocode(ADDY, max_results, restrict_geom) As g ORDER BY g.rating;
END;
$_$ LANGUAGE plpgsql STABLE;
CREATE OR REPLACE FUNCTION geocode(
- IN_ADDY NORM_ADDY, max_results integer DEFAULT 10,
+ IN_ADDY NORM_ADDY,
+ max_results integer DEFAULT 10,
+ restrict_geom geometry DEFAULT null,
OUT ADDY NORM_ADDY,
OUT GEOMOUT GEOMETRY,
OUT RATING INTEGER
)
*
FROM
- geocode_address(IN_ADDY, max_results) a
+ geocode_address(IN_ADDY, max_results, restrict_geom) a
ORDER BY
(a.addy).address,
(a.addy).predirabbrev,
-- No zip code, try state/location, need both or we'll get too much stuffs.
IF IN_ADDY.zip IS NOT NULL OR (IN_ADDY.stateAbbrev IS NOT NULL AND IN_ADDY.location IS NOT NULL) THEN
- FOR rec in SELECT * FROM geocode_location(IN_ADDY) ORDER BY 3
+ FOR rec in SELECT * FROM geocode_location(IN_ADDY, restrict_geom) As b ORDER BY b.rating LIMIT max_results
LOOP
ADDY := rec.addy;
GEOMOUT := rec.geomout;
--$Id$
-CREATE OR REPLACE FUNCTION geocode_address(IN parsed norm_addy, max_results integer DEFAULT 10, OUT addy norm_addy, OUT geomout geometry, OUT rating integer)
+CREATE OR REPLACE FUNCTION geocode_address(IN parsed norm_addy, max_results integer DEFAULT 10, restrict_geom geometry DEFAULT NULL, OUT addy norm_addy, OUT geomout geometry, OUT rating integer)
RETURNS SETOF record AS
$$
DECLARE
var_debug boolean := false;
var_sql text := '';
var_n integer := 0;
+ var_restrict_geom geometry := NULL;
+ var_bfilter text := null;
BEGIN
IF parsed.streetName IS NULL THEN
-- A street name must be given. Think about it.
ADDY.internal := parsed.internal;
in_statefp := statefp FROM state_lookup As s WHERE s.abbrev = parsed.stateAbbrev;
+
+ IF restrict_geom IS NOT NULL THEN
+ IF ST_SRID(restrict_geom) < 1 OR ST_SRID(restrict_geom) = 4236 THEN
+ -- basically has no srid or if wgs84 close enough to NAD 83 -- assume same as data
+ var_restrict_geom = ST_SetSRID(restrict_geom,4269);
+ ELSE
+ --transform and snap
+ var_restrict_geom = ST_SnapToGrid(ST_Transform(restrict_geom, 4269), 0.000001);
+ END IF;
+ END IF;
+ var_bfilter := ' SELECT zcta5ce FROM zcta5 AS zc
+ WHERE zc.statefp = ' || quote_nullable(in_statefp) || '
+ AND ST_Intersects(zc.the_geom, ' || quote_literal(var_restrict_geom::text) || '::geometry) ' ;
-- There are a couple of different things to try, from the highest preference and falling back
-- to lower-preference options.
-- lookup to try and find *something* useful.
-- In the end, we *have* to find a statefp, one way or another.
var_sql :=
- ' SELECT statefp,location,zip,exact,min(pref) FROM
+ ' SELECT statefp,location,a.zip,exact,min(pref) FROM
(SELECT zip_state.statefp as statefp,$1 as location, true As exact, ARRAY[zip_state.zip] as zip,1 as pref
FROM zip_state WHERE zip_state.zip = $2
AND (' || quote_nullable(in_statefp) || ' IS NULL OR zip_state.statefp = ' || quote_nullable(in_statefp) || ')
- UNION SELECT zip_state_loc.statefp,zip_state_loc.place As location,false As exact, array_agg(zip_state_loc.zip) AS zip,1 + abs(COALESCE(diff_zip(max(zip), $2),0) - COALESCE(diff_zip(min(zip), $2),0)) As pref
+ ' || COALESCE(' AND zip_state.zip IN(' || var_bfilter || ')', '') ||
+ ' UNION SELECT zip_state_loc.statefp,zip_state_loc.place As location,false As exact, array_agg(zip_state_loc.zip) AS zip,1 + abs(COALESCE(diff_zip(max(zip), $2),0) - COALESCE(diff_zip(min(zip), $2),0)) As pref
FROM zip_state_loc
WHERE zip_state_loc.statefp = ' || quote_nullable(in_statefp) || '
- AND lower($1) = lower(zip_state_loc.place)
- GROUP BY zip_state_loc.statefp,zip_state_loc.place
+ AND lower($1) = lower(zip_state_loc.place) ' || COALESCE(' AND zip_state_loc.zip IN(' || var_bfilter || ')', '') ||
+ ' GROUP BY zip_state_loc.statefp,zip_state_loc.place
UNION SELECT zip_state_loc.statefp,zip_state_loc.place As location,false As exact, array_agg(zip_state_loc.zip),3
FROM zip_state_loc
WHERE zip_state_loc.statefp = ' || quote_nullable(in_statefp) || '
WHERE zip_lookup_base.statefp = ' || quote_nullable(in_statefp) || '
AND (soundex($1) = soundex(zip_lookup_base.city) OR soundex($1) = soundex(zip_lookup_base.county))
GROUP BY zip_lookup_base.statefp,zip_lookup_base.city
- UNION SELECT ' || quote_nullable(in_statefp) || ' As statefp,$1 As location,false As exact,NULL, 5) as a
- WHERE statefp IS NOT NULL
- GROUP BY statefp,location,zip,exact, pref ORDER BY exact desc, pref, zip';
+ UNION SELECT ' || quote_nullable(in_statefp) || ' As statefp,$1 As location,false As exact,NULL, 5) as a '
+ ' WHERE a.statefp IS NOT NULL
+ GROUP BY statefp,location,a.zip,exact, pref ORDER BY exact desc, pref, zip';
/** FOR zip_info IN SELECT statefp,location,zip,exact,min(pref) FROM
(SELECT zip_state.statefp as statefp,parsed.location as location, true As exact, ARRAY[zip_state.zip] as zip,1 as pref
FROM zip_state WHERE zip_state.zip = parsed.zip
|| ' ORDER BY 11'
|| ' LIMIT 20'
|| ' ) AS sub'
- || ' JOIN edges e ON (' || quote_literal(zip_info.statefp) || ' = e.statefp AND sub.tlid = e.tlid)'
+ || ' JOIN edges e ON (' || quote_literal(zip_info.statefp) || ' = e.statefp AND sub.tlid = e.tlid '
+ || CASE WHEN var_restrict_geom IS NOT NULL THEN ' AND ST_Intersects(e.the_geom, $8) ' ELSE '' END || ') '
|| ' JOIN state s ON (' || quote_literal(zip_info.statefp) || ' = s.statefp)'
|| ' JOIN faces f ON (' || quote_literal(zip_info.statefp) || ' = f.statefp AND (e.tfidl = f.tfid OR e.tfidr = f.tfid))'
|| ' LEFT JOIN zip_lookup_base zip ON (sub.zip = zip.zip AND zip.statefp=' || quote_literal(zip_info.statefp) || ')'
RETURN;
END IF;
- FOR results IN EXECUTE stmt USING parsed.address,parsed.streetName, parsed.location, parsed.streetTypeAbbrev, parsed.preDirAbbrev, parsed.postDirAbbrev, parsed.zip LOOP
+ FOR results IN EXECUTE stmt USING parsed.address,parsed.streetName, parsed.location, parsed.streetTypeAbbrev, parsed.preDirAbbrev, parsed.postDirAbbrev, parsed.zip, var_restrict_geom LOOP
-- If we found a match with an exact street, then don't bother
-- trying to do non-exact matches
--$Id$
CREATE OR REPLACE FUNCTION geocode_location(
parsed NORM_ADDY,
+ restrict_geom geometry DEFAULT null,
OUT ADDY NORM_ADDY,
OUT GEOMOUT GEOMETRY,
OUT RATING INTEGER
result RECORD;
in_statefp VARCHAR;
stmt VARCHAR;
+ var_debug boolean := false;
BEGIN
in_statefp := statefp FROM state WHERE state.stusps = parsed.stateAbbrev;
+ IF var_debug THEN
+ RAISE NOTICE 'geocode_location starting: %', clock_timestamp();
+ END IF;
FOR result IN
SELECT
coalesce(zip.city)::varchar as place,
|| ' state.stusps as stateAbbrev, '
|| ' ST_Centroid(pl.the_geom) as address_geom, '
|| ' 100::integer + levenshtein_ignore_case(coalesce(pl.name), ' || quote_literal(coalesce(parsed.location,'')) || ') as in_rating '
- || ' FROM place pl '
- || ' JOIN state USING (statefp)'
- || ' WHERE soundex(pl.name) = soundex(' || quote_literal(coalesce(parsed.location,'')) || ') and pl.statefp = ' || quote_literal(coalesce(in_statefp,''))
+ || ' FROM (SELECT * FROM place WHERE statefp = ' || quote_literal(coalesce(in_statefp,'')) || ' ' || COALESCE(' AND ST_Intersects(' || quote_literal(restrict_geom::text) || '::geometry, the_geom)', '') || ') AS pl '
+ || ' INNER JOIN state ON(pl.statefp = state.statefp)'
+ || ' WHERE soundex(pl.name) = soundex(' || quote_literal(coalesce(parsed.location,'')) || ') and pl.statefp = ' || quote_literal(COALESCE(in_statefp,''))
|| ' ORDER BY levenshtein_ignore_case(coalesce(pl.name), ' || quote_literal(coalesce(parsed.location,'')) || ');'
;
+ IF var_debug THEN
+ RAISE NOTICE 'geocode_location stmt: %', stmt;
+ END IF;
FOR result IN EXECUTE stmt
LOOP
IF RATING = 100 THEN
RETURN;
+ IF var_debug THEN
+ RAISE NOTICE 'geocode_location ending hit 100 rating result: %', clock_timestamp();
+ END IF;
END IF;
END LOOP;
+
+ IF var_debug THEN
+ RAISE NOTICE 'geocode_location ending: %', clock_timestamp();
+ END IF;
RETURN;
#1076f|1940 C W, Roseville, MN 55113|1940 County Road C W, Roseville, MN 55113|POINT(-93.18492 45.02058)|25
#1076f|1940 W C, Roseville, MN 55113|1940 County Road C W, Roseville, MN 55113|POINT(-93.18492 45.02058)|29
#1076g|15709 Rockford Rd, Plymouth, MN 55447|15709 Rockford Road, Plymouth, MN 55447|POINT(-93.47898 45.02726)|0
+#1074a|8525 Cottagewood Ter NE, Blaine, MN 55434|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-93.24462 45.12481)|14
+#1074a|Cottage Wood Dr SW, Lake Shore, MN 56468|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.39339 46.43663)|32
+#1074a|Cottage Wood Dr SW, Merrifield, MN 56468|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.39339 46.43663)|32
+#1074a|Cottage Wood Dr SW, Nisswa, MN 56468|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.39339 46.43663)|32
+#1074a|Cottage Wood Dr SW, Pequot Lakes, MN 56468|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.39339 46.43663)|32
+#1074a|Cottage Wood Dr SW, Pillager, MN 56468|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.39339 46.43663)|32
+#1074a|Cottagewood Ter NE, Spring Lake Park, MN 55432|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-93.24464 45.1237)|33
+#1074a|Cottage Wood Ln, Fifty Lakes, MN 56448|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.07085 46.75406)|34
+#1074a|Cottage Wood, Fifty Lakes, MN 56448|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-94.07085 46.75406)|34
+#1074a|Cottagewood Ave, Deephaven, MN 55331|8525 COTTAGE WOOD TERR, Blaine, MN 55434|POINT(-93.5329 44.92732)|43
+#1074b|8525 Cottagewood Ter NE, Blaine, MN 55434|8525 COTTAGEWOOD TERR, Blaine, MN 55434|POINT(-93.24462 45.12481)|4
+#1070a|100 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
+#1070b|100 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
-- ad road that in some sections no street range recorded --
SELECT '#1076g' As ticket, pprint_addy((g).addy) As address, target, ST_AsText(ST_SnapToGrid((g).geomout, 0.00001)) As pt, (g).rating FROM (SELECT geocode(target) As g, target FROM (SELECT '15709 Rockford Road, Plymouth, MN 55447'::text As target) As f) AS foo;
+
+-- alternate spellings
+SELECT '#1074a' As ticket, pprint_addy((g).addy) As address, target, ST_AsText(ST_SnapToGrid((g).geomout, 0.00001)) As pt, (g).rating FROM (SELECT geocode(target) As g, target FROM (SELECT '8525 COTTAGE WOOD TERR, Blaine, MN 55434'::text As target) As f) AS foo;
+SELECT '#1074b' As ticket, pprint_addy((g).addy) As address, target, ST_AsText(ST_SnapToGrid((g).geomout, 0.00001)) As pt, (g).rating FROM (SELECT geocode(target) As g, target FROM (SELECT '8525 COTTAGEWOOD TERR, Blaine, MN 55434'::text As target) As f) AS foo;
+
+-- testing region --
+SELECT '#1070a' As ticket, pprint_addy(addy) As address, ST_AsText(ST_SnapToGrid(geomout,0.00001)) As pt, rating FROM geocode('100 Federal Street, Boston, MA 02109',3, (SELECT ST_Union(the_geom) FROM place WHERE statefp = '25' AND name = 'Lynn')::geometry);
+SELECT '#1070b' As ticket, pprint_addy(addy) As address, ST_AsText(ST_SnapToGrid(geomout,0.00001)) As pt, rating FROM geocode('100 Federal Street, MA',3, (SELECT ST_Union(the_geom) FROM place WHERE statefp = '25' AND name = 'Lynn')::geometry);
\timing
CREATE INDEX tiger_edges_the_geom_gist ON edges USING gist(the_geom);
CREATE INDEX tiger_state_the_geom_gist ON faces USING gist(the_geom);
DROP FUNCTION IF EXISTS reverse_geocode(geometry); /** changed to use default parameters **/
-DROP FUNCTION IF EXISTS geocode(varchar); /** changed to include default parameter for max_results **/
-DROP FUNCTION IF EXISTS geocode(norm_addy); /** changed to include default parameter for max_results **/
+DROP FUNCTION IF EXISTS geocode_location(norm_addy); /** changed to include default parameter for restrict_geom**/
+DROP FUNCTION IF EXISTS geocode(varchar); /** changed to include default parameter for max_results and restrict_geom**/
+DROP FUNCTION IF EXISTS geocode(norm_addy); /** changed to include default parameter for max_results and restrict_geom **/
+DROP FUNCTION IF EXISTS geocode(varchar, integer); /** changed to include default parameter for max_results and restrict_geom **/
+DROP FUNCTION IF EXISTS geocode(norm_addy,integer); /** changed to include default parameter for max_results and restrict_geom **/
DROP FUNCTION IF EXISTS geocode_address(norm_addy); /** changed to include default parameter for max_results **/
+DROP FUNCTION IF EXISTS geocode_address(norm_addy,integer); /** changed to include default parameter for max_results and restrict_geom **/
-- TODO: Put in logic to update lookup tables as they change. street_type_lookup has changed since initial release --
CREATE TABLE zcta5