--- normalize_address(addressString)\r
--- This takes an address string and parses it into address (internal/street)\r
--- street name, type, direction prefix and suffix, location, state and\r
--- zip code, depending on what can be found in the string.\r
---\r
--- The US postal address standard is used:\r
--- <Street Number> <Direction Prefix> <Street Name> <Street Type>\r
--- <Direction Suffix> <Internal Address> <Location> <State> <Zip Code>\r
---\r
--- State is assumed to be included in the string, and MUST be matchable to\r
--- something in the state_lookup table. Fuzzy matching is used if no direct\r
--- match is found.\r
---\r
--- Two formats of zip code are acceptable: five digit, and five + 4.\r
---\r
--- The internal addressing indicators are looked up from the\r
--- secondary_unit_lookup table. A following identifier is accepted\r
--- but it must start with a digit.\r
---\r
--- The location is parsed from the string using other indicators, such\r
--- as street type, direction suffix or internal address, if available.\r
--- If these are not, the location is extracted using comparisons against\r
--- the places_lookup table, then the countysub_lookup table to determine\r
--- what, in the original string, is intended to be the location. In both\r
--- cases, an exact match is first pursued, then a word-by-word fuzzy match.\r
--- The result is not the name of the location from the tables, but the\r
--- section of the given string that corresponds to the name from the tables.\r
---\r
--- Zip codes and street names are not validated.\r
---\r
--- Direction indicators are extracted by comparison with the direction_lookup\r
--- table.\r
---\r
--- Street addresses are assumed to be a single word, starting with a number.\r
--- Address is manditory; if no address is given, and the street is numbered,\r
--- the resulting address will be the street name, and the street name\r
--- will be an empty string.\r
---\r
--- In some cases, the street type is part of the street name.\r
--- eg State Hwy 22a. As long as the word following the type starts with a\r
--- number (this is usually the case) this will be caught. Some street names\r
--- include a type name, and have a street type that differs. This will be\r
--- handled properly, so long as both are given. If the street type is\r
--- omitted, the street names included type will be parsed as the street type.\r
---\r
--- The output is currently a colon seperated list of values:\r
--- InternalAddress:StreetAddress:DirectionPrefix:StreetName:StreetType:\r
--- DirectionSuffix:Location:State:ZipCode\r
--- This returns each element as entered. It's mainly meant for debugging.\r
--- There is also another option that returns:\r
--- StreetAddress:DirectionPrefixAbbreviation:StreetName:StreetTypeAbbreviation:\r
--- DirectionSuffixAbbreviation:Location:StateAbbreviation:ZipCode\r
--- This is more standardized and better for use with a geocoder.\r
-CREATE OR REPLACE FUNCTION normalize_address(\r
- in_rawInput VARCHAR\r
-) RETURNS norm_addy\r
-AS $_$\r
-DECLARE\r
- debug_flag boolean := false;\r
- result norm_addy;\r
- addressString VARCHAR;\r
- zipString VARCHAR;\r
- preDir VARCHAR;\r
- postDir VARCHAR;\r
- fullStreet VARCHAR;\r
- reducedStreet VARCHAR;\r
- streetType VARCHAR;\r
- state VARCHAR;\r
- tempString VARCHAR;\r
- tempInt INTEGER;\r
- rec RECORD;\r
- ws VARCHAR;\r
- rawInput VARCHAR;\r
-BEGIN\r
- result.parsed := FALSE;\r
-\r
- rawInput := trim(in_rawInput);\r
-\r
- IF rawInput IS NULL THEN\r
- RETURN result;\r
- END IF;\r
-\r
- ws := E'[ ,.\t\n\f\r]';\r
-\r
- IF debug_flag THEN\r
- raise notice 'input: %', rawInput;\r
- END IF;\r
-\r
- -- Assume that the address begins with a digit, and extract it from\r
- -- the input string.\r
- addressString := substring(rawInput from '^([0-9].*?)[ ,/.]');\r
-\r
- IF debug_flag THEN\r
- raise notice 'addressString: %', addressString;\r
- END IF;\r
-\r
- -- There are two formats for zip code, the normal 5 digit, and\r
- -- the nine digit zip-4. It may also not exist.\r
- zipString := substring(rawInput from ws || '([0-9]{5})$');\r
- IF zipString IS NULL THEN\r
- zipString := substring(rawInput from ws || '([0-9]{5})-[0-9]{4}$');\r
- -- Check if all we got was a zipcode, of either form\r
- IF zipString IS NULL THEN\r
- zipString := substring(rawInput from '^([0-9]{5})$');\r
- IF zipString IS NULL THEN\r
- zipString := substring(rawInput from '^([0-9]{5})-[0-9]{4}$');\r
- END IF;\r
- -- If it was only a zipcode, then just return it.\r
- IF zipString IS NOT NULL THEN\r
- result.zip := zipString;\r
- result.parsed := TRUE;\r
- RETURN result;\r
- END IF;\r
- END IF;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'zipString: %', zipString;\r
- END IF;\r
-\r
- IF zipString IS NOT NULL THEN\r
- fullStreet := substring(rawInput from '(.*)'\r
- || ws || '+' || cull_null(zipString) || '[- ]?([0-9]{4})?$');\r
- ELSE\r
- fullStreet := rawInput;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'fullStreet: %', fullStreet;\r
- END IF;\r
-\r
- -- FIXME: state_extract should probably be returning a record so we can\r
- -- avoid having to parse the result from it.\r
- tempString := state_extract(fullStreet);\r
- IF tempString IS NOT NULL THEN\r
- state := split_part(tempString, ':', 1);\r
- result.stateAbbrev := split_part(tempString, ':', 2);\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'stateAbbrev: %', result.stateAbbrev;\r
- END IF;\r
-\r
- -- The easiest case is if the address is comma delimited. There are some\r
- -- likely cases:\r
- -- street level, location, state\r
- -- street level, location state\r
- -- street level, location\r
- -- street level, internal address, location, state\r
- -- street level, internal address, location state\r
- -- street level, internal address location state\r
- -- street level, internal address, location\r
- -- street level, internal address location\r
- -- The first three are useful.\r
- tempString := substring(fullStreet, '(?i),' || ws || '+(.*?)(,?' || ws ||\r
- '*' || cull_null(state) || '$)');\r
- IF tempString = '' THEN tempString := NULL; END IF;\r
- IF tempString IS NOT NULL THEN\r
- result.location := tempString;\r
- IF addressString IS NOT NULL THEN\r
- fullStreet := substring(fullStreet, '(?i)' || addressString || ws ||\r
- '+(.*),' || ws || '+' || result.location);\r
- ELSE\r
- fullStreet := substring(fullStreet, '(?i)(.*),' || ws || '+' ||\r
- result.location);\r
- END IF;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'fullStreet: %', fullStreet;\r
- raise notice 'location: %', result.location;\r
- END IF;\r
-\r
- -- Pull out the full street information, defined as everything between the\r
- -- address and the state. This includes the location.\r
- -- This doesnt need to be done if location has already been found.\r
- IF result.location IS NULL THEN\r
- IF addressString IS NOT NULL THEN\r
- IF state IS NOT NULL THEN\r
- fullStreet := substring(fullStreet, '(?i)' || addressString ||\r
- ws || '+(.*?)' || ws || '+' || state);\r
- ELSE\r
- fullStreet := substring(fullStreet, '(?i)' || addressString ||\r
- ws || '+(.*?)');\r
- END IF;\r
- ELSE\r
- IF state IS NOT NULL THEN\r
- fullStreet := substring(fullStreet, '(?i)(.*?)' || ws ||\r
- '+' || state);\r
- ELSE\r
- fullStreet := substring(fullStreet, '(?i)(.*?)');\r
- END IF;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'fullStreet: %', fullStreet;\r
- END IF;\r
-\r
- result.location := location_extract(fullStreet, result.stateAbbrev);\r
-\r
- -- A location can't be a street type, sorry.\r
- IF lower(result.location) IN (SELECT lower(name) FROM street_type_lookup) THEN\r
- result.location := NULL;\r
- END IF;\r
-\r
- -- If the location was found, remove it from fullStreet\r
- IF result.location IS NOT NULL THEN\r
- fullStreet := substring(fullStreet, '(?i)(.*)' || ws || '+' ||\r
- result.location);\r
- END IF;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'fullStreet: %', fullStreet;\r
- raise notice 'location: %', result.location;\r
- END IF;\r
-\r
- -- Determine if any internal address is included, such as apartment\r
- -- or suite number.\r
- SELECT INTO tempInt count(*) FROM secondary_unit_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('\r
- || ws || '|$)');\r
- IF tempInt = 1 THEN\r
- result.internal := substring(fullStreet, '(?i)' || ws || '('\r
- || name || ws || '*#?' || ws\r
- || '*(?:[0-9][-0-9a-zA-Z]*)?' || ')(?:' || ws || '|$)')\r
- FROM secondary_unit_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('\r
- || ws || '|$)');\r
- ELSIF tempInt > 1 THEN\r
- -- In the event of multiple matches to a secondary unit designation, we\r
- -- will assume that the last one is the true one.\r
- tempInt := 0;\r
- FOR rec in SELECT trim(substring(fullStreet, '(?i)' || ws || '('\r
- || name || '(?:' || ws || '*#?' || ws\r
- || '*(?:[0-9][-0-9a-zA-Z]*)?)' || ws || '?|$)')) as value\r
- FROM secondary_unit_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('\r
- || ws || '|$)') LOOP\r
- IF tempInt < position(rec.value in fullStreet) THEN\r
- tempInt := position(rec.value in fullStreet);\r
- result.internal := rec.value;\r
- END IF;\r
- END LOOP;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'internal: %', result.internal;\r
- END IF;\r
-\r
- IF result.location IS NULL THEN\r
- -- If the internal address is given, the location is everything after it.\r
- result.location := substring(fullStreet, result.internal || ws || '+(.*)$');\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'location: %', result.location;\r
- END IF;\r
-\r
- -- Pull potential street types from the full street information\r
- tempInt := count(*) FROM street_type_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name\r
- || ')(?:' || ws || '|$)');\r
- IF tempInt = 1 THEN\r
- SELECT INTO rec abbrev, substring(fullStreet, '(?i)' || ws || '('\r
- || name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name\r
- || ')(?:' || ws || '|$)');\r
- streetType := rec.given;\r
- result.streetTypeAbbrev := rec.abbrev;\r
- ELSIF tempInt > 1 THEN\r
- tempInt := 0;\r
- FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '('\r
- || name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name\r
- || ')(?:' || ws || '|$)') LOOP\r
- -- If we have found an internal address, make sure the type\r
- -- precedes it.\r
- IF result.internal IS NOT NULL THEN\r
- IF position(rec.given IN fullStreet) < position(result.internal IN fullStreet) THEN\r
- IF tempInt < position(rec.given IN fullStreet) THEN\r
- streetType := rec.given;\r
- result.streetTypeAbbrev := rec.abbrev;\r
- tempInt := position(rec.given IN fullStreet);\r
- END IF;\r
- END IF;\r
- ELSIF tempInt < position(rec.given IN fullStreet) THEN\r
- streetType := rec.given;\r
- result.streetTypeAbbrev := rec.abbrev;\r
- tempInt := position(rec.given IN fullStreet);\r
- END IF;\r
- END LOOP;\r
- END IF;\r
-\r
- IF debug_flag THEN\r
- raise notice 'streetTypeAbbrev: %', result.streetTypeAbbrev;\r
- END IF;\r
-\r
- -- There is a little more processing required now. If the word after the\r
- -- street type begins with a number, the street type should be considered\r
- -- part of the name, as well as the next word. eg, State Route 225a. If\r
- -- the next word starts with a char, then everything after the street type\r
- -- will be considered location. If there is no street type, then I'm sad.\r
- IF streetType IS NOT NULL THEN\r
- tempString := substring(fullStreet, streetType || ws ||\r
- E'+([0-9][^ ,.\t\r\n\f]*?)' || ws);\r
- IF tempString IS NOT NULL THEN\r
- IF result.location IS NULL THEN\r
- result.location := substring(fullStreet, streetType || ws || '+'\r
- || tempString || ws || '+(.*)$');\r
- END IF;\r
- reducedStreet := substring(fullStreet, '(.*)' || ws || '+'\r
- || result.location || '$');\r
- streetType := NULL;\r
- result.streetTypeAbbrev := NULL;\r
- ELSE\r
- IF result.location IS NULL THEN\r
- result.location := substring(fullStreet, streetType || ws || '+(.*)$');\r
- END IF;\r
- reducedStreet := substring(fullStreet, '^(.*)' || ws || '+'\r
- || streetType);\r
- END IF;\r
-\r
- -- The pre direction should be at the beginning of the fullStreet string.\r
- -- The post direction should be at the beginning of the location string\r
- -- if there is no internal address\r
- tempString := substring(reducedStreet, '(?i)(^' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- IF tempString IS NOT NULL THEN\r
- preDir := tempString;\r
- result.preDirAbbrev := abbrev FROM direction_lookup\r
- where texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- result.streetName := substring(reducedStreet, '^' || preDir || ws || '(.*)');\r
- ELSE\r
- result.streetName := reducedStreet;\r
- END IF;\r
-\r
- IF texticregexeq(result.location, '(?i)' || result.internal || '$') THEN\r
- -- If the internal address is at the end of the location, then no\r
- -- location was given. We still need to look for post direction.\r
- SELECT INTO rec abbrev,\r
- substring(result.location, '(?i)^(' || name || ')' || ws) as value\r
- FROM direction_lookup WHERE texticregexeq(result.location, '(?i)^'\r
- || name || ws) ORDER BY length(name) desc;\r
- IF rec.value IS NOT NULL THEN\r
- postDir := rec.value;\r
- result.postDirAbbrev := rec.abbrev;\r
- END IF;\r
- result.location := null;\r
- ELSIF result.internal IS NULL THEN\r
- -- If no location is given, the location string will be the post direction\r
- SELECT INTO tempInt count(*) FROM direction_lookup WHERE\r
- upper(result.location) = upper(name);\r
- IF tempInt != 0 THEN\r
- postDir := result.location;\r
- SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup WHERE\r
- upper(postDir) = upper(name);\r
- result.location := NULL;\r
- ELSE\r
- -- postDirection is not equal location, but may be contained in it.\r
- SELECT INTO tempString substring(result.location, '(?i)(^' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(result.location, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) desc;\r
- IF tempString IS NOT NULL THEN\r
- postDir := tempString;\r
- SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup\r
- where texticregexeq(result.location, '(?i)(^' || name || ')' || ws);\r
- result.location := substring(result.location, '^' || postDir || ws || '+(.*)');\r
- END IF;\r
- END IF;\r
- ELSE\r
- -- internal is not null, but is not at the end of the location string\r
- -- look for post direction before the internal address\r
- SELECT INTO tempString substring(fullStreet, '(?i)' || streetType\r
- || ws || '+(' || name || ')' || ws || '+' || result.internal)\r
- FROM direction_lookup WHERE texticregexeq(fullStreet, '(?i)'\r
- || ws || name || ws || '+' || result.internal) ORDER BY length(name) desc;\r
- IF tempString IS NOT NULL THEN\r
- postDir := tempString;\r
- SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name || ws);\r
- END IF;\r
- END IF;\r
- ELSE\r
- -- No street type was found\r
-\r
- -- If an internal address was given, then the split becomes easy, and the\r
- -- street name is everything before it, without directions.\r
- IF result.internal IS NOT NULL THEN\r
- reducedStreet := substring(fullStreet, '(?i)^(.*?)' || ws || '+'\r
- || result.internal);\r
- tempInt := count(*) FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)' || ws || name || '$');\r
- IF tempInt > 0 THEN\r
- postDir := substring(reducedStreet, '(?i)' || ws || '('\r
- || name || ')' || '$') FROM direction_lookup\r
- WHERE texticregexeq(reducedStreet, '(?i)' || ws || name || '$');\r
- result.postDirAbbrev := abbrev FROM direction_lookup\r
- WHERE texticregexeq(reducedStreet, '(?i)' || ws || name || '$');\r
- END IF;\r
- tempString := substring(reducedStreet, '(?i)^(' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)^(' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- IF tempString IS NOT NULL THEN\r
- preDir := tempString;\r
- result.preDirAbbrev := abbrev FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- result.streetName := substring(reducedStreet, '(?i)^' || preDir || ws\r
- || '+(.*?)(?:' || ws || '+' || cull_null(postDir) || '|$)');\r
- ELSE\r
- result.streetName := substring(reducedStreet, '(?i)^(.*?)(?:' || ws\r
- || '+' || cull_null(postDir) || '|$)');\r
- END IF;\r
- ELSE\r
-\r
- -- If a post direction is given, then the location is everything after,\r
- -- the street name is everything before, less any pre direction.\r
- tempInt := count(*) FROM direction_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '(?:'\r
- || ws || '|$)');\r
-\r
- IF tempInt = 1 THEN\r
- -- A single postDir candidate was found. This makes it easier.\r
- postDir := substring(fullStreet, '(?i)' || ws || '('\r
- || name || ')(?:' || ws || '|$)') FROM direction_lookup WHERE\r
- texticregexeq(fullStreet, '(?i)' || ws || name || '(?:'\r
- || ws || '|$)');\r
- result.postDirAbbrev := abbrev FROM direction_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name\r
- || '(?:' || ws || '|$)');\r
- IF result.location IS NULL THEN\r
- result.location := substring(fullStreet, '(?i)' || ws || postDir\r
- || ws || '+(.*?)$');\r
- END IF;\r
- reducedStreet := substring(fullStreet, '^(.*?)' || ws || '+'\r
- || postDir);\r
- tempString := substring(reducedStreet, '(?i)(^' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- IF tempString IS NOT NULL THEN\r
- preDir := tempString;\r
- result.preDirAbbrev := abbrev FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- result.streetName := substring(reducedStreet, '^' || preDir || ws\r
- || '+(.*)');\r
- ELSE\r
- result.streetName := reducedStreet;\r
- END IF;\r
- ELSIF tempInt > 1 THEN\r
- -- Multiple postDir candidates were found. We need to find the last\r
- -- incident of a direction, but avoid getting the last word from\r
- -- a two word direction. eg extracting "East" from "North East"\r
- -- We do this by sorting by length, and taking the last direction\r
- -- in the results that is not included in an earlier one.\r
- -- This wont be a problem it preDir is North East and postDir is\r
- -- East as the regex requires a space before the direction. Only\r
- -- the East will return from the preDir.\r
- tempInt := 0;\r
- FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '('\r
- || name || ')(?:' || ws || '|$)') AS value\r
- FROM direction_lookup\r
- WHERE texticregexeq(fullStreet, '(?i)' || ws || name\r
- || '(?:' || ws || '|$)')\r
- ORDER BY length(name) desc LOOP\r
- tempInt := 0;\r
- IF tempInt < position(rec.value in fullStreet) THEN\r
- IF postDir IS NULL THEN\r
- tempInt := position(rec.value in fullStreet);\r
- postDir := rec.value;\r
- result.postDirAbbrev := rec.abbrev;\r
- ELSIF NOT texticregexeq(postDir, '(?i)' || rec.value) THEN\r
- tempInt := position(rec.value in fullStreet);\r
- postDir := rec.value;\r
- result.postDirAbbrev := rec.abbrev;\r
- END IF;\r
- END IF;\r
- END LOOP;\r
- IF result.location IS NULL THEN\r
- result.location := substring(fullStreet, '(?i)' || ws || postDir || ws\r
- || '+(.*?)$');\r
- END IF;\r
- reducedStreet := substring(fullStreet, '(?i)^(.*?)' || ws || '+'\r
- || postDir);\r
- SELECT INTO tempString substring(reducedStreet, '(?i)(^' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- IF tempString IS NOT NULL THEN\r
- preDir := tempString;\r
- SELECT INTO result.preDirAbbrev abbrev FROM direction_lookup WHERE\r
- texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- result.streetName := substring(reducedStreet, '^' || preDir || ws\r
- || '+(.*)');\r
- ELSE\r
- result.streetName := reducedStreet;\r
- END IF;\r
- ELSE\r
-\r
- -- There is no street type, directional suffix or internal address\r
- -- to allow distinction between street name and location.\r
- IF result.location IS NULL THEN\r
- IF debug_flag THEN\r
- raise notice 'fullStreet: %', fullStreet;\r
- END IF;\r
-\r
- result.location := location_extract(fullStreet, result.stateAbbrev);\r
- -- If the location was found, remove it from fullStreet\r
- IF result.location IS NOT NULL THEN\r
- fullStreet := substring(fullStreet, '(?i)(.*),' || ws || '+' ||\r
- result.location);\r
- END IF;\r
- END IF;\r
-\r
- -- Check for a direction prefix.\r
- SELECT INTO tempString substring(fullStreet, '(?i)(^' || name\r
- || ')' || ws) FROM direction_lookup WHERE\r
- texticregexeq(fullStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name);\r
- IF tempString IS NOT NULL THEN\r
- preDir := tempString;\r
- SELECT INTO result.preDirAbbrev abbrev FROM direction_lookup WHERE\r
- texticregexeq(fullStreet, '(?i)(^' || name || ')' || ws)\r
- ORDER BY length(name) DESC;\r
- IF result.location IS NOT NULL THEN\r
- -- The location may still be in the fullStreet, or may\r
- -- have been removed already\r
- result.streetName := substring(fullStreet, '^' || preDir || ws\r
- || '+(.*?)(' || ws || '+' || result.location || '|$)');\r
- ELSE\r
- result.streetName := substring(fullStreet, '^' || preDir || ws\r
- || '+(.*?)' || ws || '*');\r
- END IF;\r
- ELSE\r
- IF result.location IS NOT NULL THEN\r
- -- The location may still be in the fullStreet, or may\r
- -- have been removed already\r
- result.streetName := substring(fullStreet, '^(.*?)(' || ws\r
- || '+' || result.location || '|$)');\r
- ELSE\r
- result.streetName := fullStreet;\r
- END IF;\r
- END IF;\r
- END IF;\r
- END IF;\r
- END IF;\r
-\r
- result.address := to_number(addressString, '99999999999');\r
- result.zip := zipString;\r
-\r
- result.parsed := TRUE;\r
- RETURN result;\r
-END\r
-$_$ LANGUAGE plpgsql;\r
+-- normalize_address(addressString)
+-- This takes an address string and parses it into address (internal/street)
+-- street name, type, direction prefix and suffix, location, state and
+-- zip code, depending on what can be found in the string.
+--
+-- The US postal address standard is used:
+-- <Street Number> <Direction Prefix> <Street Name> <Street Type>
+-- <Direction Suffix> <Internal Address> <Location> <State> <Zip Code>
+--
+-- State is assumed to be included in the string, and MUST be matchable to
+-- something in the state_lookup table. Fuzzy matching is used if no direct
+-- match is found.
+--
+-- Two formats of zip code are acceptable: five digit, and five + 4.
+--
+-- The internal addressing indicators are looked up from the
+-- secondary_unit_lookup table. A following identifier is accepted
+-- but it must start with a digit.
+--
+-- The location is parsed from the string using other indicators, such
+-- as street type, direction suffix or internal address, if available.
+-- If these are not, the location is extracted using comparisons against
+-- the places_lookup table, then the countysub_lookup table to determine
+-- what, in the original string, is intended to be the location. In both
+-- cases, an exact match is first pursued, then a word-by-word fuzzy match.
+-- The result is not the name of the location from the tables, but the
+-- section of the given string that corresponds to the name from the tables.
+--
+-- Zip codes and street names are not validated.
+--
+-- Direction indicators are extracted by comparison with the direction_lookup
+-- table.
+--
+-- Street addresses are assumed to be a single word, starting with a number.
+-- Address is manditory; if no address is given, and the street is numbered,
+-- the resulting address will be the street name, and the street name
+-- will be an empty string.
+--
+-- In some cases, the street type is part of the street name.
+-- eg State Hwy 22a. As long as the word following the type starts with a
+-- number (this is usually the case) this will be caught. Some street names
+-- include a type name, and have a street type that differs. This will be
+-- handled properly, so long as both are given. If the street type is
+-- omitted, the street names included type will be parsed as the street type.
+--
+-- The output is currently a colon seperated list of values:
+-- InternalAddress:StreetAddress:DirectionPrefix:StreetName:StreetType:
+-- DirectionSuffix:Location:State:ZipCode
+-- This returns each element as entered. It's mainly meant for debugging.
+-- There is also another option that returns:
+-- StreetAddress:DirectionPrefixAbbreviation:StreetName:StreetTypeAbbreviation:
+-- DirectionSuffixAbbreviation:Location:StateAbbreviation:ZipCode
+-- This is more standardized and better for use with a geocoder.
+CREATE OR REPLACE FUNCTION normalize_address(
+ in_rawInput VARCHAR
+) RETURNS norm_addy
+AS $_$
+DECLARE
+ debug_flag boolean := false;
+ result norm_addy;
+ addressString VARCHAR;
+ zipString VARCHAR;
+ preDir VARCHAR;
+ postDir VARCHAR;
+ fullStreet VARCHAR;
+ reducedStreet VARCHAR;
+ streetType VARCHAR;
+ state VARCHAR;
+ tempString VARCHAR;
+ tempInt INTEGER;
+ rec RECORD;
+ ws VARCHAR;
+ rawInput VARCHAR;
+BEGIN
+ result.parsed := FALSE;
+
+ rawInput := trim(in_rawInput);
+
+ IF rawInput IS NULL THEN
+ RETURN result;
+ END IF;
+
+ ws := E'[ ,.\t\n\f\r]';
+
+ IF debug_flag THEN
+ raise notice 'input: %', rawInput;
+ END IF;
+
+ -- Assume that the address begins with a digit, and extract it from
+ -- the input string.
+ addressString := substring(rawInput from '^([0-9].*?)[ ,/.]');
+
+ IF debug_flag THEN
+ raise notice 'addressString: %', addressString;
+ END IF;
+
+ -- There are two formats for zip code, the normal 5 digit, and
+ -- the nine digit zip-4. It may also not exist.
+ zipString := substring(rawInput from ws || '([0-9]{5})$');
+ IF zipString IS NULL THEN
+ zipString := substring(rawInput from ws || '([0-9]{5})-[0-9]{4}$');
+ -- Check if all we got was a zipcode, of either form
+ IF zipString IS NULL THEN
+ zipString := substring(rawInput from '^([0-9]{5})$');
+ IF zipString IS NULL THEN
+ zipString := substring(rawInput from '^([0-9]{5})-[0-9]{4}$');
+ END IF;
+ -- If it was only a zipcode, then just return it.
+ IF zipString IS NOT NULL THEN
+ result.zip := zipString;
+ result.parsed := TRUE;
+ RETURN result;
+ END IF;
+ END IF;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'zipString: %', zipString;
+ END IF;
+
+ IF zipString IS NOT NULL THEN
+ fullStreet := substring(rawInput from '(.*)'
+ || ws || '+' || cull_null(zipString) || '[- ]?([0-9]{4})?$');
+ ELSE
+ fullStreet := rawInput;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'fullStreet: %', fullStreet;
+ END IF;
+
+ -- FIXME: state_extract should probably be returning a record so we can
+ -- avoid having to parse the result from it.
+ tempString := state_extract(fullStreet);
+ IF tempString IS NOT NULL THEN
+ state := split_part(tempString, ':', 1);
+ result.stateAbbrev := split_part(tempString, ':', 2);
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'stateAbbrev: %', result.stateAbbrev;
+ END IF;
+
+ -- The easiest case is if the address is comma delimited. There are some
+ -- likely cases:
+ -- street level, location, state
+ -- street level, location state
+ -- street level, location
+ -- street level, internal address, location, state
+ -- street level, internal address, location state
+ -- street level, internal address location state
+ -- street level, internal address, location
+ -- street level, internal address location
+ -- The first three are useful.
+ tempString := substring(fullStreet, '(?i),' || ws || '+(.*?)(,?' || ws ||
+ '*' || cull_null(state) || '$)');
+ IF tempString = '' THEN tempString := NULL; END IF;
+ IF tempString IS NOT NULL THEN
+ result.location := tempString;
+ IF addressString IS NOT NULL THEN
+ fullStreet := substring(fullStreet, '(?i)' || addressString || ws ||
+ '+(.*),' || ws || '+' || result.location);
+ ELSE
+ fullStreet := substring(fullStreet, '(?i)(.*),' || ws || '+' ||
+ result.location);
+ END IF;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'fullStreet: %', fullStreet;
+ raise notice 'location: %', result.location;
+ END IF;
+
+ -- Pull out the full street information, defined as everything between the
+ -- address and the state. This includes the location.
+ -- This doesnt need to be done if location has already been found.
+ IF result.location IS NULL THEN
+ IF addressString IS NOT NULL THEN
+ IF state IS NOT NULL THEN
+ fullStreet := substring(fullStreet, '(?i)' || addressString ||
+ ws || '+(.*?)' || ws || '+' || state);
+ ELSE
+ fullStreet := substring(fullStreet, '(?i)' || addressString ||
+ ws || '+(.*?)');
+ END IF;
+ ELSE
+ IF state IS NOT NULL THEN
+ fullStreet := substring(fullStreet, '(?i)(.*?)' || ws ||
+ '+' || state);
+ ELSE
+ fullStreet := substring(fullStreet, '(?i)(.*?)');
+ END IF;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'fullStreet: %', fullStreet;
+ END IF;
+
+ result.location := location_extract(fullStreet, result.stateAbbrev);
+
+ -- A location can't be a street type, sorry.
+ IF lower(result.location) IN (SELECT lower(name) FROM street_type_lookup) THEN
+ result.location := NULL;
+ END IF;
+
+ -- If the location was found, remove it from fullStreet
+ IF result.location IS NOT NULL THEN
+ fullStreet := substring(fullStreet, '(?i)(.*)' || ws || '+' ||
+ result.location);
+ END IF;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'fullStreet: %', fullStreet;
+ raise notice 'location: %', result.location;
+ END IF;
+
+ -- Determine if any internal address is included, such as apartment
+ -- or suite number.
+ SELECT INTO tempInt count(*) FROM secondary_unit_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('
+ || ws || '|$)');
+ IF tempInt = 1 THEN
+ result.internal := substring(fullStreet, '(?i)' || ws || '('
+ || name || ws || '*#?' || ws
+ || '*(?:[0-9][-0-9a-zA-Z]*)?' || ')(?:' || ws || '|$)')
+ FROM secondary_unit_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('
+ || ws || '|$)');
+ ELSIF tempInt > 1 THEN
+ -- In the event of multiple matches to a secondary unit designation, we
+ -- will assume that the last one is the true one.
+ tempInt := 0;
+ FOR rec in SELECT trim(substring(fullStreet, '(?i)' || ws || '('
+ || name || '(?:' || ws || '*#?' || ws
+ || '*(?:[0-9][-0-9a-zA-Z]*)?)' || ws || '?|$)')) as value
+ FROM secondary_unit_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '('
+ || ws || '|$)') LOOP
+ IF tempInt < position(rec.value in fullStreet) THEN
+ tempInt := position(rec.value in fullStreet);
+ result.internal := rec.value;
+ END IF;
+ END LOOP;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'internal: %', result.internal;
+ END IF;
+
+ IF result.location IS NULL THEN
+ -- If the internal address is given, the location is everything after it.
+ result.location := substring(fullStreet, result.internal || ws || '+(.*)$');
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'location: %', result.location;
+ END IF;
+
+ -- Pull potential street types from the full street information
+ tempInt := count(*) FROM street_type_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name
+ || ')(?:' || ws || '|$)');
+ IF tempInt = 1 THEN
+ SELECT INTO rec abbrev, substring(fullStreet, '(?i)' || ws || '('
+ || name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name
+ || ')(?:' || ws || '|$)');
+ streetType := rec.given;
+ result.streetTypeAbbrev := rec.abbrev;
+ ELSIF tempInt > 1 THEN
+ tempInt := 0;
+ FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '('
+ || name || ')(?:' || ws || '|$)') AS given FROM street_type_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || '(' || name
+ || ')(?:' || ws || '|$)') LOOP
+ -- If we have found an internal address, make sure the type
+ -- precedes it.
+ IF result.internal IS NOT NULL THEN
+ 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 := rec.abbrev;
+ tempInt := position(rec.given IN fullStreet);
+ END IF;
+ END IF;
+ ELSIF tempInt < position(rec.given IN fullStreet) THEN
+ streetType := rec.given;
+ result.streetTypeAbbrev := rec.abbrev;
+ tempInt := position(rec.given IN fullStreet);
+ END IF;
+ END LOOP;
+ END IF;
+
+ IF debug_flag THEN
+ raise notice 'streetTypeAbbrev: %', result.streetTypeAbbrev;
+ END IF;
+
+ -- There is a little more processing required now. If the word after the
+ -- street type begins with a number, the street type should be considered
+ -- part of the name, as well as the next word. eg, State Route 225a. If
+ -- the next word starts with a char, then everything after the street type
+ -- will be considered location. If there is no street type, then I'm sad.
+ IF streetType IS NOT NULL THEN
+ tempString := substring(fullStreet, streetType || ws ||
+ E'+([0-9][^ ,.\t\r\n\f]*?)' || ws);
+ IF tempString IS NOT NULL THEN
+ IF result.location IS NULL THEN
+ result.location := substring(fullStreet, streetType || ws || '+'
+ || tempString || ws || '+(.*)$');
+ END IF;
+ reducedStreet := substring(fullStreet, '(.*)' || ws || '+'
+ || result.location || '$');
+ streetType := NULL;
+ result.streetTypeAbbrev := NULL;
+ ELSE
+ IF result.location IS NULL THEN
+ result.location := substring(fullStreet, streetType || ws || '+(.*)$');
+ END IF;
+ reducedStreet := substring(fullStreet, '^(.*)' || ws || '+'
+ || streetType);
+ END IF;
+
+ -- The pre direction should be at the beginning of the fullStreet string.
+ -- The post direction should be at the beginning of the location string
+ -- if there is no internal address
+ tempString := substring(reducedStreet, '(?i)(^' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ IF tempString IS NOT NULL THEN
+ preDir := tempString;
+ result.preDirAbbrev := abbrev FROM direction_lookup
+ where texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ result.streetName := substring(reducedStreet, '^' || preDir || ws || '(.*)');
+ ELSE
+ result.streetName := reducedStreet;
+ END IF;
+
+ IF texticregexeq(result.location, '(?i)' || result.internal || '$') THEN
+ -- If the internal address is at the end of the location, then no
+ -- location was given. We still need to look for post direction.
+ SELECT INTO rec abbrev,
+ substring(result.location, '(?i)^(' || name || ')' || ws) as value
+ FROM direction_lookup WHERE texticregexeq(result.location, '(?i)^'
+ || name || ws) ORDER BY length(name) desc;
+ IF rec.value IS NOT NULL THEN
+ postDir := rec.value;
+ result.postDirAbbrev := rec.abbrev;
+ END IF;
+ result.location := null;
+ ELSIF result.internal IS NULL THEN
+ -- If no location is given, the location string will be the post direction
+ SELECT INTO tempInt count(*) FROM direction_lookup WHERE
+ upper(result.location) = upper(name);
+ IF tempInt != 0 THEN
+ postDir := result.location;
+ SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup WHERE
+ upper(postDir) = upper(name);
+ result.location := NULL;
+ ELSE
+ -- postDirection is not equal location, but may be contained in it.
+ SELECT INTO tempString substring(result.location, '(?i)(^' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(result.location, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) desc;
+ IF tempString IS NOT NULL THEN
+ postDir := tempString;
+ SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup
+ where texticregexeq(result.location, '(?i)(^' || name || ')' || ws);
+ result.location := substring(result.location, '^' || postDir || ws || '+(.*)');
+ END IF;
+ END IF;
+ ELSE
+ -- internal is not null, but is not at the end of the location string
+ -- look for post direction before the internal address
+ SELECT INTO tempString substring(fullStreet, '(?i)' || streetType
+ || ws || '+(' || name || ')' || ws || '+' || result.internal)
+ FROM direction_lookup WHERE texticregexeq(fullStreet, '(?i)'
+ || ws || name || ws || '+' || result.internal) ORDER BY length(name) desc;
+ IF tempString IS NOT NULL THEN
+ postDir := tempString;
+ SELECT INTO result.postDirAbbrev abbrev FROM direction_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name || ws);
+ END IF;
+ END IF;
+ ELSE
+ -- No street type was found
+
+ -- If an internal address was given, then the split becomes easy, and the
+ -- street name is everything before it, without directions.
+ IF result.internal IS NOT NULL THEN
+ reducedStreet := substring(fullStreet, '(?i)^(.*?)' || ws || '+'
+ || result.internal);
+ tempInt := count(*) FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)' || ws || name || '$');
+ IF tempInt > 0 THEN
+ postDir := substring(reducedStreet, '(?i)' || ws || '('
+ || name || ')' || '$') FROM direction_lookup
+ WHERE texticregexeq(reducedStreet, '(?i)' || ws || name || '$');
+ result.postDirAbbrev := abbrev FROM direction_lookup
+ WHERE texticregexeq(reducedStreet, '(?i)' || ws || name || '$');
+ END IF;
+ tempString := substring(reducedStreet, '(?i)^(' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)^(' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ IF tempString IS NOT NULL THEN
+ preDir := tempString;
+ result.preDirAbbrev := abbrev FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ result.streetName := substring(reducedStreet, '(?i)^' || preDir || ws
+ || '+(.*?)(?:' || ws || '+' || cull_null(postDir) || '|$)');
+ ELSE
+ result.streetName := substring(reducedStreet, '(?i)^(.*?)(?:' || ws
+ || '+' || cull_null(postDir) || '|$)');
+ END IF;
+ ELSE
+
+ -- If a post direction is given, then the location is everything after,
+ -- the street name is everything before, less any pre direction.
+ tempInt := count(*) FROM direction_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name || '(?:'
+ || ws || '|$)');
+
+ IF tempInt = 1 THEN
+ -- A single postDir candidate was found. This makes it easier.
+ postDir := substring(fullStreet, '(?i)' || ws || '('
+ || name || ')(?:' || ws || '|$)') FROM direction_lookup WHERE
+ texticregexeq(fullStreet, '(?i)' || ws || name || '(?:'
+ || ws || '|$)');
+ result.postDirAbbrev := abbrev FROM direction_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name
+ || '(?:' || ws || '|$)');
+ IF result.location IS NULL THEN
+ result.location := substring(fullStreet, '(?i)' || ws || postDir
+ || ws || '+(.*?)$');
+ END IF;
+ reducedStreet := substring(fullStreet, '^(.*?)' || ws || '+'
+ || postDir);
+ tempString := substring(reducedStreet, '(?i)(^' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ IF tempString IS NOT NULL THEN
+ preDir := tempString;
+ result.preDirAbbrev := abbrev FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ result.streetName := substring(reducedStreet, '^' || preDir || ws
+ || '+(.*)');
+ ELSE
+ result.streetName := reducedStreet;
+ END IF;
+ ELSIF tempInt > 1 THEN
+ -- Multiple postDir candidates were found. We need to find the last
+ -- incident of a direction, but avoid getting the last word from
+ -- a two word direction. eg extracting "East" from "North East"
+ -- We do this by sorting by length, and taking the last direction
+ -- in the results that is not included in an earlier one.
+ -- This wont be a problem it preDir is North East and postDir is
+ -- East as the regex requires a space before the direction. Only
+ -- the East will return from the preDir.
+ tempInt := 0;
+ FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '('
+ || name || ')(?:' || ws || '|$)') AS value
+ FROM direction_lookup
+ WHERE texticregexeq(fullStreet, '(?i)' || ws || name
+ || '(?:' || ws || '|$)')
+ ORDER BY length(name) desc LOOP
+ tempInt := 0;
+ IF tempInt < position(rec.value in fullStreet) THEN
+ IF postDir IS NULL THEN
+ tempInt := position(rec.value in fullStreet);
+ postDir := rec.value;
+ result.postDirAbbrev := rec.abbrev;
+ ELSIF NOT texticregexeq(postDir, '(?i)' || rec.value) THEN
+ tempInt := position(rec.value in fullStreet);
+ postDir := rec.value;
+ result.postDirAbbrev := rec.abbrev;
+ END IF;
+ END IF;
+ END LOOP;
+ IF result.location IS NULL THEN
+ result.location := substring(fullStreet, '(?i)' || ws || postDir || ws
+ || '+(.*?)$');
+ END IF;
+ reducedStreet := substring(fullStreet, '(?i)^(.*?)' || ws || '+'
+ || postDir);
+ SELECT INTO tempString substring(reducedStreet, '(?i)(^' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ IF tempString IS NOT NULL THEN
+ preDir := tempString;
+ SELECT INTO result.preDirAbbrev abbrev FROM direction_lookup WHERE
+ texticregexeq(reducedStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ result.streetName := substring(reducedStreet, '^' || preDir || ws
+ || '+(.*)');
+ ELSE
+ result.streetName := reducedStreet;
+ END IF;
+ ELSE
+
+ -- There is no street type, directional suffix or internal address
+ -- to allow distinction between street name and location.
+ IF result.location IS NULL THEN
+ IF debug_flag THEN
+ raise notice 'fullStreet: %', fullStreet;
+ END IF;
+
+ result.location := location_extract(fullStreet, result.stateAbbrev);
+ -- If the location was found, remove it from fullStreet
+ IF result.location IS NOT NULL THEN
+ fullStreet := substring(fullStreet, '(?i)(.*),' || ws || '+' ||
+ result.location);
+ END IF;
+ END IF;
+
+ -- Check for a direction prefix.
+ SELECT INTO tempString substring(fullStreet, '(?i)(^' || name
+ || ')' || ws) FROM direction_lookup WHERE
+ texticregexeq(fullStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name);
+ IF tempString IS NOT NULL THEN
+ preDir := tempString;
+ SELECT INTO result.preDirAbbrev abbrev FROM direction_lookup WHERE
+ texticregexeq(fullStreet, '(?i)(^' || name || ')' || ws)
+ ORDER BY length(name) DESC;
+ IF result.location IS NOT NULL THEN
+ -- The location may still be in the fullStreet, or may
+ -- have been removed already
+ result.streetName := substring(fullStreet, '^' || preDir || ws
+ || '+(.*?)(' || ws || '+' || result.location || '|$)');
+ ELSE
+ result.streetName := substring(fullStreet, '^' || preDir || ws
+ || '+(.*?)' || ws || '*');
+ END IF;
+ ELSE
+ IF result.location IS NOT NULL THEN
+ -- The location may still be in the fullStreet, or may
+ -- have been removed already
+ result.streetName := substring(fullStreet, '^(.*?)(' || ws
+ || '+' || result.location || '|$)');
+ ELSE
+ result.streetName := fullStreet;
+ END IF;
+ END IF;
+ END IF;
+ END IF;
+ END IF;
+
+ result.address := to_number(addressString, '99999999999');
+ result.zip := zipString;
+
+ result.parsed := TRUE;
+ RETURN result;
+END
+$_$ LANGUAGE plpgsql;
---$Id$\r
-SET search_path TO tiger, public;\r
--- Create direction lookup table\r
-DROP TABLE IF EXISTS direction_lookup;\r
-CREATE TABLE direction_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(3));\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('WEST', 'W');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('W', 'W');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SW', 'SW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH-WEST', 'SW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTHWEST', 'SW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH-EAST', 'SE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTHEAST', 'SE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH_WEST', 'SW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH_EAST', 'SE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH', 'S');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH WEST', 'SW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH EAST', 'SE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('SE', 'SE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('S', 'S');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NW', 'NW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH-WEST', 'NW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTHWEST', 'NW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH-EAST', 'NE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTHEAST', 'NE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH_WEST', 'NW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH_EAST', 'NE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH', 'N');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH WEST', 'NW');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH EAST', 'NE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('NE', 'NE');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('N', 'N');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('EAST', 'E');\r
-INSERT INTO direction_lookup (name, abbrev) VALUES('E', 'E');\r
-CREATE INDEX direction_lookup_abbrev_idx ON direction_lookup (abbrev);\r
-\r
-\r
-\r
--- Create secondary unit lookup table\r
-DROP TABLE IF EXISTS secondary_unit_lookup;\r
-CREATE TABLE secondary_unit_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(5));\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('APARTMENT', 'APT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('APT', 'APT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BASEMENT', 'BSMT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BSMT', 'BSMT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BUILDING', 'BLDG');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BLDG', 'BLDG');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('DEPARTMENT', 'DEPT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('DEPT', 'DEPT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FLOOR', 'FL');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FL', 'FL');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FRONT', 'FRNT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FRNT', 'FRNT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('HANGAR', 'HNGR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('HNGR', 'HNGR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOBBY', 'LBBY');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LBBY', 'LBBY');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOT', 'LOT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOWER', 'LOWR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOWR', 'LOWR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('OFFICE', 'OFC');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('OFC', 'OFC');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PENTHOUSE', 'PH');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PH', 'PH');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PIER', 'PIER');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('REAR', 'REAR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('ROOM', 'RM');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('RM', 'RM');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SIDE', 'SIDE');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SLIP', 'SLIP');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SPACE', 'SPC');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SPC', 'SPC');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('STOP', 'STOP');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SUITE', 'STE');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('STE', 'STE');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('TRAILER', 'TRLR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('TRLR', 'TRLR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UNIT', 'UNIT');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UPPER', 'UPPR');\r
-INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UPPR', 'UPPR');\r
-CREATE INDEX secondary_unit_lookup_abbrev_idx ON secondary_unit_lookup (abbrev);\r
-\r
-\r
-\r
--- Create state lookup table\r
-DROP TABLE IF EXISTS state_lookup;\r
-CREATE TABLE state_lookup (st_code INTEGER PRIMARY KEY, name VARCHAR(40) UNIQUE, abbrev VARCHAR(3) UNIQUE);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Alabama', 'AL', '01');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Alaska', 'AK', '02');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('American Samoa', 'AS', -1);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Arizona', 'AZ', '04');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Arkansas', 'AR', '05');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('California', 'CA', '06');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Colorado', 'CO', '08');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Connecticut', 'CT', '09');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Delaware', 'DE', '10');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('District of Columbia', 'DC', '11');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Federated States of Micronesia', 'FM', -2);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Florida', 'FL', '12');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Georgia', 'GA', '13');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Guam', 'GU', -7);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Hawaii', 'HI', '15');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Idaho', 'ID', '16');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Illinois', 'IL', '17');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Indiana', 'IN', '18');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Iowa', 'IA', '19');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Kansas', 'KS', '20');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Kentucky', 'KY', '21');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Louisiana', 'LA', '22');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Maine', 'ME', '23');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Marshall Islands', 'MH', -3);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Maryland', 'MD', '24');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Massachusetts', 'MA', '25');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Michigan', 'MI', '26');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Minnesota', 'MN', '27');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Mississippi', 'MS', '28');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Missouri', 'MO', '29');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Montana', 'MT', '30');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Nebraska', 'NE', '31');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Nevada', 'NV', '32');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Hampshire', 'NH', '33');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Jersey', 'NJ', '34');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Mexico', 'NM', '35');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New York', 'NY', '36');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('North Carolina', 'NC', '37');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('North Dakota', 'ND', '38');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Northern Mariana Islands', 'MP', -4);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Ohio', 'OH', '39');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Oklahoma', 'OK', '40');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Oregon', 'OR', '41');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Palau', 'PW', -5);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Pennsylvania', 'PA', '42');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Puerto Rico', 'PR', '72');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Rhode Island', 'RI', '44');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('South Carolina', 'SC', '45');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('South Dakota', 'SD', '46');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Tennessee', 'TN', '47');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Texas', 'TX', '48');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Utah', 'UT', '49');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Vermont', 'VT', '50');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Virgin Islands', 'VI', -6);\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Virginia', 'VA', '51');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Washington', 'WA', '53');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('West Virginia', 'WV', '54');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Wisconsin', 'WI', '55');\r
-INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Wyoming', 'WY', '56');\r
-\r
-\r
--- Create street type lookup table\r
-DROP TABLE IF EXISTS street_type_lookup;\r
-CREATE TABLE street_type_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(4));\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLEE', 'Aly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLEY', 'Aly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALLY', 'Aly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALY', 'Aly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANEX', 'Anx');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANNEX', 'Anx');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANNX', 'Anx');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANX', 'Anx');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ARC', 'Arc');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ARCADE', 'Arc');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AV', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVE', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVEN', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVENU', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVENUE', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVN', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVNUE', 'Ave');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BAYOO', 'Byu');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BAYOU', 'Byu');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BCH', 'Bch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BEACH', 'Bch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BEND', 'Bnd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BND', 'Bnd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLF', 'Blf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUF', 'Blf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUFF', 'Blf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUFFS', 'Blfs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOT', 'Btm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOTTM', 'Btm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOTTOM', 'Btm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BTM', 'Btm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLVD', 'Blvd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOUL', 'Blvd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOULEVARD', 'Blvd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOULV', 'Blvd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BR', 'Br');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRANCH', 'Br');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRNCH', 'Br');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRDGE', 'Brg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRG', 'Brg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRIDGE', 'Brg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRK', 'Brk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BROOK', 'Brk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BROOKS', 'Brks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BURG', 'Bg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BURGS', 'Bgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYP', 'Byp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPA', 'Byp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPAS', 'Byp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPASS', 'ByP');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPS', 'Byp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAMP', 'Cp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CMP', 'Cp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CP', 'Cp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CANYN', 'Cyn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CANYON', 'Cyn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNYN', 'Cyn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CYN', 'Cyn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAPE', 'Cpe');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CPE', 'Cpe');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAUSEWAY', 'Cswy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAUSWAY', 'Cswy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CSWY', 'Cswy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CEN', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENT', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTER', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTR', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTRE', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNTER', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNTR', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTR', 'Ctr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTERS', 'Ctrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIR', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRC', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCL', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCLE', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRCL', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRCLE', 'Cir');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCLES', 'Cirs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLF', 'Clf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLIFF', 'Clf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLFS', 'Clfs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLIFFS', 'Clfs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLB', 'Clb');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLUB', 'Clb');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COMMON', 'Cmn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COR', 'Cor');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORNER', 'Cor');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORNERS', 'Cors');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORS', 'Cors');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURSE', 'Crse');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSE', 'Crse');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURT', 'Ct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRT', 'Ct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CT', 'Ct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURTS', 'Cts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COVE', 'Cv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CV', 'Cv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('COVES', 'Cvs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CK', 'Crk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CR', 'Crk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CREEK', 'Crk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRK', 'Crk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRECENT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRES', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRESCENT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRESENT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSCNT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSENT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSNT', 'Cres');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CREST', 'Crst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CROSSING', 'Xing');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSSING', 'Xing');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSSNG', 'Xing');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('XING', 'Xing');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CROSSROAD', 'Xrd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CURVE', 'Curv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DALE', 'Dl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DL', 'Dl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DAM', 'Dm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DM', 'Dm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DIV', 'Dv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DIVIDE', 'Dv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DV', 'Dv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DVD', 'Dv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DR', 'Dr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIV', 'Dr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIVE', 'Dr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRV', 'Dr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIVES', 'Drs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EST', 'Est');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTATE', 'Est');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTATES', 'Ests');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTS', 'Ests');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXP', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPR', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPRESS', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPRESSWAY', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPW', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPY', 'Expy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXT', 'Ext');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTENSION', 'Ext');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTN', 'Ext');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTNSN', 'Ext');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTENSIONS', 'Exts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTS', 'Exts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FALL', 'Fall');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FALLS', 'Fls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLS', 'Fls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FERRY', 'Fry');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRRY', 'Fry');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRY', 'Fry');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FIELD', 'Fld');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLD', 'Fld');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FIELDS', 'Flds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLDS', 'Flds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLAT', 'Flt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLT', 'Flt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLATS', 'Flts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLTS', 'Flts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORD', 'Frd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRD', 'Frd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORDS', 'Frds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FOREST', 'Frst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORESTS', 'Frst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRST', 'Frst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORG', 'Frg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORGE', 'Frg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRG', 'Frg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORGES', 'Frgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORK', 'Frk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRK', 'Frk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORKS', 'Frks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRKS', 'Frks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORT', 'Ft');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRT', 'Ft');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FT', 'Ft');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FREEWAY', 'Fwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FREEWY', 'Fwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRWAY', 'Fwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRWY', 'Fwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FWY', 'Fwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDEN', 'Gdn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDN', 'Gdn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GDN', 'Gdn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDEN', 'Gdn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDN', 'Gdn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDENS', 'Gdns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GDNS', 'Gdns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDNS', 'Gdns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATEWAY', 'Gtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATEWY', 'Gtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATWAY', 'Gtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GTWAY', 'Gtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GTWY', 'Gtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLEN', 'Gln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLN', 'Gln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLENS', 'Glns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GREEN', 'Grn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRN', 'Grn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GREENS', 'Grns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROV', 'Grv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROVE', 'Grv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRV', 'Grv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROVES', 'Grvs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARB', 'Hbr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBOR', 'Hbr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBR', 'Hbr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HBR', 'Hbr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HRBOR', 'Hbr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBORS', 'Hbrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HAVEN', 'Hvn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HAVN', 'Hvn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HVN', 'Hvn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HEIGHT', 'Hts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HEIGHTS', 'Hts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HGTS', 'Hts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HT', 'Hts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HTS', 'Hts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIGHWAY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIGHWY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIWAY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HIWY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HWAY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HWY', 'Hwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HILL', 'Hl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HL', 'Hl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HILLS', 'Hls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HLS', 'Hls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HLLW', 'Holw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLLOW', 'Holw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLLOWS', 'Holw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLW', 'Holw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLWS', 'Holw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('INLET', 'Inlt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('INLT', 'Inlt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('IS', 'Is');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLAND', 'Is');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLND', 'Is');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLANDS', 'Iss');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLNDS', 'Iss');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISS', 'Iss');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLE', 'Isle');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLES', 'Isle');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCT', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTION', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTN', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTION', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTN', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTON', 'Jct');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTNS', 'Jcts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTS', 'Jcts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTIONS', 'Jcts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KEY', 'Ky');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KY', 'Ky');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KEYS', 'Kys');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KYS', 'Kys');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNL', 'Knl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOL', 'Knl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOLL', 'Knl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNLS', 'Knls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOLLS', 'Knls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAKE', 'Lk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LK', 'Lk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAKES', 'Lks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LKS', 'Lks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAND', 'Land');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANDING', 'Lndg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LNDG', 'Lndg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LNDNG', 'Lndg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LA', 'Ln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANE', 'Ln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANES', 'Ln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LN', 'Ln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LGT', 'Lgt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LIGHT', 'Lgt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LIGHTS', 'Lgts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LF', 'Lf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOAF', 'Lf');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LCK', 'Lck');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOCK', 'Lck');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LCKS', 'Lcks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOCKS', 'Lcks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LDG', 'Ldg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LDGE', 'Ldg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LODG', 'Ldg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LODGE', 'Ldg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOOP', 'Loop');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOOPS', 'Loop');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MALL', 'Mall');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MANOR', 'Mnr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNR', 'Mnr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MANORS', 'Mnrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNRS', 'Mnrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MDW', 'Mdw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEADOW', 'Mdw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MDWS', 'Mdws');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEADOWS', 'Mdws');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEDOWS', 'Mdws');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEWS', 'Mews');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MILL', 'Ml');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ML', 'Ml');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MILLS', 'Mls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MLS', 'Mls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MISSION', 'Msn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MISSN', 'Msn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MSN', 'Msn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MSSN', 'Msn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOTORWAY', 'Mtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNT', 'Mt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNT', 'Mt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MT', 'Mt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTAIN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTAIN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTIN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTIN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTN', 'Mtn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTNS', 'Mtns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTAINS', 'Mtns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('NCK', 'Nck');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('NECK', 'Nck');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCH', 'Orch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCHARD', 'Orch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCHRD', 'Orch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVAL', 'Oval');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVL', 'Oval');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVERPASS', 'Opas');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARK', 'Park');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PK', 'Park');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRK', 'Park');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKS', 'Park');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWAY', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWY', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWAY', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWY', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKY', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWAYS', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWYS', 'Pkwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PASS', 'Pass');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PASSAGE', 'Psge');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PATH', 'Path');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PATHS', 'Path');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PIKE', 'Pike');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PIKES', 'Pike');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PINE', 'Pne');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PINES', 'Pnes');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PNES', 'Pnes');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PL', 'Pl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLACE', 'Pl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAIN', 'Pln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLN', 'Pln');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAINES', 'Plns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAINS', 'Plns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLNS', 'Plns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAZA', 'Plz');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLZ', 'Plz');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLZA', 'Plz');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('POINT', 'Pt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PT', 'Pt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('POINTS', 'Pts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PTS', 'Pts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PORT', 'Prt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRT', 'Prt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PORTS', 'Prts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRTS', 'Prts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PR', 'Pr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRAIRIE', 'Pr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRARIE', 'Pr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRR', 'Pr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAD', 'Radl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADIAL', 'Radl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADIEL', 'Radl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADL', 'Radl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAMP', 'Ramp');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RANCH', 'Rnch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RANCHES', 'Rnch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RNCH', 'Rnch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RNCHS', 'Rnch');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAPID', 'Rpd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RPD', 'Rpd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAPIDS', 'Rpds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RPDS', 'Rpds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('REST', 'Rst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RST', 'Rst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDG', 'Rdg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDGE', 'Rdg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIDGE', 'Rdg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDGS', 'Rdgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIDGES', 'Rdgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIV', 'Riv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIVER', 'Riv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIVR', 'Riv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RVR', 'Riv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RD', 'Rd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROAD', 'Rd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDS', 'Rds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROADS', 'Rds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROUTE', 'Rte');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ROW', 'Row');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RUE', 'Rue');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RUN', 'Run');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHL', 'Shl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOAL', 'Shl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHLS', 'Shls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOALS', 'Shls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOAR', 'Shr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHORE', 'Shr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHR', 'Shr');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOARS', 'Shrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHORES', 'Shrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHRS', 'Shrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SKYWAY', 'Skwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPG', 'Spg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPNG', 'Spg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRING', 'Spg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRNG', 'Spg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPGS', 'Spgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPNGS', 'Spgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRINGS', 'Spgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRNGS', 'Spgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPUR', 'Spur');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPURS', 'Spur');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQ', 'Sq');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQR', 'Sq');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQRE', 'Sq');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQU', 'Sq');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQUARE', 'Sq');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQRS', 'Sqs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQUARES', 'Sqs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STA', 'Sta');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STATION', 'Sta');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STATN', 'Sta');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STN', 'Sta');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRA', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAV', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVE', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVEN', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVENUE', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVN', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRVN', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRVNUE', 'Stra');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREAM', 'Strm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREME', 'Strm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRM', 'Strm');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('ST', 'St');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STR', 'St');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREET', 'St');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRT', 'St');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREETS', 'Sts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SMT', 'Smt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMIT', 'Smt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMITT', 'Smt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMMIT', 'Smt');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TER', 'Ter');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TERR', 'Ter');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TERRACE', 'Ter');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('THROUGHWAY', 'Trwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACE', 'Trce');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACES', 'Trce');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRCE', 'Trce');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACK', 'Trak');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACKS', 'Trak');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAK', 'Trak');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRK', 'Trak');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRKS', 'Trak');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAFFICWAY', 'Trfy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRFY', 'Trfy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TR', 'Trl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAIL', 'Trl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAILS', 'Trl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRL', 'Trl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRLS', 'Trl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNEL', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNL', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNLS', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNEL', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNELS', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNNL', 'Tunl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TPK', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TPKE', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRNPK', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRPK', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TURNPIKE', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TURNPK', 'Tpke');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNDERPASS', 'Upas');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UN', 'Un');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNION', 'Un');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNIONS', 'Uns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLEY', 'Vly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLY', 'Vly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLLY', 'Vly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLY', 'Vly');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLEYS', 'Vlys');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLYS', 'Vlys');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VDCT', 'Via');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIA', 'Via');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIADCT', 'Via');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIADUCT', 'Via');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIEW', 'Vw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VW', 'Vw');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIEWS', 'Vws');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VWS', 'Vws');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILL', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAG', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAGE', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLG', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLIAGE', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLG', 'Vlg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAGES', 'Vlgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLGS', 'Vlgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLE', 'Vl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VL', 'Vl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIS', 'Vis');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIST', 'Vis');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VISTA', 'Vis');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VST', 'Vis');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('VSTA', 'Vis');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALK', 'Walk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALKS', 'Walk');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALL', 'Wall');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WAY', 'Way');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WY', 'Way');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WAYS', 'Ways');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WELL', 'Wl');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WELLS', 'Wls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WLS', 'Wls');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYU', 'Byu');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLFS', 'Blfs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRKS', 'Brks');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BG', 'Bg');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('BGS', 'Bgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTRS', 'Ctrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRS', 'Cirs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CMN', 'Cmn');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTS', 'Cts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CVS', 'Cvs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRST', 'Crst');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('XRD', 'Xrd');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('CURV', 'Curv');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRS', 'Drs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRDS', 'Frds');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRGS', 'Frgs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLNS', 'Glns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRNS', 'Grns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRVS', 'Grvs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('HBRS', 'Hbrs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('LGTS', 'Lgts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTWY', 'Mtwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTNS', 'Mtns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('OPAS', 'Opas');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PSGE', 'Psge');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('PNE', 'Pne');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('RTE', 'Rte');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SKWY', 'Skwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQS', 'Sqs');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('STS', 'Sts');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRWY', 'Trwy');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UPAS', 'Upas');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNS', 'Uns');\r
-INSERT INTO street_type_lookup (name, abbrev) VALUES ('WL', 'Wl');\r
-CREATE INDEX street_type_lookup_abbrev_idx ON street_type_lookup (abbrev);\r
-\r
--- Create place and countysub lookup tables\r
-DROP TABLE IF EXISTS place_lookup;\r
-CREATE TABLE place_lookup (\r
- st_code INTEGER,\r
- state VARCHAR(2),\r
- pl_code INTEGER,\r
- name VARCHAR(90),\r
- PRIMARY KEY (st_code,pl_code)\r
-);\r
-\r
-/**\r
-INSERT INTO place_lookup\r
- SELECT\r
- pl.state::integer as st_code,\r
- sl.abbrev as state,\r
- pl.placefp::integer as pl_code,\r
- pl.name as name\r
- FROM\r
- pl99_d00 pl\r
- JOIN state_lookup sl ON (pl.state = lpad(sl.st_code,2,'0'))\r
- GROUP BY pl.state, sl.abbrev, pl.placefp, pl.name;\r
-**/\r
-CREATE INDEX place_lookup_name_idx ON place_lookup (soundex(name));\r
-CREATE INDEX place_lookup_state_idx ON place_lookup (state);\r
-\r
-DROP TABLE IF EXISTS county_lookup;\r
-CREATE TABLE county_lookup (\r
- st_code INTEGER,\r
- state VARCHAR(2),\r
- co_code INTEGER,\r
- name VARCHAR(90),\r
- PRIMARY KEY (st_code, co_code)\r
-);\r
-\r
-/**\r
-INSERT INTO county_lookup\r
- SELECT\r
- co.state::integer as st_code,\r
- sl.abbrev as state,\r
- co.county::integer as co_code,\r
- co.name as name\r
- FROM\r
- co99_d00 co\r
- JOIN state_lookup sl ON (co.state = lpad(sl.st_code,2,'0'))\r
- GROUP BY co.state, sl.abbrev, co.county, co.name;\r
-**/\r
-CREATE INDEX county_lookup_name_idx ON county_lookup (soundex(name));\r
-CREATE INDEX county_lookup_state_idx ON county_lookup (state);\r
-\r
-DROP TABLE IF EXISTS countysub_lookup;\r
-CREATE TABLE countysub_lookup (\r
- st_code INTEGER,\r
- state VARCHAR(2),\r
- co_code INTEGER,\r
- county VARCHAR(90),\r
- cs_code INTEGER,\r
- name VARCHAR(90),\r
- PRIMARY KEY (st_code, co_code, cs_code)\r
-);\r
-\r
-/**\r
-INSERT INTO countysub_lookup\r
- SELECT\r
- cs.state::integer as st_code,\r
- sl.abbrev as state,\r
- cs.county::integer as co_code,\r
- cl.name as county,\r
- cs.cousubfp::integer as cs_code,\r
- cs.name as name\r
- FROM\r
- cs99_d00 cs\r
- JOIN state_lookup sl ON (cs.state = lpad(sl.st_code,2,'0'))\r
- JOIN county_lookup cl ON (cs.state = lpad(cl.st_code,2,'0') AND cs.county = cl.co_code)\r
- GROUP BY cs.state, sl.abbrev, cs.county, cl.name, cs.cousubfp, cs.name;\r
-**/\r
-CREATE INDEX countysub_lookup_name_idx ON countysub_lookup (soundex(name));\r
-CREATE INDEX countysub_lookup_state_idx ON countysub_lookup (state);\r
-\r
-DROP TABLE IF EXISTS zip_lookup_all;\r
-CREATE TABLE zip_lookup_all (\r
- zip INTEGER,\r
- st_code INTEGER,\r
- state VARCHAR(2),\r
- co_code INTEGER,\r
- county VARCHAR(90),\r
- cs_code INTEGER,\r
- cousub VARCHAR(90),\r
- pl_code INTEGER,\r
- place VARCHAR(90),\r
- cnt INTEGER\r
-);\r
-\r
-/** SET work_mem = '2GB';\r
-\r
-INSERT INTO zip_lookup_all\r
- SELECT *,count(*) as cnt FROM\r
- (SELECT\r
- zipl as zip,\r
- rl.statel as st_code,\r
- sl.abbrev as state,\r
- rl.countyl as co_code,\r
- cl.name as county,\r
- rl.cousubl as cs_code,\r
- cs.name as countysub,\r
- rl.placel as pl_code,\r
- pl.name as place\r
- FROM\r
- roads_local rl\r
- JOIN state_lookup sl ON (rl.statel = lpad(sl.st_code,2,'0'))\r
- LEFT JOIN county_lookup cl ON (rl.statel = lpad(cl.st_code,2,'0') AND rl.countyl = cl.co_code)\r
- LEFT JOIN countysub_lookup cs ON (rl.statel = lpad(cs.st_code,2,'0') AND rl.countyl = cs.co_code AND rl.cousubl = cs.cs_code)\r
- LEFT JOIN place_lookup pl ON (rl.statel = lpad(pl.st_code,2,'0') AND rl.placel = pl.pl_code)\r
- WHERE zipl IS NOT NULL\r
- UNION ALL\r
- SELECT\r
- zipr as zip,\r
- rl.stater as st_code,\r
- sl.abbrev as state,\r
- rl.countyr as co_code,\r
- cl.name as county,\r
- rl.cousubr as cs_code,\r
- cs.name as countysub,\r
- rl.placer as pl_code,\r
- pl.name as place\r
- FROM\r
- roads_local rl\r
- JOIN state_lookup sl ON (rl.stater = lpad(sl.st_code,2,'0'))\r
- LEFT JOIN county_lookup cl ON (rl.stater = lpad(cl.st_code,2,'0') AND rl.countyr = cl.co_code)\r
- LEFT JOIN countysub_lookup cs ON (rl.stater = lpad(cs.st_code,2,'0') AND rl.countyr = cs.co_code AND rl.cousubr = cs.cs_code)\r
- LEFT JOIN place_lookup pl ON (rl.stater = lpad(pl.st_code,2,'0') AND rl.placer = pl.pl_code)\r
- WHERE zipr IS NOT NULL\r
- ) as subquery\r
- GROUP BY zip, st_code, state, co_code, county, cs_code, countysub, pl_code, place;\r
-**/\r
-DROP TABLE IF EXISTS zip_lookup_base;\r
-CREATE TABLE zip_lookup_base (\r
- zip varchar(5),\r
- state VARCHAR(40),\r
- county VARCHAR(90),\r
- city VARCHAR(90),\r
- statefp varchar(2),\r
- PRIMARY KEY (zip)\r
-);\r
-\r
--- INSERT INTO zip_lookup_base\r
--- Populate through magic\r
--- If anyone knows of a good, public, free, place to pull this information from, that'd be awesome to have...\r
-\r
-DROP TABLE IF EXISTS zip_lookup;\r
-CREATE TABLE zip_lookup (\r
- zip INTEGER,\r
- st_code INTEGER,\r
- state VARCHAR(2),\r
- co_code INTEGER,\r
- county VARCHAR(90),\r
- cs_code INTEGER,\r
- cousub VARCHAR(90),\r
- pl_code INTEGER,\r
- place VARCHAR(90),\r
- cnt INTEGER,\r
- PRIMARY KEY (zip)\r
-);\r
-\r
-DROP TABLE IF EXISTS zcta500;\r
-CREATE TABLE zcta500\r
-(\r
- gid serial NOT NULL PRIMARY KEY,\r
- zcta5ce character varying(5),\r
- classfp character varying(2),\r
- mtfcc character varying(5),\r
- funcstat character varying(1),\r
- aland numeric(14),\r
- awater numeric(14),\r
- intptlat character varying(11),\r
- intptlon character varying(12),\r
- the_geom geometry,\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-/**\r
-INSERT INTO zip_lookup\r
- SELECT\r
- DISTINCT ON (zip)\r
- zip,\r
- st_code,\r
- state,\r
- co_code,\r
- county,\r
- cs_code,\r
- cousub,\r
- pl_code,\r
- place,\r
- cnt\r
- FROM zip_lookup_all\r
- ORDER BY zip,cnt desc;\r
- **/\r
-DROP TABLE IF EXISTS county;\r
-CREATE TABLE county\r
-(\r
- gid SERIAL NOT NULL,\r
- statefp character varying(2),\r
- countyfp character varying(3),\r
- countyns character varying(8),\r
- cntyidfp character varying(5) PRIMARY KEY NOT NULL,\r
- "name" character varying(100),\r
- namelsad character varying(100),\r
- lsad character varying(2),\r
- classfp character varying(2),\r
- mtfcc character varying(5),\r
- csafp character varying(3),\r
- cbsafp character varying(5),\r
- metdivfp character varying(5),\r
- funcstat character varying(1),\r
- aland bigint,\r
- awater double precision,\r
- intptlat character varying(11),\r
- intptlon character varying(12),\r
- the_geom geometry,\r
- CONSTRAINT uidx_county_gid UNIQUE (gid),\r
- CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-\r
-DROP TABLE IF EXISTS state;\r
-CREATE TABLE state\r
-(\r
- gid serial NOT NULL,\r
- region character varying(2),\r
- division character varying(2),\r
- statefp character varying(2),\r
- statens character varying(8),\r
- stusps character varying(2) NOT NULL,\r
- "name" character varying(100),\r
- lsad character varying(2),\r
- mtfcc character varying(5),\r
- funcstat character varying(1),\r
- aland bigint,\r
- awater bigint,\r
- intptlat character varying(11),\r
- intptlon character varying(12),\r
- the_geom geometry,\r
- CONSTRAINT state_pkey PRIMARY KEY (stusps),\r
- CONSTRAINT uidx_tiger_state_gid UNIQUE (gid),\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-\r
-DROP TABLE IF EXISTS place;\r
-CREATE TABLE place\r
-(\r
- gid serial NOT NULL,\r
- statefp character varying(2),\r
- placefp character varying(5),\r
- placens character varying(8),\r
- plcidfp character varying(7) PRIMARY KEY,\r
- "name" character varying(100),\r
- namelsad character varying(100),\r
- lsad character varying(2),\r
- classfp character varying(2),\r
- cpi character varying(1),\r
- pcicbsa character varying(1),\r
- pcinecta character varying(1),\r
- mtfcc character varying(5),\r
- funcstat character varying(1),\r
- aland bigint,\r
- awater bigint,\r
- intptlat character varying(11),\r
- intptlon character varying(12),\r
- the_geom geometry,\r
- CONSTRAINT uidx_tiger_place_gid UNIQUE (gid),\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-\r
-DROP TABLE IF EXISTS zip_state;\r
-CREATE TABLE zip_state\r
-(\r
- zip character varying(5) NOT NULL,\r
- stusps character varying(2) NOT NULL,\r
- statefp character varying(2),\r
- CONSTRAINT zip_state_pkey PRIMARY KEY (zip, stusps)\r
-);\r
-\r
-DROP TABLE IF EXISTS zip_state_loc;\r
-CREATE TABLE zip_state_loc\r
-(\r
- zip character varying(5) NOT NULL,\r
- stusps character varying(2) NOT NULL,\r
- statefp character varying(2),\r
- place varchar(100),\r
- CONSTRAINT zip_state_loc_pkey PRIMARY KEY (zip, stusps, place)\r
-);\r
-\r
-DROP TABLE IF EXISTS cousub;\r
-CREATE TABLE cousub\r
-(\r
- gid serial NOT NULL,\r
- statefp character varying(2),\r
- countyfp character varying(3),\r
- cousubfp character varying(5),\r
- cousubns character varying(8),\r
- cosbidfp character varying(10) NOT NULL PRIMARY KEY,\r
- "name" character varying(100),\r
- namelsad character varying(100),\r
- lsad character varying(2),\r
- classfp character varying(2),\r
- mtfcc character varying(5),\r
- cnectafp character varying(3),\r
- nectafp character varying(5),\r
- nctadvfp character varying(5),\r
- funcstat character varying(1),\r
- aland numeric(14),\r
- awater numeric(14),\r
- intptlat character varying(11),\r
- intptlon character varying(12),\r
- the_geom geometry,\r
- CONSTRAINT uidx_cousub_gid UNIQUE (gid),\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-\r
-CREATE INDEX tige_cousub_the_geom_gist ON cousub USING gist(the_geom);\r
-\r
-DROP TABLE IF EXISTS edges;\r
-CREATE TABLE edges\r
-(\r
- gid SERIAL NOT NULL PRIMARY KEY,\r
- statefp character varying(2),\r
- countyfp character varying(3),\r
- tlid numeric(10),\r
- tfidl numeric(10),\r
- tfidr numeric(10),\r
- mtfcc character varying(5),\r
- fullname character varying(100),\r
- smid character varying(22),\r
- lfromadd character varying(12),\r
- ltoadd character varying(12),\r
- rfromadd character varying(12),\r
- rtoadd character varying(12),\r
- zipl character varying(5),\r
- zipr character varying(5),\r
- featcat character varying(1),\r
- hydroflg character varying(1),\r
- railflg character varying(1),\r
- roadflg character varying(1),\r
- olfflg character varying(1),\r
- passflg character varying(1),\r
- divroad character varying(1),\r
- exttyp character varying(1),\r
- ttyp character varying(1),\r
- deckedroad character varying(1),\r
- artpath character varying(1),\r
- persist character varying(1),\r
- gcseflg character varying(1),\r
- offsetl character varying(1),\r
- offsetr character varying(1),\r
- tnidf numeric(10),\r
- tnidt numeric(10),\r
- the_geom geometry,\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTILINESTRING'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-CREATE INDEX idx_edges_tlid ON edges USING btree(tlid);\r
-\r
-DROP TABLE IF EXISTS faces;\r
-\r
-CREATE TABLE faces\r
-(\r
-gid serial NOT NULL PRIMARY KEY,\r
- tfid numeric(10,0),\r
- statefp00 varchar(2),\r
- countyfp00 varchar(3),\r
- tractce00 varchar(6),\r
- blkgrpce00 varchar(1),\r
- blockce00 varchar(4),\r
- cousubfp00 varchar(5),\r
- submcdfp00 varchar(5),\r
- conctyfp00 varchar(5),\r
- placefp00 varchar(5),\r
- aiannhfp00 varchar(5),\r
- aiannhce00 varchar(4),\r
- comptyp00 varchar(1),\r
- trsubfp00 varchar(5),\r
- trsubce00 varchar(3),\r
- anrcfp00 varchar(5),\r
- elsdlea00 varchar(5),\r
- scsdlea00 varchar(5),\r
- unsdlea00 varchar(5),\r
- uace00 varchar(5),\r
- cd108fp varchar(2),\r
- sldust00 varchar(3),\r
- sldlst00 varchar(3),\r
- vtdst00 varchar(6),\r
- zcta5ce00 varchar(5),\r
- tazce00 varchar(6),\r
- ugace00 varchar(5),\r
- puma5ce00 varchar(5),\r
- statefp varchar(2),\r
- countyfp varchar(3),\r
- tractce varchar(6),\r
- blkgrpce varchar(1),\r
- blockce varchar(4),\r
- cousubfp varchar(5),\r
- submcdfp varchar(5),\r
- conctyfp varchar(5),\r
- placefp varchar(5),\r
- aiannhfp varchar(5),\r
- aiannhce varchar(4),\r
- comptyp varchar(1),\r
- trsubfp varchar(5),\r
- trsubce varchar(3),\r
- anrcfp varchar(5),\r
- ttractce varchar(6),\r
- tblkgpce varchar(1),\r
- elsdlea varchar(5),\r
- scsdlea varchar(5),\r
- unsdlea varchar(5),\r
- uace varchar(5),\r
- cd111fp varchar(2),\r
- sldust varchar(3),\r
- sldlst varchar(3),\r
- vtdst varchar(6),\r
- zcta5ce varchar(5),\r
- tazce varchar(6),\r
- ugace varchar(5),\r
- puma5ce varchar(5),\r
- csafp varchar(3),\r
- cbsafp varchar(5),\r
- metdivfp varchar(5),\r
- cnectafp varchar(3),\r
- nectafp varchar(5),\r
- nctadvfp varchar(5),\r
- lwflag varchar(1),\r
- "offset" varchar(1),\r
- atotal double precision,\r
- intptlat varchar(11),\r
- intptlon varchar(12),\r
- the_geom geometry,\r
- CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),\r
- CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),\r
- CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)\r
-);\r
-CREATE INDEX idx_tiger_faces_tfid ON faces USING btree (tfid);\r
-\r
-\r
--- Index: tiger.faces_the_geom_gist\r
-\r
--- DROP INDEX tiger.faces_the_geom_gist;\r
-\r
-CREATE INDEX tiger_faces_the_geom_gist\r
- ON faces\r
- USING gist\r
- (the_geom);\r
-\r
-CREATE TABLE featnames\r
-(\r
- gid SERIAL NOT NULL,\r
- tlid bigint,\r
- fullname character varying(100),\r
- "name" character varying(100),\r
- predirabrv character varying(15),\r
- pretypabrv character varying(50),\r
- prequalabr character varying(15),\r
- sufdirabrv character varying(15),\r
- suftypabrv character varying(50),\r
- sufqualabr character varying(15),\r
- predir character varying(2),\r
- pretyp character varying(3),\r
- prequal character varying(2),\r
- sufdir character varying(2),\r
- suftyp character varying(3),\r
- sufqual character varying(2),\r
- linearid character varying(22),\r
- mtfcc character varying(5),\r
- paflag character varying(1),\r
- CONSTRAINT featnames_pkey PRIMARY KEY (gid)\r
-);\r
-ALTER TABLE featnames ADD COLUMN statefp character varying(2);\r
-CREATE INDEX idx_tiger_featnames_snd_name ON featnames USING btree (soundex(name));\r
-CREATE INDEX idx_tiger_featnames_lname ON featnames USING btree (lower(name));\r
-CREATE INDEX idx_tiger_featnames_tlid_statefp ON featnames USING btree (tlid,statefp);\r
-\r
-CREATE TABLE addr\r
-(\r
- gid SERIAL NOT NULL,\r
- tlid bigint,\r
- fromhn character varying(12),\r
- tohn character varying(12),\r
- side character varying(1),\r
- zip character varying(5),\r
- plus4 character varying(4),\r
- fromtyp character varying(1),\r
- totyp character varying(1),\r
- fromarmid integer,\r
- toarmid integer,\r
- arid character varying(22),\r
- mtfcc character varying(5),\r
- CONSTRAINT addr_pkey PRIMARY KEY (gid)\r
-);\r
-ALTER TABLE addr ADD COLUMN statefp character varying(2);\r
-\r
-CREATE INDEX idx_tiger_addr_tlid_statefp ON addr USING btree(tlid,statefp);\r
-CREATE INDEX idx_tiger_addr_zip ON addr USING btree (zip);\r
-\r
-\r
+--$Id$
+SET search_path TO tiger, public;
+-- Create direction lookup table
+DROP TABLE IF EXISTS direction_lookup;
+CREATE TABLE direction_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(3));
+INSERT INTO direction_lookup (name, abbrev) VALUES('WEST', 'W');
+INSERT INTO direction_lookup (name, abbrev) VALUES('W', 'W');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SW', 'SW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH-WEST', 'SW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTHWEST', 'SW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH-EAST', 'SE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTHEAST', 'SE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH_WEST', 'SW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH_EAST', 'SE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH', 'S');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH WEST', 'SW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SOUTH EAST', 'SE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('SE', 'SE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('S', 'S');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NW', 'NW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH-WEST', 'NW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTHWEST', 'NW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH-EAST', 'NE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTHEAST', 'NE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH_WEST', 'NW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH_EAST', 'NE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH', 'N');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH WEST', 'NW');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NORTH EAST', 'NE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('NE', 'NE');
+INSERT INTO direction_lookup (name, abbrev) VALUES('N', 'N');
+INSERT INTO direction_lookup (name, abbrev) VALUES('EAST', 'E');
+INSERT INTO direction_lookup (name, abbrev) VALUES('E', 'E');
+CREATE INDEX direction_lookup_abbrev_idx ON direction_lookup (abbrev);
+
+
+
+-- Create secondary unit lookup table
+DROP TABLE IF EXISTS secondary_unit_lookup;
+CREATE TABLE secondary_unit_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(5));
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('APARTMENT', 'APT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('APT', 'APT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BASEMENT', 'BSMT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BSMT', 'BSMT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BUILDING', 'BLDG');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('BLDG', 'BLDG');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('DEPARTMENT', 'DEPT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('DEPT', 'DEPT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FLOOR', 'FL');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FL', 'FL');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FRONT', 'FRNT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('FRNT', 'FRNT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('HANGAR', 'HNGR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('HNGR', 'HNGR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOBBY', 'LBBY');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LBBY', 'LBBY');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOT', 'LOT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOWER', 'LOWR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('LOWR', 'LOWR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('OFFICE', 'OFC');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('OFC', 'OFC');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PENTHOUSE', 'PH');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PH', 'PH');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('PIER', 'PIER');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('REAR', 'REAR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('ROOM', 'RM');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('RM', 'RM');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SIDE', 'SIDE');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SLIP', 'SLIP');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SPACE', 'SPC');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SPC', 'SPC');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('STOP', 'STOP');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('SUITE', 'STE');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('STE', 'STE');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('TRAILER', 'TRLR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('TRLR', 'TRLR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UNIT', 'UNIT');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UPPER', 'UPPR');
+INSERT INTO secondary_unit_lookup (name, abbrev) VALUES ('UPPR', 'UPPR');
+CREATE INDEX secondary_unit_lookup_abbrev_idx ON secondary_unit_lookup (abbrev);
+
+
+
+-- Create state lookup table
+DROP TABLE IF EXISTS state_lookup;
+CREATE TABLE state_lookup (st_code INTEGER PRIMARY KEY, name VARCHAR(40) UNIQUE, abbrev VARCHAR(3) UNIQUE);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Alabama', 'AL', '01');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Alaska', 'AK', '02');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('American Samoa', 'AS', -1);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Arizona', 'AZ', '04');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Arkansas', 'AR', '05');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('California', 'CA', '06');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Colorado', 'CO', '08');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Connecticut', 'CT', '09');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Delaware', 'DE', '10');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('District of Columbia', 'DC', '11');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Federated States of Micronesia', 'FM', -2);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Florida', 'FL', '12');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Georgia', 'GA', '13');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Guam', 'GU', -7);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Hawaii', 'HI', '15');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Idaho', 'ID', '16');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Illinois', 'IL', '17');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Indiana', 'IN', '18');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Iowa', 'IA', '19');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Kansas', 'KS', '20');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Kentucky', 'KY', '21');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Louisiana', 'LA', '22');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Maine', 'ME', '23');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Marshall Islands', 'MH', -3);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Maryland', 'MD', '24');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Massachusetts', 'MA', '25');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Michigan', 'MI', '26');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Minnesota', 'MN', '27');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Mississippi', 'MS', '28');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Missouri', 'MO', '29');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Montana', 'MT', '30');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Nebraska', 'NE', '31');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Nevada', 'NV', '32');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Hampshire', 'NH', '33');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Jersey', 'NJ', '34');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New Mexico', 'NM', '35');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('New York', 'NY', '36');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('North Carolina', 'NC', '37');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('North Dakota', 'ND', '38');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Northern Mariana Islands', 'MP', -4);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Ohio', 'OH', '39');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Oklahoma', 'OK', '40');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Oregon', 'OR', '41');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Palau', 'PW', -5);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Pennsylvania', 'PA', '42');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Puerto Rico', 'PR', '72');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Rhode Island', 'RI', '44');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('South Carolina', 'SC', '45');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('South Dakota', 'SD', '46');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Tennessee', 'TN', '47');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Texas', 'TX', '48');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Utah', 'UT', '49');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Vermont', 'VT', '50');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Virgin Islands', 'VI', -6);
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Virginia', 'VA', '51');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Washington', 'WA', '53');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('West Virginia', 'WV', '54');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Wisconsin', 'WI', '55');
+INSERT INTO state_lookup (name, abbrev, st_code) VALUES ('Wyoming', 'WY', '56');
+
+
+-- Create street type lookup table
+DROP TABLE IF EXISTS street_type_lookup;
+CREATE TABLE street_type_lookup (name VARCHAR(20) PRIMARY KEY, abbrev VARCHAR(4));
+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');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ALY', 'Aly');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANEX', 'Anx');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANNEX', 'Anx');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANNX', 'Anx');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ANX', 'Anx');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ARC', 'Arc');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ARCADE', 'Arc');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AV', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVE', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVEN', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVENU', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVENUE', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVN', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('AVNUE', 'Ave');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BAYOO', 'Byu');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BAYOU', 'Byu');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BCH', 'Bch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BEACH', 'Bch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BEND', 'Bnd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BND', 'Bnd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLF', 'Blf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUF', 'Blf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUFF', 'Blf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLUFFS', 'Blfs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOT', 'Btm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOTTM', 'Btm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOTTOM', 'Btm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BTM', 'Btm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLVD', 'Blvd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOUL', 'Blvd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOULEVARD', 'Blvd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BOULV', 'Blvd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BR', 'Br');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRANCH', 'Br');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRNCH', 'Br');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRDGE', 'Brg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRG', 'Brg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRIDGE', 'Brg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRK', 'Brk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BROOK', 'Brk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BROOKS', 'Brks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BURG', 'Bg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BURGS', 'Bgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYP', 'Byp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPA', 'Byp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPAS', 'Byp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPASS', 'ByP');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYPS', 'Byp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAMP', 'Cp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CMP', 'Cp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CP', 'Cp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CANYN', 'Cyn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CANYON', 'Cyn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNYN', 'Cyn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CYN', 'Cyn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAPE', 'Cpe');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CPE', 'Cpe');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAUSEWAY', 'Cswy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CAUSWAY', 'Cswy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CSWY', 'Cswy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CEN', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENT', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTER', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTR', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTRE', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNTER', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CNTR', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTR', 'Ctr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CENTERS', 'Ctrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIR', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRC', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCL', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCLE', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRCL', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRCLE', 'Cir');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRCLES', 'Cirs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLF', 'Clf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLIFF', 'Clf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLFS', 'Clfs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLIFFS', 'Clfs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLB', 'Clb');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CLUB', 'Clb');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COMMON', 'Cmn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COR', 'Cor');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORNER', 'Cor');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORNERS', 'Cors');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CORS', 'Cors');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURSE', 'Crse');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSE', 'Crse');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURT', 'Ct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRT', 'Ct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CT', 'Ct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COURTS', 'Cts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COVE', 'Cv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CV', 'Cv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('COVES', 'Cvs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CK', 'Crk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CR', 'Crk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CREEK', 'Crk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRK', 'Crk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRECENT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRES', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRESCENT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRESENT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSCNT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSENT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSNT', 'Cres');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CREST', 'Crst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CROSSING', 'Xing');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSSING', 'Xing');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRSSNG', 'Xing');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('XING', 'Xing');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CROSSROAD', 'Xrd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CURVE', 'Curv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DALE', 'Dl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DL', 'Dl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DAM', 'Dm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DM', 'Dm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DIV', 'Dv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DIVIDE', 'Dv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DV', 'Dv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DVD', 'Dv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DR', 'Dr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIV', 'Dr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIVE', 'Dr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRV', 'Dr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRIVES', 'Drs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EST', 'Est');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTATE', 'Est');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTATES', 'Ests');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ESTS', 'Ests');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXP', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPR', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPRESS', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPRESSWAY', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPW', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXPY', 'Expy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXT', 'Ext');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTENSION', 'Ext');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTN', 'Ext');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTNSN', 'Ext');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTENSIONS', 'Exts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('EXTS', 'Exts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FALL', 'Fall');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FALLS', 'Fls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLS', 'Fls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FERRY', 'Fry');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRRY', 'Fry');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRY', 'Fry');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FIELD', 'Fld');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLD', 'Fld');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FIELDS', 'Flds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLDS', 'Flds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLAT', 'Flt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLT', 'Flt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLATS', 'Flts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FLTS', 'Flts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORD', 'Frd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRD', 'Frd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORDS', 'Frds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FOREST', 'Frst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORESTS', 'Frst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRST', 'Frst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORG', 'Frg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORGE', 'Frg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRG', 'Frg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORGES', 'Frgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORK', 'Frk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRK', 'Frk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FORKS', 'Frks');
+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');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDEN', 'Gdn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDN', 'Gdn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GARDENS', 'Gdns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GDNS', 'Gdns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRDNS', 'Gdns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATEWAY', 'Gtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATEWY', 'Gtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GATWAY', 'Gtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GTWAY', 'Gtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GTWY', 'Gtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLEN', 'Gln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLN', 'Gln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLENS', 'Glns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GREEN', 'Grn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRN', 'Grn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GREENS', 'Grns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROV', 'Grv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROVE', 'Grv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRV', 'Grv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GROVES', 'Grvs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARB', 'Hbr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBOR', 'Hbr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBR', 'Hbr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HBR', 'Hbr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HRBOR', 'Hbr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HARBORS', 'Hbrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HAVEN', 'Hvn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HAVN', 'Hvn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HVN', 'Hvn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HEIGHT', 'Hts');
+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');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HLS', 'Hls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HLLW', 'Holw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLLOW', 'Holw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLLOWS', 'Holw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLW', 'Holw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HOLWS', 'Holw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('INLET', 'Inlt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('INLT', 'Inlt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('IS', 'Is');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLAND', 'Is');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLND', 'Is');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLANDS', 'Iss');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLNDS', 'Iss');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISS', 'Iss');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLE', 'Isle');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ISLES', 'Isle');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCT', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTION', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTN', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTION', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTN', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTON', 'Jct');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTNS', 'Jcts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JCTS', 'Jcts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('JUNCTIONS', 'Jcts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KEY', 'Ky');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KY', 'Ky');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KEYS', 'Kys');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KYS', 'Kys');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNL', 'Knl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOL', 'Knl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOLL', 'Knl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNLS', 'Knls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('KNOLLS', 'Knls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAKE', 'Lk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LK', 'Lk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAKES', 'Lks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LKS', 'Lks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LAND', 'Land');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANDING', 'Lndg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LNDG', 'Lndg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LNDNG', 'Lndg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LA', 'Ln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANE', 'Ln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LANES', 'Ln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LN', 'Ln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LGT', 'Lgt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LIGHT', 'Lgt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LIGHTS', 'Lgts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LF', 'Lf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOAF', 'Lf');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LCK', 'Lck');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOCK', 'Lck');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LCKS', 'Lcks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOCKS', 'Lcks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LDG', 'Ldg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LDGE', 'Ldg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LODG', 'Ldg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LODGE', 'Ldg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOOP', 'Loop');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LOOPS', 'Loop');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MALL', 'Mall');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MANOR', 'Mnr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNR', 'Mnr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MANORS', 'Mnrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNRS', 'Mnrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MDW', 'Mdw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEADOW', 'Mdw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MDWS', 'Mdws');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEADOWS', 'Mdws');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEDOWS', 'Mdws');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MEWS', 'Mews');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MILL', 'Ml');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ML', 'Ml');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MILLS', 'Mls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MLS', 'Mls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MISSION', 'Msn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MISSN', 'Msn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MSN', 'Msn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MSSN', 'Msn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOTORWAY', 'Mtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNT', 'Mt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNT', 'Mt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MT', 'Mt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTAIN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTAIN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTIN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTIN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTN', 'Mtn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MNTNS', 'Mtns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MOUNTAINS', 'Mtns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('NCK', 'Nck');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('NECK', 'Nck');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCH', 'Orch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCHARD', 'Orch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ORCHRD', 'Orch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVAL', 'Oval');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVL', 'Oval');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('OVERPASS', 'Opas');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARK', 'Park');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PK', 'Park');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRK', 'Park');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKS', 'Park');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWAY', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWY', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWAY', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWY', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKY', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PARKWAYS', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PKWYS', 'Pkwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PASS', 'Pass');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PASSAGE', 'Psge');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PATH', 'Path');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PATHS', 'Path');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PIKE', 'Pike');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PIKES', 'Pike');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PINE', 'Pne');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PINES', 'Pnes');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PNES', 'Pnes');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PL', 'Pl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLACE', 'Pl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAIN', 'Pln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLN', 'Pln');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAINES', 'Plns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAINS', 'Plns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLNS', 'Plns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLAZA', 'Plz');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLZ', 'Plz');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PLZA', 'Plz');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('POINT', 'Pt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PT', 'Pt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('POINTS', 'Pts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PTS', 'Pts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PORT', 'Prt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRT', 'Prt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PORTS', 'Prts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRTS', 'Prts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PR', 'Pr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRAIRIE', 'Pr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRARIE', 'Pr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PRR', 'Pr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAD', 'Radl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADIAL', 'Radl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADIEL', 'Radl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RADL', 'Radl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAMP', 'Ramp');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RANCH', 'Rnch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RANCHES', 'Rnch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RNCH', 'Rnch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RNCHS', 'Rnch');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAPID', 'Rpd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RPD', 'Rpd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RAPIDS', 'Rpds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RPDS', 'Rpds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('REST', 'Rst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RST', 'Rst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDG', 'Rdg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDGE', 'Rdg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIDGE', 'Rdg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RDGS', 'Rdgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIDGES', 'Rdgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIV', 'Riv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIVER', 'Riv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RIVR', 'Riv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RVR', 'Riv');
+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');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHL', 'Shl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOAL', 'Shl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHLS', 'Shls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOALS', 'Shls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOAR', 'Shr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHORE', 'Shr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHR', 'Shr');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHOARS', 'Shrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHORES', 'Shrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SHRS', 'Shrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SKYWAY', 'Skwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPG', 'Spg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPNG', 'Spg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRING', 'Spg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRNG', 'Spg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPGS', 'Spgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPNGS', 'Spgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRINGS', 'Spgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPRNGS', 'Spgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPUR', 'Spur');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SPURS', 'Spur');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQ', 'Sq');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQR', 'Sq');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQRE', 'Sq');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQU', 'Sq');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQUARE', 'Sq');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQRS', 'Sqs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQUARES', 'Sqs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STA', 'Sta');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STATION', 'Sta');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STATN', 'Sta');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STN', 'Sta');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRA', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAV', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVE', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVEN', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVENUE', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRAVN', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRVN', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRVNUE', 'Stra');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREAM', 'Strm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREME', 'Strm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRM', 'Strm');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('ST', 'St');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STR', 'St');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREET', 'St');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STRT', 'St');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STREETS', 'Sts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SMT', 'Smt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMIT', 'Smt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMITT', 'Smt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SUMMIT', 'Smt');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TER', 'Ter');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TERR', 'Ter');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TERRACE', 'Ter');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('THROUGHWAY', 'Trwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACE', 'Trce');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACES', 'Trce');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRCE', 'Trce');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACK', 'Trak');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRACKS', 'Trak');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAK', 'Trak');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRK', 'Trak');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRKS', 'Trak');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAFFICWAY', 'Trfy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRFY', 'Trfy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TR', 'Trl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAIL', 'Trl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRAILS', 'Trl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRL', 'Trl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRLS', 'Trl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNEL', 'Tunl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TUNL', 'Tunl');
+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');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('UNIONS', 'Uns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLEY', 'Vly');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLY', 'Vly');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLLY', 'Vly');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLY', 'Vly');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VALLEYS', 'Vlys');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLYS', 'Vlys');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VDCT', 'Via');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIA', 'Via');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIADCT', 'Via');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIADUCT', 'Via');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIEW', 'Vw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VW', 'Vw');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIEWS', 'Vws');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VWS', 'Vws');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILL', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAG', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAGE', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLG', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLIAGE', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLG', 'Vlg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLAGES', 'Vlgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VLGS', 'Vlgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VILLE', 'Vl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VL', 'Vl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIS', 'Vis');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VIST', 'Vis');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VISTA', 'Vis');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VST', 'Vis');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('VSTA', 'Vis');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALK', 'Walk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALKS', 'Walk');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WALL', 'Wall');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WAY', 'Way');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WY', 'Way');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WAYS', 'Ways');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WELL', 'Wl');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WELLS', 'Wls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('WLS', 'Wls');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BYU', 'Byu');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BLFS', 'Blfs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BRKS', 'Brks');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BG', 'Bg');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('BGS', 'Bgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTRS', 'Ctrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CIRS', 'Cirs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CMN', 'Cmn');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CTS', 'Cts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CVS', 'Cvs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CRST', 'Crst');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('XRD', 'Xrd');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('CURV', 'Curv');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('DRS', 'Drs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRDS', 'Frds');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('FRGS', 'Frgs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GLNS', 'Glns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRNS', 'Grns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('GRVS', 'Grvs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('HBRS', 'Hbrs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('LGTS', 'Lgts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTWY', 'Mtwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('MTNS', 'Mtns');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('OPAS', 'Opas');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PSGE', 'Psge');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('PNE', 'Pne');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('RTE', 'Rte');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SKWY', 'Skwy');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('SQS', 'Sqs');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('STS', 'Sts');
+INSERT INTO street_type_lookup (name, abbrev) VALUES ('TRWY', 'Trwy');
+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');
+CREATE INDEX street_type_lookup_abbrev_idx ON street_type_lookup (abbrev);
+
+-- Create place and countysub lookup tables
+DROP TABLE IF EXISTS place_lookup;
+CREATE TABLE place_lookup (
+ st_code INTEGER,
+ state VARCHAR(2),
+ pl_code INTEGER,
+ name VARCHAR(90),
+ PRIMARY KEY (st_code,pl_code)
+);
+
+/**
+INSERT INTO place_lookup
+ SELECT
+ pl.state::integer as st_code,
+ sl.abbrev as state,
+ pl.placefp::integer as pl_code,
+ pl.name as name
+ FROM
+ pl99_d00 pl
+ JOIN state_lookup sl ON (pl.state = lpad(sl.st_code,2,'0'))
+ GROUP BY pl.state, sl.abbrev, pl.placefp, pl.name;
+**/
+CREATE INDEX place_lookup_name_idx ON place_lookup (soundex(name));
+CREATE INDEX place_lookup_state_idx ON place_lookup (state);
+
+DROP TABLE IF EXISTS county_lookup;
+CREATE TABLE county_lookup (
+ st_code INTEGER,
+ state VARCHAR(2),
+ co_code INTEGER,
+ name VARCHAR(90),
+ PRIMARY KEY (st_code, co_code)
+);
+
+/**
+INSERT INTO county_lookup
+ SELECT
+ co.state::integer as st_code,
+ sl.abbrev as state,
+ co.county::integer as co_code,
+ co.name as name
+ FROM
+ co99_d00 co
+ JOIN state_lookup sl ON (co.state = lpad(sl.st_code,2,'0'))
+ GROUP BY co.state, sl.abbrev, co.county, co.name;
+**/
+CREATE INDEX county_lookup_name_idx ON county_lookup (soundex(name));
+CREATE INDEX county_lookup_state_idx ON county_lookup (state);
+
+DROP TABLE IF EXISTS countysub_lookup;
+CREATE TABLE countysub_lookup (
+ st_code INTEGER,
+ state VARCHAR(2),
+ co_code INTEGER,
+ county VARCHAR(90),
+ cs_code INTEGER,
+ name VARCHAR(90),
+ PRIMARY KEY (st_code, co_code, cs_code)
+);
+
+/**
+INSERT INTO countysub_lookup
+ SELECT
+ cs.state::integer as st_code,
+ sl.abbrev as state,
+ cs.county::integer as co_code,
+ cl.name as county,
+ cs.cousubfp::integer as cs_code,
+ cs.name as name
+ FROM
+ cs99_d00 cs
+ JOIN state_lookup sl ON (cs.state = lpad(sl.st_code,2,'0'))
+ JOIN county_lookup cl ON (cs.state = lpad(cl.st_code,2,'0') AND cs.county = cl.co_code)
+ GROUP BY cs.state, sl.abbrev, cs.county, cl.name, cs.cousubfp, cs.name;
+**/
+CREATE INDEX countysub_lookup_name_idx ON countysub_lookup (soundex(name));
+CREATE INDEX countysub_lookup_state_idx ON countysub_lookup (state);
+
+DROP TABLE IF EXISTS zip_lookup_all;
+CREATE TABLE zip_lookup_all (
+ zip INTEGER,
+ st_code INTEGER,
+ state VARCHAR(2),
+ co_code INTEGER,
+ county VARCHAR(90),
+ cs_code INTEGER,
+ cousub VARCHAR(90),
+ pl_code INTEGER,
+ place VARCHAR(90),
+ cnt INTEGER
+);
+
+/** SET work_mem = '2GB';
+
+INSERT INTO zip_lookup_all
+ SELECT *,count(*) as cnt FROM
+ (SELECT
+ zipl as zip,
+ rl.statel as st_code,
+ sl.abbrev as state,
+ rl.countyl as co_code,
+ cl.name as county,
+ rl.cousubl as cs_code,
+ cs.name as countysub,
+ rl.placel as pl_code,
+ pl.name as place
+ FROM
+ roads_local rl
+ JOIN state_lookup sl ON (rl.statel = lpad(sl.st_code,2,'0'))
+ LEFT JOIN county_lookup cl ON (rl.statel = lpad(cl.st_code,2,'0') AND rl.countyl = cl.co_code)
+ LEFT JOIN countysub_lookup cs ON (rl.statel = lpad(cs.st_code,2,'0') AND rl.countyl = cs.co_code AND rl.cousubl = cs.cs_code)
+ LEFT JOIN place_lookup pl ON (rl.statel = lpad(pl.st_code,2,'0') AND rl.placel = pl.pl_code)
+ WHERE zipl IS NOT NULL
+ UNION ALL
+ SELECT
+ zipr as zip,
+ rl.stater as st_code,
+ sl.abbrev as state,
+ rl.countyr as co_code,
+ cl.name as county,
+ rl.cousubr as cs_code,
+ cs.name as countysub,
+ rl.placer as pl_code,
+ pl.name as place
+ FROM
+ roads_local rl
+ JOIN state_lookup sl ON (rl.stater = lpad(sl.st_code,2,'0'))
+ LEFT JOIN county_lookup cl ON (rl.stater = lpad(cl.st_code,2,'0') AND rl.countyr = cl.co_code)
+ LEFT JOIN countysub_lookup cs ON (rl.stater = lpad(cs.st_code,2,'0') AND rl.countyr = cs.co_code AND rl.cousubr = cs.cs_code)
+ LEFT JOIN place_lookup pl ON (rl.stater = lpad(pl.st_code,2,'0') AND rl.placer = pl.pl_code)
+ WHERE zipr IS NOT NULL
+ ) as subquery
+ GROUP BY zip, st_code, state, co_code, county, cs_code, countysub, pl_code, place;
+**/
+DROP TABLE IF EXISTS zip_lookup_base;
+CREATE TABLE zip_lookup_base (
+ zip varchar(5),
+ state VARCHAR(40),
+ county VARCHAR(90),
+ city VARCHAR(90),
+ statefp varchar(2),
+ PRIMARY KEY (zip)
+);
+
+-- INSERT INTO zip_lookup_base
+-- Populate through magic
+-- If anyone knows of a good, public, free, place to pull this information from, that'd be awesome to have...
+
+DROP TABLE IF EXISTS zip_lookup;
+CREATE TABLE zip_lookup (
+ zip INTEGER,
+ st_code INTEGER,
+ state VARCHAR(2),
+ co_code INTEGER,
+ county VARCHAR(90),
+ cs_code INTEGER,
+ cousub VARCHAR(90),
+ pl_code INTEGER,
+ place VARCHAR(90),
+ cnt INTEGER,
+ PRIMARY KEY (zip)
+);
+
+DROP TABLE IF EXISTS zcta500;
+CREATE TABLE zcta500
+(
+ gid serial NOT NULL PRIMARY KEY,
+ zcta5ce character varying(5),
+ classfp character varying(2),
+ mtfcc character varying(5),
+ funcstat character varying(1),
+ aland numeric(14),
+ awater numeric(14),
+ intptlat character varying(11),
+ intptlon character varying(12),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+/**
+INSERT INTO zip_lookup
+ SELECT
+ DISTINCT ON (zip)
+ zip,
+ st_code,
+ state,
+ co_code,
+ county,
+ cs_code,
+ cousub,
+ pl_code,
+ place,
+ cnt
+ FROM zip_lookup_all
+ ORDER BY zip,cnt desc;
+ **/
+DROP TABLE IF EXISTS county;
+CREATE TABLE county
+(
+ gid SERIAL NOT NULL,
+ statefp character varying(2),
+ countyfp character varying(3),
+ countyns character varying(8),
+ cntyidfp character varying(5) PRIMARY KEY NOT NULL,
+ "name" character varying(100),
+ namelsad character varying(100),
+ lsad character varying(2),
+ classfp character varying(2),
+ mtfcc character varying(5),
+ csafp character varying(3),
+ cbsafp character varying(5),
+ metdivfp character varying(5),
+ funcstat character varying(1),
+ aland bigint,
+ awater double precision,
+ intptlat character varying(11),
+ intptlon character varying(12),
+ the_geom geometry,
+ CONSTRAINT uidx_county_gid UNIQUE (gid),
+ CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)
+);
+
+DROP TABLE IF EXISTS state;
+CREATE TABLE state
+(
+ gid serial NOT NULL,
+ region character varying(2),
+ division character varying(2),
+ statefp character varying(2),
+ statens character varying(8),
+ stusps character varying(2) NOT NULL,
+ "name" character varying(100),
+ lsad character varying(2),
+ mtfcc character varying(5),
+ funcstat character varying(1),
+ aland bigint,
+ awater bigint,
+ intptlat character varying(11),
+ intptlon character varying(12),
+ the_geom geometry,
+ CONSTRAINT state_pkey PRIMARY KEY (stusps),
+ CONSTRAINT uidx_tiger_state_gid UNIQUE (gid),
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+
+DROP TABLE IF EXISTS place;
+CREATE TABLE place
+(
+ gid serial NOT NULL,
+ statefp character varying(2),
+ placefp character varying(5),
+ placens character varying(8),
+ plcidfp character varying(7) PRIMARY KEY,
+ "name" character varying(100),
+ namelsad character varying(100),
+ lsad character varying(2),
+ classfp character varying(2),
+ cpi character varying(1),
+ pcicbsa character varying(1),
+ pcinecta character varying(1),
+ mtfcc character varying(5),
+ funcstat character varying(1),
+ aland bigint,
+ awater bigint,
+ intptlat character varying(11),
+ intptlon character varying(12),
+ the_geom geometry,
+ CONSTRAINT uidx_tiger_place_gid UNIQUE (gid),
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+
+DROP TABLE IF EXISTS zip_state;
+CREATE TABLE zip_state
+(
+ zip character varying(5) NOT NULL,
+ stusps character varying(2) NOT NULL,
+ statefp character varying(2),
+ CONSTRAINT zip_state_pkey PRIMARY KEY (zip, stusps)
+);
+
+DROP TABLE IF EXISTS zip_state_loc;
+CREATE TABLE zip_state_loc
+(
+ zip character varying(5) NOT NULL,
+ stusps character varying(2) NOT NULL,
+ statefp character varying(2),
+ place varchar(100),
+ CONSTRAINT zip_state_loc_pkey PRIMARY KEY (zip, stusps, place)
+);
+
+DROP TABLE IF EXISTS cousub;
+CREATE TABLE cousub
+(
+ gid serial NOT NULL,
+ statefp character varying(2),
+ countyfp character varying(3),
+ cousubfp character varying(5),
+ cousubns character varying(8),
+ cosbidfp character varying(10) NOT NULL PRIMARY KEY,
+ "name" character varying(100),
+ namelsad character varying(100),
+ lsad character varying(2),
+ classfp character varying(2),
+ mtfcc character varying(5),
+ cnectafp character varying(3),
+ nectafp character varying(5),
+ nctadvfp character varying(5),
+ funcstat character varying(1),
+ aland numeric(14),
+ awater numeric(14),
+ intptlat character varying(11),
+ intptlon character varying(12),
+ the_geom geometry,
+ CONSTRAINT uidx_cousub_gid UNIQUE (gid),
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+
+CREATE INDEX tige_cousub_the_geom_gist ON cousub USING gist(the_geom);
+
+DROP TABLE IF EXISTS edges;
+CREATE TABLE edges
+(
+ gid SERIAL NOT NULL PRIMARY KEY,
+ statefp character varying(2),
+ countyfp character varying(3),
+ tlid numeric(10),
+ tfidl numeric(10),
+ tfidr numeric(10),
+ mtfcc character varying(5),
+ fullname character varying(100),
+ smid character varying(22),
+ lfromadd character varying(12),
+ ltoadd character varying(12),
+ rfromadd character varying(12),
+ rtoadd character varying(12),
+ zipl character varying(5),
+ zipr character varying(5),
+ featcat character varying(1),
+ hydroflg character varying(1),
+ railflg character varying(1),
+ roadflg character varying(1),
+ olfflg character varying(1),
+ passflg character varying(1),
+ divroad character varying(1),
+ exttyp character varying(1),
+ ttyp character varying(1),
+ deckedroad character varying(1),
+ artpath character varying(1),
+ persist character varying(1),
+ gcseflg character varying(1),
+ offsetl character varying(1),
+ offsetr character varying(1),
+ tnidf numeric(10),
+ tnidt numeric(10),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTILINESTRING'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+CREATE INDEX idx_edges_tlid ON edges USING btree(tlid);
+
+DROP TABLE IF EXISTS faces;
+
+CREATE TABLE faces
+(
+gid serial NOT NULL PRIMARY KEY,
+ tfid numeric(10,0),
+ statefp00 varchar(2),
+ countyfp00 varchar(3),
+ tractce00 varchar(6),
+ blkgrpce00 varchar(1),
+ blockce00 varchar(4),
+ cousubfp00 varchar(5),
+ submcdfp00 varchar(5),
+ conctyfp00 varchar(5),
+ placefp00 varchar(5),
+ aiannhfp00 varchar(5),
+ aiannhce00 varchar(4),
+ comptyp00 varchar(1),
+ trsubfp00 varchar(5),
+ trsubce00 varchar(3),
+ anrcfp00 varchar(5),
+ elsdlea00 varchar(5),
+ scsdlea00 varchar(5),
+ unsdlea00 varchar(5),
+ uace00 varchar(5),
+ cd108fp varchar(2),
+ sldust00 varchar(3),
+ sldlst00 varchar(3),
+ vtdst00 varchar(6),
+ zcta5ce00 varchar(5),
+ tazce00 varchar(6),
+ ugace00 varchar(5),
+ puma5ce00 varchar(5),
+ statefp varchar(2),
+ countyfp varchar(3),
+ tractce varchar(6),
+ blkgrpce varchar(1),
+ blockce varchar(4),
+ cousubfp varchar(5),
+ submcdfp varchar(5),
+ conctyfp varchar(5),
+ placefp varchar(5),
+ aiannhfp varchar(5),
+ aiannhce varchar(4),
+ comptyp varchar(1),
+ trsubfp varchar(5),
+ trsubce varchar(3),
+ anrcfp varchar(5),
+ ttractce varchar(6),
+ tblkgpce varchar(1),
+ elsdlea varchar(5),
+ scsdlea varchar(5),
+ unsdlea varchar(5),
+ uace varchar(5),
+ cd111fp varchar(2),
+ sldust varchar(3),
+ sldlst varchar(3),
+ vtdst varchar(6),
+ zcta5ce varchar(5),
+ tazce varchar(6),
+ ugace varchar(5),
+ puma5ce varchar(5),
+ csafp varchar(3),
+ cbsafp varchar(5),
+ metdivfp varchar(5),
+ cnectafp varchar(3),
+ nectafp varchar(5),
+ nctadvfp varchar(5),
+ lwflag varchar(1),
+ "offset" varchar(1),
+ atotal double precision,
+ intptlat varchar(11),
+ intptlon varchar(12),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_the_geom CHECK (st_ndims(the_geom) = 2),
+ CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
+ CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
+);
+CREATE INDEX idx_tiger_faces_tfid ON faces USING btree (tfid);
+
+
+-- Index: tiger.faces_the_geom_gist
+
+-- DROP INDEX tiger.faces_the_geom_gist;
+
+CREATE INDEX tiger_faces_the_geom_gist
+ ON faces
+ USING gist
+ (the_geom);
+
+CREATE TABLE featnames
+(
+ gid SERIAL NOT NULL,
+ tlid bigint,
+ fullname character varying(100),
+ "name" character varying(100),
+ predirabrv character varying(15),
+ pretypabrv character varying(50),
+ prequalabr character varying(15),
+ sufdirabrv character varying(15),
+ suftypabrv character varying(50),
+ sufqualabr character varying(15),
+ predir character varying(2),
+ pretyp character varying(3),
+ prequal character varying(2),
+ sufdir character varying(2),
+ suftyp character varying(3),
+ sufqual character varying(2),
+ linearid character varying(22),
+ mtfcc character varying(5),
+ paflag character varying(1),
+ CONSTRAINT featnames_pkey PRIMARY KEY (gid)
+);
+ALTER TABLE featnames ADD COLUMN statefp character varying(2);
+CREATE INDEX idx_tiger_featnames_snd_name ON featnames USING btree (soundex(name));
+CREATE INDEX idx_tiger_featnames_lname ON featnames USING btree (lower(name));
+CREATE INDEX idx_tiger_featnames_tlid_statefp ON featnames USING btree (tlid,statefp);
+
+CREATE TABLE addr
+(
+ gid SERIAL NOT NULL,
+ tlid bigint,
+ fromhn character varying(12),
+ tohn character varying(12),
+ side character varying(1),
+ zip character varying(5),
+ plus4 character varying(4),
+ fromtyp character varying(1),
+ totyp character varying(1),
+ fromarmid integer,
+ toarmid integer,
+ arid character varying(22),
+ mtfcc character varying(5),
+ CONSTRAINT addr_pkey PRIMARY KEY (gid)
+);
+ALTER TABLE addr ADD COLUMN statefp character varying(2);
+
+CREATE INDEX idx_tiger_addr_tlid_statefp ON addr USING btree(tlid,statefp);
+CREATE INDEX idx_tiger_addr_zip ON addr USING btree (zip);
+
+