File: geocode_address_state.sql

package info (click to toggle)
postgis 1.3.3-3
  • links: PTS, VCS
  • area: main
  • in suites: lenny
  • size: 10,468 kB
  • ctags: 4,310
  • sloc: sql: 73,321; ansic: 35,513; xml: 6,160; java: 6,061; sh: 3,428; perl: 1,447; cpp: 987; makefile: 727; yacc: 276; python: 192
file content (81 lines) | stat: -rw-r--r-- 3,909 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
CREATE OR REPLACE FUNCTION geocode_address_state(
    result REFCURSOR,
    parsed NORM_ADDY
) RETURNS REFCURSOR
AS $_$
DECLARE
  tempInt VARCHAR;
BEGIN
  -- Check to see if the road name can be matched.
  SELECT INTO tempInt count(*) FROM tiger_geocode_roads
      WHERE soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
      AND parsed.stateAbbrev = tiger_geocode_roads.state;

  IF tempInt = 0 THEN
    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 soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
      AND parsed.stateAbbrev = tiger_geocode_roads.state
      ) 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;

  IF tempInt = 0 THEN
    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
  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 soundex(parsed.streetName) = soundex(tiger_geocode_roads.fename)
      AND parsed.stateAbbrev = tiger_geocode_roads.state
      ) 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)
  ORDER BY subquery.rating;
  RETURN result;
END;
$_$ LANGUAGE plpgsql;