postgis/doc/extras_tigergeocoder.xml
Regina Obe be216ec941 fix function name typo in geocode_intersection
git-svn-id: http://svn.osgeo.org/postgis/trunk@8350 b70326c6-7e19-0410-871a-916f4a2858ee
2011-12-11 02:42:57 +00:00

933 lines
50 KiB
XML

<?xml version="1.0" encoding="UTF-8"?>
<sect1 id="Tiger_Geocoder">
<title>Tiger Geocoder</title>
<sect1info>
<abstract>
<para>A plpgsql based geocoder written to work with the <ulink url="http://www.census.gov/geo/www/tiger/index.html">TIGER (Topologically Integrated Geographic Encoding and Referencing system ) / Line and Master Address database export</ulink> released by the US Census Bureau. In prior versions the TIGER files were
released in ASCII format. The older geocoder used to work with that format is in <varname>extras/tiger_geocoder/tiger_2006andbefore</varname>. </para>
<para>There are four components to the geocoder: the data loader functions, the address normalizer, the address geocoder, and the reverse geocoder. The latest version updated to use the TIGER 2010 census data is located in the <varname>extras/tiger_geocoder/tiger_2010</varname> folder.</para>
<para>Although it is designed specifically for the US, a lot of the concepts and functions are applicable and can be adapted to work with other country address and road networks.</para>
<para>The script builds a schema called <varname>tiger</varname> to house all the tiger related functions, reusable lookup data such as road type prefixes, suffixes, states, various control tables for managing data load, and skeleton base tables from which all the tiger loaded tables inherit from.</para>
<para>Another schema called <varname>tiger_data</varname> is also created which houses all the census data for each state that the loader downloads from Census site and loads into the database. In the current model, each set of state tables is
prefixed with the state code e.g ma_addr, ca_edges etc with constraints to enforce only that state data. Each of these tables inherits from the base addr, faces, edges, etc located in the tiger schema. </para>
<para>All the geocode functions only reference the base tables, so there is no requirement that the data schema be called <varname>tiger_data</varname> or that data can't be further partitioned into other schemas -- e.g a different schema
for each state, as long as all the tables inherit from the tables in the <varname>tiger</varname> schema.</para>
<note><para>If you are using a prerelease version of PostGIS 2.0.0 tiger geocoder, you can upgrade the scripts using the accompanying upgrade_geocoder.bat / .sh scripts in tiger_2010. We'll be
refining the upgrade scripts until release.</para></note>
<para>Design:</para>
<para>The goal of this project is to build a fully functional geocoder that can process an arbitrary
address string and using normalized TIGER census data, produce a point geometry and rating reflecting the location of the given address and likeliness of the location.</para>
<para>The <varname>reverse_geocode</varname> function, introduced in PostGIS 2.0.0 is useful for deriving the street address and cross streets of a GPS location.</para>
<para>The geocoder should be simple for anyone familiar with PostGIS to install and use, and should be easily installable and usable on all platforms supported by PostGIS.</para>
<para>It should be robust enough to function properly despite formatting and spelling errors.</para>
<para>It should be extensible enough to be used with future data updates, or alternate data sources with a minimum of coding changes.</para>
</abstract>
<note><para>The <varname>tiger</varname> schema must be added to the database search path for the functions to work properly.</para></note>
</sect1info>
<para>There is another geocoder for PostGIS gaining in popularity and more suitable for international use. It is called <ulink url="http://wiki.openstreetmap.org/wiki/Nominatim">Nominatim</ulink>
and uses OpenStreetMap gazeteer formatted data. It requires osm2pgsql for loading the data, PostgreSQL 8.4+ and PostGIS 1.5+ to function. It is packaged as a webservice interface and seems designed to be called as a webservice.
Just like the tiger geocoder, it has both a geocoder and a reverse geocoder component. From the documentation, it is unclear if it has a pure SQL interface like the tiger geocoder, or if a good deal of the logic is implemented in the web interface.</para>
<refentry id="Drop_Indexes_Generate_Script">
<refnamediv>
<refname>Drop_Indexes_Generate_Script</refname>
<refpurpose>Generates a script that drops all non-primary key and non-unique indexes on tiger schema and user specified schema. Defaults schema to <varname>tiger_data</varname> if no schema is specified.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Drop_Indexes_Generate_Script</function></funcdef>
<paramdef><type choice='opt'>text </type> <parameter>param_schema=tiger_data</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Generates a script that drops all non-primary key and non-unique indexes on tiger schema and user specified schema. Defaults schema to <varname>tiger_data</varname> if no schema is specified.</para>
<para>This is useful for minimizing index bloat that may confuse the query planner or take up unnecessary space. Use in combination with <xref linkend="Install_Missing_Indexes"/> to add just the indexes used by the geocoder.</para>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT drop_indexes_generate_script() As actionsql;
actionsql
---------------------------------------------------------
DROP INDEX tiger.idx_tiger_countysub_lookup_lower_name;
DROP INDEX tiger.idx_tiger_edges_countyfp;
DROP INDEX tiger.idx_tiger_faces_countyfp;
DROP INDEX tiger.tiger_place_the_geom_gist;
DROP INDEX tiger.tiger_edges_the_geom_gist;
DROP INDEX tiger.tiger_state_the_geom_gist;
DROP INDEX tiger.idx_tiger_addr_least_address;
DROP INDEX tiger.idx_tiger_addr_tlid;
DROP INDEX tiger.idx_tiger_addr_zip;
DROP INDEX tiger.idx_tiger_county_countyfp;
DROP INDEX tiger.idx_tiger_county_lookup_lower_name;
DROP INDEX tiger.idx_tiger_county_lookup_snd_name;
DROP INDEX tiger.idx_tiger_county_lower_name;
DROP INDEX tiger.idx_tiger_county_snd_name;
DROP INDEX tiger.idx_tiger_county_the_geom_gist;
DROP INDEX tiger.idx_tiger_countysub_lookup_snd_name;
DROP INDEX tiger.idx_tiger_cousub_countyfp;
DROP INDEX tiger.idx_tiger_cousub_cousubfp;
DROP INDEX tiger.idx_tiger_cousub_lower_name;
DROP INDEX tiger.idx_tiger_cousub_snd_name;
DROP INDEX tiger.idx_tiger_cousub_the_geom_gist;
DROP INDEX tiger_data.idx_tiger_data_ma_addr_least_address;
DROP INDEX tiger_data.idx_tiger_data_ma_addr_tlid;
DROP INDEX tiger_data.idx_tiger_data_ma_addr_zip;
DROP INDEX tiger_data.idx_tiger_data_ma_county_countyfp;
DROP INDEX tiger_data.idx_tiger_data_ma_county_lookup_lower_name;
DROP INDEX tiger_data.idx_tiger_data_ma_county_lookup_snd_name;
DROP INDEX tiger_data.idx_tiger_data_ma_county_lower_name;
DROP INDEX tiger_data.idx_tiger_data_ma_county_snd_name;
:
:
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Install_Missing_Indexes"/>, <xref linkend="Missing_Indexes_Generate_Script"/></para>
</refsection>
</refentry>
<refentry id="Drop_State_Tables_Generate_Script">
<refnamediv>
<refname>Drop_State_Tables_Generate_Script</refname>
<refpurpose>Generates a script that drops all tables in the specified schema that are prefixed with the state abbreviation. Defaults schema to <varname>tiger_data</varname> if no schema is specified.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Drop_State_Tables_Generate_Script</function></funcdef>
<paramdef><type>text </type> <parameter>address</parameter></paramdef>
<paramdef><type choice='opt'>text </type> <parameter>param_schema=tiger_data</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Generates a script that drops all tables in the specified schema that are prefixed with the state abbreviation. Defaults schema to <varname>tiger_data</varname> if no schema is specified.
This function is useful for dropping tables of a state just before you reload a state in case something went wrong during your previous load.</para>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT drop_state_tables_generate_script('PA');
DROP TABLE tiger_data.pa_addr;
DROP TABLE tiger_data.pa_county;
DROP TABLE tiger_data.pa_county_lookup;
DROP TABLE tiger_data.pa_cousub;
DROP TABLE tiger_data.pa_edges;
DROP TABLE tiger_data.pa_faces;
DROP TABLE tiger_data.pa_featnames;
DROP TABLE tiger_data.pa_place;
DROP TABLE tiger_data.pa_state;
DROP TABLE tiger_data.pa_zip_lookup_base;
DROP TABLE tiger_data.pa_zip_state;
DROP TABLE tiger_data.pa_zip_state_loc;
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_Generate_Script"/></para>
</refsection>
</refentry>
<refentry id="Geocode">
<refnamediv>
<refname>Geocode</refname>
<refpurpose>Takes in an address as a string (or other normalized address) and outputs a set of possible locations which include a point geometry in NAD 83 long lat, a normalized address for each, and the rating. The lower the rating the more likely the match.
Results are sorted by lowest rating first. Can optionally pass in maximum results, defaults to 10, and restrict_region (defaults to NULL)</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>setof record <function>geocode</function></funcdef>
<paramdef><type>varchar </type> <parameter>address</parameter></paramdef>
<paramdef><type choice='opt'>integer </type> <parameter>max_results=10</parameter></paramdef>
<paramdef><type choice='opt'>geometry </type> <parameter>restrict_region=NULL</parameter></paramdef>
<paramdef><type>norm_addy </type> <parameter>OUT addy</parameter></paramdef>
<paramdef><type>geometry </type> <parameter>OUT geomout</parameter></paramdef>
<paramdef><type>integer </type> <parameter>OUT rating</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>setof record <function>geocode</function></funcdef>
<paramdef><type>norm_addy </type> <parameter>in_addy</parameter></paramdef>
<paramdef><type choice='opt'>integer </type> <parameter>max_results=10</parameter></paramdef>
<paramdef><type choice='opt'>geometry </type> <parameter>restrict_region=NULL</parameter></paramdef>
<paramdef><type>norm_addy </type> <parameter>OUT addy</parameter></paramdef>
<paramdef><type>geometry </type> <parameter>OUT geomout</parameter></paramdef>
<paramdef><type>integer </type> <parameter>OUT rating</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Takes in an address as a string (or already normalized address) and outputs a set of possible locations which include a point geometry in NAD 83 long lat, a <varname>normalized_address</varname> (addy) for each, and the rating. The lower the rating the more likely the match.
Results are sorted by lowest rating first. Uses Tiger data (edges,faces,addr), PostgreSQL fuzzy string matching (soundex,levenshtein) and PostGIS line interpolation functions to interpolate address along the Tiger edges. The higher the rating the less likely the geocode is right.
The geocoded point is defaulted to offset 10 meters from center-line off to side (L/R) of street address is located on.</para>
<para>Enhanced: 2.0.0 to support Tiger 2010 structured data and revised some logic to improve speed, accuracy of geocoding, and to offset point from centerline to side of street address is located on. New parameter max_results useful for specifying ot just return the best result.</para>
</refsection>
<refsection>
<title>Examples: Basic</title>
<para>The below examples timings are on a 3.0 GHZ single processor Windows 7 machine with 2GB ram running PostgreSQL 9.1rc1/PostGIS 2.0 loaded with all of MA,MN,CA, RI state Tiger data loaded.</para>
<para>Exact matches are faster to compute (61ms)</para>
<programlisting>SELECT g.rating, ST_X(g.geomout) As lon, ST_Y(g.geomout) As lat,
(addy).address As stno, (addy).streetname As street,
(addy).streettypeabbrev As styp, (addy).location As city, (addy).stateabbrev As st,(addy).zip
FROM geocode('75 State Street, Boston MA 02109') As g;
rating | lon | lat | stno | street | styp | city | st | zip
--------+-------------------+------------------+------+--------+------+--------+----+-------
0 | -71.0556722990239 | 42.3589914927049 | 75 | State | St | Boston | MA | 02109
</programlisting>
<para>Even if zip is not passed in the geocoder can guess (took about 122-150 ms)</para>
<programlisting>SELECT g.rating, ST_AsText(ST_SnapToGrid(g.geomout,0.00001)) As wktlonlat,
(addy).address As stno, (addy).streetname As street,
(addy).streettypeabbrev As styp, (addy).location As city, (addy).stateabbrev As st,(addy).zip
FROM geocode('226 Hanover Street, Boston, MA',1) As g;
rating | wktlonlat | stno | street | styp | city | st | zip
--------+---------------------------+------+---------+------+--------+----+-------
1 | POINT(-71.05528 42.36316) | 226 | Hanover | St | Boston | MA | 02113
</programlisting>
<para>Can handle misspellings and provides more than one possible solution with ratings and takes longer (500ms).</para>
<programlisting>SELECT g.rating, ST_AsText(ST_SnapToGrid(g.geomout,0.00001)) As wktlonlat,
(addy).address As stno, (addy).streetname As street,
(addy).streettypeabbrev As styp, (addy).location As city, (addy).stateabbrev As st,(addy).zip
FROM geocode('31 - 37 Stewart Street, Boston, MA 02116') As g;
rating | wktlonlat | stno | street | styp | city | st | zip
--------+---------------------------+------+--------+------+--------+----+-------
70 | POINT(-71.06459 42.35113) | 31 | Stuart | St | Boston | MA | 02116
</programlisting>
<para>Using to do a batch geocode of addresses. Easiest is to set <varname>max_results=1</varname>. Only process those not yet geocoded (have no rating).</para>
<programlisting>CREATE TABLE addresses_to_geocode(addid serial PRIMARY KEY, address text,
lon numeric, lat numeric, new_address text, rating integer);
INSERT INTO addresses_to_geocode(address)
VALUES ('529 Main Street, Boston MA, 02129'),
('77 Massachusetts Avenue, Cambridge, MA 02139'),
('25 Wizard of Oz, Walaford, KS 99912323'),
('26 Capen Street, Medford, MA'),
('124 Mount Auburn St, Cambridge, Massachusetts 02138'),
('950 Main Street, Worcester, MA 01610');
-- only update the first 3 addresses (323-704 ms - there are caching and shared memory effects so first geocode you do is always slower) --
-- for large numbers of addresses you don't want to update all at once
-- since the whole geocode must commit at once
-- For this example we rejoin with LEFT JOIN
-- and set to rating to -1 rating if no match
-- to ensure we don't regeocode a bad address
UPDATE addresses_to_geocode
SET (rating, new_address, lon, lat)
= ( COALESCE((g.geo).rating,-1), pprint_addy((g.geo).addy),
ST_X((g.geo).geomout)::numeric(8,5), ST_Y((g.geo).geomout)::numeric(8,5) )
FROM (SELECT addid
FROM addresses_to_geocode
WHERE rating IS NULL ORDER BY addid LIMIT 3) As a
LEFT JOIN (SELECT addid, (geocode(address,1)) As geo
FROM addresses_to_geocode As ag
WHERE ag.rating IS NULL ORDER BY addid LIMIT 3) As g ON a.addid = g.addid
WHERE a.addid = addresses_to_geocode.addid;
result
-----
Query returned successfully: 3 rows affected, 480 ms execution time.
SELECT * FROM addresses_to_geocode WHERE rating is not null;
addid | address | lon | lat | new_address | rating
-------+----------------------------------------------+-----------+----------+-------------------------------------------+--------
1 | 529 Main Street, Boston MA, 02129 | -71.07181 | 42.38359 | 529 Main St, Boston, MA 02129 | 0
2 | 77 Massachusetts Avenue, Cambridge, MA 02139 | -71.09428 | 42.35988 | 77 Massachusetts Ave, Cambridge, MA 02139 | 0
3 | 25 Wizard of Oz, Walaford, KS 99912323 | | | | -1
</programlisting>
</refsection>
<refsection>
<title>Examples: Using Geometry filter</title>
<programlisting>
SELECT g.rating, ST_AsText(ST_SnapToGrid(g.geomout,0.00001)) As wktlonlat,
(addy).address As stno, (addy).streetname As street,
(addy).streettypeabbrev As styp,
(addy).location As city, (addy).stateabbrev As st,(addy).zip
FROM geocode('100 Federal Street, MA',
3,
(SELECT ST_Union(the_geom)
FROM place WHERE statefp = '25' AND name = 'Lynn')::geometry
) As g;
rating | wktlonlat | stno | street | styp | city | st | zip
--------+--------------------------+------+---------+------+------+----+-------
8 | POINT(-70.96796 42.4659) | 100 | Federal | St | Lynn | MA | 01905
Total query runtime: 245 ms.
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Normalize_Address" />,<xref linkend="Pprint_Addy" />,<xref linkend="ST_AsText"/>,<xref linkend="ST_SnapToGrid"/>, <xref linkend="ST_X"/>, <xref linkend="ST_Y"/></para>
</refsection>
</refentry>
<refentry id="Geocode_Intersection">
<refnamediv>
<refname>Geocode_Intersection</refname>
<refpurpose>Takes in 2 streets that intersect and a state, city, zip, and outputs a set of possible locations on the first cross street that is at the intersection, also includes a point geometry in NAD 83 long lat, a normalized address for each location, and the rating. The lower the rating the more likely the match.
Results are sorted by lowest rating first. Can optionally pass in maximum results, defaults to 10</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>setof record <function>geocode_intersection</function></funcdef>
<paramdef><type>text </type> <parameter> roadway1</parameter></paramdef>
<paramdef><type>text </type> <parameter> roadway2</parameter></paramdef>
<paramdef><type>text </type> <parameter> in_state</parameter></paramdef>
<paramdef><type choice='opt'>text </type> <parameter> in_city</parameter></paramdef>
<paramdef><type choice='opt'>text </type> <parameter> in_zip</parameter></paramdef>
<paramdef><type choice='opt'>integer </type> <parameter>max_results=10</parameter></paramdef>
<paramdef><type>norm_addy </type> <parameter>OUT addy</parameter></paramdef>
<paramdef><type>geometry </type> <parameter>OUT geomout</parameter></paramdef>
<paramdef><type>integer </type> <parameter>OUT rating</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Takes in 2 streets that intersect and a state, city, zip, and outputs a set of possible locations on the first cross street that is at the intersection, also includes a point geometry in NAD 83 long lat, a normalized address for each location, and the rating. The lower the rating the more likely the match.
Results are sorted by lowest rating first. Can optionally pass in maximum results, defaults to 10.
Returns <varname>normalized_address</varname> (addy) for each, geomout as the point location in nad 83 long lat, and the rating. The lower the rating the more likely the match.
Results are sorted by lowest rating first. Uses Tiger data (edges,faces,addr), PostgreSQL fuzzy string matching (soundex,levenshtein) </para>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples: Basic</title>
<para>The below examples timings are on a 3.0 GHZ single processor Windows 7 machine with 2GB ram running PostgreSQL 9.0/PostGIS 1.5 loaded with all of MA state Tiger data loaded.</para>
<para>Currently a bit slow (3000 ms)</para>
<programlisting>SELECT pprint_addy(addy), st_astext(geomout),rating
FROM geocode_intersection( 'Haverford St','Germania St', 'MA', 'Boston', '02130',1);
pprint_addy | st_astext | rating
----------------------------------+----------------------------+--------
98 Haverford St, Boston, MA 02130 | POINT(-71.101375 42.31376) | 0
</programlisting>
<para>Even if zip is not passed in the geocoder can guess (took about 3500 ms)</para>
<programlisting>SELECT pprint_addy(addy), st_astext(geomout),rating
FROM geocode_intersection('Weld', 'School', 'MA', 'Boston');
pprint_addy | st_astext | rating
-------------------------------+--------------------------+--------
98 Weld Ave, Boston, MA 02119 | POINT(-71.099 42.314234) | 3
99 Weld Ave, Boston, MA 02119 | POINT(-71.099 42.314234) | 3
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Geocode" />,<xref linkend="Pprint_Addy" />,<xref linkend="ST_AsText"/></para>
</refsection>
</refentry>
<refentry id="Install_Missing_Indexes">
<refnamediv>
<refname>Install_Missing_Indexes</refname>
<refpurpose>Finds all tables with key columns used in geocoder joins and filter conditions that are missing used indexes on those columns and will add them.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>boolean <function>Install_Missing_Indexes</function></funcdef>
<paramdef />
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Finds all tables in <varname>tiger</varname> and <varname>tiger_data</varname> schemas with key columns used in geocoder joins and filters that are missing indexes on those columns and will output the SQL DDL to
define the index for those tables and then execute the generated script. This is a helper function that adds new indexes needed to make queries faster that may have been missing during the load process.
This function is a companion to <xref linkend="Missing_Indexes_Generate_Script" /> that in addition to generating the create index script, also executes it.
It is called as part of the <filename>update_geocode.sql</filename> upgrade script.</para>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT install_missing_indexes();
install_missing_indexes
-------------------------
t
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_Generate_Script"/>, <xref linkend="Missing_Indexes_Generate_Script"/></para>
</refsection>
</refentry>
<refentry id="Loader_Generate_Script">
<refnamediv>
<refname>Loader_Generate_Script</refname>
<refpurpose>Generates a shell script for the specified platform for the specified states that will download Tiger data, stage and load into <varname>tiger_data</varname> schema. Each state script is returned as a separate record. Latest version supports Tiger 2010 structural changes.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>setof text <function>loader_generate_script</function></funcdef>
<paramdef><type>text[]</type> <parameter>param_states</parameter></paramdef>
<paramdef><type>text</type> <parameter>os</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Generates a shell script for the specified platform for the specified states that will download Tiger data, stage and load into <varname>tiger_data</varname> schema. Each state script is returned as a separate record.</para>
<para>It uses unzip on Linux (7-zip on Windows by default) and wget to do the downloading. It uses <xref linkend="shp2pgsql_usage" /> to load in the data. Note the smallest unit it does is a whole state, but you can overwrite this by downloading the files yourself. It will only
process the files in the staging and temp folders.</para>
<para>It uses the following control tables to control the process and different OS shell syntax variations.</para>
<orderedlist>
<listitem>
<para><varname>loader_variables</varname> keeps track of various variables such as census site, year, data and staging schemas</para>
</listitem>
<listitem>
<para><varname>loader_platform</varname> profiles of various platforms and where the various executables are located. Comes with windows and linux. More can be added.</para>
</listitem>
<listitem>
<para><varname>loader_lookuptables</varname> each record defines a kind of table (state, county), whether to process records in it and how to load them in. Defines the steps to import data, stage data, add, removes columns, indexes, and constraints for each. Each table is prefixed with the state and inherits from a table in the tiger schema. e.g. creates <varname>tiger_data.ma_faces</varname> which inherits from <varname>tiger.faces</varname></para>
</listitem>
</orderedlist>
<para>Availability: 2.0.0 to support Tiger 2010 structured data.</para>
</refsection>
<refsection>
<title>Examples</title>
<para>Generate script to load up data for 2 states in Windows shell script format.</para>
<programlisting>SELECT loader_generate_script(ARRAY['MA','RI'], 'windows') AS result;
-- result --
set STATEDIR="\gisdata\www2.census.gov\geo\pvs\tiger2010st\44_Rhode_Island"
set TMPDIR=\gisdata\temp\
set UNZIPTOOL="C:\Program Files\7-Zip\7z.exe"
set WGETTOOL="C:\wget\wget.exe"
set PGBIN=C:\Program Files\PostgreSQL\8.4\bin\
set PGPORT=5432
set PGHOST=localhost
set PGUSER=postgres
set PGPASSWORD=yourpasswordhere
set PGDATABASE=geocoder
set PSQL="%PGBIN%psql"
set SHP2PGSQL="%PGBIN%shp2pgsql"
%WGETTOOL% http://www2.census.gov/geo/pvs/tiger2010st/44_Rhode_Island/ --no-parent --relative --recursive --level=2 --accept=zip,txt --mirror --reject=html
:
:</programlisting>
<para>Generate sh script</para>
<programlisting>SELECT loader_generate_script(ARRAY['MA','RI'], 'sh') AS result;
-- result --
STATEDIR="/gisdata/www2.census.gov/geo/pvs/tiger2010st/44_Rhode_Island"
TMPDIR="/gisdata/temp/"
UNZIPTOOL=unzip
PGPORT=5432
PGHOST=localhost
PGUSER=postgres
PGPASSWORD=yourpasswordhere
PGDATABASE=geocoder
PSQL=psql
SHP2PGSQ=shp2pgsql
wget http://www2.census.gov/geo/pvs/tiger2010st/44_Rhode_Island/ --no-parent --relative --recursive --level=2 --accept=zip,txt --mirror --reject=html
:
:</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para></para>
</refsection>
</refentry>
<refentry id="Missing_Indexes_Generate_Script">
<refnamediv>
<refname>Missing_Indexes_Generate_Script</refname>
<refpurpose>Finds all tables with key columns used in geocoder joins that are missing indexes on those columns and will output the SQL DDL to
define the index for those tables.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Missing_Indexes_Generate_Script</function></funcdef>
<paramdef />
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Finds all tables in <varname>tiger</varname> and <varname>tiger_data</varname> schemas with key columns used in geocoder joins that are missing indexes on those columns and will output the SQL DDL to
define the index for those tables. This is a helper function that adds new indexes needed to make queries faster that may have been missing during the load process.
As the geocoder is improved, this function will be updated to accommodate new indexes being used. If this function outputs nothing, it means
all your tables have what we think are the key indexes already in place.</para>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT missing_indexes_generate_script();
-- output: This was run on a database that was created before many corrections were made to the loading script ---
CREATE INDEX idx_tiger_county_countyfp ON tiger.county USING btree(countyfp);
CREATE INDEX idx_tiger_cousub_countyfp ON tiger.cousub USING btree(countyfp);
CREATE INDEX idx_tiger_edges_tfidr ON tiger.edges USING btree(tfidr);
CREATE INDEX idx_tiger_edges_tfidl ON tiger.edges USING btree(tfidl);
CREATE INDEX idx_tiger_zip_lookup_all_zip ON tiger.zip_lookup_all USING btree(zip);
CREATE INDEX idx_tiger_data_ma_county_countyfp ON tiger_data.ma_county USING btree(countyfp);
CREATE INDEX idx_tiger_data_ma_cousub_countyfp ON tiger_data.ma_cousub USING btree(countyfp);
CREATE INDEX idx_tiger_data_ma_edges_countyfp ON tiger_data.ma_edges USING btree(countyfp);
CREATE INDEX idx_tiger_data_ma_faces_countyfp ON tiger_data.ma_faces USING btree(countyfp);
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_Generate_Script"/>, <xref linkend="Install_Missing_Indexes" /></para>
</refsection>
</refentry>
<refentry id="Normalize_Address">
<refnamediv>
<refname>Normalize_Address</refname>
<refpurpose>Given a textual street address, returns a composite <varname>norm_addy</varname> type that has road suffix, prefix and type standardized, street, streetname etc. broken into separate fields. This function
will work with just the lookup data packaged with the tiger_geocoder (no need for tiger census data).</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>norm_addy <function>normalize_address</function></funcdef>
<paramdef><type>varchar </type> <parameter>in_address</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Given a textual street address, returns a composite <varname>norm_addy</varname> type that has road suffix, prefix and type standardized, street, streetname etc. broken into separate fields. This is the first step in the geocoding process to
get all addresses into normalized postal form. No other data is required aside from what is packaged with the geocoder.</para>
<para>This function just uses the various direction/state/suffix lookup tables preloaded with the tiger_geocoder and located in the <varname>tiger</varname> schema, so it doesn't need you to download tiger census data or any other additional data to make use of it.
You may find the need to add more abbreviations or alternative namings to the various lookup tables in the <varname>tiger</varname> schema.</para>
<para>It uses various control lookup tables located in <varname>tiger</varname> schema to normalize the input address.</para>
<para>Fields in the <varname>norm_addy</varname> type object returned by this function in this order where () indicates a field required by the geocoder, [] indicates an optional field:</para>
<para>(address) [predirAbbrev] (streetName) [streetTypeAbbrev] [postdirAbbrev] [internal] [location] [stateAbbrev] [zip]</para>
<orderedlist>
<listitem>
<para><varname>address</varname> is an integer: The street number</para>
</listitem>
<listitem>
<para><varname>predirAbbrev</varname> is varchar: Directional prefix of road such as N, S, E, W etc. These are controlled using the <varname>direction_lookup</varname> table.</para>
</listitem>
<listitem>
<para><varname>streetName</varname> varchar</para>
</listitem>
<listitem>
<para><varname>streetTypeAbbrev</varname> varchar abbreviated version of street type: e.g. St, Ave, Cir. These are controlled using the <varname>street_type_lookup</varname> table.</para>
</listitem>
<listitem>
<para><varname>postdirAbbrev</varname> varchar abbreviated directional suffice of road N, S, E, W etc. These are controlled using the <varname>direction_lookup</varname> table.</para>
</listitem>
<listitem>
<para><varname>internal</varname> varchar internal address such as an apartment or suite number.</para>
</listitem>
<listitem>
<para><varname>location</varname> varchar usually a city or governing province.</para>
</listitem>
<listitem>
<para><varname>stateAbbrev</varname> varchar two character US State. e.g MA, NY, MI. These are controlled by the <varname>state_lookup</varname> table.</para>
</listitem>
<listitem>
<para><varname>zip</varname> varchar 5-digit zipcode. e.g. 02109.</para>
</listitem>
<listitem>
<para><varname>parsed</varname> boolean - denotes if addess was formed from normalize process. The normalize_address function sets this to true before returning the address.</para>
</listitem>
</orderedlist>
</refsection>
<refsection>
<title>Examples</title>
<para>Output select fields. Use <xref linkend="Pprint_Addy" /> if you want a pretty textual output.</para>
<programlisting>SELECT address As orig, (g.na).streetname, (g.na).streettypeabbrev
FROM (SELECT address, normalize_address(address) As na
FROM addresses_to_geocode) As g;
orig | streetname | streettypeabbrev
-----------------------------------------------------+---------------+------------------
28 Capen Street, Medford, MA | Capen | St
124 Mount Auburn St, Cambridge, Massachusetts 02138 | Mount Auburn | St
950 Main Street, Worcester, MA 01610 | Main | St
529 Main Street, Boston MA, 02129 | Main | St
77 Massachusetts Avenue, Cambridge, MA 02139 | Massachusetts | Ave
25 Wizard of Oz, Walaford, KS 99912323 | Wizard of Oz |
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Geocode"/>, <xref linkend="Pprint_Addy"/></para>
</refsection>
</refentry>
<refentry id="Pprint_Addy">
<refnamediv>
<refname>Pprint_Addy</refname>
<refpurpose>Given a <varname>norm_addy</varname> composite type object, returns a pretty print representation of it. Usually used in conjunction with normalize_address.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>varchar <function>pprint_addy</function></funcdef>
<paramdef><type>norm_addy </type> <parameter>in_addy</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Given a <varname>norm_addy</varname> composite type object, returns a pretty print representation of it. No other data is required aside from what is packaged with the geocoder.</para>
<para>Usually used in conjunction with <xref linkend="Normalize_Address"/>.</para>
</refsection>
<refsection>
<title>Examples</title>
<para>Pretty print a single address</para>
<programlisting>SELECT pprint_addy(normalize_address('202 East Fremont Street, Las Vegas, Nevada 89101')) As pretty_address;
pretty_address
---------------------------------------
202 E Fremont St, Las Vegas, NV 89101
</programlisting>
<para>Pretty print address a table of addresses</para>
<programlisting>SELECT address As orig, pprint_addy(normalize_address(address)) As pretty_address
FROM addresses_to_geocode;
orig | pretty_address
-----------------------------------------------------+-------------------------------------------
529 Main Street, Boston MA, 02129 | 529 Main St, Boston MA, 02129
77 Massachusetts Avenue, Cambridge, MA 02139 | 77 Massachusetts Ave, Cambridge, MA 02139
28 Capen Street, Medford, MA | 28 Capen St, Medford, MA
124 Mount Auburn St, Cambridge, Massachusetts 02138 | 124 Mount Auburn St, Cambridge, MA 02138
950 Main Street, Worcester, MA 01610 | 950 Main St, Worcester, MA 01610</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Normalize_Address"/></para>
</refsection>
</refentry>
<refentry id="Reverse_Geocode">
<refnamediv>
<refname>Reverse_Geocode</refname>
<refpurpose>Takes a geometry point in a known spatial ref sys and returns a record containing an array of theoretically possible addresses and an array of cross streets. If include_strnum_range = true, includes the street range in the cross streets.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>record <function>Reverse_Geocode</function></funcdef>
<paramdef><type>geometry </type> <parameter>pt</parameter></paramdef>
<paramdef choice='opt'><type>boolean </type> <parameter>include_strnum_range=false</parameter></paramdef>
<paramdef><type>geometry[] </type> <parameter>OUT intpt</parameter></paramdef>
<paramdef><type>norm_addy[] </type> <parameter>OUT addy</parameter></paramdef>
<paramdef><type>varchar[] </type> <parameter>OUT street</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Takes a geometry point in a known spatial ref and returns a record containing an array of theoretically possible addresses and an array of cross streets. If include_strnum_range = true, includes the street range in the cross streets.
include_strnum_range defaults to false if not passed in. Addresses are sorted according to which road a point is closest to so first address is most likely the right one.</para>
<para>Why do we say theoretical instead of actual addresses. The Tiger data doesn't have real addresses, but just street ranges. As such the theoretical address is an interpolated address based on the
street ranges. Like for example interpolating one of my addresses returns a 26 Court St. and 26 Court Sq., though there is no such place as 26 Court Sq. This is because a point may be at a corner of 2
streets and thus the logic interpolates along both streets. The logic also assumes addresses are equally spaced along a street, which of course is wrong since you can have a municipal building taking up
a good chunk of the street range and the rest of the buildings are clustered at the end.</para>
<para>Note: Hmm this function relies on Tiger data. If you have not loaded data covering the region of this point, then hmm you will get a record filled with NULLS.</para>
<para> Returned elements of the record are as follows:</para>
<orderedlist>
<listitem>
<para><varname>intpt</varname> is an array of points: These are the center line points on the street closest to the input point. There are as many points as there are addresses.</para>
</listitem>
<listitem>
<para><varname>addy</varname> is an array of norm_addy (normalized addresses): These are an array of possible addresses that fit the input point. The first one in the array is most likely.
Generally there should be only one, except in the case when a point is at the corner of 2 or 3 streets, or the point is somewhere on the road and not off to the side.</para>
</listitem>
<listitem>
<para><varname>street</varname> an array of varchar: These are cross streets (or the street) (streets that intersect or are the street the point is projected to be on).</para>
</listitem>
</orderedlist>
<!-- use this format if new function -->
<para>Availability: 2.0.0 </para>
</refsection>
<refsection>
<title>Examples</title>
<para>Example of a point at the corner of two streets, but closest to one. This is approximate location of MIT: 77 Massachusetts Ave, Cambridge, MA 02139
Note that although we don't have 3 streets, PostgreSQL will just return null for entries above our upper bound so safe to use. This includes street ranges</para>
<programlisting>SELECT pprint_addy(r.addy[1]) As st1, pprint_addy(r.addy[2]) As st2, pprint_addy(r.addy[3]) As st3,
array_to_string(r.street, ',') As cross_streets
FROM reverse_geocode(ST_GeomFromText('POINT(-71.093902 42.359446)',4269),true) As r;
result
------
st1 | st2 | st3 | cross_streets
-------------------------------------------+-----+-----+----------------------------------------------
67 Massachusetts Ave, Cambridge, MA 02139 | | | 67 - 127 Massachusetts Ave,32 - 88 Vassar St</programlisting>
<para>Here we choose not to include the address ranges for the cross streets and picked a location
really really close to a corner of 2 streets thus could be known by two different addresses.</para>
<programlisting>SELECT pprint_addy(r.addy[1]) As st1, pprint_addy(r.addy[2]) As st2,
pprint_addy(r.addy[3]) As st3, array_to_string(r.street, ',') As cross_str
FROM reverse_geocode(ST_GeomFromText('POINT(-71.06941 42.34225)',4269)) As r;
result
--------
st1 | st2 | st3 | cross_str
---------------------------------+---------------------------------+-----+------------------------
5 Bradford St, Boston, MA 02118 | 49 Waltham St, Boston, MA 02118 | | Waltham St
</programlisting>
<para>For this one we reuse our geocoded example from <xref linkend="Geocode" /> and we only want the primary address and at most 2 cross streets.</para>
<programlisting>SELECT actual_addr, lon, lat, pprint_addy((rg).addy[1]) As int_addr1,
(rg).street[1] As cross1, (rg).street[2] As cross2
FROM (SELECT address As actual_addr, lon, lat,
reverse_geocode( ST_SetSRID(ST_Point(lon,lat),4326) ) As rg
FROM addresses_to_geocode WHERE rating > -1) As foo;
actual_addr | lon | lat | int_addr1 | cross1 | cross2
-----------------------------------------------------+-----------+----------+-------------------------------------------+-----------------+------------
529 Main Street, Boston MA, 02129 | -71.07181 | 42.38359 | 527 Main St, Boston, MA 02129 | Medford St |
77 Massachusetts Avenue, Cambridge, MA 02139 | -71.09428 | 42.35988 | 77 Massachusetts Ave, Cambridge, MA 02139 | Vassar St |
26 Capen Street, Medford, MA | -71.12377 | 42.41101 | 9 Edison Ave, Medford, MA 02155 | Capen St | Tesla Ave
124 Mount Auburn St, Cambridge, Massachusetts 02138 | -71.12304 | 42.37328 | 3 University Rd, Cambridge, MA 02138 | Mount Auburn St |
950 Main Street, Worcester, MA 01610 | -71.82368 | 42.24956 | 3 Maywood St, Worcester, MA 01603 | Main St | Maywood Pl
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Pprint_Addy" />, <xref linkend="Geocode" /></para>
</refsection>
</refentry>
<refentry id="Topology_Load_Tiger">
<refnamediv>
<refname>Topology_Load_Tiger</refname>
<refpurpose>Loads a defined region of tiger data into a PostGIS Topology and transforming the tiger data to spatial reference of the topology
and snapping to the precision tolerance of the topology.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Topology_Load_Tiger</function></funcdef>
<paramdef><type>varchar </type> <parameter>topo_name</parameter></paramdef>
<paramdef><type>varchar </type> <parameter>region_type</parameter></paramdef>
<paramdef><type>varchar </type> <parameter>region_id</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Loads a defined region of tiger data into a PostGIS Topology. The faces, nodes and edges are transformed to the spatial reference system of the target topology and points are snapped to the tolerance of the target topology. The created faces, nodes, edges maintain the same ids as the original Tiger data faces, nodes, edges
so that datasets can be in the future be more easily reconciled with tiger data. Returns summary details about the process.</para>
<para>This would be useful for example for redistricting data where you require the newly formed polygons to follow the center lines of streets and for the resulting polygons not to overlap.</para>
<note><para>This function relies on Tiger data as well as the installation of the PostGIS topology module. For more information, refer to <xref linkend="Topology" /> and <xref linkend="installation_configuration" />. If you have not loaded data covering the region of interest, then no topology records will be created. This function will also fail if you have not created a topology using the topology functions.</para></note>
<note><para>Most topology validation errors are a result of tolerance issues where after transformation the edges points don't quite line up or overlap.
To remedy the situation you may want to increase or lower the precision if you get topology validation failures.</para></note>
<para> Required arguments:</para>
<orderedlist>
<listitem>
<para><varname>topo_name</varname> The name of an existing PostGIS topology to load data into.</para>
</listitem>
<listitem>
<para><varname>region_type</varname> The type of bounding region. Currently only <varname>place</varname> and <varname>county</varname> are supported. Plan is to have several more. This is the table to look into to define the region bounds. e.g <varname>tiger.place</varname>, <varname>tiger.county</varname></para>
</listitem>
<listitem>
<para><varname>region_id</varname> This is what TIGER calls the geoid. It is the unique identifier of the region in the table. For place it is the <varname>plcidfp</varname> column in <varname>tiger.place</varname>. For county it is the <varname>cntyidfp</varname> column in <varname>tiger.county</varname>
</para>
</listitem>
</orderedlist>
<!-- use this format if new function -->
<para>Availability: 2.0.0 </para>
</refsection>
<refsection>
<title>Example: Boston, Massachusetts Topology</title>
<para>Create a topology for Boston, Massachusetts in Mass State Plane Feet (2249)
with tolerance 0.25 feet and then load in Boston city tiger faces, edges, nodes.</para>
<programlisting>SELECT topology.CreateTopology('topo_boston', 2249, 0.25);
createtopology
--------------
15
-- 60,902 ms ~ 1 minute on windows 7 desktop running 9.1 (with 5 states tiger data loaded)
SELECT tiger.topology_load_tiger('topo_boston', 'place', '2507000');
-- topology_loader_tiger --
29722 edges holding in temporary. 11108 faces added. 1875 edges of faces added. 20576 nodes added.
19962 nodes contained in a face. 0 edge start end corrected. 31597 edges added.
-- 41 ms --
SELECT topology.TopologySummary('topo_boston');
-- topologysummary--
Topology topo_boston (15), SRID 2249, precision 0.25
20576 nodes, 31597 edges, 11109 faces, 0 topogeoms in 0 layers
-- 28,797 ms to validate yeh returned no errors --
SELECT * FROM
topology.ValidateTopology('topo_boston');
error | id1 | id2
-------------------+----------+-----------
</programlisting>
</refsection>
<refsection>
<title>Example: Suffolk, Massachusetts Topology</title>
<para>Create a topology for Suffolk, Massachusetts in Mass State Plane Meters (26986)
with tolerance 0.25 meters and then load in Suffolk county tiger faces, edges, nodes.</para>
<programlisting>SELECT topology.CreateTopology('topo_suffolk', 26986, 0.25);
-- this took 56,275 ms ~ 1 minute on Windows 7 32-bit with 5 states of tiger loaded
-- must have been warmed up after loading boston
SELECT tiger.topology_load_tiger('topo_suffolk', 'county', '25025');
-- topology_loader_tiger --
36003 edges holding in temporary. 13518 faces added. 2172 edges of faces added.
24761 nodes added. 24075 nodes contained in a face. 0 edge start end corrected. 38175 edges added.
-- 31 ms --
SELECT topology.TopologySummary('topo_suffolk');
-- topologysummary--
Topology topo_suffolk (14), SRID 26986, precision 0.25
24761 nodes, 38175 edges, 13519 faces, 0 topogeoms in 0 layers
-- 33,606 ms to validate --
SELECT * FROM
topology.ValidateTopology('topo_suffolk');
error | id1 | id2
-------------------+----------+-----------
coincident nodes | 81045651 | 81064553
edge crosses node | 81045651 | 85737793
edge crosses node | 81045651 | 85742215
edge crosses node | 81045651 | 620628939
edge crosses node | 81064553 | 85697815
edge crosses node | 81064553 | 85728168
edge crosses node | 81064553 | 85733413
</programlisting>
</refsection>
<refsection>
<title>See Also</title>
<para><xref linkend="CreateTopology" />, <xref linkend="CreateTopoGeom" />, <xref linkend="TopologySummary" />, <xref linkend="ValidateTopology" /></para>
</refsection>
</refentry>
</sect1>