postgis/doc/reference_management.xml

646 lines
23 KiB
XML

<?xml version="1.0" encoding="UTF-8"?>
<sect1 id="Management_Functions">
<sect1info>
<abstract>
<para>These functions assist in defining tables containing geometry columns.
</para>
</abstract>
</sect1info>
<title>Table Management Functions</title>
<refentry id="AddGeometryColumn">
<refnamediv>
<refname>AddGeometryColumn</refname>
<refpurpose>Adds a geometry column to an existing table.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>AddGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>type</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>dimension</parameter></paramdef>
<paramdef choice="opt"><type>boolean </type>
<parameter>use_typmod=true</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>AddGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>type</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>dimension</parameter></paramdef>
<paramdef choice="opt"><type>boolean </type>
<parameter>use_typmod=true</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>AddGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>catalog_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>type</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>dimension</parameter></paramdef>
<paramdef choice="opt"><type>boolean </type>
<parameter>use_typmod=true</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Adds a geometry column to an existing table of attributes. The
<varname>schema_name</varname> is the name of the table schema. 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 a string
corresponding to the geometry type, eg, 'POLYGON' or
'MULTILINESTRING' . An error is thrown if the schemaname doesn't exist
(or not visible in the current search_path) or the specified SRID,
geometry type, or dimension is invalid.</para>
<note>
<para>Changed: 2.0.0 This function no longer updates geometry_columns since geometry_columns is a view that reads from system catalogs. It by default
also does not create constraints, but instead uses the built in type modifier behavior of PostgreSQL. So for example building a wgs84 POINT column with this function is now
equivalent to: <code>ALTER TABLE some_table ADD COLUMN geom geometry(Point,4326);</code> </para>
<para>Changed: 2.0.0 If you require the old behavior of constraints use the default <varname>use_typmod</varname>, but set it to false.</para>
</note>
<note>
<para>Changed: 2.0.0 Views can no longer be manually registered in geometry_columns, however views built against geometry typmod tables geometries and used without wrapper functions will register themselves correctly
because they inherit the typmod behavior of their parent table column.
Views that use geometry functions that output other geometries will need to be cast to typmod geometries for these view geometry columns to be registered correctly
in geometry_columns. Refer to <xref linkend="Manual_Register_Spatial_Column"/>.
</para>
</note>
<para>&sfs_compliant;</para>
<para>&Z_support;</para>
<para>&curve_support;</para>
<para>Enhanced: 2.0.0 use_typmod argument introduced. Defaults to creating typmod geometry column instead of constraint-based.</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>-- Create schema to hold data
CREATE SCHEMA my_schema;
-- Create a new simple PostgreSQL table
CREATE TABLE my_schema.my_spatial_table (id serial);
-- Describing the table shows a simple table with a single "id" column.
postgis=# \d my_schema.my_spatial_table
Table "my_schema.my_spatial_table"
Column | Type | Modifiers
--------+---------+-------------------------------------------------------------------------
id | integer | not null default nextval('my_schema.my_spatial_table_id_seq'::regclass)
-- Add a spatial column to the table
SELECT AddGeometryColumn ('my_schema','my_spatial_table','geom',4326,'POINT',2);
-- Add a point using the old constraint based behavior
SELECT AddGeometryColumn ('my_schema','my_spatial_table','geom_c',4326,'POINT',2, false);
--Add a curvepolygon using old constraint behavior
SELECT AddGeometryColumn ('my_schema','my_spatial_table','geomcp_c',4326,'CURVEPOLYGON',2, false);
-- Describe the table again reveals the addition of a new geometry columns.
\d my_schema.my_spatial_table
addgeometrycolumn
-------------------------------------------------------------------------
my_schema.my_spatial_table.geomcp_c SRID:4326 TYPE:CURVEPOLYGON DIMS:2
(1 row)
Table "my_schema.my_spatial_table"
Column | Type | Modifiers
----------+----------------------+-------------------------------------------------------------------------
id | integer | not null default nextval('my_schema.my_spatial_table_id_seq'::regclass)
geom | geometry(Point,4326) |
geom_c | geometry |
geomcp_c | geometry |
Check constraints:
"enforce_dims_geom_c" CHECK (st_ndims(geom_c) = 2)
"enforce_dims_geomcp_c" CHECK (st_ndims(geomcp_c) = 2)
"enforce_geotype_geom_c" CHECK (geometrytype(geom_c) = 'POINT'::text OR geom_c IS NULL)
"enforce_geotype_geomcp_c" CHECK (geometrytype(geomcp_c) = 'CURVEPOLYGON'::text OR geomcp_c IS NULL)
"enforce_srid_geom_c" CHECK (st_srid(geom_c) = 4326)
"enforce_srid_geomcp_c" CHECK (st_srid(geomcp_c) = 4326)
-- geometry_columns view also registers the new columns --
SELECT f_geometry_column As col_name, type, srid, coord_dimension As ndims
FROM geometry_columns
WHERE f_table_name = 'my_spatial_table' AND f_table_schema = 'my_schema';
col_name | type | srid | ndims
----------+--------------+------+-------
geom | Point | 4326 | 2
geom_c | Point | 4326 | 2
geomcp_c | CurvePolygon | 4326 | 2
</programlisting>
</refsection>
<refsection>
<title>See Also</title>
<para><xref linkend="DropGeometryColumn"/>, <xref linkend="DropGeometryTable"/>, <xref linkend="geometry_columns"/>, <xref linkend="Manual_Register_Spatial_Column"/></para>
</refsection>
</refentry>
<refentry id="DropGeometryColumn">
<refnamediv>
<refname>DropGeometryColumn</refname>
<refpurpose>Removes a geometry column from a spatial
table.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>DropGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>DropGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>DropGeometryColumn</function></funcdef>
<paramdef><type>varchar </type>
<parameter>catalog_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Removes a geometry column from a spatial table. Note that
schema_name will need to match the f_table_schema field of the table's
row in the geometry_columns table.</para>
<para>&sfs_compliant;</para>
<para>&Z_support;</para>
<para>&curve_support;</para>
<note>
<para>Changed: 2.0.0 This function is provided for backward compatibility. Now that since geometry_columns is now a view against the system catalogs,
you can drop a geometry column like any other table column using <code>ALTER TABLE</code></para>
</note>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>
SELECT DropGeometryColumn ('my_schema','my_spatial_table','geom');
----RESULT output ---
dropgeometrycolumn
------------------------------------------------------
my_schema.my_spatial_table.geom effectively removed.
-- In PostGIS 2.0+ the above is also equivalent to the standard
-- the standard alter table. Both will deregister from geometry_columns
ALTER TABLE my_schema.my_spatial_table DROP column geom;
</programlisting>
</refsection>
<refsection>
<title>See Also</title>
<para><xref linkend="AddGeometryColumn"/>, <xref linkend="DropGeometryTable"/>, <xref linkend="geometry_columns"/></para>
</refsection>
</refentry>
<refentry id="DropGeometryTable">
<refnamediv>
<refname>DropGeometryTable</refname>
<refpurpose>Drops a table and all its references in
geometry_columns.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>boolean <function>DropGeometryTable</function></funcdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>boolean <function>DropGeometryTable</function></funcdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>boolean <function>DropGeometryTable</function></funcdef>
<paramdef><type>varchar </type>
<parameter>catalog_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Drops a table and all its references in geometry_columns. Note:
uses current_schema() on schema-aware pgsql installations if schema is
not provided.</para>
<note>
<para>Changed: 2.0.0 This function is provided for backward compatibility. Now that since geometry_columns is now a view against the system catalogs,
you can drop a table with geometry columns like any other table using <code>DROP TABLE</code></para>
</note>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT DropGeometryTable ('my_schema','my_spatial_table');
----RESULT output ---
my_schema.my_spatial_table dropped.
-- The above is now equivalent to --
DROP TABLE my_schema.my_spatial_table;
</programlisting>
</refsection>
<refsection>
<title>See Also</title>
<para><xref linkend="AddGeometryColumn"/>, <xref linkend="DropGeometryColumn"/>, <xref linkend="geometry_columns"/></para>
</refsection>
</refentry>
<refentry id="Find_SRID">
<refnamediv>
<refname>Find_SRID</refname>
<refpurpose>Returns the SRID defined for a geometry column.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>integer <function>Find_SRID</function></funcdef>
<paramdef><type>varchar </type> <parameter>a_schema_name</parameter></paramdef>
<paramdef><type>varchar </type> <parameter>a_table_name</parameter></paramdef>
<paramdef><type>varchar </type> <parameter>a_geomfield_name</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Returns the integer SRID of the
specified geometry column by searching through the GEOMETRY_COLUMNS table.
If the geometry column has not been properly added (e.g. with the
<xref linkend="AddGeometryColumn" /> function), this function will not work.</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting> SELECT Find_SRID('public', 'tiger_us_state_2007', 'geom_4269');
find_srid
----------
4269
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
<para><xref linkend="ST_SRID" /></para>
</refsection>
</refentry>
<refentry id="Populate_Geometry_Columns">
<refnamediv>
<refname>Populate_Geometry_Columns</refname>
<refpurpose>Ensures geometry columns are defined with type modifiers or have appropriate spatial constraints.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>Populate_Geometry_Columns</function></funcdef>
<paramdef><type>boolean </type> <parameter>use_typmod=true</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>int <function>Populate_Geometry_Columns</function></funcdef>
<paramdef><type>oid</type> <parameter>relation_oid</parameter></paramdef>
<paramdef><type>boolean </type> <parameter>use_typmod=true</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Ensures geometry columns have appropriate type modifiers or spatial constraints to ensure they are registered correctly in the <varname>geometry_columns</varname> view.
By default will convert all geometry
columns with no type modifier to ones with type modifiers.
</para>
<para>For backwards compatibility and for spatial needs such as table inheritance where each child table may have different geometry type, the old check constraint behavior is still supported.
If you need the old behavior, you need to pass in the new optional argument as false <varname>use_typmod=false</varname>. When this is done geometry columns will be created with no type modifiers
but will have 3 constraints defined. In particular,
this means that every geometry column belonging to a table has at least
three constraints:</para>
<itemizedlist>
<listitem>
<para><varname>enforce_dims_geom</varname> - ensures every
geometry has the same dimension (see <xref
linkend="ST_NDims" />)</para>
</listitem>
<listitem>
<para><varname>enforce_geotype_geom</varname> - ensures every
geometry is of the same type (see <xref
linkend="GeometryType" />)</para>
</listitem>
<listitem>
<para><varname>enforce_srid_geom</varname> - ensures every
geometry is in the same projection (see <xref
linkend="ST_SRID" />)</para>
</listitem>
</itemizedlist>
<para>If a table <varname>oid</varname> is provided, this function
tries to determine the srid, dimension, and geometry type of all
geometry columns in the table, adding constraints as necessary. If
successful, an appropriate row is inserted into the geometry_columns
table, otherwise, the exception is caught and an error notice is raised
describing the problem.</para>
<para>If the <varname>oid</varname> of a view is provided, as with a
table oid, this function tries to determine the srid, dimension, and
type of all the geometries in the view, inserting appropriate entries
into the <varname>geometry_columns</varname> table, but nothing is done
to enforce constraints.</para>
<para>The parameterless variant is a simple wrapper for the parameterized
variant that first truncates and repopulates the geometry_columns table
for every spatial table and view in the database, adding spatial
constraints to tables where appropriate. It returns a summary of the
number of geometry columns detected in the database and the number that
were inserted into the <varname>geometry_columns</varname> table. The
parameterized version simply returns the number of rows inserted into
the <varname>geometry_columns</varname> table.</para>
<para>Availability: 1.4.0</para>
<para>Changed: 2.0.0 By default, now uses type modifiers instead of check constraints to constrain geometry types. You can still use check
constraint behavior instead by using the new <varname>use_typmod</varname> and setting it to false.</para>
<para>Enhanced: 2.0.0 <varname>use_typmod</varname> optional argument was introduced that allows controlling if columns are created with typmodifiers or with check constraints.</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>
CREATE TABLE public.myspatial_table(gid serial, geom geometry);
INSERT INTO myspatial_table(geom) VALUES(ST_GeomFromText('LINESTRING(1 2, 3 4)',4326) );
-- This will now use typ modifiers. For this to work, there must exist data
SELECT Populate_Geometry_Columns('public.myspatial_table'::regclass);
populate_geometry_columns
--------------------------
1
\d myspatial_table
Table "public.myspatial_table"
Column | Type | Modifiers
--------+---------------------------+---------------------------------------------------------------
gid | integer | not null default nextval('myspatial_table_gid_seq'::regclass)
geom | geometry(LineString,4326) |
</programlisting>
<programlisting>-- This will change the geometry columns to use constraints if they are not typmod or have constraints already.
--For this to work, there must exist data
CREATE TABLE public.myspatial_table_cs(gid serial, geom geometry);
INSERT INTO myspatial_table_cs(geom) VALUES(ST_GeomFromText('LINESTRING(1 2, 3 4)',4326) );
SELECT Populate_Geometry_Columns('public.myspatial_table_cs'::regclass, false);
populate_geometry_columns
--------------------------
1
\d myspatial_table_cs
Table "public.myspatial_table_cs"
Column | Type | Modifiers
--------+----------+------------------------------------------------------------------
gid | integer | not null default nextval('myspatial_table_cs_gid_seq'::regclass)
geom | geometry |
Check constraints:
"enforce_dims_geom" CHECK (st_ndims(geom) = 2)
"enforce_geotype_geom" CHECK (geometrytype(geom) = 'LINESTRING'::text OR geom IS NULL)
"enforce_srid_geom" CHECK (st_srid(geom) = 4326)</programlisting>
</refsection>
<!--
<refsection>
<title>See Also</title>
<para><xref linkend="Probe_Geometry_Columns" /></para>
</refsection>
-->
</refentry>
<refentry id="UpdateGeometrySRID">
<refnamediv>
<refname>UpdateGeometrySRID</refname>
<refpurpose>Updates the SRID of all features in a geometry
column, and the table metadata.
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>text <function>UpdateGeometrySRID</function></funcdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>UpdateGeometrySRID</function></funcdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
</funcprototype>
<funcprototype>
<funcdef>text <function>UpdateGeometrySRID</function></funcdef>
<paramdef><type>varchar </type>
<parameter>catalog_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>schema_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>table_name</parameter></paramdef>
<paramdef><type>varchar </type>
<parameter>column_name</parameter></paramdef>
<paramdef><type>integer </type>
<parameter>srid</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Updates the SRID of all features in a geometry column, updating
constraints and reference in geometry_columns.
If the column was enforced by a type definition, the type definition will be changed.
Note: uses
current_schema() on schema-aware pgsql installations if schema is not
provided.</para>
<para>&Z_support;</para>
<para>&curve_support;</para>
</refsection>
<refsection>
<title>Examples</title>
<para>Insert geometries into roads table with a SRID set already using <link linkend="ST_GeomFromEWKT">EWKT format</link>:</para>
<programlisting>COPY roads (geom) FROM STDIN;
SRID=4326;LINESTRING(0 0, 10 10)
SRID=4326;LINESTRING(10 10, 15 0)
\.
</programlisting>
<para>This will change the srid of the roads table to 4326 from whatever it was before:</para>
<programlisting>SELECT UpdateGeometrySRID('roads','geom',4326);</programlisting>
<para>The prior example is equivalent to this DDL statement:</para>
<programlisting>ALTER TABLE roads
ALTER COLUMN geom TYPE geometry(MULTILINESTRING, 4326)
USING ST_SetSRID(geom,4326);</programlisting>
<para>If you got the projection wrong (or brought it in as unknown) in load and you wanted to transform to web mercator all in one shot you can do this with
DDL but there is no equivalent PostGIS management function to do so in one go.</para>
<programlisting>ALTER TABLE roads
ALTER COLUMN geom TYPE geometry(MULTILINESTRING, 3857) USING ST_Transform(ST_SetSRID(geom,4326),3857) ;</programlisting>
</refsection>
<refsection>
<title>See Also</title>
<para>
<xref linkend="RT_UpdateRasterSRID"/>,
<xref linkend="ST_SetSRID"/>,
<xref linkend="ST_Transform"/>,
<xref linkend="ST_GeomFromEWKT"/>
</para>
</refsection>
</refentry>
</sect1>