#1076 more work toward Highway geocoding -- significant rework of original patch. Still need to parse out the direction information

git-svn-id: http://svn.osgeo.org/postgis/trunk@7586 b70326c6-7e19-0410-871a-916f4a2858ee
This commit is contained in:
Regina Obe 2011-07-04 17:32:35 +00:00
parent 3a2aa14e36
commit f455ac4143
9 changed files with 227 additions and 149 deletions

View file

@ -35,7 +35,7 @@ BEGIN
(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_accum(zip_state_loc.zip) AS zip,1 + COALESCE(diff_zip(min(zip), $2),0) As pref
UNION SELECT zip_state_loc.statefp,zip_state_loc.place As location,false As exact, array_accum(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)
@ -89,9 +89,9 @@ BEGIN
|| ' interpolate_from_address($1, to_number(sub.fromhn,''99999999'')::integer,'
|| ' to_number(sub.tohn,''99999999'')::integer, e.the_geom) as address_geom,'
|| ' sub.sub_rating + '
|| CASE WHEN parsed.zip > '' THEN ' least((coalesce(diff_zip(' || quote_nullable(parsed.zip) || ' , sub.zip),0) *1.00/2)::integer, coalesce(levenshtein_ignore_case(' || quote_nullable(zip_info.zip[1]) || ', sub.zip),0) ) '
ELSE '1' END::text
|| ' + coalesce(levenshtein_ignore_case($3, coalesce(p.name,zip.city,cs.name,co.name)),0)'
|| CASE WHEN parsed.zip > '' THEN ' least((coalesce(diff_zip($7 , sub.zip),0) *1.00/2)::integer, coalesce(levenshtein_ignore_case($7, sub.zip),0) ) '
ELSE '3' END::text
|| ' + coalesce(least(levenshtein_ignore_case($3, coalesce(p.name,zip.city,cs.name,co.name)), levenshtein_ignore_case($3, coalesce(cs.name,co.name))),5)'
|| ' as sub_rating,'
|| ' sub.exact_address as exact_address'
|| ' FROM ('
@ -150,7 +150,7 @@ BEGIN
RETURN;
END IF;
FOR results IN EXECUTE stmt USING parsed.address,parsed.streetName, parsed.location, parsed.streetTypeAbbrev, parsed.preDirAbbrev, parsed.postDirAbbrev LOOP
FOR results IN EXECUTE stmt USING parsed.address,parsed.streetName, parsed.location, parsed.streetTypeAbbrev, parsed.preDirAbbrev, parsed.postDirAbbrev, parsed.zip LOOP
-- If we found a match with an exact street, then don't bother
-- trying to do non-exact matches

View file

@ -28,7 +28,7 @@ $$ SELECT greatest(to_number( CASE WHEN trim($1) ~ '^[0-9]+$' THEN $1 ELSE '0' E
CREATE OR REPLACE FUNCTION diff_zip(zip1 varchar, zip2 varchar)
RETURNS integer AS
$$ SELECT abs(to_number( CASE WHEN trim(substring($1,1,5)) ~ '^[0-9]+$' THEN $1 ELSE '0' END,'99999')::integer - to_number( CASE WHEN trim(substring($2,1,5)) ~ '^[0-9]+$' THEN $2 ELSE '0' END,'99999')::integer )::integer; $$
LANGUAGE sql IMMUTABLE
LANGUAGE sql IMMUTABLE STRICT
COST 200;
-- function return true or false if 2 numeric streets are equal such as 15th St, 23rd st

View file

@ -71,6 +71,9 @@ DECLARE
rec RECORD;
ws VARCHAR;
rawInput VARCHAR;
-- is this a highway
-- (we treat these differently since the road name often comes after the streetType)
isHighway boolean := false;
BEGIN
--$Id$-
result.parsed := FALSE;
@ -293,17 +296,18 @@ BEGIN
|| ')(?:' || ws || '|$)');
IF tempInt = 1 THEN
SELECT INTO rec abbrev, substring(fullStreet, '(?i)' || ws || '('
|| name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup
|| name || ')(?:' || ws || '|$)') AS given, is_hw FROM street_type_lookup
WHERE fullStreet ILIKE '%' || name || '%' AND
trim(upper(fullStreet)) != name AND
texticregexeq(fullStreet, '(?i)' || ws || '(' || name
|| ')(?:' || ws || '|$)') ;
streetType := rec.given;
result.streetTypeAbbrev := rec.abbrev;
isHighway := rec.is_hw;
ELSIF tempInt > 1 THEN
tempInt := 0;
FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '?('
|| name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup
|| name || ')(?:' || ws || '|$)') AS given, is_hw FROM street_type_lookup
WHERE fullStreet ILIKE '%' || name || '%' AND
trim(upper(fullStreet)) != name AND
texticregexeq(fullStreet, '(?i)' || ws || '(' || name
@ -314,13 +318,15 @@ BEGIN
IF position(rec.given IN fullStreet) < position(result.internal IN fullStreet) THEN
IF tempInt < position(rec.given IN fullStreet) THEN
streetType := rec.given;
result.streetTypeAbbrev := trim(rec.abbrev);
result.streetTypeAbbrev := rec.abbrev;
isHighway := rec.is_hw;
tempInt := position(rec.given IN fullStreet);
END IF;
END IF;
ELSIF tempInt < position(rec.given IN fullStreet) THEN
streetType := rec.given;
result.streetTypeAbbrev := trim(rec.abbrev);
result.streetTypeAbbrev := rec.abbrev;
isHighway := rec.is_hw;
tempInt := position(rec.given IN fullStreet);
END IF;
END LOOP;
@ -337,10 +343,13 @@ BEGIN
-- will be considered location. If there is no street type, then I'm sad.
IF streetType IS NOT NULL THEN
-- Check if the fullStreet contains the streetType and ends in just numbers
-- If it does its a road number like a country road or state route
-- If it does its a road number like a country road or state route or other highway
-- Just set the number to be the name of street
tempString := substring(fullStreet, streetType || ws || '+' || E'([0-9]+)' || ws || '*$');
tempString := NULL;
IF isHighway THEN
tempString := substring(fullStreet, streetType || ws || '+' || E'([0-9a-zA-Z]+)' || ws || '*');
END IF;
IF tempString > '' AND result.location IS NOT NULL THEN
reducedStreet := tempString;
result.streetName := trim(reducedStreet);
@ -642,5 +651,4 @@ BEGIN
END
$$
LANGUAGE plpgsql STABLE
COST 100;
COST 100;

View file

@ -3,56 +3,76 @@ T2|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|0
T3|100 Federal St, Boston, MA 02110|POINT(-71.05631 42.35477)|1
T4|529 Main St, Boston, MA 02129|POINT(-71.07187 42.38351)|0
T5|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|0
T6|100 Federal St, Boston, MA 02110|POINT(-71.05631 42.35477)|0
T6|100 Federal St, Boston, MA 02110|POINT(-71.05631 42.35477)|1
T6|100 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
T6|100 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02885)|8
T6|100 Federal St, Millers Falls, MA 01349|POINT(-72.49842 42.56976)|9
T6|100 Federal St, Andover, MA 01810|POINT(-71.20228 42.69118)|10
T6|100 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|10
T6|100 Federal St, Lawrence, MA 01810|POINT(-71.20228 42.69118)|10
T6|100 Federal St, Belchertown, MA 01007|POINT(-72.41221 42.29456)|10
T6|100 Federal St, Agawam Town, MA 01001|POINT(-72.6234 42.0848)|11
T6|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|14
T7|529 Main St, Boston, MA 02129|POINT(-71.07187 42.38351)|0
T8|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|0
T9|100 Federal St, Boston, MA 02110|POINT(-71.05631 42.35477)|0
T9|100 Federal St, Boston, MA 02110|POINT(-71.05631 42.35477)|1
T9|100 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
T9|100 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02885)|8
T9|100 Federal St, Millers Falls, MA 01349|POINT(-72.49842 42.56976)|9
T9|100 Federal St, Andover, MA 01810|POINT(-71.20228 42.69118)|10
T9|100 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|10
T9|100 Federal St, Lawrence, MA 01810|POINT(-71.20228 42.69118)|10
T9|100 Federal St, Belchertown, MA 01007|POINT(-72.41221 42.29456)|10
T9|100 Federal St, Agawam Town, MA 01001|POINT(-72.6234 42.0848)|11
T9|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|14
T9|100 Federal St, Greenfield Town, MA 01301|POINT(-72.59899 42.59028)|15
T9|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|29
T10|530 Main St, Boston, MA 02129|POINT(-71.07173 42.38345)|0
T11|76 State St, Boston, MA 02109|POINT(-71.05615 42.359)|0
T12|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|1
T12|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|6
T12|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|6
T12|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|8
T12|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|8
T12|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|8
T12|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|8
T12|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|9
T12|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|13
T12|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|13
T12|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|14
T12|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|27
T12|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|3
T12|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
T12|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|8
T12|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|9
T12|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|10
T12|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|10
T12|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|10
T12|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|10
T12|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|11
T12|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|15
T12|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|16
T12|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|29
#TB1|24 School St, Boston, MA 02108|24 School Street, Boston, MA 02108|POINT(-71.05888 42.35762)|0
#TB1|20 School St, Boston, MA 02108|20 School Street, Boston, MA 02109|POINT(-71.05876 42.35758)|1
T13|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|1
T13|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|6
T13|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|6
T13|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|8
T13|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|8
T13|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|8
T13|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|8
T13|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|9
T13|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|13
T13|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|13
T13|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|14
T13|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|27
T14|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|1
T15|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|11
T16|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|11
T16|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|16
T16|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|16
T16|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|18
T16|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|18
T16|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|18
T16|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|18
T16|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|19
T16|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|23
T16|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|23
T16|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|24
T16|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|37
T13|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|3
T13|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|8
T13|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|8
T13|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|9
T13|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|10
T13|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|10
T13|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|10
T13|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|10
T13|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|11
T13|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|15
T13|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|16
T13|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|29
T14|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|3
T15|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|13
T16|101 Federal St, Boston, MA 02110|POINT(-71.0563 42.35469)|13
T16|101 Federal St, Lynn, MA 01905|POINT(-70.96783 42.4659)|18
T16|101 Federal St, Blackstone, MA 01504|POINT(-71.5247 42.02886)|18
T16|101 Federal St, Millers Falls, MA 01349|POINT(-72.49939 42.56802)|19
T16|101 Federal St, Andover, MA 01810|POINT(-71.20125 42.69015)|20
T16|101 Federal St, Northampton, MA 01062|POINT(-72.65537 42.32273)|20
T16|101 Federal St, Lawrence, MA 01810|POINT(-71.20125 42.69015)|20
T16|101 Federal St, Belchertown, MA 01007|POINT(-72.41206 42.29446)|20
T16|101 Federal St, Agawam Town, MA 01001|POINT(-72.62231 42.08371)|21
T16|101 Federal St, Greenfield Town, MA 01301|POINT(-72.59909 42.59006)|25
T16|Federal Ct, Boston, MA 02110|POINT(-71.05672 42.35413)|26
T16|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|39
#1087a|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|1
#1087a|75 State St, Milton, MA 02186|POINT(-71.04091 42.25635)|5
#1087b|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|1
#1087b|75 State St, Milton, MA 02186|POINT(-71.04091 42.25635)|4
#1087b|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|3
#1087b|75 State St, Milton, MA 02186|POINT(-71.04091 42.25635)|6
#1087c|75 State St, Boston, MA 02109|POINT(-71.0557 42.35908)|0
#1073a|212 3rd Ave N, Minneapolis, MN 55401|212 3rd Ave N, MINNEAPOLIS, MN 553404|POINT(-93.27181 44.98502)|2
#1073a|212 3rd Ave S, Minneapolis, MN 55404|212 3rd Ave N, MINNEAPOLIS, MN 553404|POINT(-93.26355 44.98062)|3
@ -63,4 +83,7 @@ T16|Federal Ln, Dedham, MA 02026|POINT(-71.18356 42.23829)|37
#1076b|16725 24th Ave N, Plymouth, MN 55447|16725 County Road 24, Plymouth, MN 55447|POINT(-93.4927 45.00457)|27
#1076c|13800 9, Andover, MN 55304|13800 County Hwy 9, Andover, MN 55304|POINT(-93.35733 45.22052)|30
#1076d|13800 9, Andover, MN 55304|13800 9, Andover, MN 55304|POINT(-93.35733 45.22052)|10
#1076e|3900 6, North Eastham, MA 02642|3900 Route 6, Eastham, Massachusetts 02642|POINT(-69.98743 41.85543)|21
#1076e|3900 6, North Eastham, MA 02642|3900 Route 6, Eastham, Massachusetts 02642|POINT(-69.98743 41.85543)|15
#1076f|1940 W C, Roseville, MN 55113|1940 County Road C W, Roseville, MN 55113|POINT(-93.18492 45.02058)|27
#1076f|1940 C W, Roseville, MN 55113|1940 County Road C W, Roseville, MN 55113|POINT(-93.18492 45.02058)|27
#1076g|15709 Rockford Rd, Plymouth, MN 55447|15709 Rockford Road, Plymouth, MN 55447|POINT(-93.47898 45.02726)|0

View file

@ -45,6 +45,11 @@ SELECT '#1076a' As ticket, pprint_addy((g).addy) As address, target, ST_AsText(S
SELECT '#1076b' 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,2) As g, target FROM (SELECT '16725 County Road 24, Plymouth, MN 55447'::text As target) As f) As foo;
SELECT '#1076c' 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,1) As g, target FROM (SELECT '13800 County Hwy 9, Andover, MN 55304'::text As target) AS f) As foo;
SELECT '#1076d' 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,1) As g, target FROM (SELECT '13800 9, Andover, MN 55304'::text As target) AS f) As foo;
SELECT '#1076e' 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,1) As g, target FROM (SELECT '3900 Route 6, Eastham, Massachusetts 02642'::text As target) AS f) As foo;
SELECT '#1076e' 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,4) As g, target FROM (SELECT '3900 Route 6, Eastham, Massachusetts 02642'::text As target) AS f) As foo;
-- country road that starts with a letter
SELECT '#1076f' 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,3) As g, target FROM (SELECT '1940 County Road C W, Roseville, MN 55113'::text As target) AS f) As foo;
-- 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;
\timing

View file

@ -19,3 +19,5 @@
#1076c|13800||9|Co Hwy|||Andover|MN|55304|t
#1076d|13800|| 9||||Andover|MN|55304|t
#1076e|14||Forest|Rd|||Acton|MA||t
#1076f|1940||C|Co Rd|||Roseville|MN|55113|t
#1076g|3900||6|Rte|||Eastham|MA|02642|t

View file

@ -37,4 +37,11 @@ SELECT '#1076c' As ticket, * FROM normalize_address('13800 County Hwy 9, Andover
SELECT '#1076d' As ticket, * FROM normalize_address('13800 9, Andover, MN 55304');
-- this one is a regular street that happens to have a street type as the name
SELECT '#1076e' As ticket, * FROM normalize_address('14 Forest Road, Acton, MA');
-- A country road with a letter name and direction
-- NOTE this doesn't completely normalize right since the direction W is being cut off --
SELECT '#1076f' As ticket, * FROM normalize_address('1940 County Road C W, Roseville, MN 55113');
-- Route with a name that sounds like a direction --
SELECT '#1076g' As ticket, * FROM normalize_address('3900 Route 6, Eastham, Massachusetts 02642');
\timing

View file

@ -149,7 +149,7 @@ UPDATE state_lookup SET statefp = lpad(st_code::text,2,'0');
-- Create street type lookup table
DROP TABLE IF EXISTS street_type_lookup;
CREATE TABLE street_type_lookup (name VARCHAR(50) PRIMARY KEY, abbrev VARCHAR(50));
CREATE TABLE street_type_lookup (name VARCHAR(50) PRIMARY KEY, abbrev VARCHAR(50), is_hw boolean NOT NULL DEFAULT false);
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLEE', 'Aly');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLEY', 'Aly');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLY', 'Aly');
@ -327,11 +327,6 @@ INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRKS', 'Frks');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORT', 'Ft');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRT', 'Ft');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FT', 'Ft');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FREEWAY', 'Fwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FREEWY', 'Fwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRWAY', 'Fwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRWY', 'Fwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('FWY', 'Fwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDEN', 'Gdn');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDN', 'Gdn');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('GDN', 'Gdn');
@ -369,12 +364,6 @@ INSERT INTO street_type_lookup (name, abbrev) VALUES ('HEIGHTS', 'Hts');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HGTS', 'Hts');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HT', 'Hts');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HTS', 'Hts');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIGHWAY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIGHWY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIWAY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIWY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HWAY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HWY', 'Hwy');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HILL', 'Hl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HL', 'Hl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('HILLS', 'Hls');
@ -548,7 +537,6 @@ INSERT INTO street_type_lookup (name, abbrev) VALUES ('RD', 'Rd');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROAD', 'Rd');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDS', 'Rds');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROADS', 'Rds');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROUTE', 'Rte');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROW', 'Row');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('RUE', 'Rue');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('RUN', 'Run');
@ -629,12 +617,6 @@ INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNLS', 'Tunl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNEL', 'Tunl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNELS', 'Tunl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNL', 'Tunl');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TPK', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TPKE', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRNPK', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRPK', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TURNPIKE', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('TURNPK', 'Tpke');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNDERPASS', 'Upas');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('UN', 'Un');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNION', 'Un');
@ -712,43 +694,63 @@ INSERT INTO street_type_lookup (name, abbrev) VALUES ('UPAS', 'Upas');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNS', 'Uns');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('WL', 'Wl');
-- prefix and suffix street names for highways and roads with spaces in them
INSERT INTO street_type_lookup (name, abbrev)
SELECT name, abbrev
-- prefix and suffix street names for highways and roads
-- these usually have numbers for street names and often have spaces in type
INSERT INTO street_type_lookup (name, abbrev, is_hw)
SELECT name, abbrev, true
FROM (VALUES
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('COUNTY ROAD', 'Co Rd'),
('CO RD', 'Co Rd'),
('CORD', 'Co Rd'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RD', 'Forest Rd'),
('FOREST ROAD', 'Forest Rd'),
('FOREST RTE', 'Forest Rte'),
('FOREST ROUTE', 'Forest Rte'),
('STATE HWY', 'State Hwy'),
('STATE HIGHWAY', 'State Hwy'),
('STATE HIGH WAY', 'State Hwy'),
('STATE RD', 'State Rd'),
('STATE ROAD', 'State Rd'),
('STATE ROUTE', 'State Rte'),
('STATE RTE', 'State Rte'),
('US HWY', 'US Hwy'),
('US HIGHWAY', 'US Hwy'),
('US HIGH WAY', 'US Hwy'),
('US RTE', 'US Rte'),
('US ROUTE', 'US Rte'),
('US RT', 'US Rte'),
('USFS HWY', 'USFS Hwy'),
('USFS HIGHWAY', 'USFS Hwy'),
('USFS HIGH WAY', 'USFS Hwy'),
('USFS RD', 'USFS Rd'),
('USFS ROAD', 'USFS Rd')
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('COUNTY ROAD', 'Co Rd'),
('CO RD', 'Co Rd'),
('CORD', 'Co Rd'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RD', 'Forest Rd'),
('FOREST ROAD', 'Forest Rd'),
('FOREST RTE', 'Forest Rte'),
('FOREST ROUTE', 'Forest Rte'),
('FREEWAY', 'Fwy'),
('FREEWY', 'Fwy'),
('FRWAY', 'Fwy'),
('FRWY', 'Fwy'),
('FWY', 'Fwy'),
('HIGHWAY', 'Hwy'),
('HIGHWY', 'Hwy'),
('HIWAY', 'Hwy'),
('HIWY', 'Hwy'),
('HWAY', 'Hwy'),
('HWY', 'Hwy'),
('ROUTE', 'Rte'),
('RTE', 'Rte'),
('STATE HWY', 'State Hwy'),
('STATE HIGHWAY', 'State Hwy'),
('STATE HIGH WAY', 'State Hwy'),
('STATE RD', 'State Rd'),
('STATE ROAD', 'State Rd'),
('STATE ROUTE', 'State Rte'),
('STATE RTE', 'State Rte'),
('TPK', 'Tpke'),
('TPKE', 'Tpke'),
('TRNPK', 'Tpke'),
('TRPK', 'Tpke'),
('TURNPIKE', 'Tpke'),
('TURNPK', 'Tpke'),
('US HWY', 'US Hwy'),
('US HIGHWAY', 'US Hwy'),
('US HIGH WAY', 'US Hwy'),
('US RTE', 'US Rte'),
('US ROUTE', 'US Rte'),
('US RT', 'US Rte'),
('USFS HWY', 'USFS Hwy'),
('USFS HIGHWAY', 'USFS Hwy'),
('USFS HIGH WAY', 'USFS Hwy'),
('USFS RD', 'USFS Rd'),
('USFS ROAD', 'USFS Rd')
) t(name, abbrev)
WHERE t.name NOT IN(SELECT name FROM street_type_lookup);
CREATE INDEX street_type_lookup_abbrev_idx ON street_type_lookup (abbrev);

View file

@ -50,6 +50,10 @@ CREATE TABLE zcta5
CONSTRAINT pk_tiger_zcta5_zcta5ce PRIMARY KEY (zcta5ce,statefp)
);
ALTER TABLE street_type_lookup ALTER COLUMN abbrev TYPE varchar(50);
ALTER TABLE street_type_lookup ALTER COLUMN name TYPE varchar(50);
ALTER TABLE street_type_lookup ADD COLUMN is_hw boolean NOT NULL DEFAULT false;
BEGIN;
-- Type used to pass around a normalized address between functions
-- This is s bit dangerous since it could potentially drop peoples tables
@ -67,43 +71,70 @@ CREATE TYPE norm_addy AS (
stateAbbrev VARCHAR,
zip VARCHAR,
parsed BOOLEAN);*/
-- prefix and suffix street names for highways and roads with spaces in them
INSERT INTO street_type_lookup (name, abbrev)
SELECT name, abbrev
-- prefix and suffix street names for numbered highways
CREATE TEMPORARY TABLE temp_types AS
SELECT name, abbrev
FROM (VALUES
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('COUNTY ROAD', 'Co Rd'),
('CO RD', 'Co Rd'),
('CORD', 'Co Rd'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RTE', 'Forest Rte'),
('FOREST ROUTE', 'Forest Rte'),
('STATE HWY', 'State Hwy'),
('STATE HIGHWAY', 'State Hwy'),
('STATE HIGH WAY', 'State Hwy'),
('STATE RD', 'State Rd'),
('STATE ROAD', 'State Rd'),
('STATE ROUTE', 'State Rte'),
('STATE RTE', 'State Rte'),
('US HWY', 'US Hwy'),
('US HIGHWAY', 'US Hwy'),
('US HIGH WAY', 'US Hwy'),
('US RTE', 'US Rte'),
('US ROUTE', 'US Rte'),
('US RT', 'US Rte'),
('USFS HWY', 'USFS Hwy'),
('USFS HIGHWAY', 'USFS Hwy'),
('USFS HIGH WAY', 'USFS Hwy'),
('USFS RD', 'USFS Rd'),
('USFS ROAD', 'USFS Rd')
) t(name, abbrev)
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('COUNTY ROAD', 'Co Rd'),
('CO RD', 'Co Rd'),
('CORD', 'Co Rd'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RD', 'Forest Rd'),
('FOREST ROAD', 'Forest Rd'),
('FOREST RTE', 'Forest Rte'),
('FOREST ROUTE', 'Forest Rte'),
('FREEWAY', 'Fwy'),
('FREEWY', 'Fwy'),
('FRWAY', 'Fwy'),
('FRWY', 'Fwy'),
('FWY', 'Fwy'),
('HIGHWAY', 'Hwy'),
('HIGHWY', 'Hwy'),
('HIWAY', 'Hwy'),
('HIWY', 'Hwy'),
('HWAY', 'Hwy'),
('HWY', 'Hwy'),
('ROUTE', 'Rte'),
('RTE', 'Rte'),
('STATE HWY', 'State Hwy'),
('STATE HIGHWAY', 'State Hwy'),
('STATE HIGH WAY', 'State Hwy'),
('STATE RD', 'State Rd'),
('STATE ROAD', 'State Rd'),
('STATE ROUTE', 'State Rte'),
('STATE RTE', 'State Rte'),
('TPK', 'Tpke'),
('TPKE', 'Tpke'),
('TRNPK', 'Tpke'),
('TRPK', 'Tpke'),
('TURNPIKE', 'Tpke'),
('TURNPK', 'Tpke'),
('US HWY', 'US Hwy'),
('US HIGHWAY', 'US Hwy'),
('US HIGH WAY', 'US Hwy'),
('US RTE', 'US Rte'),
('US ROUTE', 'US Rte'),
('US RT', 'US Rte'),
('USFS HWY', 'USFS Hwy'),
('USFS HIGHWAY', 'USFS Hwy'),
('USFS HIGH WAY', 'USFS Hwy'),
('USFS RD', 'USFS Rd'),
('USFS ROAD', 'USFS Rd')
) t(name, abbrev);
DELETE FROM street_type_lookup WHERE name IN(SELECT name FROM temp_types);
INSERT INTO street_type_lookup (name, abbrev, is_hw)
SELECT name, abbrev, true
FROM temp_types As t
WHERE t.name NOT IN(SELECT name FROM street_type_lookup);
DROP TABLE temp_types;
DELETE FROM street_type_lookup WHERE name = 'FOREST';
-- System/General helper functions
\i utility/utmzone.sql