forked from postgis/postgis
-
Notifications
You must be signed in to change notification settings - Fork 0
/
extras_tigergeocoder.xml
1453 lines (1211 loc) · 80.6 KB
/
extras_tigergeocoder.xml
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
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<?xml version="1.0" encoding="UTF-8"?>
<sect1 id="Tiger_Geocoder">
<sect1info>
<abstract>
<para>A plpgsql based geocoder written to work with the <ulink url="http://www.census.gov/geo/www/tiger/">TIGER (Topologically Integrated Geographic Encoding and Referencing system ) / Line and Master Address database export</ulink> released by the US Census Bureau. </para>
<para>There are four components to the geocoder: the data loader functions, the address normalizer, the address geocoder, and the reverse geocoder. </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 <varname>ma_addr</varname>, <varname>ma_edges</varname> etc with constraints to enforce only that state data. Each of these tables inherits from the tables <varname>addr</varname>, <varname>faces</varname>, <varname>edges</varname>, etc located in the <varname>tiger schema</varname>. </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>
<para>For instructions on how to enable the extension in your database and also to load data using it, refer to <xref linkend="install_tiger_geocoder_extension" />.</para>
<para> <note><para>
If you are using tiger geocoder (tiger_2010),
you can upgrade the scripts using the accompanying upgrade_geocoder.bat
/ .sh scripts in extras/tiger. One major change between <varname>tiger_2010</varname> and <varname>tiger_2011+</varname> is that the <varname>county</varname> and <varname>state</varname> tables are no longer broken out by state. If you have data from tiger_2010 and want to replace with tiger_2015, refer to <xref linkend="upgrade_tiger_geocoder" />
</para></note>
<note>
<para>New in PostGIS 2.2.0 release is support for Tiger 2015 data and inclusion of Address Standardizer as part of PostGIS.</para>
<para>New in PostGIS 2.1.0 release is ability to install tiger geocoder with PostgreSQL extension model if you are running PostgreSQL 9.1+. Refer to <xref linkend="install_tiger_geocoder_extension" /> for details.</para></note>
</para>
<para>The <xref linkend="Pagc_Normalize_Address" /> function as a drop in replacement for in-built <xref linkend="Normalize_Address" />. Refer to <xref linkend="installing_pagc_address_standardizer" /> for compile and installation instructions.</para>
<para>Design:</para>
<para>The goal of this project is to build a fully functional geocoder that can process an arbitrary
United States 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. The higher the rating number the worse the result.</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>
<para>
<note><para>The <varname>tiger</varname> schema must be added to the database search path for the functions to work properly.</para></note>
</para>
</abstract>
</sect1info>
<title>Tiger Geocoder</title>
<para>There are a couple other open source geocoders for PostGIS, that unlike tiger geocoder have the advantage of multi-country geocoding support</para>
<itemizedlist>
<listitem><para><ulink url="http://wiki.openstreetmap.org/wiki/Nominatim">Nominatim</ulink>
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></listitem>
<listitem><para><ulink url="http://www.gisgraphy.com/">GIS Graphy</ulink> also utilizes PostGIS and like Nominatim works with OpenStreetMap (OSM) data. It comes with a loader to load OSM data and similar to Nominatim is capable of geocoding not just US. Much like Nominatim, it runs as a webservice and relies on Java 1.5, Servlet apps, Solr. GisGraphy is cross-platform and also has a reverse geocoder among some other neat features.</para></listitem>
</itemizedlist>
<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 choice="opt"><type>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_Nation_Tables_Generate_Script">
<refnamediv>
<refname>Drop_Nation_Tables_Generate_Script</refname>
<refpurpose>Generates a script that drops all tables in the specified schema that start with <varname>county_all</varname>, <varname>state_all</varname> or state code followed by <varname>county</varname> or <varname>state</varname>.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Drop_Nation_Tables_Generate_Script</function></funcdef>
<paramdef choice="opt"><type>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 start with <varname>county_all</varname>, <varname>state_all</varname> or stae code followed by <varname>county</varname> or <varname>state</varname>. This is needed if you are upgrading from <varname>tiger_2010</varname> to <varname>tiger_2011</varname> data.</para>
<para>Availability: 2.1.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT drop_nation_tables_generate_script();
DROP TABLE tiger_data.county_all;
DROP TABLE tiger_data.county_all_lookup;
DROP TABLE tiger_data.state_all;
DROP TABLE tiger_data.ma_county;
DROP TABLE tiger_data.ma_state;</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_Generate_Nation_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>param_state</parameter></paramdef>
<paramdef choice="opt"><type>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 choice="opt"><type>integer </type> <parameter>max_results=10</parameter></paramdef>
<paramdef choice="opt"><type>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 choice="opt"><type>integer </type> <parameter>max_results=10</parameter></paramdef>
<paramdef choice="opt"><type>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. The new parameter <varname>max_results</varname> useful for specifying number of best results or just returning 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', 1) As g;
rating | lon | lat | stno | street | styp | city | st | zip
--------+-------------------+----------------+------+--------+------+--------+----+-------
0 | -71.0557505845646 | 42.35897920691 | 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',1) As g;
rating | wktlonlat | stno | street | styp | city | st | zip
--------+---------------------------+------+--------+------+--------+----+-------
70 | POINT(-71.06466 42.35114) | 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.rating,-1), pprint_addy(g.addy),
ST_X(g.geomout)::numeric(8,5), ST_Y(g.geomout)::numeric(8,5) )
FROM (SELECT addid, address
FROM addresses_to_geocode
WHERE rating IS NULL ORDER BY addid LIMIT 3) As a
LEFT JOIN LATERAL geocode(a.address,1) As g ON true
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.07177 | 42.38357 | 529 Main St, Boston, MA 02129 | 0
2 | 77 Massachusetts Avenue, Cambridge, MA 02139 | -71.09396 | 42.35961 | 77 Massachusetts Ave, Cambridge, MA 02139 | 0
3 | 25 Wizard of Oz, Walaford, KS 99912323 | -97.92913 | 38.12717 | Willowbrook, KS 67502 | 108
(3 rows)</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
--------+---------------------------+------+---------+------+------+----+-------
7 | POINT(-70.96796 42.4659) | 100 | Federal | St | Lynn | MA | 01905
16 | POINT(-70.96786 42.46853) | NULL | Federal | St | Lynn | MA | 01905
(2 rows)
Time: 622.939 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 geomout as the point location in NAD 83 long lat, a <varname>normalized_address</varname> (addy) 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. Uses Tiger data (edges, faces, addr), PostgreSQL fuzzy string matching (soundex, levenshtein).</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 choice="opt"><type>text </type> <parameter> in_city</parameter></paramdef>
<paramdef choice="opt"><type>text </type> <parameter> in_zip</parameter></paramdef>
<paramdef choice="opt"><type>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. Currently a bit slow (3000 ms)</para>
<para>Testing on Windows 2003 64-bit 8GB on PostGIS 2.0 PostgreSQL 64-bit Tiger 2011 data loaded -- (41ms)</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 on the windows 7 box), on the windows 2003 64-bit 741 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="Get_Geocode_Setting">
<refnamediv>
<refname>Get_Geocode_Setting</refname>
<refpurpose>Returns value of specific setting stored in tiger.geocode_settings table.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Get_Geocode_Setting</function></funcdef>
<paramdef><type>text </type> <parameter> setting_name</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Returns value of specific setting stored in tiger.geocode_settings table. Settings allow you to toggle debugging of functions. Later plans will be to control rating with settings. Current list of settings are as follows:</para>
<screen> name | setting | unit | category | short_desc
--------------------------------+---------+---------+-----------+------------------------------------------------------------------------------------------------------------------------------
debug_geocode_address | false | boolean | debug | outputs debug information in notice log such as queries when geocode_address is called if true
debug_geocode_intersection | false | boolean | debug | outputs debug information in notice log such as queries when geocode_intersection is called if true
debug_normalize_address | false | boolean | debug | outputs debug information in notice log such as queries and intermediate expressions when normalize_address is called if true
debug_reverse_geocode | false | boolean | debug | if true, outputs debug information in notice log such as queries and intermediate expressions when reverse_geocode
reverse_geocode_numbered_roads | 0 | integer | rating | For state and county highways, 0 - no preference in name,
1 - prefer the numbered highway name, 2 - prefer local state/county name
use_pagc_address_parser | false | boolean | normalize | If set to true, will try to use the address_standardizer extension (via pagc_normalize_address)
instead of tiger normalize_address built one </screen>
<para>Changed: 2.2.0 : default settings are now kept in a table called geocode_settings_default. Use customized settingsa are in geocode_settings and only contain those that have been set by user.</para>
<para>Availability: 2.1.0</para>
</refsection>
<refsection>
<title>Example return debugging setting</title>
<programlisting>SELECT get_geocode_setting('debug_geocode_address) As result;
result
---------
false
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Set_Geocode_Setting" /></para>
</refsection>
</refentry>
<refentry id="Get_Tract">
<refnamediv>
<refname>Get_Tract</refname>
<refpurpose>Returns census tract or field from tract table of where the geometry is located. Default to returning short name of tract.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>get_tract</function></funcdef>
<paramdef><type>geometry </type> <parameter> loc_geom</parameter></paramdef>
<paramdef choice="opt"><type>text </type> <parameter> output_field=name</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Given a geometry will return the census tract location of that geometry. NAD 83 long lat is assumed if no spatial ref sys is specified.</para>
<note><para>This function uses the census <varname>tract</varname> whic is not loaded by default. If you have already loaded your state table, you can load tract
as well as bg, and tabblock using the <xref linkend="Loader_Generate_Census_Script" /> script.</para>
<para>If you have not loaded your state data yet and want these additional tables loaded, do the following</para>
<programlisting>UPDATE tiger.loader_lookuptables SET load = true WHERE load = false AND lookup_name IN('tract', 'bg', 'tabblock');</programlisting>
<para>then they will be included by the <xref linkend="Loader_Generate_Script" />.</para>
</note>
<para>Availability: 2.0.0</para>
</refsection>
<refsection>
<title>Examples: Basic</title>
<programlisting>SELECT get_tract(ST_Point(-71.101375, 42.31376) ) As tract_name;
tract_name
---------
1203.01
</programlisting>
<programlisting>--this one returns the tiger geoid
SELECT get_tract(ST_Point(-71.101375, 42.31376), 'tract_id' ) As tract_id;
tract_id
---------
25025120301</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Geocode" />></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></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_Census_Script">
<refnamediv>
<refname>Loader_Generate_Census_Script</refname>
<refpurpose>Generates a shell script for the specified platform for the specified states that will download Tiger census state tract, bg, and tabblocks data tables, stage and load into <varname>tiger_data</varname> schema. Each state script is returned as a separate record.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>setof text <function>loader_generate_census_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 census state <varname>tract</varname>, block groups <varname>bg</varname>, and <varname>tabblocks</varname> data tables, 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. 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 </para>
<note><para><xref linkend="Loader_Generate_Script" /> includes this logic, but if you installed tiger geocoder prior to PostGIS 2.0.0 alpha5, you'll need to run this on the states you have already done
to get these additional tables.</para></note>
</refsection>
<refsection>
<title>Examples</title>
<para>Generate script to load up data for select states in Windows shell script format.</para>
<programlisting>SELECT loader_generate_census_script(ARRAY['MA'], 'windows');
-- result --
set STATEDIR="\gisdata\www2.census.gov\geo\pvs\tiger2010st\25_Massachusetts"
set TMPDIR=\gisdata\temp\
set UNZIPTOOL="C:\Program Files\7-Zip\7z.exe"
set WGETTOOL="C:\wget\wget.exe"
set PGBIN=C:\projects\pg\pg91win\bin\
set PGPORT=5432
set PGHOST=localhost
set PGUSER=postgres
set PGPASSWORD=yourpasswordhere
set PGDATABASE=tiger_postgis20
set PSQL="%PGBIN%psql"
set SHP2PGSQL="%PGBIN%shp2pgsql"
cd \gisdata
%WGETTOOL% http://www2.census.gov/geo/pvs/tiger2010st/25_Massachusetts/25/ --no-parent --relative --accept=*bg10.zip,*tract10.zip,*tabblock10.zip --mirror --reject=html
del %TMPDIR%\*.* /Q
%PSQL% -c "DROP SCHEMA tiger_staging CASCADE;"
%PSQL% -c "CREATE SCHEMA tiger_staging;"
cd %STATEDIR%
for /r %%z in (*.zip) do %UNZIPTOOL% e %%z -o%TMPDIR%
cd %TMPDIR%
%PSQL% -c "CREATE TABLE tiger_data.MA_tract(CONSTRAINT pk_MA_tract PRIMARY KEY (tract_id) ) INHERITS(tiger.tract); "
%SHP2PGSQL% -c -s 4269 -g the_geom -W "latin1" tl_2010_25_tract10.dbf tiger_staging.ma_tract10 | %PSQL%
%PSQL% -c "ALTER TABLE tiger_staging.MA_tract10 RENAME geoid10 TO tract_id; SELECT loader_load_staged_data(lower('MA_tract10'), lower('MA_tract')); "
%PSQL% -c "CREATE INDEX tiger_data_MA_tract_the_geom_gist ON tiger_data.MA_tract USING gist(the_geom);"
%PSQL% -c "VACUUM ANALYZE tiger_data.MA_tract;"
%PSQL% -c "ALTER TABLE tiger_data.MA_tract ADD CONSTRAINT chk_statefp CHECK (statefp = '25');"
: </programlisting>
<para>Generate sh script</para>
<programlisting>STATEDIR="/gisdata/www2.census.gov/geo/pvs/tiger2010st/25_Massachusetts"
TMPDIR="/gisdata/temp/"
UNZIPTOOL=unzip
WGETTOOL="/usr/bin/wget"
export PGBIN=/usr/pgsql-9.0/bin
export PGPORT=5432
export PGHOST=localhost
export PGUSER=postgres
export PGPASSWORD=yourpasswordhere
export PGDATABASE=geocoder
PSQL=${PGBIN}/psql
SHP2PGSQL=${PGBIN}/shp2pgsql
cd /gisdata
wget http://www2.census.gov/geo/pvs/tiger2010st/25_Massachusetts/25/ --no-parent --relative --accept=*bg10.zip,*tract10.zip,*tabblock10.zip --mirror --reject=html
rm -f ${TMPDIR}/*.*
${PSQL} -c "DROP SCHEMA tiger_staging CASCADE;"
${PSQL} -c "CREATE SCHEMA tiger_staging;"
cd $STATEDIR
for z in *.zip; do $UNZIPTOOL -o -d $TMPDIR $z; done
:
: </programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_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 and also loads census tract, block groups, and blocks tables.</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 and load census tract (tract), block groups (bg), and blocks (tabblocks) tables .</para>
<note><para>If you are using pgAdmin 3, be warned that by default pgAdmin 3 truncates long text. To fix, change
<emphasis>File -> Options -> Query Tool -> Query Editor - > Max. characters per column</emphasis> to larger than 50000 characters.</para></note>
</refsection>
<refsection>
<title>Examples</title>
<para>Using psql where gistest is your database and <filename>/gisdata/data_load.sh</filename> is the file to create with the shell commands to run.</para>
<programlisting><![CDATA[psql -U postgres -h localhost -d gistest -A -t \
-c "SELECT Loader_Generate_Script(ARRAY['MA'], 'gistest')" > /gisdata/data_load.sh;]]>
</programlisting>
<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 TMPDIR=\gisdata\temp\
set UNZIPTOOL="C:\Program Files\7-Zip\7z.exe"
set WGETTOOL="C:\wget\wget.exe"
set PGBIN=C:\Program Files\PostgreSQL\9.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"
cd \gisdata
cd \gisdata
%WGETTOOL% ftp://ftp2.census.gov/geo/tiger/TIGER2015/PLACE/tl_*_25_* --no-parent --relative --recursive --level=2 --accept=zip --mirror --reject=html
cd \gisdata/ftp2.census.gov/geo/tiger/TIGER2015/PLACE
:
:</programlisting>
<para>Generate sh script</para>
<programlisting>SELECT loader_generate_script(ARRAY['MA','RI'], 'sh') AS result;
-- result --
TMPDIR="/gisdata/temp/"
UNZIPTOOL=unzip
WGETTOOL="/usr/bin/wget"
export PGBIN=/usr/lib/postgresql/9.4/bin
export PGPORT=5432
export PGHOST=localhost
export PGUSER=postgres
export PGPASSWORD=yourpasswordhere
export PGDATABASE=geocoder
PSQL=${PGBIN}/psql
SHP2PGSQL=${PGBIN}/shp2pgsql
cd /gisdata
cd /gisdata
wget ftp://ftp2.census.gov/geo/tiger/TIGER2015/PLACE/tl_*_25_* --no-parent --relative --recursive --level=2 --accept=zip --mirror --reject=html
cd /gisdata/ftp2.census.gov/geo/tiger/TIGER2015/PLACE
rm -f ${TMPDIR}/*.*
:
:</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="install_tiger_geocoder_extension" />, <xref linkend="Loader_Generate_Nation_Script" /></para>
</refsection>
</refentry>
<refentry id="Loader_Generate_Nation_Script">
<refnamediv>
<refname>Loader_Generate_Nation_Script</refname>
<refpurpose>Generates a shell script for the specified platform that loads in the county and state lookup tables.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>loader_generate_nation_script</function></funcdef>
<paramdef><type>text</type> <parameter>os</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Generates a shell script for the specified platform that loads in the <varname>county_all</varname>, <varname>county_all_lookup</varname>, <varname>state_all</varname> tables into <varname>tiger_data</varname> schema. These inherit respectively from the <varname>county</varname>, <varname>county_lookup</varname>, <varname>state</varname> tables in <varname>tiger</varname> schema.</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. </para>
<para>It uses the following control tables <varname>tiger.loader_platform</varname>, <varname>tiger.loader_variables</varname>, and <varname>tiger.loader_lookuptables</varname> 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/unix. 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>Enhanced: 2.4.1 zip code 5 tabulation area (zcta5) load step was fixed and when enabled, zcta5 data is loaded as a single table called zcta5_all as part of the nation script load.</para>
<para>Availability: 2.1.0 </para>
<note><para>If you want zip code 5 tabulation area (zcta5) to be included in your nation script load, do the following:</para> <programlisting>UPDATE tiger.loader_lookuptables SET load = true WHERE table_name = 'zcta510';</programlisting></note>
<note><para>If you were running <varname>tiger_2010</varname> version and you want to reload as state with newer tiger data, you'll need to for the very first load generate and run drop statements <xref linkend="Drop_Nation_Tables_Generate_Script" /> before you run this script.</para></note>
</refsection>
<refsection>
<title>Examples</title>
<para>Generate script script to load nation data Windows.</para>
<programlisting>SELECT loader_generate_nation_script('windows'); </programlisting>
<para>Generate script to load up data for Linux/Unix systems.</para>
<programlisting>SELECT loader_generate_nation_script('sh'); </programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="Loader_Generate_Script" /></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></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] [parsed] [zip4] [address_alphanumeric]</para>
<para>Enhanced: 2.4.0 norm_addy object includes additional fields zip4 and address_alphanumeric.</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>
<listitem>
<para><varname>zip4</varname> last 4 digits of a 9 digit zip code. Availability: PostGIS 2.4.0.</para>
</listitem>
<listitem>
<para><varname>address_alphanumeric</varname> Full street number even if it has alpha characters like 17R. Parsing of this is better using <xref linkend="Pagc_Normalize_Address" /> function. Availability: PostGIS 2.4.0.</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
-----------------------------------------------------+---------------+------------------