forked from postgis/postgis
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathusing_postgis_dataman.xml
2621 lines (2198 loc) · 106 KB
/
using_postgis_dataman.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"?>
<chapter id="using_postgis_dbmanagement">
<title>Using PostGIS: Data Management and Queries</title>
<sect1 id="RefObject">
<title>GIS Objects</title>
<para>The GIS objects supported by PostGIS are a superset of the "Simple
Features" defined by the OpenGIS Consortium (OGC). As of version 0.9,
PostGIS supports all the objects and functions specified in the OGC
"Simple Features for SQL" specification.</para>
<para>PostGIS extends the standard with support for 3DZ,3DM and 4D
coordinates.</para>
<sect2 id="OpenGISWKBWKT">
<title>OpenGIS WKB and WKT</title>
<para>The OpenGIS specification defines two standard ways of expressing
spatial objects: the Well-Known Text (WKT) form and the Well-Known
Binary (WKB) form. Both WKT and WKB include information about the type
of the object and the coordinates which form the object.</para>
<para>Examples of the text representations (WKT) of the spatial objects
of the features are as follows:</para>
<itemizedlist>
<listitem>
<para>POINT(0 0)</para>
</listitem>
<listitem>
<para>LINESTRING(0 0,1 1,1 2)</para>
</listitem>
<listitem>
<para>POLYGON((0 0,4 0,4 4,0 4,0 0),(1 1, 2 1, 2 2, 1 2,1 1))</para>
</listitem>
<listitem>
<para>MULTIPOINT((0 0),(1 2))</para>
</listitem>
<listitem>
<para>MULTILINESTRING((0 0,1 1,1 2),(2 3,3 2,5 4))</para>
</listitem>
<listitem>
<para>MULTIPOLYGON(((0 0,4 0,4 4,0 4,0 0),(1 1,2 1,2 2,1 2,1 1)),
((-1 -1,-1 -2,-2 -2,-2 -1,-1 -1)))</para>
</listitem>
<listitem>
<para>GEOMETRYCOLLECTION(POINT(2 3),LINESTRING(2 3,3 4))</para>
</listitem>
</itemizedlist>
<para>The OpenGIS specification also requires that the internal storage
format of spatial objects include a spatial referencing system
identifier (SRID). The SRID is required when creating spatial objects
for insertion into the database.</para>
<para>Input/Output of these formats are available using the following
interfaces:</para>
<programlisting>bytea WKB = ST_AsBinary(geometry);
text WKT = ST_AsText(geometry);
geometry = ST_GeomFromWKB(bytea WKB, SRID);
geometry = ST_GeometryFromText(text WKT, SRID);</programlisting>
<para>For example, a valid insert statement to create and insert an OGC
spatial object would be:</para>
<programlisting>INSERT INTO geotable ( the_geom, the_name )
VALUES ( ST_GeomFromText('POINT(-126.4 45.32)', 312), 'A Place');</programlisting>
</sect2>
<sect2 id="EWKB_EWKT">
<title>PostGIS EWKB, EWKT and Canonical Forms</title>
<para>OGC formats only support 2d geometries, and the associated SRID is
*never* embedded in the input/output representations.</para>
<para>PostGIS extended formats are currently superset of OGC one (every
valid WKB/WKT is a valid EWKB/EWKT) but this might vary in the future,
specifically if OGC comes out with a new format conflicting with our
extensions. Thus you SHOULD NOT rely on this feature!</para>
<para>PostGIS EWKB/EWKT add 3dm,3dz,4d coordinates support and embedded
SRID information.</para>
<para>Examples of the text representations (EWKT) of the extended
spatial objects of the features are as follows.</para>
<itemizedlist>
<listitem>
<para>POINT(0 0 0) -- XYZ</para>
</listitem>
<listitem>
<para>SRID=32632;POINT(0 0) -- XY with SRID</para>
</listitem>
<listitem>
<para>POINTM(0 0 0) -- XYM</para>
</listitem>
<listitem>
<para>POINT(0 0 0 0) -- XYZM</para>
</listitem>
<listitem>
<para>SRID=4326;MULTIPOINTM(0 0 0,1 2 1) -- XYM with SRID</para>
</listitem>
<listitem>
<para>MULTILINESTRING((0 0 0,1 1 0,1 2 1),(2 3 1,3 2 1,5 4
1))</para>
</listitem>
<listitem>
<para>POLYGON((0 0 0,4 0 0,4 4 0,0 4 0,0 0 0),(1 1 0,2 1 0,2 2 0,1 2
0,1 1 0))</para>
</listitem>
<listitem>
<para>MULTIPOLYGON(((0 0 0,4 0 0,4 4 0,0 4 0,0 0 0),(1 1 0,2 1 0,2 2
0,1 2 0,1 1 0)),((-1 -1 0,-1 -2 0,-2 -2 0,-2 -1 0,-1 -1 0)))</para>
</listitem>
<listitem>
<para>GEOMETRYCOLLECTIONM( POINTM(2 3 9), LINESTRINGM(2 3 4, 3 4 5) )</para>
</listitem>
<listitem>
<para>MULTICURVE( (0 0, 5 5), CIRCULARSTRING(4 0, 4 4, 8 4) )</para>
</listitem>
<listitem>
<para>POLYHEDRALSURFACE( ((0 0 0, 0 0 1, 0 1 1, 0 1 0, 0 0 0)),
((0 0 0, 0 1 0, 1 1 0, 1 0 0, 0 0 0)), ((0 0 0, 1 0 0, 1 0 1, 0 0 1, 0 0 0)), ((1 1 0, 1 1 1, 1 0 1, 1 0 0, 1 1 0)),
((0 1 0, 0 1 1, 1 1 1, 1 1 0, 0 1 0)), ((0 0 1, 1 0 1, 1 1 1, 0 1 1, 0 0 1)) )</para>
</listitem>
<listitem>
<para>TRIANGLE ((0 0, 0 9, 9 0, 0 0))</para>
</listitem>
<listitem>
<para>TIN( ((0 0 0, 0 0 1, 0 1 0, 0 0 0)),
((0 0 0, 0 1 0, 1 1 0, 0 0 0)) )</para>
</listitem>
</itemizedlist>
<para>Input/Output of these formats are available using the following
interfaces:</para>
<programlisting>bytea EWKB = ST_AsEWKB(geometry);
text EWKT = ST_AsEWKT(geometry);
geometry = ST_GeomFromEWKB(bytea EWKB);
geometry = ST_GeomFromEWKT(text EWKT);</programlisting>
<para>For example, a valid insert statement to create and insert a
PostGIS spatial object would be:</para>
<programlisting>INSERT INTO geotable ( the_geom, the_name )
VALUES ( ST_GeomFromEWKT('SRID=312;POINTM(-126.4 45.32 15)'), 'A Place' )</programlisting>
<para>The "canonical forms" of a PostgreSQL type are the representations
you get with a simple query (without any function call) and the one
which is guaranteed to be accepted with a simple insert, update or copy.
For the postgis 'geometry' type these are: <programlisting>- Output
- binary: EWKB
ascii: HEXEWKB (EWKB in hex form)
- Input
- binary: EWKB
ascii: HEXEWKB|EWKT </programlisting></para>
<para>For example this statement reads EWKT and returns HEXEWKB in the
process of canonical ascii input/output:</para>
<programlisting>=# SELECT 'SRID=4;POINT(0 0)'::geometry;
geometry
----------------------------------------------------
01010000200400000000000000000000000000000000000000
(1 row)</programlisting>
</sect2>
<sect2 id="SQL_MM_Part3">
<title>SQL-MM Part 3</title>
<para>The SQL Multimedia Applications Spatial specification extends the
simple features for SQL spec by defining a number of circularly
interpolated curves.</para>
<para>The SQL-MM definitions include 3dm, 3dz and 4d coordinates, but do
not allow the embedding of SRID information.</para>
<para>The well-known text extensions are not yet fully supported.
Examples of some simple curved geometries are shown below:</para>
<itemizedlist>
<listitem>
<para>CIRCULARSTRING(0 0, 1 1, 1 0)</para>
<para>CIRCULARSTRING(0 0, 4 0, 4 4, 0 4, 0 0)</para>
<para>The CIRCULARSTRING is the basic curve type, similar to a
LINESTRING in the linear world. A single segment required three
points, the start and end points (first and third) and any other
point on the arc. The exception to this is for a closed circle,
where the start and end points are the same. In this case the
second point MUST be the center of the arc, ie the opposite side of
the circle. To chain arcs together, the last point of the previous
arc becomes the first point of the next arc, just like in
LINESTRING. This means that a valid circular string must have an
odd number of points greater than 1.</para>
</listitem>
<listitem>
<para>COMPOUNDCURVE(CIRCULARSTRING(0 0, 1 1, 1 0),(1 0, 0 1))</para>
<para>A compound curve is a single, continuous curve that has both
curved (circular) segments and linear segments. That means that
in addition to having well-formed components, the end point of
every component (except the last) must be coincident with the
start point of the following component.</para>
</listitem>
<listitem>
<para>CURVEPOLYGON(CIRCULARSTRING(0 0, 4 0, 4 4, 0 4, 0 0),(1 1, 3
3, 3 1, 1 1))</para>
<para>Example compound curve in a curve polygon:
CURVEPOLYGON(COMPOUNDCURVE(CIRCULARSTRING(0 0,2 0, 2 1, 2 3, 4 3),(4 3, 4 5, 1 4, 0 0)),
CIRCULARSTRING(1.7 1, 1.4 0.4, 1.6 0.4, 1.6 0.5, 1.7 1) )
</para>
<para>A CURVEPOLYGON is just like a polygon, with an outer ring
and zero or more inner rings. The difference is that a ring can
take the form of a circular string, linear string or compound
string.</para>
<para>As of PostGIS 1.4 PostGIS supports compound curves in a curve polygon.</para>
</listitem>
<listitem>
<para>MULTICURVE((0 0, 5 5),CIRCULARSTRING(4 0, 4 4, 8 4))</para>
<para>The MULTICURVE is a collection of curves, which can include
linear strings, circular strings or compound strings.</para>
</listitem>
<listitem>
<para>MULTISURFACE(CURVEPOLYGON(CIRCULARSTRING(0 0, 4 0, 4 4, 0 4, 0
0),(1 1, 3 3, 3 1, 1 1)),((10 10, 14 12, 11 10, 10 10),(11 11, 11.5
11, 11 11.5, 11 11)))</para>
<para>This is a collection of surfaces, which can be (linear)
polygons or curve polygons.</para>
</listitem>
</itemizedlist>
<note>
<para>PostGIS prior to 1.4 does not support compound curves in a curve polygon, but
PostGIS 1.4 and above do support the use of Compound Curves in
a Curve Polygon.</para>
</note>
<note>
<para>All floating point comparisons within the SQL-MM implementation
are performed to a specified tolerance, currently 1E-8.</para>
</note>
</sect2>
</sect1>
<sect1 id="PostGIS_Geography">
<title>PostGIS Geography Type</title>
<para>The geography type provides native support for spatial features represented on "geographic" coordinates (sometimes called "geodetic" coordinates, or "lat/lon", or "lon/lat"). Geographic coordinates are spherical coordinates expressed in angular units (degrees). </para>
<para>The basis for the PostGIS geometry type is a plane. The shortest path between two points on the plane is a straight line. That means calculations on geometries (areas, distances, lengths, intersections, etc) can be calculated using cartesian mathematics and straight line vectors.</para>
<para>The basis for the PostGIS geographic type is a sphere. The shortest path between two points on the sphere is a great circle arc. That means that calculations on geographies (areas, distances, lengths, intersections, etc) must be calculated on the sphere, using more complicated mathematics. For more accurate measurements, the calculations must take the actual spheroidal shape of the world into account, and the mathematics becomes very complicated indeed.</para>
<para>Because the underlying mathematics is much more complicated, there are fewer functions defined for the geography type than for the geometry type. Over time, as new algorithms are added, the capabilities of the geography type will expand.</para>
<para>It uses a data type called <varname>geography</varname>. None of the GEOS functions support the <varname>geography</varname>
type. As a workaround one can convert back and forth between geometry and geography types.</para>
<para>Prior to PostGIS 2.2, the geography type only supported WGS 84 long lat (SRID:4326).
For PostGIS 2.2 and above, any long/lat based spatial reference system defined in the <varname>spatial_ref_sys</varname> table can be used.
You can even add your own custom spheroidal spatial refence system as described in <ulink url="http://www.bostongis.com/blog/index.php?/archives/266-geography-type-is-not-limited-to-earth.html">geography type is not limited to earth</ulink>.</para>
<para>Regardless which spatial reference system you use, the units returned by the measurement (<xref linkend="ST_Distance" />, <xref linkend="ST_Length" />, <xref linkend="ST_Perimeter" />, <xref linkend="ST_Area" />) and for input of <xref linkend="ST_DWithin" /> are in meters.</para>
<para>The geography type uses the PostgreSQL 8.3+ typmod definition format so that a table with a geography field
can be added in a single step. All the standard OGC formats except for curves are supported.</para>
<sect2 id="Geography_Basics">
<title>Geography Basics</title>
<para>The geography type does not support curves, TINS, or POLYHEDRALSURFACEs, but other geometry types are supported. Standard geometry type data will autocast to geography if it is of SRID 4326. You can also use the EWKT and EWKB
conventions to insert data.</para>
<itemizedlist>
<listitem>
<para>POINT: Creating a table with 2d point geography when srid is not specified defaults to 4326 WGS 84 long lat:</para>
<para><programlisting>CREATE TABLE ptgeogwgs(gid serial PRIMARY KEY, geog geography(POINT) );</programlisting></para>
<para>POINT: Creating a table with 2d point geography in NAD83 longlat:</para>
<para><programlisting>CREATE TABLE ptgeognad83(gid serial PRIMARY KEY, geog geography(POINT,4269) );</programlisting></para>
<para>Creating a table with z coordinate point and explicitly specifying srid</para>
<para><programlisting>CREATE TABLE ptzgeogwgs84(gid serial PRIMARY KEY, geog geography(POINTZ,4326) );</programlisting></para>
</listitem>
<listitem>
<para>LINESTRING</para>
<para><programlisting>CREATE TABLE lgeog(gid serial PRIMARY KEY, geog geography(LINESTRING) );</programlisting></para>
</listitem>
<listitem>
<para>POLYGON</para>
<para><programlisting>--polygon NAD 1927 long lat
CREATE TABLE lgeognad27(gid serial PRIMARY KEY, geog geography(POLYGON,4267) );</programlisting></para>
</listitem>
<listitem>
<para>MULTIPOINT</para>
</listitem>
<listitem>
<para>MULTILINESTRING</para>
</listitem>
<listitem>
<para>MULTIPOLYGON</para>
</listitem>
<listitem>
<para>GEOMETRYCOLLECTION</para>
</listitem>
<!-- TODO: Add other examples -->
</itemizedlist>
<para>The geography fields don't get registered in the <varname>geometry_columns</varname>. They get registered in a view called
<varname>geography_columns</varname> which is a view against the system catalogs so is always automatically kept up to date without need
for an AddGeom... like function.</para>
<para>Now, check the "geography_columns" view and see that your table is listed.</para>
<para>You can create a new table with a GEOGRAPHY column using the CREATE TABLE syntax.</para>
<para>
<programlisting>CREATE TABLE global_points (
id SERIAL PRIMARY KEY,
name VARCHAR(64),
location GEOGRAPHY(POINT,4326)
);</programlisting>
</para>
<para>Note that the location column has type GEOGRAPHY and that geography type supports two optional modifier: a type modifier that restricts the kind of shapes and dimensions allowed in the column; an SRID modifier that restricts the coordinate reference identifier to a particular number.</para>
<para>Allowable values for the type modifier are: POINT, LINESTRING, POLYGON, MULTIPOINT, MULTILINESTRING, MULTIPOLYGON. The modifier also supports dimensionality restrictions through suffixes: Z, M and ZM. So, for example a modifier of 'LINESTRINGM' would only allow line strings with three dimensions in, and would treat the third dimension as a measure.
Similarly, 'POINTZM' would expect four dimensional data.</para>
<para>If you do not specify an SRID, the SRID will default to 4326 WGS 84 long/lat will be used, and all calculations will proceed using WGS84.</para>
<para>Once you have created your table, you can see it in the GEOGRAPHY_COLUMNS table:</para>
<para><programlisting>
-- See the contents of the metadata view
SELECT * FROM geography_columns;</programlisting></para>
<para>You can insert data into the table the same as you would if it was using a GEOMETRY column:</para>
<para><programlisting>-- Add some data into the test table
INSERT INTO global_points (name, location) VALUES ('Town', ST_GeogFromText('SRID=4326;POINT(-110 30)') );
INSERT INTO global_points (name, location) VALUES ('Forest', ST_GeogFromText('SRID=4326;POINT(-109 29)') );
INSERT INTO global_points (name, location) VALUES ('London', ST_GeogFromText('SRID=4326;POINT(0 49)') );</programlisting></para>
<para>Creating an index works the same as GEOMETRY.
PostGIS will note that the column type is GEOGRAPHY and create an appropriate sphere-based index instead of the usual planar index used for GEOMETRY.</para>
<para><programlisting>-- Index the test table with a spherical index
CREATE INDEX global_points_gix ON global_points USING GIST ( location );</programlisting>
</para>
<para>Query and measurement functions use units of meters. So distance parameters should be expressed in meters, and return values should be expected in meters (or square meters for areas).</para>
<para><programlisting>-- Show a distance query and note, London is outside the 1000km tolerance
SELECT name FROM global_points WHERE ST_DWithin(location, ST_GeogFromText('SRID=4326;POINT(-110 29)'), 1000000);</programlisting>
</para>
<para>You can see the power of GEOGRAPHY in action by calculating how close a plane flying from Seattle to London (LINESTRING(-122.33 47.606, 0.0 51.5)) comes to Reykjavik (POINT(-21.96 64.15)).</para>
<para><programlisting>-- Distance calculation using GEOGRAPHY (122.2km)
SELECT ST_Distance('LINESTRING(-122.33 47.606, 0.0 51.5)'::geography, 'POINT(-21.96 64.15)':: geography);</programlisting>
</para>
<para><programlisting>-- Distance calculation using GEOMETRY (13.3 "degrees")
SELECT ST_Distance('LINESTRING(-122.33 47.606, 0.0 51.5)'::geometry, 'POINT(-21.96 64.15)':: geometry);</programlisting>
</para>
<para>Testing different lon/lat projects, requires PostGIS 2.2+.
Any long lat spatial reference system listed in <varname>spatial_ref_sys</varname> table is allowed.</para>
<para> <programlisting>-- NAD 83 lon/lat
SELECT 'SRID=4269;POINT(-123 34)'::geography;
geography
----------------------------------------------------
0101000020AD1000000000000000C05EC00000000000004140
(1 row)</programlisting>
<programlisting>-- NAD27 lon/lat
SELECT 'SRID=4267;POINT(-123 34)'::geography;
geography
----------------------------------------------------
0101000020AB1000000000000000C05EC00000000000004140
(1 row)</programlisting>
<programlisting>-- NAD83 UTM zone meters, yields error since its a meter based projection
SELECT 'SRID=26910;POINT(-123 34)'::geography;
ERROR: Only lon/lat coordinate systems are supported in geography.
LINE 1: SELECT 'SRID=26910;POINT(-123 34)'::geography;</programlisting></para>
<para>The GEOGRAPHY type calculates the true shortest distance over the sphere between Reykjavik and the great circle flight path between Seattle and London.</para>
<para> <ulink url="http://gc.kls2.com/cgi-bin/gc?PATH=SEA-LHR">Great Circle mapper</ulink>
The GEOMETRY type calculates a meaningless cartesian distance between Reykjavik and the straight line path from Seattle to London plotted on a flat map of the world. The nominal units of the result might be called "degrees", but the result doesn't correspond to any true angular difference between the points, so even calling them "degrees" is inaccurate.</para>
</sect2>
<sect2 id="PostGIS_GeographyVSGeometry">
<title>When to use Geography Data type over Geometry data type</title>
<para>The geography type allows you to store data in longitude/latitude coordinates, but at a cost: there are fewer functions defined on GEOGRAPHY than there are on GEOMETRY; those functions that are defined take more CPU time to execute.</para>
<para>The type you choose should be conditioned on the expected working area of the application you are building. Will your data span the globe or a large continental area, or is it local to a state, county or municipality? </para>
<itemizedlist>
<listitem><para>If your data is contained in a small area, you might find that choosing an appropriate projection and using GEOMETRY is the best solution, in terms of performance and functionality available.</para></listitem>
<listitem><para>If your data is global or covers a continental region, you may find that GEOGRAPHY allows you to build a system without having to worry about projection details.
You store your data in longitude/latitude, and use the functions that have been defined on GEOGRAPHY.</para></listitem>
<listitem><para>If you don't understand projections, and you don't want to learn about them, and you're prepared to accept the limitations in functionality available in GEOGRAPHY, then it might be easier for you to use GEOGRAPHY than GEOMETRY.
Simply load your data up as longitude/latitude and go from there.</para></listitem>
</itemizedlist>
<para>Refer to <xref linkend="PostGIS_TypeFunctionMatrix" /> for compare between
what is supported for Geography vs. Geometry. For a brief listing and description of Geography functions, refer to
<xref linkend="PostGIS_GeographyFunctions" />
</para>
</sect2>
<sect2 id="PostGIS_Geography_AdvancedFAQ">
<title>Geography Advanced FAQ</title>
<qandaset>
<qandaentry>
<question>
<para>Do you calculate on the sphere or the spheroid?</para>
</question>
<answer>
<para> By default, all distance and area calculations are done on the spheroid. You should find that the results of calculations in local areas match up will with local planar results in good local projections.
Over larger areas, the spheroidal calculations will be more accurate than any calculation done on a projected plane.
</para>
<para>All the geography functions have the option of using a sphere calculation, by setting a final boolean parameter to 'FALSE'. This will somewhat speed up calculations, particularly for cases where the geometries are very simple.</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>What about the date-line and the poles?</para>
</question>
<answer>
<para> All the calculations have no conception of date-line or poles, the coordinates are spherical (longitude/latitude)
so a shape that crosses the dateline is, from a calculation point of view, no different from any other shape.
</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>What is the longest arc you can process?</para>
</question>
<answer>
<para>We use great circle arcs as the "interpolation line" between two points. That means any two points are actually joined up two ways, depending on which direction you travel along the great circle. All our code assumes that the points are joined by the *shorter* of the two paths along the great circle.
As a consequence, shapes that have arcs of more than 180 degrees will not be correctly modelled.</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>Why is it so slow to calculate the area of Europe / Russia / insert big geographic region here ?</para>
</question>
<answer>
<para>Because the polygon is so darned huge! Big areas are bad for two reasons: their bounds are huge,
so the index tends to pull the feature no matter what query you run; the number of vertices is huge,
and tests (distance, containment) have to traverse the vertex list at least once and sometimes N times
(with N being the number of vertices in the other candidate feature).
</para>
<para>As with GEOMETRY, we recommend that when you have very large polygons, but are doing queries in small areas, you "denormalize" your geometric data into smaller chunks so that the index can effectively subquery parts of the object and so queries don't have to pull out the whole object every time.
Just because you *can* store all of Europe in one polygon doesn't mean you *should*.</para>
</answer>
</qandaentry>
</qandaset>
</sect2>
</sect1>
<sect1>
<title>Using OpenGIS Standards</title>
<para>The OpenGIS "Simple Features Specification for SQL" defines standard
GIS object types, the functions required to manipulate them, and a set of
meta-data tables. In order to ensure that meta-data remain consistent,
operations such as creating and removing a spatial column are carried out
through special procedures defined by OpenGIS.</para>
<para>There are two OpenGIS meta-data tables:
<varname>SPATIAL_REF_SYS</varname> and
<varname>GEOMETRY_COLUMNS</varname>. The
<varname>SPATIAL_REF_SYS</varname> table holds the numeric IDs and textual
descriptions of coordinate systems used in the spatial database.</para>
<sect2 id="spatial_ref_sys">
<title>The SPATIAL_REF_SYS Table and Spatial Reference Systems</title>
<para>The spatial_ref_sys table is a PostGIS included and OGC compliant database table that lists over 3000
known <ulink url="http://www.sharpgis.net/post/2007/05/Spatial-references2c-coordinate-systems2c-projections2c-datums2c-ellipsoids-e28093-confusing.aspx">spatial reference systems</ulink>
and details needed to transform/reproject between them.</para>
<para>Although the PostGIS spatial_ref_sys table contains over 3000 of the more commonly used spatial reference system definitions that can be handled by the proj library, it does not contain all known to man and
you can even define your own custom projection if you are familiar with proj4 constructs. Keep in mind that most spatial reference systems are regional and have no meaning when used outside of the bounds they were intended for.</para>
<para>An excellent resource for finding spatial reference systems not defined in the core set is <ulink url="http://spatialreference.org/">http://spatialreference.org/</ulink></para>
<para>Some of the more commonly used spatial reference systems are: <ulink url="http://spatialreference.org/ref/epsg/4326/">4326 - WGS 84 Long Lat</ulink>,
<ulink url="http://spatialreference.org/ref/epsg/4269/">4269 - NAD 83 Long Lat</ulink>,
<ulink url="http://spatialreference.org/ref/epsg/3395/">3395 - WGS 84 World Mercator</ulink>,
<ulink url="http://spatialreference.org/ref/epsg/2163/">2163 - US National Atlas Equal Area</ulink>,
Spatial reference systems for each NAD 83, WGS 84 UTM zone - UTM zones are one of the most ideal for measurement, but only cover 6-degree regions.
</para>
<para>
Various US state plane spatial reference systems (meter or feet based) - usually one or 2 exists per US state. Most of the meter ones are in the core set, but many of the
feet based ones or ESRI created ones you will need to pull from <ulink url="http://spatialreference.org">spatialreference.org</ulink>.
</para>
<para>
For details on determining which UTM zone to use for your area of interest, check out the <ulink url="http://trac.osgeo.org/postgis/wiki/UsersWikiplpgsqlfunctionsDistance">utmzone PostGIS plpgsql helper function</ulink>.
</para>
<para>The <varname>SPATIAL_REF_SYS</varname> table definition is as
follows:</para>
<programlisting>CREATE TABLE spatial_ref_sys (
srid INTEGER NOT NULL PRIMARY KEY,
auth_name VARCHAR(256),
auth_srid INTEGER,
srtext VARCHAR(2048),
proj4text VARCHAR(2048)
)</programlisting>
<para>The <varname>SPATIAL_REF_SYS</varname> columns are as
follows:</para>
<variablelist>
<varlistentry>
<term><ulink url="http://en.wikipedia.org/wiki/SRID">SRID</ulink></term>
<listitem>
<para>An integer value that uniquely identifies the Spatial
Referencing System (SRS) within the database.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>AUTH_NAME</term>
<listitem>
<para>The name of the standard or standards body that is being
cited for this reference system. For example, "EPSG" would be a
valid <varname>AUTH_NAME</varname>.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>AUTH_SRID</term>
<listitem>
<para>The ID of the Spatial Reference System as defined by the
Authority cited in the <varname>AUTH_NAME</varname>. In the case
of EPSG, this is where the EPSG projection code would go.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SRTEXT</term>
<listitem>
<para>The Well-Known Text representation of the Spatial Reference
System. An example of a WKT SRS representation is:</para>
<programlisting>PROJCS["NAD83 / UTM Zone 10N",
GEOGCS["NAD83",
DATUM["North_American_Datum_1983",
SPHEROID["GRS 1980",6378137,298.257222101]
],
PRIMEM["Greenwich",0],
UNIT["degree",0.0174532925199433]
],
PROJECTION["Transverse_Mercator"],
PARAMETER["latitude_of_origin",0],
PARAMETER["central_meridian",-123],
PARAMETER["scale_factor",0.9996],
PARAMETER["false_easting",500000],
PARAMETER["false_northing",0],
UNIT["metre",1]
]</programlisting>
<para>For a listing of EPSG projection codes and their
corresponding WKT representations, see <ulink
url="http://www.opengeospatial.org/">http://www.opengeospatial.org/</ulink>.
For a discussion of WKT in general, see the OpenGIS "Coordinate
Transformation Services Implementation Specification" at <ulink
url="http://www.opengeospatial.org/standards">http://www.opengeospatial.org/standards</ulink>.
For information on the European Petroleum Survey Group (EPSG) and
their database of spatial reference systems, see <ulink
url="http://www.epsg.org/">http://www.epsg.org</ulink>.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>PROJ4TEXT</term>
<listitem>
<para>PostGIS uses the Proj4 library to provide coordinate
transformation capabilities. The <varname>PROJ4TEXT</varname>
column contains the Proj4 coordinate definition string for a
particular SRID. For example:</para>
<programlisting>+proj=utm +zone=10 +ellps=clrk66 +datum=NAD27 +units=m</programlisting>
<para>For more information about, see the Proj4 web site at <ulink
url="http://trac.osgeo.org/proj/">http://trac.osgeo.org/proj/</ulink>.
The <filename>spatial_ref_sys.sql</filename> file contains both
<varname>SRTEXT</varname> and <varname>PROJ4TEXT</varname>
definitions for all EPSG projections.</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2 id="geometry_columns">
<title>The GEOMETRY_COLUMNS VIEW</title>
<para>In versions of PostGIS prior to 2.0.0, geometry_columns was a table that could be directly edited, and sometimes got out of synch with the actual definition of the geometry columns.
In PostGIS 2.0.0, <varname>GEOMETRY_COLUMNS</varname> became a view with the same front-facing structure as prior versions, but reading from database system catalogs
Its structure is as follows:</para>
<programlisting>\d geometry_columns</programlisting>
<screen> View "public.geometry_columns"
Column | Type | Modifiers
-------------------+------------------------+-----------
f_table_catalog | character varying(256) |
f_table_schema | character varying(256) |
f_table_name | character varying(256) |
f_geometry_column | character varying(256) |
coord_dimension | integer |
srid | integer |
type | character varying(30) |</screen>
<para>The column meanings have not changed from prior versions and are:</para>
<variablelist>
<varlistentry>
<term>F_TABLE_CATALOG, F_TABLE_SCHEMA, F_TABLE_NAME</term>
<listitem>
<para>The fully qualified name of the feature table containing the
geometry column. Note that the terms "catalog" and "schema" are
Oracle-ish. There is not PostgreSQL analogue of "catalog" so that
column is left blank -- for "schema" the PostgreSQL schema name is
used (<varname>public</varname> is the default).</para>
</listitem>
</varlistentry>
<varlistentry>
<term>F_GEOMETRY_COLUMN</term>
<listitem>
<para>The name of the geometry column in the feature table.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>COORD_DIMENSION</term>
<listitem>
<para>The spatial dimension (2, 3 or 4 dimensional) of the
column.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SRID</term>
<listitem>
<para>The ID of the spatial reference system used for the
coordinate geometry in this table. It is a foreign key reference
to the <varname>SPATIAL_REF_SYS</varname>.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TYPE</term>
<listitem>
<para>The type of the spatial object. To restrict the spatial
column to a single type, use one of: POINT, LINESTRING, POLYGON,
MULTIPOINT, MULTILINESTRING, MULTIPOLYGON, GEOMETRYCOLLECTION or
corresponding XYM versions POINTM, LINESTRINGM, POLYGONM,
MULTIPOINTM, MULTILINESTRINGM, MULTIPOLYGONM, GEOMETRYCOLLECTIONM.
For heterogeneous (mixed-type) collections, you can use "GEOMETRY"
as the type.</para>
<note>
<para>This attribute is (probably) not part of the OpenGIS
specification, but is required for ensuring type
homogeneity.</para>
</note>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2 id="Create_Spatial_Table">
<title>Creating a Spatial Table</title>
<para>Creating a table with spatial data, can be done in one step. As shown in the following example
which creates a roads table with a 2D linestring geometry column in WGS84 long lat</para>
<programlisting>CREATE TABLE ROADS ( ID int4
, ROAD_NAME varchar(25), geom geometry(LINESTRING,4326) );</programlisting>
<para>We can add additional columns using standard ALTER TABLE command as we do in this next example where we add a 3-D linestring.</para>
<programlisting>ALTER TABLE roads ADD COLUMN geom2 geometry(LINESTRINGZ,4326);</programlisting>
<para>For backwards compability, you can still create a spatial table in two stages using the management functions.</para>
<itemizedlist>
<listitem>
<para>Create a normal non-spatial table.</para>
<para>For example: <command>CREATE TABLE ROADS ( ID int4, ROAD_NAME
varchar(25) )</command></para>
</listitem>
<listitem>
<para>Add a spatial column to the table using the OpenGIS
"AddGeometryColumn" function. Refer to <xref linkend="AddGeometryColumn" /> for more details.</para>
<para>The syntax is: <programlisting>AddGeometryColumn(
<schema_name>,
<table_name>,
<column_name>,
<srid>,
<type>,
<dimension>
)</programlisting> Or, using current schema: <programlisting>AddGeometryColumn(
<table_name>,
<column_name>,
<srid>,
<type>,
<dimension>
)</programlisting></para>
<para>Example1: <command>SELECT AddGeometryColumn('public',
'roads', 'geom', 423, 'LINESTRING', 2)</command></para>
<para>Example2: <command>SELECT AddGeometryColumn( 'roads',
'geom', 423, 'LINESTRING', 2)</command></para>
</listitem>
</itemizedlist>
<para>Here is an example of SQL used to create a table and add a spatial
column (assuming that an SRID of 128 exists already):</para>
<programlisting>CREATE TABLE parks (
park_id INTEGER,
park_name VARCHAR,
park_date DATE,
park_type VARCHAR
);
SELECT AddGeometryColumn('parks', 'park_geom', 128, 'MULTIPOLYGON', 2 );</programlisting>
<para>Here is another example, using the generic "geometry" type and the
undefined SRID value of 0:</para>
<programlisting>CREATE TABLE roads (
road_id INTEGER,
road_name VARCHAR
);
SELECT AddGeometryColumn( 'roads', 'roads_geom', 0, 'GEOMETRY', 3 );</programlisting>
</sect2>
<sect2 id="Manual_Register_Spatial_Column">
<title>Manually Registering Geometry Columns in geometry_columns</title>
<para>The AddGeometryColumn() approach creates a geometry column of specified type.
This type and dimension are queryable from the <varname>geometry_columns</varname> view.
Starting with PostGIS 2.0, geometry_columns is no longer editable and all geometry columns are autoregistered.</para>
<para>If your geometry columns were created as generic in a table or view and no constraints applied, they will not have a dimension, type or srid in geometry_columns views, but will still be listed.</para>
<para>Two of the cases
where this may happen, but you can't use
AddGeometryColumn, is in the case of SQL Views and bulk inserts. For bulk insert case, you can correct the registration in the geometry_columns table
by constraining the column or doing an alter table. For views, you could expose using a CAST operation.
Note in PostGIS 2.0+ if your column is typmod based, the creation process would register it correctly, so no need to do anything.
Also views that have no spatial function applied to the geometry will register the same as the underlying table geometry column.</para>
<programlisting>--Lets say you have a view created like this
CREATE VIEW public.vwmytablemercator AS
SELECT gid, ST_Transform(geom,3395) As geom, f_name
FROM public.mytable;
-- For it to register correctly in PostGIS 2.0+
-- You need to cast the geometry
--
DROP VIEW public.vwmytablemercator;
CREATE VIEW public.vwmytablemercator AS
SELECT gid, ST_Transform(geom,3395)::geometry(Geometry, 3395) As geom, f_name
FROM public.mytable;
-- If you know the geometry type for sure is a 2D POLYGON then you could do
DROP VIEW public.vwmytablemercator;
CREATE VIEW public.vwmytablemercator AS
SELECT gid, ST_Transform(geom,3395)::geometry(Polygon, 3395) As geom, f_name
FROM public.mytable;</programlisting>
<programlisting>--Lets say you created a derivative table by doing a bulk insert
SELECT poi.gid, poi.geom, citybounds.city_name
INTO myschema.my_special_pois
FROM poi INNER JOIN citybounds ON ST_Intersects(citybounds.geom, poi.geom);
--Create 2d index on new table
CREATE INDEX idx_myschema_myspecialpois_geom_gist
ON myschema.my_special_pois USING gist(geom);
-- If your points are 3D points or 3M points,
-- then you might want to create an nd index instead of a 2d index
-- like so
CREATE INDEX my_special_pois_geom_gist_nd
ON my_special_pois USING gist(geom gist_geometry_ops_nd);
--To manually register this new table's geometry column in geometry_columns
-- Note that this approach will work for both PostGIS 2.0+ and PostGIS 1.4+
-- For PostGIS 2.0 it will also change the underlying structure of the table to
-- to make the column typmod based.
-- For PostGIS prior to 2.0, this technique can also be used to register views
SELECT populate_geometry_columns('myschema.my_special_pois'::regclass);
--If you are using PostGIS 2.0 and for whatever reason, you
-- you need the old constraint based definition behavior
-- (such as case of inherited tables where all children do not have the same type and srid)
-- set new optional use_typmod argument to false
SELECT populate_geometry_columns('myschema.my_special_pois'::regclass, false); </programlisting>
<para>Although the old-constraint based method is still supported, a constraint-based geometry column used directly
in a view, will not register correctly in geometry_columns, as will a typmod one.
In this example we define a column using typmod and another using constraints.</para>
<programlisting>CREATE TABLE pois_ny(gid SERIAL PRIMARY KEY
, poi_name text, cat varchar(20)
, geom geometry(POINT,4326) );
SELECT AddGeometryColumn('pois_ny', 'geom_2160', 2160, 'POINT', 2, false);</programlisting>
<para>If we run in psql</para>
<programlisting>\d pois_ny;</programlisting>
<para>We observe they are defined differently -- one is typmod, one is constraint</para>
<screen> Table "public.pois_ny"
Column | Type | Modifiers
-----------+-----------------------+------------------------------------------------------
gid | integer | not null default nextval('pois_ny_gid_seq'::regclass)
poi_name | text |
cat | character varying(20) |
geom | geometry(Point,4326) |
geom_2160 | geometry |
Indexes:
"pois_ny_pkey" PRIMARY KEY, btree (gid)
Check constraints:
"enforce_dims_geom_2160" CHECK (st_ndims(geom_2160) = 2)
"enforce_geotype_geom_2160" CHECK (geometrytype(geom_2160) = 'POINT'::text
OR geom_2160 IS NULL)
"enforce_srid_geom_2160" CHECK (st_srid(geom_2160) = 2160)</screen>
<para>In geometry_columns, they both register correctly</para>
<programlisting>SELECT f_table_name, f_geometry_column, srid, type
FROM geometry_columns
WHERE f_table_name = 'pois_ny';</programlisting>
<screen>f_table_name | f_geometry_column | srid | type
-------------+-------------------+------+-------
pois_ny | geom | 4326 | POINT
pois_ny | geom_2160 | 2160 | POINT</screen>
<para>However -- if we were to create a view like this</para>
<programlisting>CREATE VIEW vw_pois_ny_parks AS
SELECT *
FROM pois_ny
WHERE cat='park';
SELECT f_table_name, f_geometry_column, srid, type
FROM geometry_columns
WHERE f_table_name = 'vw_pois_ny_parks';</programlisting>
<para>The typmod based geom view column registers correctly,
but the constraint based one does not.</para>
<screen> f_table_name | f_geometry_column | srid | type
------------------+-------------------+------+----------
vw_pois_ny_parks | geom | 4326 | POINT
vw_pois_ny_parks | geom_2160 | 0 | GEOMETRY</screen>
<para>This may change in future versions of PostGIS, but for now
To force the constraint based view column to register correctly, we need to do this:</para>
<programlisting>DROP VIEW vw_pois_ny_parks;
CREATE VIEW vw_pois_ny_parks AS
SELECT gid, poi_name, cat
, geom
, geom_2160::geometry(POINT,2160) As geom_2160
FROM pois_ny
WHERE cat='park';
SELECT f_table_name, f_geometry_column, srid, type
FROM geometry_columns
WHERE f_table_name = 'vw_pois_ny_parks';</programlisting>
<screen> f_table_name | f_geometry_column | srid | type
------------------+-------------------+------+-------
vw_pois_ny_parks | geom | 4326 | POINT
vw_pois_ny_parks | geom_2160 | 2160 | POINT</screen>
</sect2>
<sect2 id="OGC_Validity">
<title>Ensuring OpenGIS compliancy of geometries</title>
<para>PostGIS is compliant with the Open Geospatial Consortium’s (OGC)
OpenGIS Specifications. As such, many PostGIS methods require, or more
accurately, assume that geometries that are operated on are both simple
and valid. For example, it does not make sense to calculate the area of
a polygon that has a hole defined outside of the polygon, or to construct
a polygon from a non-simple boundary line.</para>
<para>According to the OGC Specifications, a <emphasis>simple</emphasis>
geometry is one that has no anomalous geometric points, such as self
intersection or self tangency and primarily refers to 0 or 1-dimensional
geometries (i.e. <varname>[MULTI]POINT, [MULTI]LINESTRING</varname>).
Geometry validity, on the other hand, primarily refers to 2-dimensional
geometries (i.e. <varname>[MULTI]POLYGON)</varname> and defines the set
of assertions that characterizes a valid polygon. The description of each
geometric class includes specific conditions that further detail geometric
simplicity and validity.</para>
<para>A <varname>POINT</varname> is inheritably <emphasis>simple</emphasis>
as a 0-dimensional geometry object.</para>
<para><varname>MULTIPOINT</varname>s are <emphasis>simple</emphasis> if
no two coordinates (<varname>POINT</varname>s) are equal (have identical
coordinate values).</para>
<para>A <varname>LINESTRING</varname> is <emphasis>simple</emphasis> if
it does not pass through the same <varname>POINT</varname> twice (except
for the endpoints, in which case it is referred to as a linear ring and
additionally considered closed).</para>
<informaltable border="0" frame="none">
<tgroup cols="2" align="center">
<tbody>
<row>
<entry><para><informalfigure>
<mediaobject>
<imageobject>
<imagedata fileref="images/st_issimple01.png" />
</imageobject>
<caption><para><emphasis role="bold">(a)</emphasis></para></caption>
</mediaobject>
</informalfigure></para></entry>
<entry><para><informalfigure>
<mediaobject>
<imageobject>
<imagedata fileref="images/st_issimple02.png" />
</imageobject>
<caption><para><emphasis role="bold">(b)</emphasis></para></caption>
</mediaobject>
</informalfigure></para></entry>
</row>
<row>
<entry><para><informalfigure>
<mediaobject>
<imageobject>
<imagedata fileref="images/st_issimple03.png" />
</imageobject>
<caption><para><emphasis role="bold">(c)</emphasis></para></caption>
</mediaobject>
</informalfigure></para></entry>
<entry><para><informalfigure>
<mediaobject>
<imageobject>
<imagedata fileref="images/st_issimple04.png" />
</imageobject>
<caption><para><emphasis role="bold">(d)</emphasis></para></caption>
</mediaobject>
</informalfigure></para></entry>
</row>
</tbody>
</tgroup>
<tgroup cols="1">
<tbody>
<row>
<entry><para><emphasis role="bold">(a)</emphasis> and
<emphasis role="bold">(c)</emphasis> are simple
<varname>LINESTRING</varname>s, <emphasis role="bold">(b)</emphasis>
and <emphasis role="bold">(d)</emphasis> are not.</para></entry>
</row>
</tbody>
</tgroup>
</informaltable>