postgis/doc/postgis.xml
2001-12-21 19:44:57 +00:00

1250 lines
61 KiB
XML

<?xml version="1.0"?>
<?xml-stylesheet href="file:///C|/Program%20Files/SoftQuad/XMetaL%202%20Eval/display/docbookx.css" type="text/css"?>
<!DOCTYPE book PUBLIC "-//OASIS//DTD DocBook V3.1//EN">
<book>
<title>PostGIS Manual</title>
<bookinfo>
<editor>
<firstname>Paul</firstname>
<surname>Ramsey</surname>
<affiliation>
<orgname><ulink url="http://www.refractions.net">Refractions Research
Inc</ulink></orgname>
<address><street>209 - 560 Johnson
Street</street><city>Victoria</city><state>British
Columbia</state><country>Canada</country><email>pramsey@refractions.net</email></address>
</affiliation>
</editor>
<abstract>
<para>PostGIS is an extension to the PostgreSQL object-relational
database system which allows GIS (Geographic Information Systems) objects to be
stored in the database. PostGIS includes support for GiST-based R-Tree spatial indexes, and
functions for basic analysis of GIS objects.</para>
</abstract>
</bookinfo>
<chapter>
<title>Introduction</title>
<para>PostGIS is developed by Refractions Research Inc, as a spatial database technology research project. Refractions is a GIS and database
consulting company in Victoria, British Columbia, Canada, specializing in data
integration and custom software development. We plan on supporting and
developing PostGIS to support a range of important GIS functionality, including
full OpenGIS support, advanced topological constructs (coverages, surfaces, networks), desktop user
interface tools for viewing and editing GIS data, and web-based access
tools.</para>
<sect1>
<title>Credits</title>
<variablelist>
<varlistentry>
<term>Dave Blasby &lt;dblasby@refractions.net&gt;</term>
<listitem>
<para>The principal developer of PostGIS. Dave maintains the server
side objects and index support, the server side analytical
functions, and the Mapserver connectivity.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Paul Ramsey &lt;pramsey@refractions.net&gt;</term>
<listitem>
<para>Maintains the JDBC objects and keeps track of the
documentation and packaging.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Jeff Lounsbury &lt;jeffloun@refractions.net&gt;</term>
<listitem>
<para>Maintains the Shape loader/dumper.</para>
</listitem>
</varlistentry>
</variablelist>
</sect1>
<sect1>
<title>More Information</title>
<itemizedlist>
<listitem>
<para>The latest software, documentation and news items are available
at the PostGIS web site,
<ulink url="http://postgis.refractions.net">http://postgis.refractions.net</ulink>.</para>
</listitem>
<listitem>
<para>More information about the PostgreSQL database server is
available at the PostgreSQL main site
<ulink url="http://www.postgresql.org">http://www.postgresql.org</ulink>.</para>
</listitem>
<listitem>
<para>More information about GiST indexing is available at the GiST
development site,
<ulink url="http://www.sai.msu.su/~megera/postgres/gist">http://www.sai.msu.su/~megera/postgres/gist</ulink>.</para>
</listitem><listitem><para>More information about Mapserver internet map server is available at <ulink url="http://mapserver.gis.umn.edu/">http://mapserver.gis.umn.edu</ulink>.</para></listitem><listitem><para>The "<ulink url="http://www.opengis.org/techno/specs/99-049.pdf">Simple Features for Specification for SQL</ulink>" is available at the OpenGIS Consortium web site: <ulink url="http://www.opengis.org">http://www.opengis.org</ulink>.</para></listitem>
</itemizedlist>
</sect1>
</chapter>
<chapter>
<title>Installation</title>
<sect1 id="PGInstall">
<title>PostGIS</title>
<para>The PostGIS module is a extension to the PostgreSQL backend server.
As such, PostGIS 0.6 <emphasis>requires</emphasis> a full copy of the PostgreSQL
7.1.x source tree in order to compile. The PostgreSQL source code is available at
<ulink url="http://www.postgresql.org">http://www.postgresql.org</ulink>.</para>
<para>PostGIS 0.6 has been built and tested against PostgreSQL 7.1.2. It
will probably work with any of the 7.1.x versions. It will
<emphasis>not</emphasis> work with any version prior to 7.1, or with version 7.2 (not yet released at date of writing). The <emphasis>next</emphasis> version, PostGIS 0.7, will work with PostgreSQL version 7.2.</para>
<orderedlist>
<listitem>
<para>Before you can compile the postgis server modules, you must
compile and install the PostgreSQL package.</para>
</listitem>
<listitem>
<para>Retrieve the PostGIS source archive from
<ulink url="http://postgis.refractions.net/postgis-0.6.tar.gz">http://postgis.refractions.net/postgis-0.6.tar.gz</ulink>. Uncompress and untar the
archive in the "contrib" directory of the PostgreSQL source tree.</para>
<programlisting># cd [postgresql source tree]/contrib
# gzip -d -c postgis-0.6.tar.gz | tar xvf -</programlisting></listitem>
<listitem>
<para>Once your PostgreSQL installation is up-to-date, enter the
"postgis" directory, and run the compile and install commands. </para>
<programlisting># cd ./postgis-0.6
# make
# make install</programlisting></listitem>
<listitem><para>
As of version 0.6, PostGIS requires the PL/pgSQL procedural language extension.
Before loading the postgis.sql file, you must first enable PL/pgSQL.
You should use the <filename>createlang</filename> command.
The PostgreSQL 7.1 Programmer's Guide has the details if you want to this
manually for some reason.
<programlisting>
# createlang plpgsql [yourdatabase]
</programlisting>
</listitem>
<listitem>
<para>Finally, you
must load the PostGIS object and function definitions into your database. </para>
<programlisting># psql -d [yourdatabase] -f postgis.sql</programlisting><para>The PostGIS server extensions are now loaded and ready to
use.</para>
</listitem>
</orderedlist>
<sect2><title>Upgrading</title><para>Upgrading PostGIS can be tricky, because the underlying C libraries which
support the object types and geometries may have changed between versions.
To avoid problems when upgrading, you will have to dump all the tables
in your database, destroy the database, create a new one, execute the
new <filename>postgis.sql</filename> file, then upload your database dump:</para><programlisting># pg_dump -t "*" -f dumpfile.sql yourdatabase
# dropdb yourdatabase
# createdb yourdatabase
# psql -f postgis.sql -d yourdatabase
# psql -f dumpfile.sql -d yourdatabase
# vacuumdb -z yourdatabase</programlisting><note><para>When upgrading to 0.6, all your geometries will be created with an SRID
of -1. To create valid OpenGIS geometries, you will have to create a
valid SRID in the SPATIAL_REF_SYS table, and then update your geometries
to reference the SRID with the following SQL (with the appropriate
substitutions:</para><programlisting>UPDATE TABLE &lt;table&gt; SET &lt;geocolumn&gt; = SetSRID(&lt;geocolumn&gt;,&lt;SRID&gt;);</programlisting></note></sect2></sect1>
<sect1>
<title>JDBC</title>
<para>The JDBC extensions provide Java objects corresponding to the
internal PostGIS types. These objects can be used to write Java clients which
query the PostGIS database and draw or do calculations on the GIS data in
PostGIS.</para>
<orderedlist>
<listitem>
<para>Enter the "jdbc" sub-directory of the PostGIS distribution.
</para>
</listitem>
<listitem>
<para>Edit the <filename>Makefile</filename> to provide the correct paths of your java
compiler (JAVAC) and interpreter (JAVA). </para>
</listitem>
<listitem>
<para>Run the "make" command. Copy the <filename>postgis.jar</filename> file to wherever
you keep your java libraries.</para>
</listitem>
</orderedlist>
</sect1>
<sect1>
<title>Loader/Dumper</title>
<para>The data loader should compile very easily.</para>
<programlisting># cd postgis-0.6/loader
# make</programlisting><para>The loader is called <filename>shp2pgsql</filename> and converts ESRI Shape files into
SQL suitable for loading in PostGIS/PostgreSQL.</para>
</sect1>
</chapter>
<chapter>
<title>Frequently Asked Questions</title>
<qandaset>
<qandaentry>
<question>
<para>What kind of geometric objects can I store?</para>
</question>
<answer>
<para>You can store point, line, polygon, multipoint, multiline,
multipolygon, and geometrycollections. These are specified in the Open GIS Well
Known Text Format (with 3d extentions).</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>How do I insert a GIS object into the database?</para>
</question>
<answer>
<para>First, you need to create a table with a column of type
"geometry" to hold your GIS data. Connect to your database with "psql" and try
the following SQL: </para><programlisting>CREATE TABLE gtest ( ID int4, NAME varchar(20) );
SELECT AddGeometryColumn('dbname','gtest','geom',-1,'LINESTRING',2);</programlisting><para>If the table creation fails, you probably have not
loaded the PostGIS functions and objects into this database. See the
<link linkend="PGInstall">installation instructions</link>.</para>
<para>Then, you can insert a geometry into the table using a SQL
insert statement. The GIS object itself is formatted using the OpenGIS
Consortium "well-known text" format: </para><programlisting>INSERT INTO gtest (ID, NAME, GEOM)
VALUES (1, 'First Geometry', GeometryFromText('LINESTRING(2 3,4 5,6 5,7 8)', -1));
SELECT id, name, AsText(geom) AS geom FROM gtest;</programlisting><para>For more information about other GIS objects, see the
<link linkend="RefObject">object reference</link>.</para>
<para>To view your GIS data in the table: <emphasis></emphasis>. The return value should look
something like this:</para>
<literallayout> id | name | geom
----+----------------+-----------------------------
1 | First Geometry | LINESTRING(2 3,4 5,6 5,7 8)
(1 row)</literallayout>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>How do I construct a spatial query?</para>
</question>
<answer>
<para>There are a number of spatial operators available to
PostgreSQL, and several of them have been implemented by PostGIS in order to
provide indexing support. However, all the operators have been implemented with
the following important simplifying assumption: <emphasis>all features shall be
represented by their bounding boxes</emphasis>.</para>
<para>We recognize that using bounding boxes to proxy for features is
a limiting assumption, but it was an important one in moving from the
conception of a PostgreSQL spatial database to the implementation. Using
bounding boxes makes queries faster, indexes smaller, and operators
simpler. Commercial spatial databases use the same assumption -- bounding boxes are important to most indexing schemes.</para>
<para>The most important spatial operator from a user's perspective
is the "&amp;&amp;" operator, which tests whether one feature's bounding box
overlaps that of another. An example of a spatial query using &amp;&amp; is:</para><programlisting>SELECT id,name FROM GTEST WHERE GEOM &amp;&amp; 'BOX3D(3 4,4 5)'::box3d</programlisting><para>Note that the bounding box used for querying must be
explicitly declared as a <varname>box3d</varname> using the "::box3d" casting operation.</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>How do I speed up spatial queries on large tables?</para>
</question>
<answer>
<para>Fast queries on large tables is the <emphasis>raison
d'etre</emphasis> of spatial databases (along with transaction support) so
having a good index in important.</para>
<para>To build a spatial index on a table with a <varname>geometry</varname> column,
use the "CREATE INDEX" function as follows:</para>
<programlisting>CREATE INDEX [indexname] ON [tablename]
USING GIST ( [geometrycolumn] gist_geometry_ops) WITH (islossy);</programlisting><para>The "USING GIST" option tells the server to use a GiST
(Generalized Search Tree) index. The reference to "gist_geometry_ops" tells the
server to use a particular set of comparison operators for building the index:
the "gist_geometry_ops" are part of the PostGIS extension. Finally, the
"islossy" option tells the server that the features being indexed can be
proxied by a smaller data structure -- in the case of geometries, the features
are represented in the index by their bounding boxes.</para>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>How can I get my search to return things that really are inside
the search box, not just overlapping bounding boxes?</para>
</question>
<answer>
<para>The '&amp;&amp;' operator only checks bounding box overlaps,
but you can use the "truly_inside()" function to get only those feature which
<emphasis>actually</emphasis> intersect the search box. For example, by
combining the use of "&amp;&amp;" for a fast index search and truly_inside()
for an accurate final check of the result set, you can get only those features
inside the search box (note that this <emphasis>only</emphasis> works for
search boxes right now, not any arbitrary geometry):</para>
<programlisting>SELECT [COLUMN1],[COLUMN2],AsText([GEOMETRYCOLUMN])
FROM [TABLE] WHERE [GEOM_COLUMN] &amp;&amp; [BOX3d]
AND truly_inside([GEOM_COLUMN],[BOX3d]);</programlisting>
</answer>
</qandaentry>
<qandaentry>
<question>
<para>Why aren't PostgreSQL R-Tree indexes supported?</para>
</question>
<answer>
<para>Early versions of PostGIS used the PostgreSQL R-Tree indexes. However, PostgreSQL R-Trees have been completely discarded since version 0.6, and spatial indexing is provided with an R-Tree-over-GiST scheme. </para><para>Our tests have shown search speed for native R-Tree and GiST to be comparable. Native PostgreSQL R-Trees have two limitations which make them undesirable for
use with GIS features (note that these limitations
are due to the current PostgreSQL native R-Tree implementation, not the R-Tree concept in
general):</para>
<itemizedlist>
<listitem>
<para>Building an R-Tree index on a large table of geometries can
take over twice as long as a GiST index on the same table.</para>
</listitem>
<listitem>
<para>R-Tree indexes in PostgreSQL cannot handle features which
are larger than 8K in size. GiST indexes can, using the "lossy" trick of
substituting the bounding box for the feature itself.</para>
</listitem>
</itemizedlist>
</answer>
</qandaentry><qandaentry><question><para>Why should I use the AddGeometryColumn() function and all the other OpenGIS stuff?</para></question><answer><para>If you do not want to use the OpenGIS support functions, you do not have to. Simply create tables as in older versions, defining your geometry columns in the CREATE statement. All your geometries will have SRIDs of -1, and the OpenGIS meta-data tables will <emphasis>not</emphasis> be filled in properly. For most current applications, this will not matter.</para><para>However, in the future it is likely that client software will use the meta-data tables to interrogate the database about available layers and projections before rendering data. An obvious early example is the Mapserver internet mapping software, which could be altered to interrogate the SPATIAL_REF_SYS table for projection information on the layers it is rendering.</para><para>For these reasons it is probably wise to learn and use the OpenGIS concepts from early on.</para></answer></qandaentry>
</qandaset>
</chapter>
<chapter>
<title>Using PostGIS</title>
<sect1 id="RefObject">
<title>GIS Objects</title>
<para>The GIS objects supported by PostGIS are the "Simple Features"
defined by the OpenGIS Consortium (OGC). Note that PostGIS currently supports
the features and the representation APIs, but not the various comparison and
convolution operators given in the OGC "Simple Features for SQL"
specification.</para>
<para>Examples of the text representations of the features are as
follows:</para>
<itemizedlist>
<listitem>
<para>POINT(0 0 0)</para>
</listitem>
<listitem>
<para>LINESTRING(0 0,1 1,1 2)</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>MULTIPOINT(0 0 0,1 2 1)</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>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>GEOMETRYCOLLECTION(POINT(2 3 9),LINESTRING((2 3 4,3 4
5)))</para>
</listitem>
</itemizedlist>
<para>Note that in the examples above there are features with both
2-dimensional and 3-dimensional coordinates. PostGIS supports both 2d and 3d
coordinates -- if you describe a feature with 2D coordinates when you insert
it, the database will return that feature to you with 2D coordinates when you
extract it. See the sections on the 2d() and 3d() functions for information on
converting features to a particular coordinate dimension representation.</para>
<sect2>
<title>Standard versus Canonical Forms</title>
<para>The OpenGIS specification defines two standard ways of expressing
spatial objects: the Well-Known Text (WKT) form (shown in the previous section)
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>However, 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. For example, a valid insert statement to create
and insert a spatial object would be:</para>
<programlisting>INSERT INTO SPATIALTABLE ( THE_GEOM, THE_NAME )
VALUES (
GeometryFromText('POINT(-126.4 45.32)', 312),
'A Place'
) </programlisting>
<para>Note that the "GeometryFromText" function requires an SRID
number.</para>
<para>The "canonical form" of the spatial objects in PostgreSQL is a
text representation which includes all the information necessary to construct
the object. Unlike the OpenGIS standard forms, it includes the type,
coordinate, and SRID information. The canonical form is the default form
returned from a SELECT query. The example below shows the difference between the OGC standard and PostGIS canonical forms:</para><programlisting>db=&gt; SELECT AsText(geom) AS OGCGeom FROM thetable;
OGCGeom
-------------------------------------------------
LINESTRING(-123.741378393049 48.9124018962261,-123.741587115639 48.9123981907507)
(1 row)
db=&gt; SELECT geom AS PostGISGeom FROM thetable;
PostGISGeom
-------------------------------------------------
SRID=123;LINESTRING(-123.741378393049 48.9124018962261,-123.741587115639 48.9123981907507)
(1 row)</programlisting></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: SPATIAL_REF_SYS and
GEOMETRY_COLUMNS. The SPATIAL_REF_SYS table holds the numeric IDs and textual
descriptions of coordinate systems used in the spatial database.</para>
<sect2>
<title>The SPATIAL_REF_SYS Table</title>
<para>The SPATIAL_REF_SYS 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)
)</programlisting>
<para>The SPATIAL_REF_SYS columns are as follows:</para>
<variablelist>
<varlistentry>
<term>SRID</term>
<listitem>
<para>An integer value that uniquely identifies the Spatial
Referencing System 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
AUTH_NAME.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<varlistentry>
<term>AUTH_SRID</term>
<listitem>
<para>The ID of the Spatial Reference System as defined by the
Authority cited in the AUTH_NAME. In the case of EPSG, this is where the EPSG
projection code would go.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<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.opengis.org/techno/interop/EPSG2WKT.TXT">http://www.opengis.org/techno/interop/EPSG2WKT.TXT</ulink>.
For a discussion of WKT in general, see the OpenGIS "Coordinate Transformation
Services Implementation Specification" at
<ulink url="http://www.opengis.org/techno/specs.htm">http://www.opengis.org/techno/specs.htm</ulink>.</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>
<sect2>
<title>The GEOMETRY_COLUMNS Table</title>
<para>The GEOMETRY_COLUMNS table definition is as follows:</para>
<programlisting>CREATE TABLE GEOMETRY_COLUMNS (
F_TABLE_CATALOG VARCHAR(256) NOT NULL,
F_TABLE_SCHEMA VARCHAR(256) NOT NULL,
F_TABLE_NAME VARCHAR(256) NOT NULL,
F_GEOMETRY_COLUMN VARCHAR(256) NOT NULL,
COORD_DIMENSION INTEGER NOT NULL,
SRID INTEGER NOT NULL,
TYPE VARCHAR(30) NOT NULL
)</programlisting>
<para>The columns are as follows:</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 database name is used.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<varlistentry>
<term>F_GEOMETRY_COLUMN</term>
<listitem>
<para>The name of the geometry column in the feature
table.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<varlistentry>
<term>COORD_DIMENSION</term>
<listitem>
<para>The spatial dimension (2 or 3 dimensional) of the
column.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<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
SPATIAL_REF_SYS.</para>
</listitem>
</varlistentry>
</variablelist>
<variablelist>
<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, MULTPOINT,
MULTILINESTRING, MULTIPOLYGON, GEOMETRYCOLLECTION. 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>
<title>Creating a Spatial Table</title>
<para>Creating a table with spatial data is done in two stages:</para>
<itemizedlist>
<listitem>
<para>Create a normal non-spatial table.</para>
<para>For example: CREATE TABLE ROADS_GEOM (ID int4, NAME
varchar(25))</para>
</listitem>
<listitem>
<para>Add a spatial column to the table using the OpenGIS
"AddGeometryColumn" function. The syntax is: AddGeometryColumn(&lt;db_name&gt;,
&lt;table_name&gt;, &lt;column_name&gt;, &lt;srid&gt;, &lt;type&gt;,
&lt;dimension&gt;).</para>
<para>For example: SELECT AddGeometryColumn('roads_db',
'roads_geom', 'geom', 423, 'LINESTRING', 2)</para>
</listitem>
</itemizedlist>
<para>Here is an example of SQL used to create a table and add a
spatial column (assuming the db is 'parks_db' and that an SRID of 128 exists
already):</para>
<programlisting>CREATE TABLE PARKS ( PARK_ID int4, PARK_NAME varchar(128), PARK_DATE date, PARK_TYPE varchar(2) );
SELECT AddGeometryColumn('parks_db', 'parks', 'park_geom', 128, 'MULTIPOLYGON', 2 );</programlisting>
<para>Here is another example, using the generic "geometry" type and
the undefined SRID value of -1:</para>
<programlisting>CREATE TABLE ROADS ( ROAD_ID int4, ROAD_NAME varchar(128) );
SELECT AddGeometryColumn( 'roads_db', 'roads', 'roads_geom', -1, 'GEOMETRY', 3 );</programlisting>
</sect2>
</sect1>
<sect1>
<title>Loading GIS Data</title>
<para>Once you have created a spatial table, you are ready to upload GIS
data to the database. Currently, there are two ways to get data into a
PostGIS/PostgreSQL database: using formatted SQL statements or using the Shape
file loader/dumper.</para>
<sect2>
<title>Using SQL</title>
<para>If you can convert your data to a text representation, then using
formatted SQL might be the easiest way to get your data into PostGIS. As with
Oracle and other SQL databases, data can be bulk loaded by piping a large text
file full of SQL "INSERT" statements into the SQL terminal monitor.</para>
<para>A data upload file (<filename>roads.sql</filename> for example) might look like
this:</para>
<literallayout>INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (1,GeometryFromText('LINESTRING(191232 243118,191108 243242)',-1),'Jeff Rd');
INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (2,GeometryFromText('LINESTRING(189141 244158,189265 244817)',-1),'Geordie Rd');
INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (3,GeometryFromText('LINESTRING(192783 228138,192612 229814)',-1),'Paul St');
INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (4,GeometryFromText('LINESTRING(189412 252431,189631 259122)',-1),'Graeme Ave');
INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (5,GeometryFromText('LINESTRING(190131 224148,190871 228134)',-1),'Phil Tce');
INSERT INTO ROADS_GEOM (ID,GEOM,NAME ) VALUES (6,GeometryFromText('LINESTRING(198231 263418,198213 268322)',-1),'Dave Cres');</literallayout>
<para>The data file can be piped into PostgreSQL very easily using the
"psql" SQL terminal monitor:</para>
<literallayout>psql -d [database] -f roads.sql</literallayout>
</sect2>
<sect2>
<title>Using the Loader</title>
<para>The data loader converts ESRI Shape files into SQL suitable for
insertion into a PostGIS/PostgreSQL database. The loader has several operating
modes distinguished by command line flags:</para>
<variablelist>
<varlistentry>
<term>-d</term>
<listitem>
<para>Drops the database table before creating a new table with
the data in the Shape file.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>-a</term>
<listitem>
<para>Appends data from the Shape file into the database table.
Note that to use this option to load multiple files, the files must have the
same attributes and same data types.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>-c</term>
<listitem>
<para>Creates a new table and populates it from the Shape file.
<emphasis>This is the default mode.</emphasis></para>
</listitem>
</varlistentry>
<varlistentry>
<term>-dump</term>
<listitem>
<para>Creates a new table and populates it from the Shape file.
This uses the PostgreSQL "dump" format for the output data and is much faster
to load than the default "insert" SQL format. Use this for very large data
sets.</para>
</listitem>
</varlistentry>
</variablelist>
<para>An example session using the loader to create an input file and
uploading it might look like this:</para>
<programlisting># shp2pgsql shaperoads roadstable &gt; roads.sql
# psql -d roadsdb -f roads.sql</programlisting><para>A conversion and upload can be done all in one step using UNIX
pipes:</para>
<programlisting>shp2pgsql shaperoads roadstable | psql -d roadsdb</programlisting></sect2>
</sect1>
<sect1>
<title>Retrieving GIS Data</title>
<para>Data can be extracted from the database using either SQL or the
Shape file loader/dumper. In the section on SQL we will discuss some of the
operators available to do comparisons and queries on spatial tables.</para>
<sect2>
<title>Using SQL</title>
<para>The most straightforward means of pulling data out of the
database is to use a SQL select query and dump the resulting columns into a
parsable text file:</para>
<literallayout>db=# SELECT id, AsText(geom) AS geom, name FROM ROADS_GEOM;
id | geom | name
---+-----------------------------------------+-----------
1 | LINESTRING(191232 243118,191108 243242) | Jeff Rd
2 | LINESTRING(189141 244158,189265 244817) | Geordie Rd
3 | LINESTRING(192783 228138,192612 229814) | Paul St
4 | LINESTRING(189412 252431,189631 259122) | Graeme Ave
5 | LINESTRING(190131 224148,190871 228134) | Phil Tce
6 | LINESTRING(198231 263418,198213 268322) | Dave Cres
(6 rows)</literallayout>
<para>However, there will be times when some kind of restriction is
necessary to cut down the number of fields returned. In the case of
attribute-based restrictions, just use the same SQL syntax as normal with a
non-spatial table. In the case of spatial restrictions, the following operators
are available/useful:</para>
<variablelist>
<varlistentry>
<term>&amp;&amp;</term>
<listitem>
<para>This operator tells whether the bounding box of one
geometry overlaps the bounding box of another.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>~=</term>
<listitem>
<para>This operators tests whether two geometries are
geometrically identical. For example, if 'POLYGON((0 0,1 1,1 0,0 0))' is the
same as 'POLYGON((0 0,1 1,1 0,0 0))' (it is).</para>
</listitem>
</varlistentry>
<varlistentry>
<term>=</term>
<listitem>
<para>This operator is a little more naive, it only tests whether
the bounding boxes of to geometries are the same.</para>
</listitem>
</varlistentry>
</variablelist>
<para>Next, you can use these operators in queries. Note that when
specifying geometries and boxes on the SQL command line, you must explicitly
turn the string representations into geometries by using the "GeometryFromText()" function. So, for example:</para>
<literallayout>SELECT ID, NAME FROM ROADS_GEOM
WHERE GEOM ~= GeometryFromText('LINESTRING(191232 243118,191108 243242)',-1);</literallayout>
<para>The above query would return the single record from the
"ROADS_GEOM" table in which the geometry was equal to that value.</para>
<para>When using the "&amp;&amp;" operator, you can specify either a
BOX3D as the comparison feature or a GEOMETRY. When you specify a GEOMETRY,
however, its bounding box will be used for the comparison.</para>
<literallayout>SELECT ID, NAME FROM ROADS_GEOM
WHERE GEOM &amp;&amp; GeometryFromText('POLYGON((191232 243117,191232 243119,191234 243117,191232 243117))',-1);</literallayout>
<para>The above query will use the bounding box of the polygon for
comparison purposes.</para>
<para>The most common spatial query will probably be a "frame-based"
query, used by client software, like data browsers and web mappers, to grab a
"map frame" worth of data for display. Using a "BOX3D" object for the frame,
such a query looks like this:</para>
<literallayout>SELECT AsText(GEOM) AS GEOM FROM ROADS_GEOM
WHERE GEOM &amp;&amp; GeometryFromText('BOX3D(191232 243117,191232 243119)'::box3d,-1);</literallayout>
<para>Note the use of the SRID, to specify the projection of the BOX3D. The -1 is used to indicate no specified SRID.</para>
</sect2>
<sect2>
<title>Using the Dumper</title>
<para>This section to be written.</para>
</sect2>
<sect2><title>Using Minnesota Mapserver</title><para>The Minnesota Mapserver is an internet web-mapping server. The latest versions conform to the OpenGIS Web Map Specification.</para><itemizedlist><listitem> <para>The Mapserver homepage is at <ulink url="http://mapserver.gis.umn.edu">http://mapserver.gis.umn.edu</ulink>.</para></listitem><listitem> <para>The OpenGIS Web Map Specification is at <ulink url="http://www.opengis.org/techno/specs/01-047r2.pdf">http://www.opengis.org/techno/specs/01-047r2.pdf</ulink>.</para></listitem></itemizedlist><para>To use PostGIS with Mapserver, you will need to know about how to configure Mapserver, which is beyond the scope of this documentation. This section will cover specific PostGIS issues and configuration details.</para><para>To use PostGIS with Mapserver, you will need:</para><itemizedlist><listitem><para>The latest version of PostGIS.</para></listitem><listitem><para>Version 3.5 of Mapserver. At the date of writing, version 3.5 has not been released, but the CVS version is fully functional with PostGIS.</para></listitem></itemizedlist><para>Mapserver accesses PostGIS/PostgreSQL data like any other PostgreSQL client -- using <filename>libpq</filename>. This means that Mapserver can be installed on any machine with network access to the PostGIS server, as long as the system has the <filename>libpq</filename> PostgreSQL client libraries.</para><orderedlist><listitem><para>Compile and install Mapserver, with whatever options you desire, including the "--with-postgis" configuration option.</para></listitem><listitem><para>In your Mapserver map file, add a PostGIS layer. For example:</para><programlisting>LAYER
CONNECTIONTYPE postgis
NAME "widehighways"
# Connect to a remote spatial database
CONNECTION "user=dbuser dbname=gisdatabase host=bigserver"
# Get the lines from the 'geom' column of the 'roads' table
DATA "geom from roads"
STATUS ON
TYPE LINE
# Of the lines in the extents, only render the wide highways
FILTER "type = 'highway' and numlanes &gt;= 4"
CLASS
# Make the superhighways brighter and 2 pixels wide
EXPRESSION ([numlanes] &gt;= 6)
COLOR 255 22 22
SYMBOL "solid"
SIZE 2
END
CLASS
# All the rest are darker and only 1 pixel wide
EXPRESSION ([numlanes] &lt; 6)
COLOR 205 92 82
END
END</programlisting><para>In the example above, the PostGIS-specific directives are as follows:</para><variablelist><varlistentry><term>CONNECTIONTYPE</term><listitem><para>For PostGIS layers, this is always "postgis".</para></listitem></varlistentry><varlistentry><term>CONNECTION</term><listitem><para>The database connection is governed by the a 'connection string' which
is a standard set of keys and values like this (with the default values
in &lt;&gt;):</para><para>user=&lt;username&gt; password=&lt;password&gt; dbname=&lt;username&gt; hostname=&lt;server&gt; port=&lt;5432&gt;</para><para>An empty connection string is still valid, and any of the key/value
pairs can be omitted. At a minimum you will generally supply the database
name and username to connect with.</para></listitem></varlistentry><varlistentry><term>DATA</term><listitem><para>The form of this parameter is "&lt;column&gt; from &lt;tablename&gt;" where the column is the spatial column to be rendered to the name.</para></listitem></varlistentry><varlistentry><term>FILTER</term><listitem><para>The filter must be a valid SQL string corresponding to the logic normally following the "WHERE" keyword in a SQL query. So, for example, to render only roads with 6 or more lanes, use a filter of "num_lanes &gt;= 6".</para></listitem></varlistentry></variablelist></listitem><listitem><para>In your spatial database, ensure you have spatial (GiST) indexes built for any the layers you will be drawing.</para></listitem><listitem><para>If you will be querying your layers using Mapserver you will also need an "oid index".</para><para>Mapserver requires unique identifiers for each spatial record when doing queries, and the PostGIS module of Mapserver uses the PostgreSQL <varname>oid</varname> value to provide these unique identifiers. A side-effect of this is that in order to do fast random access of records during queries, an index on the <varname>oid</varname> is needed. </para><para>To build an "oid index", use the following SQL:</para><programlisting>CREATE INDEX &lt;indexname&gt; ON &lt;tablename&gt; ( oid );</programlisting></listitem></orderedlist></sect2></sect1>
<sect1>
<title>Building Indexes</title>
<para>Indexes are what make using a spatial database for large databases
possible. Without indexing, any search for a feature would require a
"sequential scan" of every record in the database. Indexing speeds up searching
by organizing the data into a search tree which can be quickly traversed to
find a particular record. PostgreSQL supports three kinds of indexes by
default: B-Tree indexes, R-Tree indexes, and GiST indexes.</para>
<itemizedlist>
<listitem>
<para>B-Trees are used for data which can be sorted along one axis;
for example, numbers, letters, dates. GIS data cannot be rationally sorted
along one axis (which is greater, (0,0) or (0,1) or (1,0)?) so B-Tree indexing
is of no use for us. </para>
</listitem>
<listitem>
<para>R-Trees break up data into rectangles, and sub-rectangles, and
sub-sub rectangles, etc. R-Trees are used by some spatial databases to index GIS
data, but the PostgreSQL R-Tree implementation is not as robust as the GiST
implementation.</para>
</listitem>
<listitem>
<para> GiST (Generalized Search Trees) indexes break up data into
"things to one side", "things which overlap", "things which are inside" and can
be used on a wide range of data-types, including GIS data. PostGIS uses GiST
indexing to index GIS data.</para>
</listitem>
</itemizedlist>
<sect2>
<title>GiST Indexes</title>
<para>GiST stands for "Generalized Search Tree" and is a generalized
form of R-Tree indexing. In addition to GIS indexing, GiST is used to speed up
searches on all kinds of irregular data structures (integer arrays, spectral
data, etc) which are not amenable to normal B-Tree indexing.</para>
<para>Once a GIS data table exceeds a few thousand rows, you will want
to build an index to speed up spatial searches of the data (unless all your
searches are based on attributes, in which case you'll want to build a normal
index on the attribute fields).</para>
<para>The syntax for building a GiST index on a "geometry" column is as
follows:</para>
<literallayout>CREATE INDEX [indexname] ON [tablename] USING GIST (
[geometryfield] GIST_GEOMETRY_OPS ) WITH ( ISLOSSY ); </literallayout>
<para>Building a spatial index is a computationally intensive exercise:
on tables of around 1 million rows, on a 300MHz Solaris machine, we have found
building a GiST index takes about 1 hour.</para>
<para>GiST indexes have two advantages over R-Tree indexes in
PostgreSQL. Firstly, GiST indexes build much faster than R-Trees; we have found
that it takes about 4 times more time to build an R-Tree than a GiST index on
an identical table. Secondly, GiST indexes support the concept of "lossiness"
which is important when dealing with GIS objects larger than the PostgreSQL 8K
page size. Lossiness allows PostgreSQL to store only the "important" part of an
object in an index -- in the case of GIS objects, just the bounding box. GIS
objects larger than 8K will cause R-Tree indexes to fail in the build
phase.</para>
</sect2>
<sect2>
<title>Using Indexes</title>
<para>Ordinarily, indexes invisibly speed up data access: once the
index is built, the query planner transparently decides when to use index
information to speed up a query plan. Unfortunately, the PostgreSQL query
planner does not optimize the use of GiST indexes well, so sometimes searches which should use a spatial index instead default to a sequence
scan of the whole table.</para>
<para>If you find your spatial indexes are not being used (or your
attribute indexes, for that matter) there are a couple things you can
do:</para>
<itemizedlist>
<listitem>
<para>Firstly, make sure you run the "VACUUM ANALYZE [tablename]"
command on the tables you are having problems with. "VACUUM ANALYZE" gathers
statistics about the number and distributions of values in a table, to provide
the query planner with better information to make decisions around index
usage. You should regularly vacuum your databases anyways -- many PostgreSQL DBAs have "VACUUM" run as an off-peak cron job on a regular basis.</para>
</listitem>
<listitem>
<para>If vacuuming does not work, you can force the planner to use the index
information by using the "SET =OFF" command. You should only use
this command sparingly, and only on spatially indexed queries: generally
speaking, the planner knows better than you do about when to use normal B-Tree
indexes. Once you have run your query, you should consider setting
"ENABLE_SEQSCAN" back on, so that other queries will utilize the planner as
normal.</para>
<note><para>As of version 0.6, it should not be necessary to force the planner to use the index with "ENABLE_SEQSCAN".</para></note></listitem>
</itemizedlist>
</sect2>
</sect1>
<sect1>
<title>Java Clients (JDBC)</title>
<para>Java clients can access PostGIS "geometry" objects in the
PostgreSQL database either directly as text representations or using the JDBC
extension objects bundled with PostGIS. In order to use the extension objects,
the "postgis.jar" file must be in your CLASSPATH along with the
"postgresql.jar" JDBC driver package.</para>
<programlisting>import java.sql.*;
import java.util.*;
import java.lang.*;
import org.postgis.*;
public class JavaGIS {
public static void main(String[] args)
{
java.sql.Connection conn;
try
{
/*
* Load the JDBC driver and establish a connection.
*/
Class.forName("org.postgresql.Driver");
String url = "jdbc:postgresql://localhost:5432/database";
conn = DriverManager.getConnection(url, "postgres", "");
/*
* Add the geometry types to the connection. Note that you
* must cast the connection to the pgsql-specific connection * implementation before calling the addDataType() method.
*/
((org.postgresql.Connection)conn).addDataType("geometry","org.postgis.PGgeometry");
((org.postgresql.Connection)conn).addDataType("box3d","org.postgis.PGbox3d");
/*
* Create a statement and execute a select query.
*/
Statement s = conn.createStatement();
ResultSet r = s.executeQuery("select AsText(geom) as geom,id from geomtable");
while( r.next() )
{
/*
* Retrieve the geometry as an object then cast it to the geometry type.
* Print things out.
*/
PGgeometry geom = (PGgeometry)r.getObject(1);
int id = r.getInt(2);
System.out.println("Row " + id + ":");
System.out.println(geom.toString());
}
s.close();
conn.close();
}
catch( Exception e )
{
e.printStackTrace();
}
}
}</programlisting>
<para>The "PGgeometry" object is a wrapper object which contains a
specific topological geometry object (subclasses of the abstract class
"Geometry") depending on the type: Point, LineString, Polygon, MultiPoint,
MultiLineString, MultiPolygon.</para>
<programlisting>PGgeometry geom = (PGgeometry)r.getObject(1);
if( geom.getType() = Geometry.POLYGON )
{
Polygon pl = (Polygon)geom.getGeometry();
for( int r = 0; r &lt; pl.numRings(); r++ )
{
LinearRing rng = pl.getRing(r);
System.out.println("Ring: " + r);
for( int p = 0; p &lt; rng.numPoints(); p++ )
{
Point pt = rng.getPoint(p);
System.out.println("Point: " + p);
System.out.println(pt.toString());
}
}
}</programlisting>
<para>The JavaDoc for the extension objects provides a reference for the
various data accessor functions in the geometric objects.</para>
</sect1>
<sect1>
<title> C Clients (libpq)</title>
<para>...</para>
<sect2>
<title>Text Cursors</title>
<para>...</para>
</sect2>
<sect2>
<title>Binary Cursors</title>
<para>...</para>
</sect2>
</sect1>
</chapter>
<chapter>
<title>PostGIS Reference</title>
<para>The functions given below are the ones which a user of PostGIS is
likely to need. There are other functions which are required support functions
to the PostGIS objects which are not of use to a general user.</para>
<sect1>
<title>OpenGIS Functions</title>
<variablelist>
<varlistentry>
<term>AddGeometryColumn(varchar, varchar, varchar, integer, varchar, integer)</term>
<listitem>
<para>Syntax: AddGeometryColumn(&lt;db_name&gt;,
&lt;table_name&gt;, &lt;column_name&gt;, &lt;srid&gt;, &lt;type&gt;,
&lt;dimension&gt;). Adds a geometry column to an existing table of attributes. The <varname>dbname</varname> is the name of the database instance. The <varname>srid</varname> must be an integer value reference to an entry in the SPATIAL_REF_SYS table. The <varname>type</varname> must be an uppercase string corresponding to the geometry type, eg, 'POLYGON' or 'MULTILINESTRING'.</para>
</listitem>
</varlistentry><varlistentry><term>DropGeometryColumn(varchar, varchar, varchar)</term><listitem><para>Syntax: DropGeometryColumn(&lt;db_name&gt;,&lt;table_name&gt;,&lt;column_name&gt;). Remove a geometry column from a spatial table.</para></listitem></varlistentry>
<varlistentry>
<term>AsBinary(geometry)</term>
<listitem>
<para>Returns the geometry in the OGC "well-known-binary" format,
using the endian encoding of the server on which the database is running. This
is useful in binary cursors to pull data out of the database without converting
it to a string representation.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Dimension(geometry)</term>
<listitem>
<para>Returns '2' if the geometry is two dimensional and '3' if the
geometry is three dimensional.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Envelope(geometry)</term>
<listitem>
<para>Returns a POLYGON representing the bounding box of the
geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>GeometryType(geometry)</term>
<listitem>
<para>Returns the type of the geometry as a string. Eg: 'LINESTRING', 'POLYGON',
'MULTIPOINT', etc.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>X(geometry)</term>
<listitem>
<para>Find and return the X coordinate of the first point in the
geometry. Return NULL if there is no point in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Y(geometry)</term>
<listitem>
<para>Find and return the Y coordinate of the first point in the
geometry. Return NULL if there is no point in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Z(geometry)</term>
<listitem>
<para>Find and return the Z coordinate of the first point in the
geometry. Return NULL if there is no point in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>NumPoints(geometry)</term>
<listitem>
<para>Find and return the number of points in the first linestring
in the geometry. Return NULL if there is no linestring in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>PointN(geometry,integer)</term>
<listitem>
<para>Return the N'th point in the first linestring in the
geometry. Return NULL if there is no linestring in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ExteriorRing(geometry)</term>
<listitem>
<para>Return the exterior ring of the first polygon in the
geometry. Return NULL if there is no polygon in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>NumInteriorRings(geometry)</term>
<listitem>
<para>Return the number of interior rings of the first polygon in
the geometry. Return NULL if there is no polygon in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>InteriorRingN(geometry,integer)</term>
<listitem>
<para>Return the N'th interior ring of the first polygon in the
geometry. Return NULL if there is no polygon in the geometry.</para>
</listitem>
</varlistentry><varlistentry><term>IsClosed(geometry)</term><listitem><para>Returns true of the geometry start and end points are coincident.</para></listitem></varlistentry>
<varlistentry>
<term>NumGeometries(geometry)</term>
<listitem>
<para>If geometry is a GEOMETRYCOLLECTION return the number of
geometries, otherwise return NULL.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>GeometryN(geometry)</term>
<listitem>
<para>Return the N'th geometry if the geometry is a
GEOMETRYCOLLECTION, MULTIPOINT, MULTILINESTRING or MULTIPOLYGON. Otherwise, return NULL.</para>
</listitem>
</varlistentry><varlistentry><term>Distance(geometry,geometry)</term><listitem><para>Return the cartesian distance between two geometries in projected units.</para></listitem></varlistentry><varlistentry><term>AsText(geometry)</term><listitem><para>Return the Well-Known Text representation of the geometry. For example: POLYGON(0 0,0 1,1 1,1 0,0 0)</para></listitem></varlistentry><varlistentry><term>SRID(geometry)</term><listitem><para>Returns the integer SRID number of the spatial reference system of the geometry.</para></listitem></varlistentry><varlistentry><term>GeometryFromText(varchar, integer)</term><listitem><para>Syntax: GeometryFromText(&lt;geometry&gt;,&lt;SRID&gt;) Convert a Well-Known Text representation of a geometry into a geometry object.</para></listitem></varlistentry><varlistentry><term>SetSRID(geometry)</term><listitem><para>Set the SRID on a geometry to a particular integer value. Useful in constructing bounding boxes for queries.</para></listitem></varlistentry>
<varlistentry><term>EndPoint(geometry)</term><listitem><para>Returns the last point of the geometry as a point.</para></listitem></varlistentry><varlistentry><term>StartPoint(geometry)</term><listitem><para>Returns the first point of the geometry as a point.</para></listitem></varlistentry><varlistentry><term>Centroid(geometry)</term><listitem><para>Returns the centroid of the geometry as a point.</para></listitem></varlistentry>
</variablelist>
</sect1>
<sect1>
<title>Other Functions</title>
<variablelist>
<varlistentry>
<term>A &lt;&amp; B</term>
<listitem>
<para>The "&lt;&amp;" operator returns true if A's bounding box
overlaps or is to the right of B's bounding box.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A &amp;&gt; B</term>
<listitem>
<para>The "&amp;&gt;" operator returns true if A's bounding box
overlaps or is to the left of B's bounding box.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A &lt;&lt; B</term>
<listitem>
<para>The "&lt;&lt;" operator returns true if A's bounding box is
strictly to the right of B's bounding box.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A &gt;&gt; B</term>
<listitem>
<para>The "&gt;&gt;" operator returns true if A's bounding box is
strictly to the left of B's bounding box.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A ~= B</term>
<listitem>
<para>The "~=" operator is the "same as" operator. It tests actual
geometric equality of two features. So if A and B are the same feature,
vertex-by-vertex, the operator returns true.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A ~ B</term>
<listitem>
<para>The "~" operator returns true of A's bounding box is
completely contained by B's bounding box.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>A &amp;&amp; B</term>
<listitem>
<para>The "&amp;&amp;" operator is the "overlaps" operator. If A's
bounding boux overlaps B's bounding box the operator returns true.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>area2d(geometry)</term>
<listitem>
<para>Returns the area of the geometry if it is a polygon or
multi-polygon.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>asbinary(geometry,'NDR')</term>
<listitem>
<para>Returns the geometry in the OGC "well-known-binary" format,
using little-endian encoding. This is useful in binary cursors to pull data out
of the database without converting it to a string representation.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>asbinary(geometry,'XDR')</term>
<listitem>
<para>Returns the geometry in the OGC "well-known-binary" format,
using big-endian encoding. This is useful in binary cursors to pull data out of
the database without converting it to a string representation.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>box3d(geometry)</term>
<listitem>
<para>Returns a BOX3D representing the maximum extents of the
geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>extent(geometry)</term>
<listitem>
<para>The extent() function is an "aggregate" function in the
terminology of PostgreSQL. That means that it operators on lists of data, in
the same way the sum() and mean() functions do. For example, "SELECT
EXTENT(GEOM) FROM GEOMTABLE" will return a BOX3D giving the maximum extend of
all features in the table. Similarly, "SELECT EXTENT(GEOM) FROM GEOMTABLE GROUP
BY CATEGORY" will return one extent result for each category.</para>
</listitem>
</varlistentry><varlistentry><term>find_srid(varchar,varchar,varchar)</term><listitem><para>The syntax is find_srid(&lt;db/schema&gt;, &lt;table&gt;, &lt;column&gt;) and the function returns the integer SRID of the specified column by searching through the GEOMETRY_COLUMNS table. If the geometry column has not been properly added with the AddGeometryColumns() function, this function will not work either.</para></listitem></varlistentry>
<varlistentry>
<term>force_collection(geometry)</term>
<listitem>
<para>Converts the geometry into a GEOMETRYCOLLECTION. This is
useful for simplifying the WKB representation.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>force_2d(geometry)</term>
<listitem>
<para>Forces the geometries into a "2-dimensional mode" so that all
output representations will only have the X and Y coordinates. This is useful
for force OGC-compliant output (since OGC only specifies 2-D
geometries).</para>
</listitem>
</varlistentry>
<varlistentry>
<term>force_3d(geometry)</term>
<listitem>
<para>Forces the geometries into a "3-dimensional mode" so that all
output representations will have the X, Y and Z coordinates.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>length2d(geometry)</term>
<listitem>
<para>Returns the 2-dimensional length of the geometry if it is a
linestring or multi-linestring.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>length3d(geometry)</term>
<listitem>
<para>Returns the 3-dimensional length of the geometry if it is a
linestring or multi-linestring.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>length_spheroid(geometry,spheroid)</term>
<listitem>
<para>Calculates the length of of a geometry on an elipsoid. This
is useful if the coordinates of the geometry are in latitude/longitude and a
length is desired without reprojection. The elipsoid is a separate database
type and can be constructed as follows:
<literallayout> SPHEROID[&lt;NAME&gt;,&lt;SEMI-MAJOR
AXIS&gt;,&lt;INVERSE FLATTENING&gt;] Eg:
SPHEROID["GRS_1980",6378137,298.257222101] </literallayout>An example
calculation might look like this:
<literallayout>SELECT
length_spheroid(geometry_column,'SPHEROID["GRS_1980",6378137,298.257222101]')
from geometry_table;</literallayout></para>
</listitem>
</varlistentry>
<varlistentry>
<term>length3d_spheroid(geometry,spheroid)</term>
<listitem>
<para>Calculates the length of of a geometry on an elipsoid, taking
the elevation into account. This is just like length_spheroid except vertical
coordinates (expressed in the same units as the spheroid axes) are used to
calculate the extra distance vertical displacement adds.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>mem_size(geometry)</term>
<listitem>
<para>Returns the amount of space (in bytes) the geometry
takes.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>npoints(geometry)</term>
<listitem>
<para>Returns the number of points in the geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>nrings(geometry)</term>
<listitem>
<para>If the geometry is a polygon or multi-polygon returns the
number of rings.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>numb_sub_objects(geometry)</term>
<listitem>
<para>Returns the number of objects stored in the geometry. This is
useful for MULTI-geometries and GEOMETRYCOLLECTIONs.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>perimeter2d(geometry)</term>
<listitem>
<para>Returns the 2-dimensional perimeter of the geometry, if it is
a polygon or multi-polygon.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>perimeter3d(geometry)</term>
<listitem>
<para>Returns the 3-dimensional perimeter of the geometry, if it is
a polygon or multi-polygon.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>point_inside_circle(geometry,float,float,float)</term>
<listitem>
<para>The syntax for this functions is
point_inside_circle(&lt;geometry&gt;,&lt;circle_center_x&gt;,&lt;circle_center_y&gt;,&lt;radius&gt;).
Returns the true if the geometry is a point and is inside the circle. Returns
false otherwise.</para>
</listitem>
</varlistentry><varlistentry><term>postgis_version()</term><listitem><para>Returns the version number of the PostGIS functions installed in this database.</para></listitem></varlistentry><varlistentry>
<term>summary(geometry)</term>
<listitem>
<para>Returns a text summary of the contents of the
geometry.</para>
</listitem>
</varlistentry>
<varlistentry>
<term>translate(geometry,float8,float8,float8)</term>
<listitem>
<para>Translates the geometry to a new location using the numeric
parameters as offsets. Ie: translate(geom,X,Y,Z).</para>
</listitem>
</varlistentry>
<varlistentry>
<term>truly_inside(geometryA,geometryB)</term>
<listitem>
<para>Returns true if any part of B is within the bounding box of
A.</para>
</listitem>
</varlistentry>
</variablelist>
</sect1>
</chapter>
</book>