+-- helper function to determine if street type
+-- should be put before or after the street name
+-- note in streettype lookup this is misnamed as is_hw
+-- because I originally thought only highways had that behavior
+-- it applies to foreign influenced roads like Camino (for road)
+CREATE OR REPLACE FUNCTION is_pretype(text) RETURNS boolean AS
+$$
+ SELECT EXISTS(SELECT name FROM street_type_lookup WHERE name = upper($1) AND is_hw );
+$$
+LANGUAGE sql IMMUTABLE STRICT; /** I know this should be stable but it's practically immutable :) **/
+
CREATE OR REPLACE FUNCTION pprint_addy(
input NORM_ADDY
) RETURNS VARCHAR
END IF;
result := cull_null(input.address::text)
- || CASE WHEN input.preDirAbbrev IS NOT NULL THEN ' ' ELSE '' END
- || cull_null(input.preDirAbbrev)
- || CASE WHEN input.streetName IS NOT NULL THEN ' ' ELSE '' END
- || cull_null(input.streetName)
- || CASE WHEN input.streetTypeAbbrev IS NOT NULL THEN ' ' ELSE '' END
- || cull_null(input.streetTypeAbbrev)
- || CASE WHEN input.postDirAbbrev IS NOT NULL THEN ' ' ELSE '' END
- || cull_null(input.postDirAbbrev)
+ || COALESCE(' ' || input.preDirAbbrev, '')
+ || CASE WHEN is_pretype(input.streetTypeAbbrev) THEN ' ' || input.streetTypeAbbrev ELSE '' END
+ || COALESCE(' ' || input.streetName, '')
+ || CASE WHEN NOT is_pretype(input.streetTypeAbbrev) THEN ' ' || input.streetTypeAbbrev ELSE '' END
+ || COALESCE(' ' || input.postDirAbbrev, '')
|| CASE WHEN
input.address IS NOT NULL OR
input.streetName IS NOT NULL
|| CASE WHEN input.internal IS NOT NULL THEN ', ' ELSE '' END
|| cull_null(input.location)
|| CASE WHEN input.location IS NOT NULL THEN ', ' ELSE '' END
- || cull_null(input.stateAbbrev)
- || CASE WHEN input.stateAbbrev IS NOT NULL THEN ' ' ELSE '' END
+ || COALESCE(input.stateAbbrev || ' ' , '')
|| cull_null(input.zip);
RETURN trim(result);
#1109a|4373||LAKE|Dr|||ROBBINSDALE|MN|55422|t
#1109b|4373||LAKE|Dr|||ROBBINSDALE|MN|55422|t
#1074a|3420||RHODE ISLAND|Ave|S||ST. LOUIS PARK|MN|55426|t
-#1074b|26||Court|St|||Boston|MA|02109|t
\ No newline at end of file
+#1074b|26||Court|St|||Boston|MA|02109|t
+#1112a|8401|W|35W|Svc Dr|NE||Blaine|MN|55449|t
+#1112b|8401||35W||||Blaine|MN|55449|t
+#1112c|8401||35W||W||Blaine|MN|55449|t
+#1112d|8401|W|35W||||Blaine|MN|55449|t
+#1112e|8401|W|35W||||Blaine|MN|55449|t
+#1125a|19596 Co Rd 480, COLCORD, OK 74338
+#1125b|4345 Rte 353, SALAMANCA, NY 14779|4345||353|Rte|||SALAMANCA|NY|14779|t
+#1125c|19799 State Rte O, COSBY, MO 64436|19799||O|State Rte|||COSBY|MO|64436|t
+#1125d|I- 90, Boston, MA|||90|I-|||Boston|MA||t
+#1125e|I-90, Boston, MA|||I-90||||Boston|MA||t
+#1125f|I- 90, Boston, MA|||90|I-|||Boston|MA||t
\ No newline at end of file
SELECT '#1112d' As ticket, * FROM normalize_address('8401 West 35W, Blaine, MN 55449');
SELECT '#1112e' As ticket, * FROM normalize_address('8401 W 35W, Blaine, MN 55449');
+-- Testing pretty print of highway addresses
+-- These tests excerpted from Brian Hamlin's CASS failures
+-- in #1077
+SELECT '#1125a' As ticket, pprint_addy(normalize_address('19596 COUNTY ROAD 480, COLCORD, OK 74338'));
+SELECT '#1125b' As ticket, pprint_addy(addy), addy.* FROM normalize_address('4345 353 Rte, SALAMANCA, NY 14779') AS addy;
+SELECT '#1125c' As ticket, pprint_addy(addy), addy.* FROM normalize_address('19799 STATE ROUTE O, COSBY, MO 64436') AS addy;
+
+-- some more to test interstate permutations
+SELECT '#1125d' As ticket, pprint_addy(addy), addy.* FROM normalize_address('Interstate 90,Boston, MA') As addy;
+-- this one is wrong (because the lack of space trips it up) but will fix later
+SELECT '#1125e' As ticket, pprint_addy(addy), addy.* FROM normalize_address('I-90,Boston, MA') As addy;
+SELECT '#1125f' As ticket, pprint_addy(addy), addy.* FROM normalize_address('I 90,Boston, MA') As addy;
\timing
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 ('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 ('UNS', 'Uns');
INSERT INTO street_type_lookup (name, abbrev) VALUES ('WL', 'Wl');
--- prefix and suffix street names for highways and roads
+-- prefix and suffix street names for highways and foreign named roads
+-- where street type is at front of streetname instead of after
-- these usually have numbers for street names and often have spaces in type
INSERT INTO street_type_lookup (name, abbrev, is_hw)
SELECT name, abbrev, true
- FROM (VALUES
+ FROM (VALUES
+ ('CAM', 'Cam'),
+ ('CAM.', 'Cam'),
+ ('CAMINO', 'Cam'),
+ ('CO HWY', 'Co Hwy'),
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
+ ('EXP', 'Expy'),
+ ('EXPR', 'Expy'),
+ ('EXPRESS', 'Expy'),
+ ('EXPRESSWAY', 'Expy'),
+ ('EXPW', 'Expy'),
+ ('EXPY', 'Expy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RD', 'Forest Rd'),
('HIWY', 'Hwy'),
('HWAY', 'Hwy'),
('HWY', 'Hwy'),
+ ('I', 'I-'),
+ ('I-', 'I-'),
+ ('INTERSTATE', 'I-'),
+ ('INTERSTATE ROUTE', 'I-'),
+ ('INTERSTATE RTE', 'I-'),
+ ('INTERSTATE RTE.', 'I-'),
+ ('INTERSTATE RT', 'I-'),
+ ('LOOP', 'Loop'),
('ROUTE', 'Rte'),
('RTE', 'Rte'),
('RT', 'Rte'),
-- prefix and suffix street names for numbered highways
CREATE TEMPORARY TABLE temp_types AS
SELECT name, abbrev
- FROM (VALUES
+ FROM ( VALUES
+ ('CAM', 'Cam'),
+ ('CAM.', 'Cam'),
+ ('CAMINO', 'Cam'),
+ ('CO HWY', 'Co Hwy'),
('COUNTY HWY', 'Co Hwy'),
('COUNTY HIGHWAY', 'Co Hwy'),
('COUNTY HIGH WAY', 'Co Hwy'),
('CO RTE', 'Co Rte'),
('COUNTY ROUTE', 'Co Rte'),
('CO ST AID HWY', 'Co St Aid Hwy'),
+ ('EXP', 'Expy'),
+ ('EXPR', 'Expy'),
+ ('EXPRESS', 'Expy'),
+ ('EXPRESSWAY', 'Expy'),
+ ('EXPW', 'Expy'),
+ ('EXPY', 'Expy'),
('FARM RD', 'Farm Rd'),
('FIRE RD', 'Fire Rd'),
('FOREST RD', 'Forest Rd'),
('HIWY', 'Hwy'),
('HWAY', 'Hwy'),
('HWY', 'Hwy'),
- ('RT', 'Rte'),
+ ('I', 'I-'),
+ ('I-', 'I-'),
+ ('INTERSTATE', 'I-'),
+ ('LOOP', 'Loop'),
('ROUTE', 'Rte'),
('RTE', 'Rte'),
+ ('RT', 'Rte'),
('STATE HWY', 'State Hwy'),
('STATE HIGHWAY', 'State Hwy'),
('STATE HIGH WAY', 'State Hwy'),