#HISTORY #GBT 121: update tiger_geocoder to run in PostgreSQL 8.3 - apply patch from cdwinslow

git-svn-id: http://svn.osgeo.org/postgis/trunk@3860 b70326c6-7e19-0410-871a-916f4a2858ee
This commit is contained in:
Regina Obe 2009-03-12 23:20:26 +00:00
parent 868861232d
commit 37f94e8923
10 changed files with 80 additions and 80 deletions

View file

@ -6,7 +6,7 @@ AS $_$
DECLARE
result REFCURSOR;
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
IF parsed.location IS NULL THEN
-- location is manditory. This is the location geocoder after all.

View file

@ -6,7 +6,7 @@ AS $_$
DECLARE
result REFCURSOR;
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- The first step is to determine what weve been given, and if its enough.
IF parsed.location IS NULL THEN

View file

@ -6,7 +6,7 @@ AS $_$
DECLARE
result REFCURSOR;
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Check to see if the road name can be matched.
IF parsed.stateAbbrev IS NOT NULL THEN

View file

@ -5,7 +5,7 @@ CREATE OR REPLACE FUNCTION geocode_address_place_fuzzy(
AS $_$
DECLARE
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Check to see if the road name can be matched.
IF parsed.stateAbbrev IS NOT NULL THEN

View file

@ -4,7 +4,7 @@ CREATE OR REPLACE FUNCTION geocode_address_state(
) RETURNS REFCURSOR
AS $_$
DECLARE
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Check to see if the road name can be matched.
SELECT INTO tempInt count(*) FROM tiger_geocode_roads

View file

@ -1,81 +1,81 @@
CREATE OR REPLACE FUNCTION geocode_address_zip(
result REFCURSOR,
parsed NORM_ADDY
result REFCURSOR,
parsed NORM_ADDY
) RETURNS REFCURSOR
AS $_$
DECLARE
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Check to see if the road name can be matched.
SELECT INTO tempInt count(*) FROM tiger_geocode_roads
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename);
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename);
IF tempInt = 0 THEN
RETURN NULL;
RETURN NULL;
END IF;
-- The road name matches, now we check to see if the addresses match
SELECT INTO tempInt count(*)
FROM (
SELECT *, rate_attributes(parsed.preDirAbbrev, tiger_geocode_roads.fedirp,
parsed.streetName, tiger_geocode_roads.fename, parsed.streetTypeAbbrev,
tiger_geocode_roads.fetype, parsed.postDirAbbrev,
tiger_geocode_roads.fedirs) as rating
FROM tiger_geocode_roads
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
) AS subquery, roads_local
SELECT *, rate_attributes(parsed.preDirAbbrev, tiger_geocode_roads.fedirp,
parsed.streetName, tiger_geocode_roads.fename, parsed.streetTypeAbbrev,
tiger_geocode_roads.fetype, parsed.postDirAbbrev,
tiger_geocode_roads.fedirs) as rating
FROM tiger_geocode_roads
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
) AS subquery, roads_local
WHERE includes_address(parsed.address, roads_local.fraddl, roads_local.toaddl,
roads_local.fraddr, roads_local.toaddr)
AND subquery.tlid = roads_local.tlid;
roads_local.fraddr, roads_local.toaddr)
AND subquery.tlid = roads_local.tlid;
IF tempInt = 0 THEN
RETURN NULL;
RETURN NULL;
END IF;
OPEN result FOR
SELECT
roads_local.fedirp as fedirp,
roads_local.fename as fename,
roads_local.fetype as fetype,
roads_local.fedirs as fedirs,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN coalesce(pl.name,zipl.city,csl.name,col.name) ELSE coalesce(pr.name,zipr.city,csr.name,cor.name) END as place,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN sl.abbrev ELSE sr.abbrev END as state,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN zipl ELSE zipr END as zip,
interpolate_from_address(parsed.address, roads_local.fraddl,
roads_local.toaddl, roads_local.fraddr, roads_local.toaddr,
roads_local.geom) as address_geom,
subquery.rating as rating
roads_local.fedirp as fedirp,
roads_local.fename as fename,
roads_local.fetype as fetype,
roads_local.fedirs as fedirs,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN coalesce(pl.name,zipl.city,csl.name,col.name) ELSE coalesce(pr.name,zipr.city,csr.name,cor.name) END as place,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN sl.abbrev ELSE sr.abbrev END as state,
CASE WHEN (parsed.address % 2) = roads_local.fraddl
OR (parsed.address % 2) = roads_local.toaddl
THEN zipl ELSE zipr END as zip,
interpolate_from_address(parsed.address, roads_local.fraddl,
roads_local.toaddl, roads_local.fraddr, roads_local.toaddr,
roads_local.geom) as address_geom,
subquery.rating as rating
FROM (
SELECT *, rate_attributes(parsed.preDirAbbrev, tiger_geocode_roads.fedirp,
parsed.streetName, tiger_geocode_roads.fename, parsed.streetTypeAbbrev,
tiger_geocode_roads.fetype, parsed.postDirAbbrev,
tiger_geocode_roads.fedirs) as rating
FROM tiger_geocode_roads
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
) AS subquery
JOIN roads_local ON (subquery.tlid = roads_local.tlid)
JOIN state_lookup sl ON (roads_local.statel = sl.st_code)
JOIN state_lookup sr ON (roads_local.stater = sr.st_code)
LEFT JOIN place_lookup pl ON (roads_local.statel = pl.st_code AND roads_local.placel = pl.pl_code)
LEFT JOIN place_lookup pr ON (roads_local.stater = pr.st_code AND roads_local.placer = pr.pl_code)
LEFT JOIN county_lookup col ON (roads_local.statel = col.st_code AND roads_local.countyl = col.co_code)
LEFT JOIN county_lookup cor ON (roads_local.stater = cor.st_code AND roads_local.countyr = cor.co_code)
LEFT JOIN countysub_lookup csl ON (roads_local.statel = csl.st_code AND roads_local.countyl = csl.co_code AND roads_local.cousubl = csl.cs_code)
LEFT JOIN countysub_lookup csr ON (roads_local.stater = csr.st_code AND roads_local.countyr = csr.co_code AND roads_local.cousubr = csr.cs_code)
LEFT JOIN zip_lookup_base zipl ON (roads_local.zipl = zipl.zip)
LEFT JOIN zip_lookup_base zipr ON (roads_local.zipr = zipr.zip)
SELECT *, rate_attributes(parsed.preDirAbbrev, tiger_geocode_roads.fedirp,
parsed.streetName, tiger_geocode_roads.fename, parsed.streetTypeAbbrev,
tiger_geocode_roads.fetype, parsed.postDirAbbrev,
tiger_geocode_roads.fedirs) as rating
FROM tiger_geocode_roads
WHERE parsed.zip = tiger_geocode_roads.zip
AND soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
) AS subquery
JOIN roads_local ON (subquery.tlid = roads_local.tlid)
JOIN state_lookup sl ON (roads_local.statel = sl.st_code)
JOIN state_lookup sr ON (roads_local.stater = sr.st_code)
LEFT JOIN place_lookup pl ON (roads_local.statel = pl.st_code AND roads_local.placel = pl.pl_code)
LEFT JOIN place_lookup pr ON (roads_local.stater = pr.st_code AND roads_local.placer = pr.pl_code)
LEFT JOIN county_lookup col ON (roads_local.statel = col.st_code AND roads_local.countyl = col.co_code)
LEFT JOIN county_lookup cor ON (roads_local.stater = cor.st_code AND roads_local.countyr = cor.co_code)
LEFT JOIN countysub_lookup csl ON (roads_local.statel = csl.st_code AND roads_local.countyl = csl.co_code AND roads_local.cousubl = csl.cs_code)
LEFT JOIN countysub_lookup csr ON (roads_local.stater = csr.st_code AND roads_local.countyr = csr.co_code AND roads_local.cousubr = csr.cs_code)
LEFT JOIN zip_lookup_base zipl ON (roads_local.zipl = zipl.zip)
LEFT JOIN zip_lookup_base zipr ON (roads_local.zipr = zipr.zip)
WHERE includes_address(parsed.address, roads_local.fraddl, roads_local.toaddl,
roads_local.fraddr, roads_local.toaddr)
roads_local.fraddr, roads_local.toaddr)
ORDER BY subquery.rating;
RETURN result;

View file

@ -5,13 +5,13 @@ AS $_$
DECLARE
result REFCURSOR;
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Try to match the city/state to a zipcode first
SELECT INTO tempInt count(*)
FROM zip_lookup_base zip
JOIN state_lookup sl ON (zip.state = sl.name)
JOIN zt99_d00 zl ON (lpad(zip.zip,5,'0') = zl.zcta)
JOIN zt99_d00 zl ON (zip.zip = zl.zcta::integer)
WHERE soundex(zip.city) = soundex(parsed.location) and sl.abbrev = parsed.stateAbbrev;
-- If that worked, just use the zipcode lookup
@ -30,7 +30,7 @@ BEGIN
FROM
zip_lookup_base zip
JOIN state_lookup sl on (zip.state = sl.name)
JOIN zt99_d00 zl ON (lpad(zip.zip,5,'0') = zl.zcta)
JOIN zt99_d00 zl ON (zip.zip = zl.zcta::integer)
WHERE
soundex(zip.city) = soundex(parsed.location) and sl.abbrev = parsed.stateAbbrev;
@ -40,7 +40,7 @@ BEGIN
-- Try to match the city/state to a place next
SELECT INTO tempInt count(*)
FROM pl99_d00 pl
JOIN state_lookup sl ON (pl.state = lpad(sl.st_code,2,'0'))
JOIN state_lookup sl ON (pl.state::integer = sl.st_code)
WHERE soundex(pl.name) = soundex(parsed.location) and sl.abbrev = parsed.stateAbbrev;
-- If that worked then use it
@ -57,7 +57,7 @@ BEGIN
centroid(wkb_geometry) as address_geom,
100::integer + levenshtein_ignore_case(coalesce(zip.city), parsed.location) as rating
FROM pl99_d00 pl
JOIN state_lookup sl ON (pl.state = lpad(sl.st_code,2,'0'))
JOIN state_lookup sl ON (pl.state::integer = sl.st_code)
WHERE soundex(pl.name) = soundex(parsed.location) and sl.abbrev = parsed.stateAbbrev;
RETURN result;

View file

@ -5,13 +5,13 @@ AS $_$
DECLARE
result REFCURSOR;
tempString VARCHAR;
tempInt VARCHAR;
tempInt INTEGER;
BEGIN
-- Check to see if the road name can be matched.
SELECT INTO tempInt count(*)
FROM zip_lookup_base zip
JOIN state_lookup sl on (zip.state = sl.name)
JOIN zt99_d00 zl ON (lpad(zip.zip,5,'0') = zl.zcta)
JOIN zt99_d00 zl ON (zip.zip = zl.zcta::integer)
WHERE zip = parsed.zip;
IF tempInt = 0 THEN
@ -32,7 +32,7 @@ BEGIN
FROM
zip_lookup_base zip
JOIN state_lookup sl on (zip.state = sl.name)
JOIN zt99_d00 zl ON (lpad(zip.zip,5,'0') = zl.zcta)
JOIN zt99_d00 zl ON (zip.zip = zl.zcta::integer)
WHERE
zip.zip = parsed.zip;

View file

@ -28,7 +28,7 @@ BEGIN
|| CASE WHEN input.location IS NOT NULL THEN ', ' ELSE '' END
|| cull_null(input.stateAbbrev)
|| CASE WHEN input.stateAbbrev IS NOT NULL THEN ' ' ELSE '' END
|| cull_null(lpad(input.zip,5,'0'));
|| cull_null(lpad(input.zip::text,5,'0'));
RETURN result;

View file

@ -727,7 +727,7 @@ INSERT INTO place_lookup
pl.name as name
FROM
pl99_d00 pl
JOIN state_lookup sl ON (pl.state = lpad(sl.st_code,2,'0'))
JOIN state_lookup sl ON (pl.state::integer = sl.st_code)
GROUP BY pl.state, sl.abbrev, pl.placefp, pl.name;
CREATE INDEX place_lookup_name_idx ON place_lookup (soundex(name));
@ -750,7 +750,7 @@ INSERT INTO county_lookup
co.name as name
FROM
co99_d00 co
JOIN state_lookup sl ON (co.state = lpad(sl.st_code,2,'0'))
JOIN state_lookup sl ON (co.state::integer = sl.st_code)
GROUP BY co.state, sl.abbrev, co.county, co.name;
CREATE INDEX county_lookup_name_idx ON county_lookup (soundex(name));
@ -777,8 +777,8 @@ INSERT INTO countysub_lookup
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)
JOIN state_lookup sl ON (cs.state::integer = sl.st_code)
JOIN county_lookup cl ON (cs.state::integer = cl.st_code AND cs.county::integer = 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));
@ -814,10 +814,10 @@ INSERT INTO zip_lookup_all
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)
JOIN state_lookup sl ON (rl.statel::integer = sl.st_code)
LEFT JOIN county_lookup cl ON (rl.statel::integer = cl.st_code AND rl.countyl::integer = cl.co_code)
LEFT JOIN countysub_lookup cs ON (rl.statel::integer = cs.st_code AND rl.countyl::integer = cs.co_code AND rl.cousubl = cs.cs_code)
LEFT JOIN place_lookup pl ON (rl.statel::integer = pl.st_code AND rl.placel::integer = pl.pl_code)
WHERE zipl IS NOT NULL
UNION ALL
SELECT
@ -832,10 +832,10 @@ INSERT INTO zip_lookup_all
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)
JOIN state_lookup sl ON (rl.stater = sl.st_code)
LEFT JOIN county_lookup cl ON (rl.stater = cl.st_code AND rl.countyr = cl.co_code)
LEFT JOIN countysub_lookup cs ON (rl.stater = cs.st_code AND rl.countyr = cs.co_code AND rl.cousubr = cs.cs_code)
LEFT JOIN place_lookup pl ON (rl.stater = pl.st_code 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;