From: Regina Obe Date: Fri, 15 Apr 2011 11:21:11 +0000 (+0000) Subject: git-svn-id: http://svn.osgeo.org/postgis/trunk@7037 b70326c6-7e19-0410-871a-916f4a2858ee X-Git-Tag: 2.0.0alpha1~1765 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=a679a130e1f4557946e725caf3d4aea7c0acd7a2;p=postgis git-svn-id: http://svn.osgeo.org/postgis/trunk@7037 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/extras/tiger_geocoder/tiger_2010/geocode/geocode.sql b/extras/tiger_geocoder/tiger_2010/geocode/geocode.sql index c39cc71b5..0f20c910a 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/geocode.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/geocode.sql @@ -1,127 +1,127 @@ ---$Id$ -CREATE OR REPLACE FUNCTION geocode( - input VARCHAR, - OUT ADDY NORM_ADDY, - OUT GEOMOUT GEOMETRY, - OUT RATING INTEGER -) RETURNS SETOF RECORD -AS $_$ -DECLARE - rec RECORD; -BEGIN - - IF input IS NULL THEN - RETURN; - END IF; - - -- Pass the input string into the address normalizer - ADDY := normalize_address(input); - IF NOT ADDY.parsed THEN - RETURN; - END IF; - - FOR rec IN SELECT * FROM geocode(ADDY) - LOOP - - ADDY := rec.addy; - GEOMOUT := rec.geomout; - RATING := rec.rating; - - RETURN NEXT; - END LOOP; - - RETURN; - -END; -$_$ LANGUAGE plpgsql; - - -CREATE OR REPLACE FUNCTION geocode( - IN_ADDY NORM_ADDY, - OUT ADDY NORM_ADDY, - OUT GEOMOUT GEOMETRY, - OUT RATING INTEGER -) RETURNS SETOF RECORD -AS $_$ -DECLARE - rec RECORD; -BEGIN - - IF NOT IN_ADDY.parsed THEN - RETURN; - END IF; - - -- Go for the full monty if we've got enough info - IF IN_ADDY.streetName IS NOT NULL AND - (IN_ADDY.zip IS NOT NULL OR IN_ADDY.stateAbbrev IS NOT NULL) THEN - - FOR rec IN - SELECT * - FROM - (SELECT - DISTINCT ON ( - (a.addy).address, - (a.addy).predirabbrev, - (a.addy).streetname, - (a.addy).streettypeabbrev, - (a.addy).postdirabbrev, - (a.addy).internal, - (a.addy).location, - (a.addy).stateabbrev, - (a.addy).zip - ) - * - FROM - geocode_address(IN_ADDY) a - ORDER BY - (a.addy).address, - (a.addy).predirabbrev, - (a.addy).streetname, - (a.addy).streettypeabbrev, - (a.addy).postdirabbrev, - (a.addy).internal, - (a.addy).location, - (a.addy).stateabbrev, - (a.addy).zip, - a.rating - ) as b - ORDER BY b.rating - LOOP - - ADDY := rec.addy; - GEOMOUT := rec.geomout; - RATING := rec.rating; - - RETURN NEXT; - - IF RATING = 0 THEN - RETURN; - END IF; - - END LOOP; - - IF RATING IS NOT NULL THEN - RETURN; - END IF; - END IF; - - -- 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 - LOOP - ADDY := rec.addy; - GEOMOUT := rec.geomout; - RATING := rec.rating; - - RETURN NEXT; - IF RATING = 100 THEN - RETURN; - END IF; - END LOOP; - - END IF; - - RETURN; - -END; -$_$ LANGUAGE plpgsql; +--$Id$ +CREATE OR REPLACE FUNCTION geocode( + input VARCHAR, + OUT ADDY NORM_ADDY, + OUT GEOMOUT GEOMETRY, + OUT RATING INTEGER +) RETURNS SETOF RECORD +AS $_$ +DECLARE + rec RECORD; +BEGIN + + IF input IS NULL THEN + RETURN; + END IF; + + -- Pass the input string into the address normalizer + ADDY := normalize_address(input); + IF NOT ADDY.parsed THEN + RETURN; + END IF; + + FOR rec IN SELECT * FROM geocode(ADDY) + LOOP + + ADDY := rec.addy; + GEOMOUT := rec.geomout; + RATING := rec.rating; + + RETURN NEXT; + END LOOP; + + RETURN; + +END; +$_$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION geocode( + IN_ADDY NORM_ADDY, + OUT ADDY NORM_ADDY, + OUT GEOMOUT GEOMETRY, + OUT RATING INTEGER +) RETURNS SETOF RECORD +AS $_$ +DECLARE + rec RECORD; +BEGIN + + IF NOT IN_ADDY.parsed THEN + RETURN; + END IF; + + -- Go for the full monty if we've got enough info + IF IN_ADDY.streetName IS NOT NULL AND + (IN_ADDY.zip IS NOT NULL OR IN_ADDY.stateAbbrev IS NOT NULL) THEN + + FOR rec IN + SELECT * + FROM + (SELECT + DISTINCT ON ( + (a.addy).address, + (a.addy).predirabbrev, + (a.addy).streetname, + (a.addy).streettypeabbrev, + (a.addy).postdirabbrev, + (a.addy).internal, + (a.addy).location, + (a.addy).stateabbrev, + (a.addy).zip + ) + * + FROM + geocode_address(IN_ADDY) a + ORDER BY + (a.addy).address, + (a.addy).predirabbrev, + (a.addy).streetname, + (a.addy).streettypeabbrev, + (a.addy).postdirabbrev, + (a.addy).internal, + (a.addy).location, + (a.addy).stateabbrev, + (a.addy).zip, + a.rating + ) as b + ORDER BY b.rating + LOOP + + ADDY := rec.addy; + GEOMOUT := rec.geomout; + RATING := rec.rating; + + RETURN NEXT; + + IF RATING = 0 THEN + RETURN; + END IF; + + END LOOP; + + IF RATING IS NOT NULL THEN + RETURN; + END IF; + END IF; + + -- 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 + LOOP + ADDY := rec.addy; + GEOMOUT := rec.geomout; + RATING := rec.rating; + + RETURN NEXT; + IF RATING = 100 THEN + RETURN; + END IF; + END LOOP; + + END IF; + + RETURN; + +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/geocode/geocode_address.sql b/extras/tiger_geocoder/tiger_2010/geocode/geocode_address.sql index 56822e4b8..228e5e954 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/geocode_address.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/geocode_address.sql @@ -1,162 +1,162 @@ ---$Id$ -CREATE OR REPLACE FUNCTION geocode_address(IN parsed norm_addy, OUT addy norm_addy, OUT geomout geometry, OUT rating integer) - RETURNS SETOF record AS -$$ -DECLARE - results RECORD; - zip_info RECORD; - stmt VARCHAR; - in_statefp VARCHAR; - exact_street boolean := false; -BEGIN - IF parsed.streetName IS NULL THEN - -- A street name must be given. Think about it. - RETURN; - END IF; - - ADDY.internal := parsed.internal; - - in_statefp := statefp FROM state WHERE state.stusps = parsed.stateAbbrev; - - -- There are a couple of different things to try, from the highest preference and falling back - -- to lower-preference options. - -- We start out with zip-code matching, where the zip code could possibly be in more than one - -- state. We loop through each state its in. - -- Next, we try to find the location in our side-table, which is based off of the 'place' data - -- Next, we look up the location/city and use the zip code which is returned from that - -- Finally, if we didn't get a zip code or a city match, we fall back to just a location/street - -- lookup to try and find *something* useful. - -- In the end, we *have* to find a statefp, one way or another. - FOR zip_info IN - SELECT statefp,location,zip,column1 as exact,min(pref) FROM - (SELECT zip_state.statefp as statefp,parsed.location as location,ARRAY[zip_state.zip] as zip,1 as pref - FROM zip_state WHERE zip_state.zip = parsed.zip AND (in_statefp IS NULL OR zip_state.statefp = in_statefp) - UNION SELECT zip_state_loc.statefp,parsed.location,array_accum(zip_state_loc.zip),2 - FROM zip_state_loc - WHERE zip_state_loc.statefp = in_statefp - AND soundex(parsed.location) = soundex(zip_state_loc.place) - GROUP BY zip_state_loc.statefp,parsed.location - UNION SELECT zip_lookup_base.statefp,parsed.location,array_accum(zip_lookup_base.zip),3 - FROM zip_lookup_base - WHERE zip_lookup_base.statefp = in_statefp - AND (soundex(parsed.location) = soundex(zip_lookup_base.city) OR soundex(parsed.location) = soundex(zip_lookup_base.county)) - GROUP BY zip_lookup_base.statefp,parsed.location - UNION SELECT in_statefp,parsed.location,NULL,4) as a - JOIN (VALUES (true),(false)) as b on TRUE - WHERE statefp IS NOT NULL - GROUP BY statefp,location,zip,column1 ORDER BY 4 desc, 5, 3 - LOOP - - stmt := 'SELECT DISTINCT ON (sub.predirabrv,sub.name,sub.suftypabrv,sub.sufdirabrv,coalesce(p.name,zip.city,cs.name,co.name),s.stusps,sub.zip)' - || ' sub.predirabrv as fedirp,' - || ' sub.name as fename,' - || ' sub.suftypabrv as fetype,' - || ' sub.sufdirabrv as fedirs,' - || ' coalesce(p.name,zip.city,cs.name,co.name)::varchar as place,' - || ' s.stusps as state,' - || ' sub.zip as zip,' - || ' interpolate_from_address(' || coalesce(quote_literal(parsed.address),'NULL') || ', to_number(sub.fromhn,''99999999'')::integer,' - || ' to_number(sub.tohn,''99999999'')::integer, e.the_geom) as address_geom,' - || coalesce(' sub.sub_rating + coalesce(levenshtein_ignore_case(' || quote_literal(zip_info.zip[1]) || ', sub.zip),0)', - ' sub.sub_rating + coalesce(levenshtein_ignore_case(' || quote_literal(parsed.location) || ', coalesce(p.name,zip.city,cs.name,co.name)),0)', - 'sub.sub_rating') - || ' as sub_rating,' - || ' sub.exact_address as exact_address' - || ' FROM (' - || ' SELECT tlid, predirabrv, name, suftypabrv, sufdirabrv, fromhn, tohn, side, statefp, zip, rate_attributes(' || coalesce(quote_literal(parsed.preDirAbbrev),'NULL') || ', a.predirabrv,' - || ' ' || coalesce(quote_literal(parsed.streetName),'NULL') || ', a.name, ' || coalesce(quote_literal(parsed.streetTypeAbbrev),'NULL') || ',' - || ' a.suftypabrv, ' || coalesce(quote_literal(parsed.postDirAbbrev),'NULL') || ',' - || ' a.sufdirabrv) + ' - || ' CASE ' - || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer IS NULL OR b.fromhn IS NULL THEN 20' - || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn, b.tohn) ' - || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn)' - || ' AND (' || coalesce(quote_literal(parsed.address),'NULL') || '::integer % 2) = (to_number(b.fromhn,''99999999'') % 2)::integer' - || ' THEN 0' - || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn,b.tohn)' - || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn)' - || ' THEN 2' - || ' ELSE' - || ' ((1.0 - ' - || '(least(' || coalesce(quote_literal(parsed.address || '.0'),'NULL') || '::numeric,to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) /' - || ' greatest(' || coalesce(quote_literal(parsed.address || '.0'),'NULL') || '::numeric,to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')))' - || ') * 5)::integer + 5' - || ' END' - || ' as sub_rating,' - || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn,b.tohn) ' - || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn) ' - || ' AND (' || coalesce(quote_literal(parsed.address),'NULL') || ' % 2)::numeric::integer = (to_number(b.fromhn,''99999999'') % 2)' - || ' as exact_address' - || ' FROM featnames a join addr b using (tlid,statefp)' - || ' WHERE' - || ' statefp = ' || quote_literal(zip_info.statefp) || '' - || coalesce(' AND b.zip IN (''' || array_to_string(zip_info.zip,''',''') || ''') ','') - || CASE WHEN zip_info.exact - THEN ' AND lower(' || coalesce(quote_literal(parsed.streetName),'NULL') || ') = lower(a.name)' - ELSE ' AND soundex(' || coalesce(quote_literal(parsed.streetName),'NULL') || ') = soundex(a.name)' - END - || ' ORDER BY 11' - || ' LIMIT 20' - || ' ) AS sub' - || ' JOIN edges e ON (' || quote_literal(zip_info.statefp) || ' = e.statefp AND sub.tlid = e.tlid)' - || ' 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)' - || ' LEFT JOIN place p ON (' || quote_literal(zip_info.statefp) || ' = p.statefp AND f.placefp = p.placefp)' - || ' LEFT JOIN county co ON (' || quote_literal(zip_info.statefp) || ' = co.statefp AND f.countyfp = co.countyfp)' - || ' LEFT JOIN cousub cs ON (' || quote_literal(zip_info.statefp) || ' = cs.statefp AND cs.cosbidfp = sub.statefp || co.countyfp || f.cousubfp)' - || ' WHERE' - || ' (sub.side = ''L'' and e.tfidl = f.tfid) OR (sub.side = ''R'' and e.tfidr = f.tfid)' - || ' ORDER BY 1,2,3,4,5,6,7,9' - || ' LIMIT 10' - ; - --RAISE NOTICE '%', stmt; - -- If we got an exact street match then when we hit the non-exact - -- set of tests, just drop out. - IF NOT zip_info.exact AND exact_street THEN - RETURN; - END IF; - - FOR results IN EXECUTE stmt LOOP - - -- If we found a match with an exact street, then don't bother - -- trying to do non-exact matches - IF zip_info.exact THEN - exact_street := true; - END IF; - - IF results.exact_address THEN - ADDY.address := parsed.address; - ELSE - ADDY.address := NULL; - END IF; - - ADDY.preDirAbbrev := results.fedirp; - ADDY.streetName := results.fename; - ADDY.streetTypeAbbrev := results.fetype; - ADDY.postDirAbbrev := results.fedirs; - ADDY.location := results.place; - ADDY.stateAbbrev := results.state; - ADDY.zip := results.zip; - ADDY.parsed := TRUE; - - GEOMOUT := results.address_geom; - RATING := results.sub_rating; - - RETURN NEXT; - - -- If we get an exact match, then just return that - IF RATING = 0 THEN - RETURN; - END IF; - - END LOOP; - - END LOOP; - - RETURN; -END; -$$ - LANGUAGE 'plpgsql' VOLATILE; - - +--$Id$ +CREATE OR REPLACE FUNCTION geocode_address(IN parsed norm_addy, OUT addy norm_addy, OUT geomout geometry, OUT rating integer) + RETURNS SETOF record AS +$$ +DECLARE + results RECORD; + zip_info RECORD; + stmt VARCHAR; + in_statefp VARCHAR; + exact_street boolean := false; +BEGIN + IF parsed.streetName IS NULL THEN + -- A street name must be given. Think about it. + RETURN; + END IF; + + ADDY.internal := parsed.internal; + + in_statefp := statefp FROM state WHERE state.stusps = parsed.stateAbbrev; + + -- There are a couple of different things to try, from the highest preference and falling back + -- to lower-preference options. + -- We start out with zip-code matching, where the zip code could possibly be in more than one + -- state. We loop through each state its in. + -- Next, we try to find the location in our side-table, which is based off of the 'place' data + -- Next, we look up the location/city and use the zip code which is returned from that + -- Finally, if we didn't get a zip code or a city match, we fall back to just a location/street + -- lookup to try and find *something* useful. + -- In the end, we *have* to find a statefp, one way or another. + FOR zip_info IN + SELECT statefp,location,zip,column1 as exact,min(pref) FROM + (SELECT zip_state.statefp as statefp,parsed.location as location,ARRAY[zip_state.zip] as zip,1 as pref + FROM zip_state WHERE zip_state.zip = parsed.zip AND (in_statefp IS NULL OR zip_state.statefp = in_statefp) + UNION SELECT zip_state_loc.statefp,parsed.location,array_accum(zip_state_loc.zip),2 + FROM zip_state_loc + WHERE zip_state_loc.statefp = in_statefp + AND soundex(parsed.location) = soundex(zip_state_loc.place) + GROUP BY zip_state_loc.statefp,parsed.location + UNION SELECT zip_lookup_base.statefp,parsed.location,array_accum(zip_lookup_base.zip),3 + FROM zip_lookup_base + WHERE zip_lookup_base.statefp = in_statefp + AND (soundex(parsed.location) = soundex(zip_lookup_base.city) OR soundex(parsed.location) = soundex(zip_lookup_base.county)) + GROUP BY zip_lookup_base.statefp,parsed.location + UNION SELECT in_statefp,parsed.location,NULL,4) as a + JOIN (VALUES (true),(false)) as b on TRUE + WHERE statefp IS NOT NULL + GROUP BY statefp,location,zip,column1 ORDER BY 4 desc, 5, 3 + LOOP + + stmt := 'SELECT DISTINCT ON (sub.predirabrv,sub.name,sub.suftypabrv,sub.sufdirabrv,coalesce(p.name,zip.city,cs.name,co.name),s.stusps,sub.zip)' + || ' sub.predirabrv as fedirp,' + || ' sub.name as fename,' + || ' sub.suftypabrv as fetype,' + || ' sub.sufdirabrv as fedirs,' + || ' coalesce(p.name,zip.city,cs.name,co.name)::varchar as place,' + || ' s.stusps as state,' + || ' sub.zip as zip,' + || ' interpolate_from_address(' || coalesce(quote_literal(parsed.address),'NULL') || ', to_number(sub.fromhn,''99999999'')::integer,' + || ' to_number(sub.tohn,''99999999'')::integer, e.the_geom) as address_geom,' + || coalesce(' sub.sub_rating + coalesce(levenshtein_ignore_case(' || quote_literal(zip_info.zip[1]) || ', sub.zip),0)', + ' sub.sub_rating + coalesce(levenshtein_ignore_case(' || quote_literal(parsed.location) || ', coalesce(p.name,zip.city,cs.name,co.name)),0)', + 'sub.sub_rating') + || ' as sub_rating,' + || ' sub.exact_address as exact_address' + || ' FROM (' + || ' SELECT tlid, predirabrv, name, suftypabrv, sufdirabrv, fromhn, tohn, side, statefp, zip, rate_attributes(' || coalesce(quote_literal(parsed.preDirAbbrev),'NULL') || ', a.predirabrv,' + || ' ' || coalesce(quote_literal(parsed.streetName),'NULL') || ', a.name, ' || coalesce(quote_literal(parsed.streetTypeAbbrev),'NULL') || ',' + || ' a.suftypabrv, ' || coalesce(quote_literal(parsed.postDirAbbrev),'NULL') || ',' + || ' a.sufdirabrv) + ' + || ' CASE ' + || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer IS NULL OR b.fromhn IS NULL THEN 20' + || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn, b.tohn) ' + || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn)' + || ' AND (' || coalesce(quote_literal(parsed.address),'NULL') || '::integer % 2) = (to_number(b.fromhn,''99999999'') % 2)::integer' + || ' THEN 0' + || ' WHEN ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn,b.tohn)' + || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn)' + || ' THEN 2' + || ' ELSE' + || ' ((1.0 - ' + || '(least(' || coalesce(quote_literal(parsed.address || '.0'),'NULL') || '::numeric,to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) /' + || ' greatest(' || coalesce(quote_literal(parsed.address || '.0'),'NULL') || '::numeric,to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')))' + || ') * 5)::integer + 5' + || ' END' + || ' as sub_rating,' + || coalesce(quote_literal(parsed.address),'NULL') || '::integer >= least_hn(b.fromhn,b.tohn) ' + || ' AND ' || coalesce(quote_literal(parsed.address),'NULL') || '::integer <= greatest_hn(b.fromhn,b.tohn) ' + || ' AND (' || coalesce(quote_literal(parsed.address),'NULL') || ' % 2)::numeric::integer = (to_number(b.fromhn,''99999999'') % 2)' + || ' as exact_address' + || ' FROM featnames a join addr b using (tlid,statefp)' + || ' WHERE' + || ' statefp = ' || quote_literal(zip_info.statefp) || '' + || coalesce(' AND b.zip IN (''' || array_to_string(zip_info.zip,''',''') || ''') ','') + || CASE WHEN zip_info.exact + THEN ' AND lower(' || coalesce(quote_literal(parsed.streetName),'NULL') || ') = lower(a.name)' + ELSE ' AND soundex(' || coalesce(quote_literal(parsed.streetName),'NULL') || ') = soundex(a.name)' + END + || ' ORDER BY 11' + || ' LIMIT 20' + || ' ) AS sub' + || ' JOIN edges e ON (' || quote_literal(zip_info.statefp) || ' = e.statefp AND sub.tlid = e.tlid)' + || ' 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)' + || ' LEFT JOIN place p ON (' || quote_literal(zip_info.statefp) || ' = p.statefp AND f.placefp = p.placefp)' + || ' LEFT JOIN county co ON (' || quote_literal(zip_info.statefp) || ' = co.statefp AND f.countyfp = co.countyfp)' + || ' LEFT JOIN cousub cs ON (' || quote_literal(zip_info.statefp) || ' = cs.statefp AND cs.cosbidfp = sub.statefp || co.countyfp || f.cousubfp)' + || ' WHERE' + || ' (sub.side = ''L'' and e.tfidl = f.tfid) OR (sub.side = ''R'' and e.tfidr = f.tfid)' + || ' ORDER BY 1,2,3,4,5,6,7,9' + || ' LIMIT 10' + ; + --RAISE NOTICE '%', stmt; + -- If we got an exact street match then when we hit the non-exact + -- set of tests, just drop out. + IF NOT zip_info.exact AND exact_street THEN + RETURN; + END IF; + + FOR results IN EXECUTE stmt LOOP + + -- If we found a match with an exact street, then don't bother + -- trying to do non-exact matches + IF zip_info.exact THEN + exact_street := true; + END IF; + + IF results.exact_address THEN + ADDY.address := parsed.address; + ELSE + ADDY.address := NULL; + END IF; + + ADDY.preDirAbbrev := results.fedirp; + ADDY.streetName := results.fename; + ADDY.streetTypeAbbrev := results.fetype; + ADDY.postDirAbbrev := results.fedirs; + ADDY.location := results.place; + ADDY.stateAbbrev := results.state; + ADDY.zip := results.zip; + ADDY.parsed := TRUE; + + GEOMOUT := results.address_geom; + RATING := results.sub_rating; + + RETURN NEXT; + + -- If we get an exact match, then just return that + IF RATING = 0 THEN + RETURN; + END IF; + + END LOOP; + + END LOOP; + + RETURN; +END; +$$ + LANGUAGE 'plpgsql' VOLATILE; + + diff --git a/extras/tiger_geocoder/tiger_2010/geocode/geocode_location.sql b/extras/tiger_geocoder/tiger_2010/geocode/geocode_location.sql index ed0164491..2fe4a5174 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/geocode_location.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/geocode_location.sql @@ -1,84 +1,84 @@ ---$Id$ -CREATE OR REPLACE FUNCTION geocode_location( - parsed NORM_ADDY, - OUT ADDY NORM_ADDY, - OUT GEOMOUT GEOMETRY, - OUT RATING INTEGER -) RETURNS SETOF RECORD -AS $_$ -DECLARE - result RECORD; - in_statefp VARCHAR; - stmt VARCHAR; -BEGIN - - in_statefp := statefp FROM state WHERE state.stusps = parsed.stateAbbrev; - - FOR result IN - SELECT - coalesce(zip.city)::varchar as place, - zip.zip as zip, - centroid(zcta500.the_geom) as address_geom, - stusps as state, - 100::integer + coalesce(levenshtein_ignore_case(coalesce(zip.city), parsed.location),0) as in_rating - FROM - zip_lookup_base zip - JOIN zcta500 ON (zip.zip = zcta500.zcta5ce) - JOIN state USING (statefp) - WHERE - parsed.zip = zip.zip OR - (soundex(zip.city) = soundex(parsed.location) and zip.statefp = in_statefp) - ORDER BY levenshtein_ignore_case(coalesce(zip.city), parsed.location), zip.zip - LOOP - ADDY.location := result.place; - ADDY.stateAbbrev := result.state; - ADDY.zip := result.zip; - ADDY.parsed := true; - GEOMOUT := result.address_geom; - RATING := result.in_rating; - - RETURN NEXT; - - IF RATING = 100 THEN - RETURN; - END IF; - - END LOOP; - - IF parsed.location IS NULL THEN - parsed.location := city FROM zip_lookup_base WHERE zip_lookup_base.zip = parsed.zip ORDER BY zip_lookup_base.zip LIMIT 1; - in_statefp := statefp FROM zip_lookup_base WHERE zip_lookup_base.zip = parsed.zip ORDER BY zip_lookup_base.zip LIMIT 1; - END IF; - - stmt := 'SELECT ' - || ' pl.name as place, ' - || ' state.stusps as stateAbbrev, ' - || ' 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,'')) - || ' ORDER BY levenshtein_ignore_case(coalesce(pl.name), ' || quote_literal(coalesce(parsed.location,'')) || ');' - ; - - FOR result IN EXECUTE stmt - LOOP - - ADDY.location := result.place; - ADDY.stateAbbrev := result.stateAbbrev; - ADDY.zip = parsed.zip; - ADDY.parsed := true; - GEOMOUT := result.address_geom; - RATING := result.in_rating; - - RETURN NEXT; - - IF RATING = 100 THEN - RETURN; - END IF; - END LOOP; - - RETURN; - -END; -$_$ LANGUAGE plpgsql; +--$Id$ +CREATE OR REPLACE FUNCTION geocode_location( + parsed NORM_ADDY, + OUT ADDY NORM_ADDY, + OUT GEOMOUT GEOMETRY, + OUT RATING INTEGER +) RETURNS SETOF RECORD +AS $_$ +DECLARE + result RECORD; + in_statefp VARCHAR; + stmt VARCHAR; +BEGIN + + in_statefp := statefp FROM state WHERE state.stusps = parsed.stateAbbrev; + + FOR result IN + SELECT + coalesce(zip.city)::varchar as place, + zip.zip as zip, + centroid(zcta500.the_geom) as address_geom, + stusps as state, + 100::integer + coalesce(levenshtein_ignore_case(coalesce(zip.city), parsed.location),0) as in_rating + FROM + zip_lookup_base zip + JOIN zcta500 ON (zip.zip = zcta500.zcta5ce) + JOIN state USING (statefp) + WHERE + parsed.zip = zip.zip OR + (soundex(zip.city) = soundex(parsed.location) and zip.statefp = in_statefp) + ORDER BY levenshtein_ignore_case(coalesce(zip.city), parsed.location), zip.zip + LOOP + ADDY.location := result.place; + ADDY.stateAbbrev := result.state; + ADDY.zip := result.zip; + ADDY.parsed := true; + GEOMOUT := result.address_geom; + RATING := result.in_rating; + + RETURN NEXT; + + IF RATING = 100 THEN + RETURN; + END IF; + + END LOOP; + + IF parsed.location IS NULL THEN + parsed.location := city FROM zip_lookup_base WHERE zip_lookup_base.zip = parsed.zip ORDER BY zip_lookup_base.zip LIMIT 1; + in_statefp := statefp FROM zip_lookup_base WHERE zip_lookup_base.zip = parsed.zip ORDER BY zip_lookup_base.zip LIMIT 1; + END IF; + + stmt := 'SELECT ' + || ' pl.name as place, ' + || ' state.stusps as stateAbbrev, ' + || ' 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,'')) + || ' ORDER BY levenshtein_ignore_case(coalesce(pl.name), ' || quote_literal(coalesce(parsed.location,'')) || ');' + ; + + FOR result IN EXECUTE stmt + LOOP + + ADDY.location := result.place; + ADDY.stateAbbrev := result.stateAbbrev; + ADDY.zip = parsed.zip; + ADDY.parsed := true; + GEOMOUT := result.address_geom; + RATING := result.in_rating; + + RETURN NEXT; + + IF RATING = 100 THEN + RETURN; + END IF; + END LOOP; + + RETURN; + +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/geocode/includes_address.sql b/extras/tiger_geocoder/tiger_2010/geocode/includes_address.sql index f937faa3e..5244ec86d 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/includes_address.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/includes_address.sql @@ -1,94 +1,94 @@ ---$Id$ --- This function requires the addresses to be grouped, such that the second and --- third arguments are from one side of the street, and the fourth and fifth --- from the other. -CREATE OR REPLACE FUNCTION includes_address( - given_address INTEGER, - addr1 INTEGER, - addr2 INTEGER, - addr3 INTEGER, - addr4 INTEGER -) RETURNS BOOLEAN -AS $_$ -DECLARE - lmaxaddr INTEGER := -1; - rmaxaddr INTEGER := -1; - lminaddr INTEGER := -1; - rminaddr INTEGER := -1; - maxaddr INTEGER := -1; - minaddr INTEGER := -1; - verbose BOOLEAN := false; -BEGIN - IF addr1 IS NOT NULL THEN - maxaddr := addr1; - minaddr := addr1; - lmaxaddr := addr1; - lminaddr := addr1; - END IF; - - IF addr2 IS NOT NULL THEN - IF addr2 < minaddr OR minaddr = -1 THEN - minaddr := addr2; - END IF; - IF addr2 > maxaddr OR maxaddr = -1 THEN - maxaddr := addr2; - END IF; - IF addr2 > lmaxaddr OR lmaxaddr = -1 THEN - lmaxaddr := addr2; - END IF; - IF addr2 < lminaddr OR lminaddr = -1 THEN - lminaddr := addr2; - END IF; - END IF; - - IF addr3 IS NOT NULL THEN - IF addr3 < minaddr OR minaddr = -1 THEN - minaddr := addr3; - END IF; - IF addr3 > maxaddr OR maxaddr = -1 THEN - maxaddr := addr3; - END IF; - rmaxaddr := addr3; - rminaddr := addr3; - END IF; - - IF addr4 IS NOT NULL THEN - IF addr4 < minaddr OR minaddr = -1 THEN - minaddr := addr4; - END IF; - IF addr4 > maxaddr OR maxaddr = -1 THEN - maxaddr := addr4; - END IF; - IF addr4 > rmaxaddr OR rmaxaddr = -1 THEN - rmaxaddr := addr4; - END IF; - IF addr4 < rminaddr OR rminaddr = -1 THEN - rminaddr := addr4; - END IF; - END IF; - - IF minaddr = -1 OR maxaddr = -1 THEN - -- No addresses were non-null, return FALSE (arbitrary) - RETURN FALSE; - ELSIF given_address >= minaddr AND given_address <= maxaddr THEN - -- The address is within the given range - IF given_address >= lminaddr AND given_address <= lmaxaddr THEN - -- This checks to see if the address is on this side of the - -- road, ie if the address is even, the street range must be even - IF (given_address % 2) = (lminaddr % 2) - OR (given_address % 2) = (lmaxaddr % 2) THEN - RETURN TRUE; - END IF; - END IF; - IF given_address >= rminaddr AND given_address <= rmaxaddr THEN - -- See above - IF (given_address % 2) = (rminaddr % 2) - OR (given_address % 2) = (rmaxaddr % 2) THEN - RETURN TRUE; - END IF; - END IF; - END IF; - -- The address is not within the range - RETURN FALSE; -END; -$_$ LANGUAGE plpgsql; +--$Id$ +-- This function requires the addresses to be grouped, such that the second and +-- third arguments are from one side of the street, and the fourth and fifth +-- from the other. +CREATE OR REPLACE FUNCTION includes_address( + given_address INTEGER, + addr1 INTEGER, + addr2 INTEGER, + addr3 INTEGER, + addr4 INTEGER +) RETURNS BOOLEAN +AS $_$ +DECLARE + lmaxaddr INTEGER := -1; + rmaxaddr INTEGER := -1; + lminaddr INTEGER := -1; + rminaddr INTEGER := -1; + maxaddr INTEGER := -1; + minaddr INTEGER := -1; + verbose BOOLEAN := false; +BEGIN + IF addr1 IS NOT NULL THEN + maxaddr := addr1; + minaddr := addr1; + lmaxaddr := addr1; + lminaddr := addr1; + END IF; + + IF addr2 IS NOT NULL THEN + IF addr2 < minaddr OR minaddr = -1 THEN + minaddr := addr2; + END IF; + IF addr2 > maxaddr OR maxaddr = -1 THEN + maxaddr := addr2; + END IF; + IF addr2 > lmaxaddr OR lmaxaddr = -1 THEN + lmaxaddr := addr2; + END IF; + IF addr2 < lminaddr OR lminaddr = -1 THEN + lminaddr := addr2; + END IF; + END IF; + + IF addr3 IS NOT NULL THEN + IF addr3 < minaddr OR minaddr = -1 THEN + minaddr := addr3; + END IF; + IF addr3 > maxaddr OR maxaddr = -1 THEN + maxaddr := addr3; + END IF; + rmaxaddr := addr3; + rminaddr := addr3; + END IF; + + IF addr4 IS NOT NULL THEN + IF addr4 < minaddr OR minaddr = -1 THEN + minaddr := addr4; + END IF; + IF addr4 > maxaddr OR maxaddr = -1 THEN + maxaddr := addr4; + END IF; + IF addr4 > rmaxaddr OR rmaxaddr = -1 THEN + rmaxaddr := addr4; + END IF; + IF addr4 < rminaddr OR rminaddr = -1 THEN + rminaddr := addr4; + END IF; + END IF; + + IF minaddr = -1 OR maxaddr = -1 THEN + -- No addresses were non-null, return FALSE (arbitrary) + RETURN FALSE; + ELSIF given_address >= minaddr AND given_address <= maxaddr THEN + -- The address is within the given range + IF given_address >= lminaddr AND given_address <= lmaxaddr THEN + -- This checks to see if the address is on this side of the + -- road, ie if the address is even, the street range must be even + IF (given_address % 2) = (lminaddr % 2) + OR (given_address % 2) = (lmaxaddr % 2) THEN + RETURN TRUE; + END IF; + END IF; + IF given_address >= rminaddr AND given_address <= rmaxaddr THEN + -- See above + IF (given_address % 2) = (rminaddr % 2) + OR (given_address % 2) = (rmaxaddr % 2) THEN + RETURN TRUE; + END IF; + END IF; + END IF; + -- The address is not within the range + RETURN FALSE; +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/geocode/interpolate_from_address.sql b/extras/tiger_geocoder/tiger_2010/geocode/interpolate_from_address.sql index 464827a74..024f96e58 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/interpolate_from_address.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/interpolate_from_address.sql @@ -1,58 +1,58 @@ --- This function converts string addresses to integers and passes them to --- the other interpolate_from_address function. -CREATE OR REPLACE FUNCTION interpolate_from_address(given_address INTEGER, in_addr1 VARCHAR, in_addr2 VARCHAR, road GEOMETRY) RETURNS GEOMETRY -AS $_$ -DECLARE - addr1 INTEGER; - addr2 INTEGER; - result GEOMETRY; -BEGIN - addr1 := to_number(in_addr1, '999999'); - addr2 := to_number(in_addr2, '999999'); - result = interpolate_from_address(given_address, addr1, addr2, road); - RETURN result; -END -$_$ LANGUAGE plpgsql; - --- interpolate_from_address(local_address, from_address_l, to_address_l, from_address_r, to_address_r, local_road) --- This function returns a point along the given geometry (must be linestring) --- corresponding to the given address. If the given address is not within --- the address range of the road, null is returned. --- This function requires that the address be grouped, such that the second and --- third arguments are from one side of the street, while the fourth and --- fifth are from the other. -CREATE OR REPLACE FUNCTION interpolate_from_address(given_address INTEGER, addr1 INTEGER, addr2 INTEGER, in_road GEOMETRY) RETURNS GEOMETRY -AS $_$ -DECLARE - addrwidth INTEGER; - part DOUBLE PRECISION; - road GEOMETRY; - result GEOMETRY; -BEGIN - IF in_road IS NULL THEN - RETURN NULL; - END IF; - - IF geometrytype(in_road) = 'LINESTRING' THEN - road := in_road; - ELSIF geometrytype(in_road) = 'MULTILINESTRING' THEN - road := ST_GeometryN(in_road,1); - ELSE - RETURN NULL; - END IF; - - addrwidth := greatest(addr1,addr2) - least(addr1,addr2); - part := (given_address - least(addr1,addr2)) / trunc(addrwidth, 1); - - IF addr1 > addr2 THEN - part := 1 - part; - END IF; - - IF part < 0 OR part > 1 OR part IS NULL THEN - part := 0.5; - END IF; - - result = ST_Line_Interpolate_Point(road, part); - RETURN result; -END; -$_$ LANGUAGE plpgsql; +-- This function converts string addresses to integers and passes them to +-- the other interpolate_from_address function. +CREATE OR REPLACE FUNCTION interpolate_from_address(given_address INTEGER, in_addr1 VARCHAR, in_addr2 VARCHAR, road GEOMETRY) RETURNS GEOMETRY +AS $_$ +DECLARE + addr1 INTEGER; + addr2 INTEGER; + result GEOMETRY; +BEGIN + addr1 := to_number(in_addr1, '999999'); + addr2 := to_number(in_addr2, '999999'); + result = interpolate_from_address(given_address, addr1, addr2, road); + RETURN result; +END +$_$ LANGUAGE plpgsql; + +-- interpolate_from_address(local_address, from_address_l, to_address_l, from_address_r, to_address_r, local_road) +-- This function returns a point along the given geometry (must be linestring) +-- corresponding to the given address. If the given address is not within +-- the address range of the road, null is returned. +-- This function requires that the address be grouped, such that the second and +-- third arguments are from one side of the street, while the fourth and +-- fifth are from the other. +CREATE OR REPLACE FUNCTION interpolate_from_address(given_address INTEGER, addr1 INTEGER, addr2 INTEGER, in_road GEOMETRY) RETURNS GEOMETRY +AS $_$ +DECLARE + addrwidth INTEGER; + part DOUBLE PRECISION; + road GEOMETRY; + result GEOMETRY; +BEGIN + IF in_road IS NULL THEN + RETURN NULL; + END IF; + + IF geometrytype(in_road) = 'LINESTRING' THEN + road := in_road; + ELSIF geometrytype(in_road) = 'MULTILINESTRING' THEN + road := ST_GeometryN(in_road,1); + ELSE + RETURN NULL; + END IF; + + addrwidth := greatest(addr1,addr2) - least(addr1,addr2); + part := (given_address - least(addr1,addr2)) / trunc(addrwidth, 1); + + IF addr1 > addr2 THEN + part := 1 - part; + END IF; + + IF part < 0 OR part > 1 OR part IS NULL THEN + part := 0.5; + END IF; + + result = ST_Line_Interpolate_Point(road, part); + RETURN result; +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/geocode/other_helper_functions.sql b/extras/tiger_geocoder/tiger_2010/geocode/other_helper_functions.sql index 377ddebb2..40ff6dff6 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/other_helper_functions.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/other_helper_functions.sql @@ -1,22 +1,22 @@ ---$Id$ - /*** - * - * Copyright (C) 2011 Regina Obe and Leo Hsu (Paragon Corporation) - **/ --- Note we are wrapping this in a function so we can make it immutable and those useable in an index --- It also allows us to shorten and possibly better cache the repetitive pattern in the code --- greatest(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) --- and least(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) -CREATE OR REPLACE FUNCTION least_hn(fromhn varchar, tohn varchar) - RETURNS integer AS -$$ SELECT least(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$ - LANGUAGE sql IMMUTABLE - COST 1; - --- Note we are wrapping this in a function so we can make it immutable (for some reason least and greatest aren't considered immutable) --- and thu useable in an index or cacheable for multiple calls -CREATE OR REPLACE FUNCTION greatest_hn(fromhn varchar, tohn varchar) - RETURNS integer AS -$$ SELECT greatest(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$ - LANGUAGE sql IMMUTABLE - COST 1; +--$Id$ + /*** + * + * Copyright (C) 2011 Regina Obe and Leo Hsu (Paragon Corporation) + **/ +-- Note we are wrapping this in a function so we can make it immutable and those useable in an index +-- It also allows us to shorten and possibly better cache the repetitive pattern in the code +-- greatest(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) +-- and least(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999'')) +CREATE OR REPLACE FUNCTION least_hn(fromhn varchar, tohn varchar) + RETURNS integer AS +$$ SELECT least(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$ + LANGUAGE sql IMMUTABLE + COST 1; + +-- Note we are wrapping this in a function so we can make it immutable (for some reason least and greatest aren't considered immutable) +-- and thu useable in an index or cacheable for multiple calls +CREATE OR REPLACE FUNCTION greatest_hn(fromhn varchar, tohn varchar) + RETURNS integer AS +$$ SELECT greatest(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$ + LANGUAGE sql IMMUTABLE + COST 1; diff --git a/extras/tiger_geocoder/tiger_2010/geocode/rate_attributes.sql b/extras/tiger_geocoder/tiger_2010/geocode/rate_attributes.sql index f06bc06ef..0e769bedd 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/rate_attributes.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/rate_attributes.sql @@ -1,60 +1,60 @@ ---$Id$ --- rate_attributes(dirpA, dirpB, streetNameA, streetNameB, streetTypeA, --- streetTypeB, dirsA, dirsB, locationA, locationB) --- Rates the street based on the given attributes. The locations must be --- non-null. The other eight values are handled by the other rate_attributes --- function, so it's requirements must also be met. --- changed: 2010-10-18 Regina Obe - all references to verbose to var_verbose since causes compile errors in 9.0 -CREATE OR REPLACE FUNCTION rate_attributes(VARCHAR, VARCHAR, VARCHAR, VARCHAR, - VARCHAR, VARCHAR, VARCHAR, VARCHAR, VARCHAR, VARCHAR) RETURNS INTEGER -AS $_$ -DECLARE - result INTEGER := 0; - locationWeight INTEGER := 14; - var_verbose BOOLEAN := FALSE; -BEGIN - IF $9 IS NOT NULL AND $10 IS NOT NULL THEN - result := levenshtein_ignore_case($9, $10); - ELSE - IF var_verbose THEN - RAISE NOTICE 'rate_attributes() - Location names cannot be null!'; - END IF; - RETURN NULL; - END IF; - result := result + rate_attributes($1, $2, $3, $4, $5, $6, $7, $8); - RETURN result; -END; -$_$ LANGUAGE plpgsql; - --- rate_attributes(dirpA, dirpB, streetNameA, streetNameB, streetTypeA, --- streetTypeB, dirsA, dirsB) --- Rates the street based on the given attributes. Only streetNames are --- required. If any others are null (either A or B) they are treated as --- empty strings. -CREATE OR REPLACE FUNCTION rate_attributes(VARCHAR, VARCHAR, VARCHAR, VARCHAR, - VARCHAR, VARCHAR, VARCHAR, VARCHAR) RETURNS INTEGER -AS $_$ -DECLARE - result INTEGER := 0; - directionWeight INTEGER := 2; - nameWeight INTEGER := 10; - typeWeight INTEGER := 5; - var_verbose BOOLEAN := FALSE; -BEGIN - result := result + levenshtein_ignore_case(cull_null($1), cull_null($2)) * - directionWeight; - IF $3 IS NOT NULL AND $4 IS NOT NULL THEN - result := result + levenshtein_ignore_case($3, $4) * nameWeight; - ELSE - IF var_verbose THEN - RAISE NOTICE 'rate_attributes() - Street names cannot be null!'; - END IF; - RETURN NULL; - END IF; - result := result + levenshtein_ignore_case(cull_null($5), cull_null($6)) * - typeWeight; - result := result + levenshtein_ignore_case(cull_null($7), cull_null($7)) * - directionWeight; - return result; -END; -$_$ LANGUAGE plpgsql; +--$Id$ +-- rate_attributes(dirpA, dirpB, streetNameA, streetNameB, streetTypeA, +-- streetTypeB, dirsA, dirsB, locationA, locationB) +-- Rates the street based on the given attributes. The locations must be +-- non-null. The other eight values are handled by the other rate_attributes +-- function, so it's requirements must also be met. +-- changed: 2010-10-18 Regina Obe - all references to verbose to var_verbose since causes compile errors in 9.0 +CREATE OR REPLACE FUNCTION rate_attributes(VARCHAR, VARCHAR, VARCHAR, VARCHAR, + VARCHAR, VARCHAR, VARCHAR, VARCHAR, VARCHAR, VARCHAR) RETURNS INTEGER +AS $_$ +DECLARE + result INTEGER := 0; + locationWeight INTEGER := 14; + var_verbose BOOLEAN := FALSE; +BEGIN + IF $9 IS NOT NULL AND $10 IS NOT NULL THEN + result := levenshtein_ignore_case($9, $10); + ELSE + IF var_verbose THEN + RAISE NOTICE 'rate_attributes() - Location names cannot be null!'; + END IF; + RETURN NULL; + END IF; + result := result + rate_attributes($1, $2, $3, $4, $5, $6, $7, $8); + RETURN result; +END; +$_$ LANGUAGE plpgsql; + +-- rate_attributes(dirpA, dirpB, streetNameA, streetNameB, streetTypeA, +-- streetTypeB, dirsA, dirsB) +-- Rates the street based on the given attributes. Only streetNames are +-- required. If any others are null (either A or B) they are treated as +-- empty strings. +CREATE OR REPLACE FUNCTION rate_attributes(VARCHAR, VARCHAR, VARCHAR, VARCHAR, + VARCHAR, VARCHAR, VARCHAR, VARCHAR) RETURNS INTEGER +AS $_$ +DECLARE + result INTEGER := 0; + directionWeight INTEGER := 2; + nameWeight INTEGER := 10; + typeWeight INTEGER := 5; + var_verbose BOOLEAN := FALSE; +BEGIN + result := result + levenshtein_ignore_case(cull_null($1), cull_null($2)) * + directionWeight; + IF $3 IS NOT NULL AND $4 IS NOT NULL THEN + result := result + levenshtein_ignore_case($3, $4) * nameWeight; + ELSE + IF var_verbose THEN + RAISE NOTICE 'rate_attributes() - Street names cannot be null!'; + END IF; + RETURN NULL; + END IF; + result := result + levenshtein_ignore_case(cull_null($5), cull_null($6)) * + typeWeight; + result := result + levenshtein_ignore_case(cull_null($7), cull_null($7)) * + directionWeight; + return result; +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/utility/cull_null.sql b/extras/tiger_geocoder/tiger_2010/utility/cull_null.sql index b0a734d78..dd11ced6b 100644 --- a/extras/tiger_geocoder/tiger_2010/utility/cull_null.sql +++ b/extras/tiger_geocoder/tiger_2010/utility/cull_null.sql @@ -1,8 +1,8 @@ --- Returns the value passed, or an empty string if null. --- This is used to concatinate values that may be null. -CREATE OR REPLACE FUNCTION cull_null(VARCHAR) RETURNS VARCHAR -AS $_$ -BEGIN - RETURN coalesce($1,''); -END; -$_$ LANGUAGE plpgsql; +-- Returns the value passed, or an empty string if null. +-- This is used to concatinate values that may be null. +CREATE OR REPLACE FUNCTION cull_null(VARCHAR) RETURNS VARCHAR +AS $_$ +BEGIN + RETURN coalesce($1,''); +END; +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/utility/levenshtein_ignore_case.sql b/extras/tiger_geocoder/tiger_2010/utility/levenshtein_ignore_case.sql index 8140ae95a..7e1fa9fa2 100644 --- a/extras/tiger_geocoder/tiger_2010/utility/levenshtein_ignore_case.sql +++ b/extras/tiger_geocoder/tiger_2010/utility/levenshtein_ignore_case.sql @@ -1,10 +1,10 @@ --- This function determines the levenshtein distance irespective of case. -CREATE OR REPLACE FUNCTION levenshtein_ignore_case(VARCHAR, VARCHAR) RETURNS INTEGER -AS $_$ -DECLARE - result INTEGER; -BEGIN - result := levenshtein(upper($1), upper($2)); - RETURN result; -END -$_$ LANGUAGE plpgsql; +-- This function determines the levenshtein distance irespective of case. +CREATE OR REPLACE FUNCTION levenshtein_ignore_case(VARCHAR, VARCHAR) RETURNS INTEGER +AS $_$ +DECLARE + result INTEGER; +BEGIN + result := levenshtein(upper($1), upper($2)); + RETURN result; +END +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/utility/nullable_levenshtein.sql b/extras/tiger_geocoder/tiger_2010/utility/nullable_levenshtein.sql index 6157fed2f..69be7377b 100644 --- a/extras/tiger_geocoder/tiger_2010/utility/nullable_levenshtein.sql +++ b/extras/tiger_geocoder/tiger_2010/utility/nullable_levenshtein.sql @@ -1,28 +1,28 @@ --- This function take two arguements. The first is the "given string" and --- must not be null. The second arguement is the "compare string" and may --- or may not be null. If the second string is null, the value returned is --- 3, otherwise it is the levenshtein difference between the two. --- Change 2010-10-18 Regina Obe - name verbose to var_verbose since get compile error in PostgreSQL 9.0 -CREATE OR REPLACE FUNCTION nullable_levenshtein(VARCHAR, VARCHAR) RETURNS INTEGER -AS $_$ -DECLARE - given_string VARCHAR; - result INTEGER := 3; - var_verbose BOOLEAN := FALSE; /**change from verbose to param_verbose since its a keyword and get compile error in 9.0 **/ -BEGIN - IF $1 IS NULL THEN - IF var_verbose THEN - RAISE NOTICE 'nullable_levenshtein - given string is NULL!'; - END IF; - RETURN NULL; - ELSE - given_string := $1; - END IF; - - IF $2 IS NOT NULL AND $2 != '' THEN - result := levenshtein_ignore_case(given_string, $2); - END IF; - - RETURN result; -END -$_$ LANGUAGE plpgsql; +-- This function take two arguements. The first is the "given string" and +-- must not be null. The second arguement is the "compare string" and may +-- or may not be null. If the second string is null, the value returned is +-- 3, otherwise it is the levenshtein difference between the two. +-- Change 2010-10-18 Regina Obe - name verbose to var_verbose since get compile error in PostgreSQL 9.0 +CREATE OR REPLACE FUNCTION nullable_levenshtein(VARCHAR, VARCHAR) RETURNS INTEGER +AS $_$ +DECLARE + given_string VARCHAR; + result INTEGER := 3; + var_verbose BOOLEAN := FALSE; /**change from verbose to param_verbose since its a keyword and get compile error in 9.0 **/ +BEGIN + IF $1 IS NULL THEN + IF var_verbose THEN + RAISE NOTICE 'nullable_levenshtein - given string is NULL!'; + END IF; + RETURN NULL; + ELSE + given_string := $1; + END IF; + + IF $2 IS NOT NULL AND $2 != '' THEN + result := levenshtein_ignore_case(given_string, $2); + END IF; + + RETURN result; +END +$_$ LANGUAGE plpgsql; diff --git a/extras/tiger_geocoder/tiger_2010/utility/utmzone.sql b/extras/tiger_geocoder/tiger_2010/utility/utmzone.sql index e64376b12..485e0b7ce 100644 --- a/extras/tiger_geocoder/tiger_2010/utility/utmzone.sql +++ b/extras/tiger_geocoder/tiger_2010/utility/utmzone.sql @@ -1,17 +1,17 @@ -CREATE OR REPLACE FUNCTION utmzone(geometry) RETURNS integer AS -$BODY$ -DECLARE - geomgeog geometry; - zone int; - pref int; -BEGIN - geomgeog:=transform($1,4326); - IF (y(geomgeog))>0 THEN - pref:=32600; - ELSE - pref:=32700; - END IF; - zone:=floor((x(geomgeog)+180)/6)+1; - RETURN zone+pref; -END; -$BODY$ LANGUAGE 'plpgsql' immutable; +CREATE OR REPLACE FUNCTION utmzone(geometry) RETURNS integer AS +$BODY$ +DECLARE + geomgeog geometry; + zone int; + pref int; +BEGIN + geomgeog:=transform($1,4326); + IF (y(geomgeog))>0 THEN + pref:=32600; + ELSE + pref:=32700; + END IF; + zone:=floor((x(geomgeog)+180)/6)+1; + RETURN zone+pref; +END; +$BODY$ LANGUAGE 'plpgsql' immutable;