ELSIF tempInt > 1 THEN
tempInt := 0;
-- the last matching abbrev in the string is the most likely one
- FOR rec IN SELECT abbrev, substring(fullStreet, '(?i)' || ws || '?('
- || name || ')(?:' || ws || '|$)') AS given, is_hw FROM street_type_lookup
+ FOR rec IN SELECT * FROM
+ (SELECT abbrev, substring(fullStreet, '(?i)' || ws || '?('
+ || name || ')(?:' || ws || '|$)') AS given, is_hw ,
+ ROW_NUMBER() OVER( ORDER BY position(name IN trim(fullStreet)) ) As n_type,
+ ROW_NUMBER() OVER() As nrecs
+ FROM street_type_lookup
WHERE fullStreet ILIKE '%' || name || '%' AND
trim(upper(fullStreet)) != name AND
texticregexeq(fullStreet, '(?i)' || ws || '(' || name
-- we only consider street types that are regular and not at beginning of name or are highways (since those can be at beg or end)
-- we take the one that is the longest e.g Country Road would be more correct than Road
- || ')(?:' || ws || '|$)') AND ((NOT is_hw AND position(name IN trim(fullStreet)) > 2) OR is_hw) ORDER BY length(name) DESC LIMIT 1 LOOP
+ || ')(?:' || ws || '|$)') AND ((NOT is_hw AND position(name IN trim(fullStreet)) > 2) OR is_hw) ) As foo
+ -- If it's a highway, we want the first highway that is street type
+ -- if its a regular, we want the last type in string, if tie, just return the longest
+ ORDER BY CASE WHEN is_hw THEN (nrecs - n_type) ELSE n_type END DESC, length(given) DESC LIMIT 1 LOOP
-- If we have found an internal address, make sure the type
-- precedes it.
/** TODO: I don't think we need a loop anymore since we are just returning one and the one in the last position
-- Street that has same name as type --
SELECT '#1076h' As ticket, * FROM normalize_address('4533 PARK AVE S, MINNEAPOLIS, MN 55407');
-
-- same street with alternate county name
SELECT '#1076i' As ticket, * FROM normalize_address('4533 County Road 33, MINNEAPOLIS, MN 55407');
-- this failed --
SELECT '#1109b' As ticket, * from normalize_address('4373 LAKE DR, ROBBINSDALE, MN 55422');
--- this failed
-SELECT '#1109b' As ticket, * from normalize_address('4373 LAKE DR, ROBBINSDALE, MN 55422');
+-- another type (Is) that is part of street name but a compound street name
+SELECT '#1074a' As ticket, * fROM normalize_address('3420 RHODE ISLAND AVE S, ST. LOUIS PARK, MN 55426');
\timing