PostGIS Reference 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. PostGIS has begun a transition from the existing naming convention to an SQL-MM-centric convention. As a result, most of the functions that you know and love have been renamed using the standard spatial type (ST) prefix. Previous functions are still available, though are not listed in this document where updated functions are equivalent. These will be deprecated in a future release. Management Functions AddGeometryColumn Adds a geometry column to an existing table of attributes. text AddGeometryColumn varchar table_name varchar column_name integer srid varchar type integer dimension text AddGeometryColumn varchar schema_name varchar table_name varchar column_name integer srid varchar type integer dimension text AddGeometryColumn varchar catalog_name varchar schema_name varchar table_name varchar column_name integer srid varchar type integer dimension Description Adds a geometry column to an existing table of attributes. The schema_name is the name of the table schema (unused for pre-schema PostgreSQL installations). The srid must be an integer value reference to an entry in the SPATIAL_REF_SYS table. The type must be an uppercase 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. Views and derivatively created spatial tables will need to be registered in geometry_columns manually, since AddGeometryColumn also adds a spatial column which is not needed when you already have a spatial column. Refer to . This method implements the OpenGIS Simple Features Implementation Specification for SQL. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples -- Create a new simple PostgreSQL table postgis=# 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 postgis=# SELECT AddGeometryColumn ('my_schema','my_spatial_table','the_geom',4326,'POINT',2); --Add a curvepolygon SELECT AddGeometryColumn ('my_schema','my_spatial_table','the_geomcp',4326,'CURVEPOLYGON',2); -- Describe the table again reveals the addition of a new "the_geom" column. postgis=# \d my_schema.my_spatial_table Column | Type | Modifiers ------------+----------+------------------------------------------------------------------------- id | integer | not null default nextval('my_schema.my_spatial_table_id_seq'::regclass) the_geom | geometry | the_geomcp | geometry | Check constraints: "enforce_dims_the_geom" CHECK (ndims(the_geom) = 2) "enforce_dims_the_geomcp" CHECK (ndims(the_geomcp) = 2) "enforce_geotype_the_geom" CHECK (geometrytype(the_geom) = 'POINT'::text OR the_geom IS NULL) "enforce_geotype_the_geomcp" CHECK (geometrytype(the_geomcp) = 'CURVEPOLYGON '::text OR the_geomcp IS NULL) "enforce_srid_the_geom" CHECK (srid(the_geom) = 4326) "enforce_srid_the_geomcp" CHECK (srid(the_geomcp) = 4326) See Also , , DropGeometryColumn Removes a geometry column from a spatial table. text DropGeometryColumn varchar table_name varchar column_name text DropGeometryColumn varchar schema_name varchar table_name varchar column_name text DropGeometryColumn varchar catalog_name varchar schema_name varchar table_name varchar column_name Description 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. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This function supports 3d geometry fields. This method supports Circular Strings and Curves Examples SELECT DropGeometryColumn ('my_schema','my_spatial_table','the_geomcp'); ----RESULT output --- my_schema.my_spatial_table.the_geomcp effectively removed. See Also , DropGeometryTable Drops a table and all its references in geometry_columns. boolean DropGeometryTable varchar table_name boolean DropGeometryTable varchar schema_name varchar table_name boolean DropGeometryTable varchar catalog_name varchar schema_name varchar table_name Description Drops a table and all its references in geometry_columns. Note: uses current_schema() on schema-aware pgsql installations if schema is not provided. Examples SELECT DropGeometryTable ('my_schema','my_spatial_table'); ----RESULT output --- my_schema.my_spatial_table dropped. See Also , PostGIS_Full_Version Reports full postgis version and build configuration infos. text PostGIS_Full_Version Description Reports full postgis version and build configuration infos. Examples SELECT PostGIS_Full_Version(); postgis_full_version ---------------------------------------------------------------------------------- POSTGIS="1.3.3" GEOS="3.1.0-CAPI-1.5.0" PROJ="Rel. 4.4.9, 29 Oct 2004" USE_STATS (1 row) See Also , , , PostGIS_GEOS_Version Returns the version number of the GEOS library. text PostGIS_GEOS_Version Description Returns the version number of the GEOS library, or NULL if GEOS support is not enabled. Examples SELECT PostGIS_GEOS_Version(); postgis_geos_version ---------------------- 3.1.0-CAPI-1.5.0 (1 row) See Also , , , PostGIS_Lib_Build_Date Returns build date of the PostGIS library. text PostGIS_Lib_Build_Date Description Returns build date of the PostGIS library. Examples SELECT PostGIS_Lib_Build_Date(); postgis_lib_build_date ------------------------ 2008-06-21 17:53:21 (1 row) PostGIS_Lib_Version Returns the version number of the PostGIS library. text PostGIS_Lib_Version Description Returns the version number of the PostGIS library. Examples SELECT PostGIS_Lib_Version(); postgis_lib_version --------------------- 1.3.3 (1 row) See Also , , , PostGIS_PROJ_Version Returns the version number of the PROJ4 library. text PostGIS_PROJ_Version Description Returns the version number of the PROJ4 library, or NULL if PROJ4 support is not enabled. Examples SELECT PostGIS_PROJ_Version(); postgis_proj_version ------------------------- Rel. 4.4.9, 29 Oct 2004 (1 row) See Also , , , PostGIS_Scripts_Build_Date Returns build date of the PostGIS scripts. text PostGIS_Scripts_Build_Date Description Returns build date of the PostGIS scripts. Availability: 1.0.0RC1 Examples SELECT PostGIS_Scripts_Build_Date(); postgis_scripts_build_date ------------------------- 2007-08-18 09:09:26 (1 row) See Also , , , PostGIS_Scripts_Installed Returns version of the postgis scripts installed in this database. text PostGIS_Scripts_Installed Description Returns version of the postgis scripts installed in this database. If the output of this function doesn't match the output of you probably missed to properly upgrade an existing database. See the Upgrading section for more info. Availability: 0.9.0 Examples SELECT PostGIS_Scripts_Installed(); postgis_scripts_installed ------------------------- 1.3.4SVN (1 row) See Also , , PostGIS_Scripts_Released Returns the version number of the lwpostgis.sql script released with the installed postgis lib. text PostGIS_Scripts_Released Description Returns the version number of the lwpostgis.sql script released with the installed postgis lib. Starting with version 1.1.0 this function returns the same value of . Kept for backward compatibility. Availability: 0.9.0 Examples SELECT PostGIS_Scripts_Released(); postgis_scripts_released ------------------------- 1.3.4SVN (1 row) See Also , , PostGIS_Uses_Stats Returns TRUE if STATS usage has been enabled. text PostGIS_Uses_Stats Description Returns TRUE if STATS usage has been enabled, FALSE otherwise. Examples SELECT PostGIS_Uses_Stats(); postgis_uses_stats -------------------- t (1 row) See Also PostGIS_Version Returns PostGIS version number and compile-time options. text PostGIS_Version Description Returns PostGIS version number and compile-time options. Examples SELECT PostGIS_Version(); postgis_version --------------------------------------- 1.3 USE_GEOS=1 USE_PROJ=1 USE_STATS=1 (1 row) See Also , ,, Populate_Geometry_Columns Ensures geometry columns have appropriate spatial constraints and exist in the geometry_columns table. text Populate_Geometry_Columns int Populate_Geometry_Columns oid table_oid Description Ensures geometry columns have appropriate spatial constraints and exist in the geometry_columns table. In particular, this means that every geometry column belonging to a table has at least three constraints: enforce_dims_the_geom - ensures every geometry has the same dimension (see ) enforce_geotype_the_geom - ensures every geometry is of the same type (see ) enforce_srid_the_geom - ensures every geometry is in the same projection (see ) If a table oid is provided, this function tries to determine the srid, dimension, and geometry type of all geometry columns in the table, adding contraints 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. If the oid 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 geometry_columns table, but nothing is done to enforce contraints. 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 contraints 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 geometry_columns table. The parameterized version simply returns the number of rows inserted into the geometry_columns table. Availability: 1.4.0 Examples SELECT Populate_Geometry_Columns('public.myspatial_table'::regclass); See Also Probe_Geometry_Columns Scans all tables with PostGIS geometry constraints and adds them to the geometry_columns table if they are not there. text Probe_Geometry_Columns Description Scans all tables with PostGIS geometry constraints and adds them to the geometry_columns table if they are not there. Also give stats on number of inserts and already present or possibly obsolete. This will usually only pick up records added by AddGeometryColumn() function. It will not scan views so views will need to be manually added to geometry_columns table. Examples SELECT Probe_Geometry_Columns(); probe_geometry_columns --------------------------------------- probed:6 inserted:0 conflicts:6 stale:0 (1 row) See Also UpdateGeometrySRID Updates the SRID of all features in a geometry column, geometry_columns metadata and srid table constraint text UpdateGeometrySRID varchar table_name varchar column_name integer srid text UpdateGeometrySRID varchar schema_name varchar table_name varchar column_name integer srid text UpdateGeometrySRID varchar catalog_name varchar schema_name varchar table_name varchar column_name integer srid Description Updates the SRID of all features in a geometry column, updating constraints and reference in geometry_columns. Note: uses current_schema() on schema-aware pgsql installations if schema is not provided. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves See Also Geometry Constructors ST_BdPolyFromText Construct a Polygon given an arbitrary collection of closed linestrings as a MultiLineString Well-Known text representation. geometry ST_BdPolyFromText text WKT integer srid Description Construct a Polygon given an arbitrary collection of closed linestrings as a MultiLineString Well-Known text representation. Throws an error if WKT is not a MULTILINESTRING. Throws an error if output is a MULTIPOLYGON; use ST_BdMPolyFromText in that case, or see ST_BuildArea() for a postgis-specific approach. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SFSQL 1.1 - 3.2.6.2 Availability: 1.1.0 - requires GEOS >= 2.1.0. Examples Forthcoming See Also , ST_BdMPolyFromText Construct a MultiPolygon given an arbitrary collection of closed linestrings as a MultiLineString text representation Well-Known text representation. geometry ST_BdMPolyFromText text WKT integer srid Description Construct a Polygon given an arbitrary collection of closed linestrings, polygons, MultiLineStrings as Well-Known text representation. Throws an error if WKT is not a MULTILINESTRING. Forces MULTIPOLYGON output even when result is really only composed by a single POLYGON; use ST_BdPolyFromText if you're sure a single POLYGON will result from operation, or see ST_BuildArea() for a postgis-specific approach. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SFSQL 1.1 - 3.2.6.2 Availability: 1.1.0 - requires GEOS >= 2.1.0. Examples Forthcoming See Also , ST_GeomCollFromText Makes a collection Geometry from collection WKT with the given SRID. If SRID is not give, it defaults to -1. geometry ST_GeomCollFromText text WKT integer srid geometry ST_GeomCollFromText text WKT Description Makes a collection Geometry from the Well-Known-Text (WKT) representation with the given SRID. If SRID is not give, it defaults to -1. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite Returns null if the WKT is not a GEOMETRYCOLLECTION If you are absolutely sure all your WKT geometries are collections, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: ? Examples SELECT ST_GeomCollFromText('GEOMETRYCOLLECTION(POINT(1 2),LINESTRING(1 2, 3 4))'); See Also , ST_GeomFromEWKB Return a specified ST_Geometry value from Extended Well-Known Binary representation (EWKB). geometry ST_GeomFromEWKB bytea EWKB Description Constructs a PostGIS ST_Geometry object from the OGC Extended Well-Known binary (EWKT) representation. The EWKB format is not an OGC standard, but a PostGIS specific format that includes the spatial reference system (SRID) identifier This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples line string binary rep 0f LINESTRING(-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932) in NAD 83 long lat (4269). NOTE: Even though byte arrays are delimited with \ and may have ', we need to escape both out with \ and ''. So it does not look exactly like its AsEWKB representation. SELECT ST_GeomFromEWKB(E'\\001\\002\\000\\000 \\255\\020\\000\\000\\003\\000\\000\\000\\344J= \\013B\\312Q\\300n\\303(\\010\\036!E@''\\277E''K \\312Q\\300\\366{b\\235*!E@\\225|\\354.P\\312Q \\300p\\231\\323e1!E@'); See Also , , ST_GeomFromEWKT Return a specified ST_Geometry value from Extended Well-Known Text representation (EWKT). geometry ST_GeomFromEWKT text EWKT Description Constructs a PostGIS ST_Geometry object from the OGC Extended Well-Known text (EWKT) representation. The EWKT format is not an OGC standard, but an PostGIS specific format that includes the spatial reference system (SRID) identifier This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_GeomFromEWKT('SRID=4269;LINESTRING(-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932)'); SELECT ST_GeomFromEWKT('SRID=4269;MULTILINESTRING((-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932))'); SELECT ST_GeomFromEWKT('SRID=4269;POINT(-71.064544 42.28787)'); SELECT ST_GeomFromEWKT('SRID=4269;POLYGON((-71.1776585052917 42.3902909739571,-71.1776820268866 42.3903701743239, -71.1776063012595 42.3903825660754,-71.1775826583081 42.3903033653531,-71.1776585052917 42.3902909739571))'); SELECT ST_GeomFromEWKT('SRID=4269;MULTIPOLYGON(((-71.1031880899493 42.3152774590236, -71.1031627617667 42.3152960829043,-71.102923838298 42.3149156848307, -71.1023097974109 42.3151969047397,-71.1019285062273 42.3147384934248, -71.102505233663 42.3144722937587,-71.10277487471 42.3141658254797, -71.103113945163 42.3142739188902,-71.10324876416 42.31402489987, -71.1033002961013 42.3140393340215,-71.1033488797549 42.3139495090772, -71.103396240451 42.3138632439557,-71.1041521907712 42.3141153348029, -71.1041411411543 42.3141545014533,-71.1041287795912 42.3142114839058, -71.1041188134329 42.3142693656241,-71.1041112482575 42.3143272556118, -71.1041072845732 42.3143851580048,-71.1041057218871 42.3144430686681, -71.1041065602059 42.3145009876017,-71.1041097995362 42.3145589148055, -71.1041166403905 42.3146168544148,-71.1041258822717 42.3146748022936, -71.1041375307579 42.3147318674446,-71.1041492906949 42.3147711126569, -71.1041598612795 42.314808571739,-71.1042515013869 42.3151287620809, -71.1041173835118 42.3150739481917,-71.1040809891419 42.3151344119048, -71.1040438678912 42.3151191367447,-71.1040194562988 42.3151832057859, -71.1038734225584 42.3151140942995,-71.1038446938243 42.3151006300338, -71.1038315271889 42.315094347535,-71.1037393329282 42.315054824985, -71.1035447555574 42.3152608696313,-71.1033436658644 42.3151648370544, -71.1032580383161 42.3152269126061,-71.103223066939 42.3152517403219, -71.1031880899493 42.3152774590236)), ((-71.1043632495873 42.315113108546,-71.1043583974082 42.3151211109857, -71.1043443253471 42.3150676015829,-71.1043850704575 42.3150793250568,-71.1043632495873 42.315113108546)))'); --3d circular string SELECT ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)'); See Also , , ST_GeometryFromText Return a specified ST_Geometry value from Well-Known Text representation (WKT). This is an alias name for ST_GeomFromText geometry ST_GeometryFromText text WKT geometry ST_GeometryFromText text WKT integer srid Description This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 5.1.40 See Also ST_GeomFromText Return a specified ST_Geometry value from Well-Known Text representation (WKT). geometry ST_GeomFromText text WKT geometry ST_GeomFromText text WKT integer srid Description Constructs a PostGIS ST_Geometry object from the OGC Well-Known text representation. There are 2 variants of ST_GeomFromText function, the first takes no SRID and returns a geometry with no defined spatial reference system. The second takes a spatial reference id as the second argument and returns an ST_Geometry that includes this srid as part of its meta-data. The srid must be defined in the spatial_ref_sys table. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite. This method implements the SQL/MM specification: SQL-MM 3: 5.1.40 This method supports Circular Strings and Curves Examples SELECT ST_GeomFromText('LINESTRING(-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932)'); SELECT ST_GeomFromText('LINESTRING(-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932)',4269); SELECT ST_GeomFromText('MULTILINESTRING((-71.160281 42.258729,-71.160837 42.259113,-71.161144 42.25932))'); SELECT ST_GeomFromText('POINT(-71.064544 42.28787)'); SELECT ST_GeomFromText('POLYGON((-71.1776585052917 42.3902909739571,-71.1776820268866 42.3903701743239, -71.1776063012595 42.3903825660754,-71.1775826583081 42.3903033653531,-71.1776585052917 42.3902909739571))'); SELECT ST_GeomFromText('MULTIPOLYGON(((-71.1031880899493 42.3152774590236, -71.1031627617667 42.3152960829043,-71.102923838298 42.3149156848307, -71.1023097974109 42.3151969047397,-71.1019285062273 42.3147384934248, -71.102505233663 42.3144722937587,-71.10277487471 42.3141658254797, -71.103113945163 42.3142739188902,-71.10324876416 42.31402489987, -71.1033002961013 42.3140393340215,-71.1033488797549 42.3139495090772, -71.103396240451 42.3138632439557,-71.1041521907712 42.3141153348029, -71.1041411411543 42.3141545014533,-71.1041287795912 42.3142114839058, -71.1041188134329 42.3142693656241,-71.1041112482575 42.3143272556118, -71.1041072845732 42.3143851580048,-71.1041057218871 42.3144430686681, -71.1041065602059 42.3145009876017,-71.1041097995362 42.3145589148055, -71.1041166403905 42.3146168544148,-71.1041258822717 42.3146748022936, -71.1041375307579 42.3147318674446,-71.1041492906949 42.3147711126569, -71.1041598612795 42.314808571739,-71.1042515013869 42.3151287620809, -71.1041173835118 42.3150739481917,-71.1040809891419 42.3151344119048, -71.1040438678912 42.3151191367447,-71.1040194562988 42.3151832057859, -71.1038734225584 42.3151140942995,-71.1038446938243 42.3151006300338, -71.1038315271889 42.315094347535,-71.1037393329282 42.315054824985, -71.1035447555574 42.3152608696313,-71.1033436658644 42.3151648370544, -71.1032580383161 42.3152269126061,-71.103223066939 42.3152517403219, -71.1031880899493 42.3152774590236)), ((-71.1043632495873 42.315113108546,-71.1043583974082 42.3151211109857, -71.1043443253471 42.3150676015829,-71.1043850704575 42.3150793250568,-71.1043632495873 42.315113108546)))',4326); SELECT ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)'); See Also , , ST_GeomFromWKB Creates a geometry instance from a Well-Known Binary geometry representation (WKB) and optional SRID. geometry ST_GeomFromWKB bytea geom geometry ST_GeomFromWKB bytea geom integer srid Description The ST_GeomFromWKB function, takes a well-known binary representation of a geometry and a Spatial Reference System ID (SRID) and creates an instance of the appropriate geometry type. This function plays the role of the Geometry Factory in SQL. This is an alternate name for ST_WKBToSQL. If SRID is not specified, it defaults to -1 (Unknown). This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.7.2 - the optional SRID is from the conformance suite This method implements the SQL/MM specification: SQL-MM 3: 5.1.41 ` This method supports Circular Strings and curves Examples --Although bytea rep contains single \, these need to be escaped when inserting into a table SELECT ST_AsEWKT( ST_GeomFromWKB(E'\\001\\002\\000\\000\\000\\002\\000\\000\\000\\037\\205\\353Q\\270~\\\\\\300\\323Mb\\020X\\231C@\\020X9\\264\\310~\\\\\\300)\\\\\\217\\302\\365\\230C@',4326) ); st_asewkt ------------------------------------------------------ SRID=4326;LINESTRING(-113.98 39.198,-113.981 39.195) (1 row) SELECT ST_AsText( ST_GeomFromWKB( ST_AsEWKB('POINT(2 5)'::geometry) ) ); st_astext ------------ POINT(2 5) (1 row) See Also , , ST_LineFromMultiPoint Creates a LineString from a MultiPoint geometry. geometry ST_LineFromMultiPoint geometry aMultiPoint Description Creates a LineString from a MultiPoint geometry. This function supports 3d and will not drop the z-index. Examples --Create a 3d line string from a 3d multipoint SELECT ST_AsEWKT(ST_LineFromMultiPoint(ST_GeomFromEWKT('MULTIPOINT(1 2 3, 4 5 6, 7 8 9)'))); --result-- LINESTRING(1 2 3,4 5 6,7 8 9) See Also , , ST_LineFromText Makes a Geometry from WKT representation with the given SRID. If SRID is not given, it defaults to -1. geometry ST_LineFromText text WKT geometry ST_LineFromText text WKT integer srid Description Makes a Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. If WKT passed in is not a LINESTRING, then null is returned. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite. If you know all your geometries are LINESTRINGS, its more efficient to just use ST_GeomFromText. This just calls ST_GeomFromText and adds additional validation that it returns a linestring. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 7.2.8 Examples SELECT ST_LineFromText('LINESTRING(1 2, 3 4)') AS aline, ST_LineFromText('POINT(1 2)') AS null_return; aline | null_return ------------------------------------------------ 010200000002000000000000000000F ... | t See Also ST_LineFromWKB Makes a LINESTRING from WKB with the given SRID geometry ST_LineFromWKB bytea WKB geometry ST_LineFromWKB bytea WKB integer srid Description The ST_LineFromWKB function, takes a well-known binary representation of geometry and a Spatial Reference System ID (SRID) and creates an instance of the appropriate geometry type - in this case, a LINESTRING geometry. This function plays the role of the Geometry Factory in SQL. If an SRID is not specified, it defaults to -1. NULL is returned if the input bytea does not represent a LINESTRING. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite. If you know all your geometries are LINESTRINGs, its more efficient to just use . This function just calls and adds additional validation that it returns a linestring. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 7.2.9 Examples SELECT ST_LineFromWKB(ST_AsBinary(ST_GeomFromText('LINESTRING(1 2, 3 4)'))) AS aline, ST_LineFromWKB(ST_AsBinary(ST_GeomFromText('POINT(1 2)'))) IS NULL AS null_return; aline | null_return ------------------------------------------------ 010200000002000000000000000000F ... | t See Also , ST_LinestringFromWKB Makes a geometry from WKB with the given SRID. geometry ST_LinestringFromWKB bytea WKB geometry ST_LinestringFromWKB bytea WKT integer srid Description The ST_LinestringFromWKB function, takes a well-known binary representation of geometry and a Spatial Reference System ID (SRID) and creates an instance of the appropriate geometry type - in this case, a LINESTRING geometry. This function plays the role of the Geometry Factory in SQL. If an SRID is not specified, it defaults to -1. NULL is returned if the input bytea does not represent a LINESTRING geometry. This an alias for . OGC SPEC 3.2.6.2 - optional SRID is from the conformance suite. If you know all your geometries are LINESTRINGs, it's more efficient to just use . This function just calls and adds additional validation that it returns a LINESTRING. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 7.2.9 Examples SELECT ST_LineStringFromWKB( ST_AsBinary(ST_GeomFromText('LINESTRING(1 2, 3 4)')) ) AS aline, ST_LinestringFromWKB( ST_AsBinary(ST_GeomFromText('POINT(1 2)')) ) IS NULL AS null_return; aline | null_return ------------------------------------------------ 010200000002000000000000000000F ... | t See Also , ST_MakeBox2D Creates a BOX2D defined by the given point geometries. box2d ST_MakeBox2D geometry pointLowLeft geometry pointUpRight Description Creates a BOX2D defined by the given point geometries. This is useful for doing range queries Examples --Return all features that fall reside or partly reside in a US national atlas coordinate bounding box --It is assumed here that the geometries are stored with SRID = 2163 (US National atlas equal area) SELECT feature_id, feature_name, the_geom FROM features WHERE the_geom && ST_SetSRID(ST_MakeBox2D(ST_Point(-989502.1875, 528439.5625), ST_Point(-987121.375 ,529933.1875)),2163) See Also , , , ST_MakeBox3D Creates a BOX3D defined by the given 3d point geometries. box3d ST_MakeBox3D geometry point3DLowLeftBottom geometry point3DUpRightTop Description Creates a BOX3D defined by the given 2 3D point geometries. This function supports 3d and will not drop the z-index. Examples SELECT ST_MakeBox3D(ST_MakePoint(-989502.1875, 528439.5625, 10), ST_MakePoint(-987121.375 ,529933.1875, 10)) As abb3d --bb3d-- -------- BOX3D(-989502.1875 528439.5625 10,-987121.375 529933.1875 10) See Also , , ST_MakeLine Creates a Linestring from point geometries. geometry ST_MakeLine geometry set pointfield geometry ST_MakeLine geometry point1 geometry point2 geometry ST_MakeLine geometry[] point_array Description ST_MakeLine comes in 3 forms: a spatial aggregate that takes rows of point geometries and returns a line string, a function that takes an array of points, and a regular function that takes two point geometries. You might want to use a subselect to order points before feeding them to the aggregate version of this function. This function supports 3d and will not drop the z-index. Availability: 1.4.0 - ST_MakeLine(geomarray) was introduced. ST_MakeLine aggregate functions was enhanced to handle more points faster. Examples: Spatial Aggregate version This example takes a sequence of GPS points and creates one record for each gps travel where the geometry field is a line string composed of the gps points in the order of the travel. SELECT gps.gps_track, ST_MakeLine(gps.the_geom) As newgeom FROM (SELECT gps_track,gps_time, the_geom FROM gps_points ORDER BY gps_track, gps_time) As gps GROUP BY gps.gps_track Examples: Non-Spatial Aggregate version First example is a simple one off line string composed of 2 points. The second formulates line strings from 2 points a user draws. The third is a one-off that joins 2 3d points to create a line in 3d space. SELECT ST_AsText(ST_MakeLine(ST_MakePoint(1,2), ST_MakePoint(3,4))); st_astext --------------------- LINESTRING(1 2,3 4) SELECT userpoints.id, ST_MakeLine(startpoint, endpoint) As drawn_line FROM userpoints ; SELECT ST_AsEWKT(ST_MakeLine(ST_MakePoint(1,2,3), ST_MakePoint(3,4,5))); st_asewkt ------------------------- LINESTRING(1 2 3,3 4 5) Examples: Using Array version SELECT ST_MakeLine(ARRAY(SELECT ST_Centroid(the_geom) FROM visit_locations ORDER BY visit_time)); --Making a 3d line with 3 3-d points SELECT ST_AsEWKT(ST_MakeLine(ARRAY[ST_MakePoint(1,2,3), ST_MakePoint(3,4,5), ST_MakePoint(6,6,6)])); st_asewkt ------------------------- LINESTRING(1 2 3,3 4 5,6 6 6) See Also , , , ST_MakePolygon Creates a Polygon formed by the given shell. Input geometries must be closed LINESTRINGS. geometry ST_MakePolygon geometry linestring geometry ST_MakePolygon geometry outerlinestring geometry[] interiorlinestrings Description Creates a Polygon formed by the given shell. Input geometries must be closed LINESTRINGS. Comes in 2 variants. Variant 1: takes one closed linestring. Variant 2: Creates a Polygon formed by the given shell and array of holes. You can construct a geometry array using ST_Accum or the PostgreSQL ARRAY[] and ARRAY() constructs. Input geometries must be closed LINESTRINGS. This function will not accept a MULTILINESTRING. Use or to generate line strings. This function supports 3d and will not drop the z-index. Examples: Single closed LINESTRING --2d line SELECT ST_MakePolygon(ST_GeomFromText('LINESTRING(75.15 29.53,77 29,77.6 29.5, 75.15 29.53)')); --If linestring is not closed --you can add the start point to close it SELECT ST_MakePolygon(ST_AddPoint(foo.open_line, ST_StartPoint(foo.open_line))) FROM ( SELECT ST_GeomFromText('LINESTRING(75.15 29.53,77 29,77.6 29.5)') As open_line) As foo; --3d closed line SELECT ST_MakePolygon(ST_GeomFromText('LINESTRING(75.15 29.53 1,77 29 1,77.6 29.5 1, 75.15 29.53 1)')); st_asewkt ----------- POLYGON((75.15 29.53 1,77 29 1,77.6 29.5 1,75.15 29.53 1)) --measured line -- SELECT ST_MakePolygon(ST_GeomFromText('LINESTRINGM(75.15 29.53 1,77 29 1,77.6 29.5 2, 75.15 29.53 2)')); st_asewkt ---------- POLYGONM((75.15 29.53 1,77 29 1,77.6 29.5 2,75.15 29.53 2)) Examples: Outter shell with inner shells Build a donut with an ant hole SELECT ST_MakePolygon( ST_ExteriorRing(ST_Buffer(foo.line,10)), ARRAY[ST_Translate(foo.line,1,1), ST_ExteriorRing(ST_Buffer(ST_MakePoint(20,20),1)) ] ) FROM (SELECT ST_ExteriorRing(ST_Buffer(ST_MakePoint(10,10),10,10)) As line ) As foo; Build province boundaries with holes representing lakes in the province from a set of province polygons/multipolygons and water line strings this is an example of using PostGIS ST_Accum The use of CASE because feeding a null array into ST_MakePolygon results in NULL the use of left join to guarantee we get all provinces back even if they have no lakes SELECT p.gid, p.province_name, CASE WHEN ST_Accum(w.the_geom) IS NULL THEN p.the_geom ELSE ST_MakePolygon(ST_LineMerge(ST_Boundary(p.the_geom)), ST_Accum(w.the_geom)) END FROM provinces p LEFT JOIN waterlines w ON (ST_Within(w.the_geom, p.the_geom) AND ST_IsClosed(w.the_geom)) GROUP BY p.gid, p.province_name, p.the_geom; --Same example above but utilizing a correlated subquery --and PostgreSQL built-in ARRAY() function that converts a row set to an array SELECT p.gid, p.province_name, CASE WHEN EXISTS(SELECT w.the_geom FROM waterlines w WHERE ST_Within(w.the_geom, p.the_geom) AND ST_IsClosed(w.the_geom)) THEN ST_MakePolygon(ST_LineMerge(ST_Boundary(p.the_geom)), ARRAY(SELECT w.the_geom FROM waterlines w WHERE ST_Within(w.the_geom, p.the_geom) AND ST_IsClosed(w.the_geom))) ELSE p.the_geom END As the_geom FROM provinces p; See Also , , , , ST_MakePoint Creates a 2D,3DZ or 4D point geometry. geometry ST_MakePoint double precision x double precision y geometry ST_MakePoint double precision x double precision y double precision z geometry ST_MakePoint double precision x double precision y double precision z double precision m Description Creates a 2D,3DZ or 4D point geometry (geometry with measure). ST_MakePoint while not being OGC compliant is generally faster and more precise than and . It is also easier to use if you have raw coordinates rather than WKT. Note x is longitude and y is latitude This function supports 3d and will not drop the z-index. Examples --Return point with unknown SRID SELECT ST_MakePoint(-71.1043443253471, 42.3150676015829); --Return point marked as WGS 84 long lat SELECT ST_SetSRID(ST_MakePoint(-71.1043443253471, 42.3150676015829),4326); --Return a 3D point (e.g. has altitude) SELECT ST_MakePoint(1, 2,1.5); --Get z of point SELECT ST_Z(ST_MakePoint(1, 2,1.5)); result ------- 1.5 See Also , , ST_MakePointM Creates a point geometry with an x y and m coordinate. geometry ST_MakePointM float x float y float m Description Creates a point with x, y and measure coordinates. Note x is longitude and y is latitude. Examples We use ST_AsEWKT in these examples to show the text representation instead of ST_AsText because ST_AsText does not support returning M. --Return EWKT representation of point with unknown SRID SELECT ST_AsEWKT(ST_MakePointM(-71.1043443253471, 42.3150676015829, 10)); --result st_asewkt ----------------------------------------------- POINTM(-71.1043443253471 42.3150676015829 10) --Return EWKT representation of point with measure marked as WGS 84 long lat SELECT ST_AsEWKT(ST_SetSRID(ST_MakePointM(-71.1043443253471, 42.3150676015829,10),4326)); st_asewkt --------------------------------------------------------- SRID=4326;POINTM(-71.1043443253471 42.3150676015829 10) --Return a 3d point (e.g. has altitude) SELECT ST_MakePoint(1, 2,1.5); --Get m of point SELECT ST_M(ST_MakePointM(-71.1043443253471, 42.3150676015829,10)); result ------- 10 See Also , , ST_MLineFromText Return a specified ST_MultiLineString value from WKT representation. geometry ST_MLineFromText text WKT integer srid geometry ST_MLineFromText text WKT Description Makes a Geometry from Well-Known-Text (WKT) with the given SRID. If SRID is not give, it defaults to -1. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite Returns null if the WKT is not a MULTILINESTRING If you are absolutely sure all your WKT geometries are points, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 9.4.4 Examples SELECT ST_MLineFromText('MULTILINESTRING((1 2, 3 4), (4 5, 6 7))'); See Also ST_MPointFromText Makes a Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. geometry ST_MPointFromText text WKT integer srid geometry ST_MPointFromText text WKT Description Makes a Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite Returns null if the WKT is not a MULTIPOINT If you are absolutely sure all your WKT geometries are points, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 9.2.4 Examples SELECT ST_MPointFromText('MULTIPOINT(1 2, 3 4)'); SELECT ST_MPointFromText('MULTIPOINT(-70.9590 42.1180, -70.9611 42.1223)', 4326); See Also ST_MPolyFromText Makes a MultiPolygon Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. geometry ST_MPolyFromText text WKT integer srid geometry ST_MPolyFromText text WKT Description Makes a MultiPolygon from WKT with the given SRID. If SRID is not give, it defaults to -1. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite Throws an error if the WKT is not a MULTIPOLYGON If you are absolutely sure all your WKT geometries are multipolygons, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 9.6.4 Examples SELECT ST_MPolyFromText('MULTIPOLYGON(((0 0 1,20 0 1,20 20 1,0 20 1,0 0 1),(5 5 3,5 7 3,7 7 3,7 5 3,5 5 3)))'); SELECt ST_MPolyFromText('MULTIPOLYGON(((-70.916 42.1002,-70.9468 42.0946,-70.9765 42.0872,-70.9754 42.0875,-70.9749 42.0879,-70.9752 42.0881,-70.9754 42.0891,-70.9758 42.0894,-70.9759 42.0897,-70.9759 42.0899,-70.9754 42.0902,-70.9756 42.0906,-70.9753 42.0907,-70.9753 42.0917,-70.9757 42.0924,-70.9755 42.0928,-70.9755 42.0942,-70.9751 42.0948,-70.9755 42.0953,-70.9751 42.0958,-70.9751 42.0962,-70.9759 42.0983,-70.9767 42.0987,-70.9768 42.0991,-70.9771 42.0997,-70.9771 42.1003,-70.9768 42.1005,-70.977 42.1011,-70.9766 42.1019,-70.9768 42.1026,-70.9769 42.1033,-70.9775 42.1042,-70.9773 42.1043,-70.9776 42.1043,-70.9778 42.1048,-70.9773 42.1058,-70.9774 42.1061,-70.9779 42.1065,-70.9782 42.1078,-70.9788 42.1085,-70.9798 42.1087,-70.9806 42.109,-70.9807 42.1093,-70.9806 42.1099,-70.9809 42.1109,-70.9808 42.1112,-70.9798 42.1116,-70.9792 42.1127,-70.979 42.1129,-70.9787 42.1134,-70.979 42.1139,-70.9791 42.1141,-70.9987 42.1116,-71.0022 42.1273, -70.9408 42.1513,-70.9315 42.1165,-70.916 42.1002)))',4326); See Also , ST_Point Returns an ST_Point with the given coordinate values. OGC alias for ST_MakePoint. geometry ST_Point float x_lon float y_lat Description Returns an ST_Point with the given coordinate values. MM compliant alias for ST_MakePoint that takes just an x and y. This method implements the SQL/MM specification: SQL-MM 3: 6.1.2 Examples SELECT ST_SetSRID(ST_Point(-71.1043443253471, 42.3150676015829),4326) See Also , ST_PointFromText Makes a point Geometry from WKT with the given SRID. If SRID is not given, it defaults to unknown. geometry ST_PointFromText text WKT geometry ST_PointFromText text WKT integer srid Description Constructs a PostGIS ST_Geometry point object from the OGC Well-Known text representation. If SRID is not give, it defaults to unknown (currently -1). If geometry is not a WKT point representation, returns null. If completely invalid WKT, then throws an error. There are 2 variants of ST_PointFromText function, the first takes no SRID and returns a geometry with no defined spatial reference system. The second takes a spatial reference id as the second argument and returns an ST_Geometry that includes this srid as part of its meta-data. The srid must be defined in the spatial_ref_sys table. If you are absolutely sure all your WKT geometries are points, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. If you are building points from long lat coordinates and care more about performance and accuracy than OGC compliance, use or OGC compliant alias . This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite. This method implements the SQL/MM specification:SQL-MM 3: 6.1.8 Examples SELECT ST_PointFromText('POINT(-71.064544 42.28787)'); SELECT ST_PointFromText('POINT(-71.064544 42.28787)', 4326); See Also , , , ST_PointFromWKB Makes a geometry from WKB with the given SRID geometry ST_GeomFromWKB bytea geom geometry ST_GeomFromWKB bytea geom integer srid Description The ST_PointFromWKB function, takes a well-known binary representation of geometry and a Spatial Reference System ID (SRID) and creates an instance of the appropriate geometry type - in this case, a POINT geometry. This function plays the role of the Geometry Factory in SQL. If an SRID is not specified, it defaults to -1. NULL is returned if the input bytea does not represent a POINT geometry. This method implements the OpenGIS Simple Features Implementation Specification for SQL. 3.2.7.2 This method implements the SQL/MM specification: SQL-MM 3: 6.1.9 This function supports 3D This method supports Circular Strings and Curves Examples SELECT ST_AsText( ST_PointFromWKB( ST_AsEWKB('POINT(2 5)'::geometry) ) ); st_astext ------------ POINT(2 5) (1 row) SELECT ST_AsText( ST_PointFromWKB( ST_AsEWKB('LINESTRING(2 5, 2 6)'::geometry) ) ); st_astext ----------- (1 row) See Also , ST_Polygon Returns a polygon built from the specified linestring and SRID. geometry ST_Polygon geometry aLineString integer srid Description Returns a polygon built from the specified linestring and SRID. ST_Polygon is similar to first version oST_MakePolygon except it also sets the spatial ref sys (SRID) of the polygon. Will not work with MULTILINESTRINGS so use LineMerge to merge multilines. Also does not create polygons with holes. Use ST_MakePolygon for that. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 8.3.2 This function supports 3d and will not drop the z-index. Examples --a 2d polygon SELECT ST_Polygon(ST_GeomFromText('LINESTRING(75.15 29.53,77 29,77.6 29.5, 75.15 29.53)'), 4326); --result-- POLYGON((75.15 29.53,77 29,77.6 29.5,75.15 29.53)) --a 3d polygon SELECT ST_AsEWKT(ST_Polygon(ST_GeomFromEWKT('LINESTRING(75.15 29.53 1,77 29 1,77.6 29.5 1, 75.15 29.53 1)'), 4326)); result ------ SRID=4326;POLYGON((75.15 29.53 1,77 29 1,77.6 29.5 1,75.15 29.53 1)) See Also , , , , , ST_PolygonFromText Makes a Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. geometry ST_PolygonFromText text WKT geometry ST_PolygonFromText text WKT integer srid Description Makes a Geometry from WKT with the given SRID. If SRID is not give, it defaults to -1. Returns null if WKT is not a polygon. OGC SPEC 3.2.6.2 - option SRID is from the conformance suite If you are absolutely sure all your WKT geometries are polygons, don't use this function. It is slower than ST_GeomFromText since it adds an additional validation step. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 3.2.6.2 This method implements the SQL/MM specification: SQL-MM 3: 8.3.6 Examples SELECT ST_PolygonFromText('POLYGON((-71.1776585052917 42.3902909739571,-71.1776820268866 42.3903701743239, -71.1776063012595 42.3903825660754,-71.1775826583081 42.3903033653531,-71.1776585052917 42.3902909739571))'); st_polygonfromtext ------------------ 010300000001000000050000006... SELECT ST_PolygonFromText('POINT(1 2)') IS NULL as point_is_notpoly; point_is_not_poly ---------- t See Also ST_WKBToSQL Return a specified ST_Geometry value from Well-Known Binary representation (WKB). This is an alias name for ST_GeomFromWKB that takes no srid geometry ST_WKBToSQL bytea WKB Description This method implements the SQL/MM specification: SQL-MM 3: 5.1.36 See Also ST_WKTToSQL Return a specified ST_Geometry value from Well-Known Text representation (WKT). This is an alias name for ST_GeomFromText geometry ST_WKTToSQL text WKT Description This method implements the SQL/MM specification: SQL-MM 3: 5.1.34 See Also Geometry Accessors GeometryType Returns the type of the geometry as a string. Eg: 'LINESTRING', 'POLYGON', 'MULTIPOINT', etc. text GeometryType geometry geomA Description Returns the type of the geometry as a string. Eg: 'LINESTRING', 'POLYGON', 'MULTIPOINT', etc. OGC SPEC s2.1.1.1 - Returns the name of the instantiable subtype of Geometry of which this Geometry instance is a member. The name of the instantiable subtype of Geometry is returned as a string. This function also indicates if the geometry is measured, by returning a string of the form 'POINTM'. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method supports Circular Strings and Curves Examples SELECT GeometryType(ST_GeomFromText('LINESTRING(77.29 29.07,77.42 29.26,77.27 29.31,77.29 29.07)')); geometrytype -------------- LINESTRING See Also ST_Boundary Returns the closure of the combinatorial boundary of this Geometry. geometry ST_Boundary geometry geomA Description Returns the closure of the combinatorial boundary of this Geometry. The combinatorial boundary is defined as described in section 3.12.3.2 of the OGC SPEC. Because the result of this function is a closure, and hence topologically closed, the resulting boundary can be represented using representational geometry primitives as discussed in the OGC SPEC, section 3.12.2. Performed by the GEOS module Do not call with a GEOMETRYCOLLECTION as an argument This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.14 This function supports 3d and will not drop the z-index. Examples SELECT ST_AsText(ST_Boundary(ST_GeomFromText('LINESTRING(1 1,0 0, -1 1)'))); st_astext ----------- MULTIPOINT(1 1,-1 1) SELECT ST_AsText(ST_Boundary(ST_GeomFromText('POLYGON((1 1,0 0, -1 1, 1 1))'))); st_astext ---------- LINESTRING(1 1,0 0,-1 1,1 1) --Using a 3d polygon SELECT ST_AsEWKT(ST_Boundary(ST_GeomFromEWKT('POLYGON((1 1 1,0 0 1, -1 1 1, 1 1 1))'))); st_asewkt ----------------------------------- LINESTRING(1 1 1,0 0 1,-1 1 1,1 1 1) --Using a 3d multilinestring SELECT ST_AsEWKT(ST_Boundary(ST_GeomFromEWKT('MULTILINESTRING((1 1 1,0 0 0.5, -1 1 1),(1 1 0.5,0 0 0.5, -1 1 0.5, 1 1 0.5) )'))); st_asewkt ---------- MULTIPOINT(-1 1 1,1 1 0.75) See Also , ST_CoordDim Return the coordinate dimension of the ST_Geometry value. integer ST_CoordDim geometry geomA Description Return the coordinate dimension of the ST_Geometry value. This is the MM compliant alias name for This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 5.1.3 This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_CoordDim('CIRCULARSTRING(1 2 3, 1 3 4, 5 6 7, 8 9 10, 11 12 13)'); ---result-- 3 SELECT ST_CoordDim(ST_Point(1,2)); --result-- 2 See Also ST_Dimension The inherent dimension of this Geometry object, which must be less than or equal to the coordinate dimension. integer ST_Dimension geometry g Description The inherent dimension of this Geometry object, which must be less than or equal to the coordinate dimension. OGC SPEC s2.1.1.1 - returns 0 for POINT, 1 for LINESTRING, 2 for POLYGON, and the largest dimension of the components of a GEOMETRYCOLLECTION. This method implements the SQL/MM specification: SQL-MM 3: 5.1.2 Examples SELECT ST_Dimension('GEOMETRYCOLLECTION(LINESTRING(1 1,0 0),POINT(0 0))'); ST_Dimension ----------- 1 See Also ST_EndPoint Returns the last point of a LINESTRING geometry as a POINT. boolean ST_EndPoint geometry g Description Returns the last point of a LINESTRING geometry as a POINT or NULL if the input parameter is not a LINESTRING. This method implements the SQL/MM specification: SQL-MM 3: 7.1.4 This function supports 3d and will not drop the z-index. Examples postgis=# SELECT ST_AsText(ST_EndPoint('LINESTRING(1 1, 2 2, 3 3)'::geometry)); st_astext ------------ POINT(3 3) (1 row) postgis=# SELECT ST_EndPoint('POINT(1 1)'::geometry) IS NULL AS is_null; is_null ---------- t (1 row) --3d endpoint SELECT ST_AsEWKT(ST_EndPoint('LINESTRING(1 1 2, 1 2 3, 0 0 5)')); st_asewkt -------------- POINT(0 0 5) (1 row) See Also , ST_Envelope Returns a geometry representing the bounding box of the supplied geometry. boolean ST_Envelope geometry g1 Description Returns the minimum bounding box for the supplied geometry, as a geometry. The polygon is defined by the corner points of the bounding box ((MINX, MINY), (MINX, MAXY), (MAXX, MAXY), (MAXX, MINY), (MINX, MINY)). (PostGIS will add a ZMIN/ZMAX coordinate as well). Degenerate cases (vertical lines, points) will return a geometry of lower dimension than POLYGON, ie. POINT or LINESTRING. In PostGIS, the bounding box of a geometry is represented internally using float4s instead of float8s that are used to store geometries. The bounding box coordinates are floored, guarenteeing that the geometry is contained entirely within its bounds. This has the advantage that a geometry's bounding box is half the size as the minimum bounding rectangle, which means significantly faster indexes and general performance. But it also means that the bounding box is NOT the same as the minimum bounding rectangle that bounds the geometry. This method implements the OpenGIS Simple Features Implementation Specification for SQL: v1.1: s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.15 Examples SELECT ST_AsText(ST_Envelope('POINT(1 3)'::geometry)); st_astext ------------ POINT(1 3) (1 row) SELECT ST_AsText(ST_Envelope('LINESTRING(0 0, 1 3)'::geometry)); st_astext -------------------------------- POLYGON((0 0,0 3,1 3,1 0,0 0)) (1 row) SELECT ST_AsText(ST_Envelope('POLYGON((0 0, 0 1, 1.0000001 1, 1.0000001 0, 0 0))'::geometry)); st_astext -------------------------------------------------------------- POLYGON((0 0,0 1,1.00000011920929 1,1.00000011920929 0,0 0)) (1 row) SELECT ST_AsText(ST_Envelope('POLYGON((0 0, 0 1, 1.0000000001 1, 1.0000000001 0, 0 0))'::geometry)); st_astext -------------------------------------------------------------- POLYGON((0 0,0 1,1.00000011920929 1,1.00000011920929 0,0 0)) (1 row) ST_ExteriorRing Returns a line string representing the exterior ring of the POLYGON geometry. Return NULL if the geometry is not a polygon. Will not work with MULTIPOLYGON geometry ST_ExteriorRing geometry a_polygon Description Returns a line string representing the exterior ring of the POLYGON geometry. Return NULL if the geometry is not a polygon. Only works with POLYGON geometry types This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SFSQL 1.1 - 2.1.5.1 This method implements the SQL/MM specification: SQL-MM 3: 8.2.3, 8.3.3 This function supports 3d and will not drop the z-index. Examples --If you have a table of polygons SELECT gid, ST_ExteriorRing(the_geom) AS ering FROM sometable; --If you have a table of MULTIPOLYGONs --and want to return a MULTILINESTRING composed of the exterior rings of each polygon SELECT gid, ST_Collect(ST_ExteriorRing(the_geom)) AS erings FROM (SELECT gid, (ST_Dump(the_geom)).geom As the_geom FROM sometable) As foo GROUP BY gid; --3d Example SELECT ST_AsEWKT( ST_ExteriorRing( ST_GeomFromEWKT('POLYGON((0 0 1, 1 1 1, 1 2 1, 1 1 1, 0 0 1))') ) ); st_asewkt --------- LINESTRING(0 0 1,1 1 1,1 2 1,1 1 1,0 0 1) See Also , ST_GeometryN Return the 1-based Nth geometry if the geometry is a GEOMETRYCOLLECTION, MULTIPOINT, MULTILINESTRING or MULTIPOLYGON. Otherwise, return NULL. geometry ST_GeometryN geometry geomA integer n Description Return the 1-based Nth geometry if the geometry is a GEOMETRYCOLLECTION, MULTIPOINT, MULTILINESTRING or MULTIPOLYGON. Otherwise, return NULL. Index is 1-based as for OGC specs since version 0.8.0. Previous versions implemented this as 0-based instead. If you want to extract all geometries, of a geometry, ST_Dump is more efficient and will also work for singular geoms. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 9.1.5 This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples --Extracting a subset of points from a 3d multipoint SELECT ST_AsEWKT(ST_GeometryN(the_geom, n)) FROM ( SELECT ST_GeomFromEWKT('MULTIPOINT(1 2 7, 3 4 7, 5 6 7, 8 9 10)') As the_geom) As foo CROSS JOIN generate_series(1,100) n WHERE n BETWEEN 2 and 3; st_asewkt ------------ POINT(3 4 7) POINT(5 6 7) --Extracting all geometries (useful when you want to assign an id) SELECT gid, n, ST_GeometryN(the_geom, n) FROM sometable CROSS JOIN generate_series(1,100) n WHERE n >= ST_NumGeometries(the_geom); See Also , ST_GeometryType Return the geometry type of the ST_Geometry value. text ST_GeometryType geometry g1 Description Returns the type of the geometry as a string. EG: 'ST_Linestring', 'ST_Polygon','ST_MultiPolygon' etc. This function differs from GeometryType(geometry) in the case of the string and ST in front that is returned, as well as the fact that it will not indicate whether the geometry is measured. This method implements the SQL/MM specification: SQL-MM 3: 5.1.4 Examples SELECT ST_GeometryType(ST_GeomFromText('LINESTRING(77.29 29.07,77.42 29.26,77.27 29.31,77.29 29.07)')); --result ST_LineString See Also ST_InteriorRingN Return the Nth interior linestring ring of the polygon geometry. Return NULL if the geometry is not a polygon or the given N is out of range. geometry ST_InteriorRingN geometry a_polygon integer n Description Return the Nth interior linestring ring of the polygon geometry. Return NULL if the geometry is not a polygon or the given N is out of range. index starts at 1. This will not work for MULTIPOLYGONs. Use in conjunction with ST_Dump for MULTIPOLYGONS This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 8.2.6, 8.3.5 This function supports 3d and will not drop the z-index. Examples SELECT ST_AsText(ST_InteriorRingN(the_geom, 1)) As the_geom FROM (SELECT ST_BuildArea( ST_Collect(ST_Buffer(ST_Point(1,2), 20,3), ST_Buffer(ST_Point(1, 2), 10,3))) As the_geom ) as foo See Also , , , , ST_IsClosed Returns TRUE if the LINESTRING's start and end points are coincident. boolean ST_IsClosed geometry g Description Returns TRUE if the LINESTRING's start and end points are coincident. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 7.1.5, 9.3.3 SQL-MM defines the result of ST_IsClosed(NULL) to be 0, while PostGIS returns NULL. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples postgis=# SELECT ST_IsClosed('LINESTRING(0 0, 1 1)'::geometry); st_isclosed ------------- f (1 row) postgis=# SELECT ST_IsClosed('LINESTRING(0 0, 0 1, 1 1, 0 0)'::geometry); st_isclosed ------------- t (1 row) postgis=# SELECT ST_IsClosed('MULTILINESTRING((0 0, 0 1, 1 1, 0 0),(0 0, 1 1))'::geometry); st_isclosed ------------- f (1 row) postgis=# SELECT ST_IsClosed('POINT(0 0)'::geometry); st_isclosed ------------- t (1 row) postgis=# SELECT ST_IsClosed('MULTIPOINT((0 0), (1 1))'::geometry); st_isclosed ------------- t (1 row) See Also ST_IsEmpty Returns true if this Geometry is an empty geometry . If true, then this Geometry represents the empty point set - i.e. GEOMETRYCOLLECTION(EMPTY). boolean ST_IsEmpty geometry geomA Description Returns true if this Geometry is an empty geometry . If true, then this Geometry represents an empty geometry collection, polygon, point etc. SQL-MM defines the result of ST_IsEmpty(NULL) to be 0, while PostGIS returns NULL. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.7 This method supports Circular Strings and Curves Examples SELECT ST_IsEmpty('GEOMETRYCOLLECTION(EMPTY)'); st_isempty ------------ t (1 row) SELECT ST_IsEmpty(ST_GeomFromText('POLYGON EMPTY')); st_isempty ------------ t (1 row) SELECT ST_IsEmpty(ST_GeomFromText('POLYGON((1 2, 3 4, 5 6, 1 2))')); st_isempty ------------ f (1 row) SELECT ST_IsEmpty(ST_GeomFromText('POLYGON((1 2, 3 4, 5 6, 1 2))')) = false; ?column? ---------- t (1 row) SELECT ST_IsEmpty(ST_GeomFromText('CIRCULARSTRING EMPTY')); st_isempty ------------ t (1 row) ST_IsRing Returns TRUE if this LINESTRING is both closed and simple. boolean ST_IsRing geometry g Description Returns TRUE if this LINESTRING is both (ST_StartPoint(g) ~= ST_Endpoint(g)) and (does not self intersect). This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SFSQL 1.1 - 2.1.5.1 This method implements the SQL/MM specification: SQL-MM 3: 7.1.6 SQL-MM defines the result of ST_IsRing(NULL) to be 0, while PostGIS returns NULL. Examples SELECT ST_IsRing(the_geom), ST_IsClosed(the_geom), ST_IsSimple(the_geom) FROM (SELECT 'LINESTRING(0 0, 0 1, 1 1, 1 0, 0 0)'::geometry AS the_geom) AS foo; st_isring | st_isclosed | st_issimple -----------+-------------+------------- t | t | t (1 row) SELECT ST_IsRing(the_geom), ST_IsClosed(the_geom), ST_IsSimple(the_geom) FROM (SELECT 'LINESTRING(0 0, 0 1, 1 0, 1 1, 0 0)'::geometry AS the_geom) AS foo; st_isring | st_isclosed | st_issimple -----------+-------------+------------- f | t | f (1 row) See Also , , , ST_IsSimple Returns (TRUE) if this Geometry has no anomalous geometric points, such as self intersection or self tangency. boolean ST_IsSimple geometry geomA Description Returns true if this Geometry has no anomalous geometric points, such as self intersection or self tangency. For more information on the OGC's definition of geometry simplicity and validity, refer to "Ensuring OpenGIS compliancy of geometries" SQL-MM defines the result of ST_IsSimple(NULL) to be 0, while PostGIS returns NULL. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.8 This function supports 3d and will not drop the z-index. Examples SELECT ST_IsSimple(ST_GeomFromText('POLYGON((1 2, 3 4, 5 6, 1 2))')); st_issimple ------------- t (1 row) SELECT ST_IsSimple(ST_GeomFromText('LINESTRING(1 1,2 2,2 3.5,1 3,1 2,2 1)')); st_issimple ------------- f (1 row) See Also ST_IsValid Returns true if the ST_Geometry is well formed. boolean ST_IsValid geometry g Description Test if an ST_Geometry value is well formed. For geometries that are invalid, the PostgreSQL NOTICE will provide details of why it is not valid. For more information on the OGC's definition of geometry simplicity and validity, refer to "Ensuring OpenGIS compliancy of geometries" SQL-MM defines the result of ST_IsValid(NULL) to be 0, while PostGIS returns NULL. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 5.1.9 Examples SELECT ST_IsValid(ST_GeomFromText('LINESTRING(0 0, 1 1)')) As good_line, ST_IsValid(ST_GeomFromText('POLYGON((0 0, 1 1, 1 2, 1 1, 0 0))')) As bad_poly --results NOTICE: Self-intersection at or near point 0 0 good_line | bad_poly -----------+---------- t | f See Also , , ST_IsValidReason Returns text stating if a geometry is valid or not and if not valid, a reason why. text ST_IsValidReason geometry geomA Description Returns text stating if a geometry is valid or not an if not valid, a reason why. Useful in combination with ST_IsValid to generate a detailed report of invalid geometries and reasons. Availability: 1.4 - requires GEOS >= 3.1.0. Examples --First 3 Rejects from a successful quintuplet experiment SELECT gid, ST_IsValidReason(the_geom) as validity_info FROM (SELECT ST_MakePolygon(ST_ExteriorRing(e.buff), ST_Accum(f.line)) As the_geom, gid FROM (SELECT ST_Buffer(ST_MakePoint(x1*10,y1), z1) As buff, x1*10 + y1*100 + z1*1000 As gid FROM generate_series(-4,6) x1 CROSS JOIN generate_series(2,5) y1 CROSS JOIN generate_series(1,8) z1 WHERE x1 > y1*0.5 AND z1 < x1*y1) As e INNER JOIN (SELECT ST_Translate(ST_ExteriorRing(ST_Buffer(ST_MakePoint(x1*10,y1), z1)),y1*1, z1*2) As line FROM generate_series(-3,6) x1 CROSS JOIN generate_series(2,5) y1 CROSS JOIN generate_series(1,10) z1 WHERE x1 > y1*0.75 AND z1 < x1*y1) As f ON (ST_Area(e.buff) > 78 AND ST_Contains(e.buff, f.line)) GROUP BY gid, e.buff) As quintuplet_experiment WHERE ST_IsValid(the_geom) = false ORDER BY gid LIMIT 3; gid | validity_info ------+-------------------------- 5330 | Self-intersection [32 5] 5340 | Self-intersection [42 5] 5350 | Self-intersection [52 5] --simple example SELECT ST_IsValidReason('LINESTRING(220227 150406,2220227 150407,222020 150410)'); st_isvalidreason ------------------ Valid Geometry See Also , ST_M Return the M coordinate of the point, or NULL if not available. Input must be a point. float ST_M geometry a_point Description Return the M coordinate of the point, or NULL if not available. Input must be a point. This is not (yet) part of the OGC spec, but is listed here to complete the point coordinate extractor function list. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3 New standard: ? This function supports 3d and will not drop the z-index. Examples SELECT ST_M(ST_GeomFromEWKT('POINT(1 2 3 4)')); st_m ------ 4 (1 row) See Also , , , ST_NDims Returns coordinate dimension of the geometry as a small int. Values are: 2,3 or 4. integer ST_NDims geometry g1 Description Returns the coordinate dimension of the geometry. PostGIS supports 2 - (x,y) , 3 - (x,y,z) or 2D with measure - x,y,m, and 4 - 3D with measure space x,y,z,m This function supports 3d and will not drop the z-index. Examples SELECT ST_NDims(ST_GeomFromText('POINT(1 1)')) As d2point, ST_NDims(ST_GeomFromEWKT('POINT(1 1 2)')) As d3point, ST_NDims(ST_GeomFromEWKT('POINTM(1 1 0.5)')) As d2pointm; d2point | d3point | d2pointm ---------+---------+---------- 2 | 3 | 3 See Also , , ST_NPoints Return the number of points (vertexes) in a geometry. integer ST_NPoints geometry g1 Description Return the number of points in a geometry. Works for all geometries. Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_NPoints(ST_GeomFromText('LINESTRING(77.29 29.07,77.42 29.26,77.27 29.31,77.29 29.07)')); --result 4 --Polygon in 3D space SELECT ST_NPoints(ST_GeomFromEWKT('LINESTRING(77.29 29.07 1,77.42 29.26 0,77.27 29.31 -1,77.29 29.07 3)')) --result 4 See Also ST_NRings If the geometry is a polygon or multi-polygon returns the number of rings. integer ST_NRings geometry geomA Description If the geometry is a polygon or multi-polygon returns the number of rings. Unlike NumInteriorRings, it counts the outer rings as well. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_NRings(the_geom) As Nrings, ST_NumInteriorRings(the_geom) As ninterrings FROM (SELECT ST_GeomFromText('POLYGON((1 2, 3 4, 5 6, 1 2))') As the_geom) As foo; nrings | ninterrings --------+------------- 1 | 0 (1 row) See Also ST_NumGeometries If geometry is a GEOMETRYCOLLECTION (or MULTI*) return the number of geometries, otherwise return NULL. integer ST_NumGeometries geometry a_multi_or_geomcollection Description Returns the number of Geometries. If geometry is a GEOMETRYCOLLECTION (or MULTI*) return the number of geometries, otherwise return NULL. This method implements the SQL/MM specification: SQL-MM 3: 9.1.4 Examples --Although ST_NumGeometries will return null when passed a single, you can wrap in ST_Multi to force 1 or more for all geoms SELECT ST_NumGeometries(ST_Multi(ST_GeomFromText('LINESTRING(77.29 29.07,77.42 29.26,77.27 29.31,77.29 29.07)'))); --result 1 --Geometry Collection Example - multis count as one geom in a collection SELECT ST_NumGeometries(ST_GeomFromEWKT('GEOMETRYCOLLECTION(MULTIPOINT(-2 3 , -2 2), LINESTRING(5 5 ,10 10), POLYGON((-7 4.2,-7.1 5,-7.1 4.3,-7 4.2)))')); --result 3 See Also , ST_NumInteriorRings Return the number of interior rings of the first polygon in the geometry. This will work with both POLYGON and MULTIPOLYGON types but only looks at the first polygon. Return NULL if there is no polygon in the geometry. integer ST_NumInteriorRings geometry a_polygon Description Return the number of interior rings of the first polygon in the geometry. This will work with both POLYGON and MULTIPOLYGON types but only looks at the first polygon. Return NULL if there is no polygon in the geometry. This method implements the SQL/MM specification: SQL-MM 3: 8.2.5 Examples --If you have a regular polygon SELECT gid, field1, field2, ST_NumInteriorRings(the_geom) AS numholes FROM sometable; --If you have multipolygons --And you want to know the total number of interior rings in the MULTIPOLYGON SELECT gid, field1, field2, SUM(ST_NumInteriorRings(the_geom)) AS numholes FROM (SELECT gid, field1, field2, (ST_Dump(the_geom)).geom As the_geom FROM sometable) As foo GROUP BY gid, field1,field2; See Also ST_NumInteriorRing Return the number of interior rings of the first polygon in the geometry. Synonym to ST_NumInteriorRings. integer ST_NumInteriorRing geometry a_polygon Description Return the number of interior rings of the first polygon in the geometry. Synonym to ST_NumInteriorRings. The OpenGIS specs are ambiguous about the exact function naming, so we provide both spellings. This method implements the SQL/MM specification: SQL-MM 3: 8.2.5 See Also ST_NumPoints Return the number of points in an ST_LineString or ST_CircularString value. integer ST_NumPoints geometry g1 Description Return the number of points in an ST_LineString or ST_CircularString value. Prior to 1.4 only works with Linestrings as the specs state. From 1.4 forward this is an alias for ST_NPoints which returns number of vertexes for not just line strings. Consider using ST_NPoints instead which is multi-purpose and works with many geometry types. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 7.2.4 Examples SELECT ST_NumPoints(ST_GeomFromText('LINESTRING(77.29 29.07,77.42 29.26,77.27 29.31,77.29 29.07)')); --result 4 See Also ST_PointN Return the Nth point in the first linestring or circular linestring in the geometry. Return NULL if there is no linestring in the geometry. geometry ST_PointN geometry a_linestring integer n Description Return the Nth point in the first linestring or circular linestring in the geometry. Return NULL if there is no linestring in the geometry. Index is 1-based as for OGC specs since version 0.8.0. Previous versions implemented this as 0-based instead. If you want to get the nth point of each line string in a multilinestring, use in conjunction with ST_Dump This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 7.2.5, 7.3.5 This function supports 3d and will not drop the z-index. Examples -- Extract all POINTs from a LINESTRING SELECT ST_AsText( ST_PointN( column1, generate_series(1, ST_NPoints(column1)) )) FROM ( VALUES ('LINESTRING(0 0, 1 1, 2 2)'::geometry) ) AS foo; st_astext ------------ POINT(0 0) POINT(1 1) POINT(2 2) (3 rows) See Also ST_SRID Returns the spatial reference identifier for the ST_Geometry as defined in spatial_ref_sys table. integer ST_SRID geometry g1 Description Returns the spatial reference identifier for the ST_Geometry as defined in spatial_ref_sys table. spatial_ref_sys table is a table that catalogs all spatial reference systems known to PostGIS and is used for transformations from one spatial reference system to another. So verifying you have the right spatial reference system identifier is important if you plan to ever transform your geometries. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.5 This method supports Circular Strings and Curves Examples SELECT ST_SRID(ST_GeomFromText('POINT(-71.1043 42.315)',4326)); --result 4326 See Also ,, , ST_StartPoint Returns the first point of a LINESTRING geometry as a POINT. geometry ST_StartPoint geometry geomA Description Returns the first point of a LINESTRING geometry as a POINT or NULL if the input parameter is not a LINESTRING. This method implements the SQL/MM specification: SQL-MM 3: 7.1.3 This function supports 3d and will not drop the z-index. Examples SELECT ST_AsText(ST_StartPoint('LINESTRING(0 1, 0 2)'::geometry)); st_astext ------------ POINT(0 1) (1 row) SELECT ST_StartPoint('POINT(0 1)'::geometry) IS NULL AS is_null; is_null ---------- t (1 row) --3d line SELECT ST_AsEWKT(ST_StartPoint('LINESTRING(0 1 1, 0 2 2)'::geometry)); st_asewkt ------------ POINT(0 1 1) (1 row) See Also , ST_Summary Returns a text summary of the contents of the ST_Geometry. text ST_Summary geometry g Description Returns a text summary of the contents of the geometry. This function supports 3d and will not drop the z-index. Examples SELECT ST_Summary(ST_GeomFromText('LINESTRING(0 0, 1 1)')) As good_line, ST_Summary(ST_GeomFromText('POLYGON((0 0, 1 1, 1 2, 1 1, 0 0))')) As bad_poly --results good_line | bad_poly ----------------------+------------------------- | Line[B] with 2 points : Polygon[B] with 1 rings : ring 0 has 5 points : --3d polygon SELECT ST_Summary(ST_GeomFromEWKT('LINESTRING(0 0 1, 1 1 1)')) As good_line, ST_Summary(ST_GeomFromEWKT('POLYGON((0 0 1, 1 1 2, 1 2 3, 1 1 1, 0 0 1))')) As poly --results good_line | poly ----------------------+------------------------- | Line[ZB] with 2 points : Polygon[ZB] with 1 rings : ring 0 has 5 points : See Also , ST_X Return the X coordinate of the point, or NULL if not available. Input must be a point. float ST_X geometry a_point Description Return the X coordinate of the point, or NULL if not available. Input must be a point. If you want to get the max min x values of any geometry look at ST_XMin, ST_XMax functions. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3 standard: SQL-MM 3: 6.1.3 This function supports 3d and will not drop the z-index. Examples SELECT ST_X(ST_GeomFromEWKT('POINT(1 2 3 4)')); st_x ------ 1 (1 row) SELECT ST_Y(ST_Centroid(ST_GeomFromEWKT('LINESTRING(1 2 3 4, 1 1 1 1)'))); st_y ------ 1.5 (1 row) See Also , , , , , , ST_Y Return the Y coordinate of the point, or NULL if not available. Input must be a point. float ST_Y geometry a_point Description Return the Y coordinate of the point, or NULL if not available. Input must be a point. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3 standard: SQL-MM 3: 6.1.4 This function supports 3d and will not drop the z-index. Examples SELECT ST_Y(ST_GeomFromEWKT('POINT(1 2 3 4)')); st_y ------ 2 (1 row) SELECT ST_Y(ST_Centroid(ST_GeomFromEWKT('LINESTRING(1 2 3 4, 1 1 1 1)'))); st_y ------ 1.5 (1 row) See Also , , , , , , ST_Z Return the Z coordinate of the point, or NULL if not available. Input must be a point. float ST_Z geometry a_point Description Return the Z coordinate of the point, or NULL if not available. Input must be a point. This method implements the SQL/MM specification: SQL-MM 3 standard New Spec: ? This function supports 3d and will not drop the z-index. Examples SELECT ST_Z(ST_GeomFromEWKT('POINT(1 2 3 4)')); st_z ------ 3 (1 row) See Also , , , , , ST_Zmflag Returns ZM (dimension semantic) flag of the geometries as a small int. Values are: 0=2d, 1=3dm, 2=3dz, 3=4d. smallint ST_Zmflag geometry geomA Description Returns ZM (dimension semantic) flag of the geometries as a small int. Values are: 0=2d, 1=3dm, 2=3dz, 3=4d. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_Zmflag(ST_GeomFromEWKT('LINESTRING(1 2, 3 4)')); st_zmflag ----------- 0 SELECT ST_Zmflag(ST_GeomFromEWKT('LINESTRINGM(1 2 3, 3 4 3)')); st_zmflag ----------- 1 SELECT ST_Zmflag(ST_GeomFromEWKT('CIRCULARSTRING(1 2 3, 3 4 3, 5 6 3)')); st_zmflag ----------- 2 SELECT ST_Zmflag(ST_GeomFromEWKT('POINT(1 2 3 4)')); st_zmflag ----------- 3 See Also , , Geometry Editors ST_AddPoint Adds a point to a LineString before point <position> (0-based index). geometry ST_AddPoint geometry linestring geometry point geometry ST_AddPoint geometry linestring geometry point integer position Description Adds a point to a LineString before point <position> (0-based index). Third parameter can be omitted or set to -1 for appending. Availability: 1.1.0 This function supports 3d and will not drop the z-index. Examples --guarantee all linestrings in a table are closed --by adding the start point of each linestring to the end of the line string --only for those that are not closed UPDATE sometable SET the_geom = ST_AddPoint(the_geom, ST_StartPoint(the_geom)) FROM sometable WHERE ST_IsClosed(the_geom) = false; --Adding point to a 3-d line SELECT ST_AsEWKT(ST_AddPoint(ST_GeomFromEWKT('LINESTRING(0 0 1, 1 1 1)'), ST_MakePoint(1, 2, 3))); --result st_asewkt ---------- LINESTRING(0 0 1,1 1 1,1 2 3) See Also , ST_Affine Applies a 3d affine transformation to the geometry to do things like translate, rotate, scale in one step. geometry ST_Affine geometry geomA float a float b float c float d float e float f float g float h float i float xoff float yoff float zoff geometry ST_Affine geometry geomA float a float b float d float e> float xoff float yoff Description Applies a 3d affine transformation to the geometry to do things like translate, rotate, scale in one step. Version 1: The call ST_Affine(geom, a, b, c, d, e, f, g, h, i, xoff, yoff, zoff) represents the transformation matrix / a b c xoff \ | d e f yoff | | g h i zoff | \ 0 0 0 1 / and the vertices are transformed as follows: x' = a*x + b*y + c*z + xoff y' = d*x + e*y + f*z + yoff z' = g*x + h*y + i*z + zoff All of the translate / scale functions below are expressed via such an affine transformation. Version 2: Applies a 2d affine transformation to the geometry. The call ST_Affine(geom, a, b, d, e, xoff, yoff) represents the transformation matrix / a b 0 xoff \ / a b xoff \ | d e 0 yoff | rsp. | d e yoff | | 0 0 1 0 | \ 0 0 1 / \ 0 0 0 1 / and the vertices are transformed as follows: x' = a*x + b*y + xoff y' = d*x + e*y + yoff z' = z This method is a subcase of the 3D method above. Availability: 1.1.2. Name changed from Affine to ST_Affine in 1.2.2 Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples --Rotate a 3d line 180 degrees about the z axis. Note this is long-hand for doing ST_RotateZ(); SELECT ST_AsEWKT(ST_Affine(the_geom, cos(pi()), -sin(pi()), 0, sin(pi()), cos(pi()), 0, 0, 0, 1, 0, 0, 0)) As using_affine, ST_AsEWKT(ST_RotateZ(the_geom, pi())) As using_rotatez FROM (SELECT ST_GeomFromEWKT('LINESTRING(1 2 3, 1 4 3)') As the_geom) As foo; using_affine | using_rotatez -----------------------------+----------------------------- LINESTRING(-1 -2 3,-1 -4 3) | LINESTRING(-1 -2 3,-1 -4 3) (1 row) --Rotate a 3d line 180 degrees in both the x and z axis SELECT ST_AsEWKT(ST_Affine(the_geom, cos(pi()), -sin(pi()), 0, sin(pi()), cos(pi()), -sin(pi()), 0, sin(pi()), cos(pi()), 0, 0, 0)) FROM (SELECT ST_GeomFromEWKT('LINESTRING(1 2 3, 1 4 3)') As the_geom) As foo; st_asewkt ------------------------------- LINESTRING(-1 -2 -3,-1 -4 -3) (1 row) See Also , , , ST_Force_2D Forces the geometries into a "2-dimensional mode" so that all output representations will only have the X and Y coordinates. geometry ST_Force_2D geometry geomA Description 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). This method supports Circular Strings and curves Examples SELECT ST_AsEWKT(ST_Force_2D(ST_GeomFromEWKT('CIRCULARSTRING(1 1 2, 2 3 2, 4 5 2, 6 7 2, 5 6 2)'))); st_asewkt ------------------------------------- CIRCULARSTRING(1 1,2 3,4 5,6 7,5 6) SELECT ST_AsEWKT(ST_Force_2D('POLYGON((0 0 2,0 5 2,5 0 2,0 0 2),(1 1 2,3 1 2,1 3 2,1 1 2))')); st_asewkt ---------------------------------------------- POLYGON((0 0,0 5,5 0,0 0),(1 1,3 1,1 3,1 1)) See Also ST_Force_3D Forces the geometries into XYZ mode. This is an alias for ST_Force_3DZ. geometry ST_Force_3D geometry geomA Description Forces the geometries into XYZ mode. This is an alias for ST_Force_3DZ. If a geometry has no Z component, then a 0 Z coordinate is tacked on. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples --Nothing happens to an already 3D geometry SELECT ST_AsEWKT(ST_Force_3D(ST_GeomFromEWKT('CIRCULARSTRING(1 1 2, 2 3 2, 4 5 2, 6 7 2, 5 6 2)'))); st_asewkt ----------------------------------------------- CIRCULARSTRING(1 1 2,2 3 2,4 5 2,6 7 2,5 6 2) SELECT ST_AsEWKT(ST_Force_3D('POLYGON((0 0,0 5,5 0,0 0),(1 1,3 1,1 3,1 1))')); st_asewkt -------------------------------------------------------------- POLYGON((0 0 0,0 5 0,5 0 0,0 0 0),(1 1 0,3 1 0,1 3 0,1 1 0)) See Also , , , ST_Force_3DZ Forces the geometries into XYZ mode. This is a synonym for ST_Force_3D. geometry ST_Force_3DZ geometry geomA Description Forces the geometries into XYZ mode. This is a synonym for ST_Force_3DZ. If a geometry has no Z component, then a 0 Z coordinate is tacked on. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples --Nothing happens to an already 3D geometry SELECT ST_AsEWKT(ST_Force_3DZ(ST_GeomFromEWKT('CIRCULARSTRING(1 1 2, 2 3 2, 4 5 2, 6 7 2, 5 6 2)'))); st_asewkt ----------------------------------------------- CIRCULARSTRING(1 1 2,2 3 2,4 5 2,6 7 2,5 6 2) SELECT ST_AsEWKT(ST_Force_3DZ('POLYGON((0 0,0 5,5 0,0 0),(1 1,3 1,1 3,1 1))')); st_asewkt -------------------------------------------------------------- POLYGON((0 0 0,0 5 0,5 0 0,0 0 0),(1 1 0,3 1 0,1 3 0,1 1 0)) See Also , , , ST_Force_3DM Forces the geometries into XYM mode. geometry ST_Force_3DM geometry geomA Description Forces the geometries into XYM mode. If a geometry has no M component, then a 0 M coordinate is tacked on. If it has a Z component, then Z is removed This method supports Circular Strings and curves Examples --Nothing happens to an already 3D geometry SELECT ST_AsEWKT(ST_Force_3DM(ST_GeomFromEWKT('CIRCULARSTRING(1 1 2, 2 3 2, 4 5 2, 6 7 2, 5 6 2)'))); st_asewkt ------------------------------------------------ CIRCULARSTRINGM(1 1 0,2 3 0,4 5 0,6 7 0,5 6 0) SELECT ST_AsEWKT(ST_Force_3DM('POLYGON((0 0 1,0 5 1,5 0 1,0 0 1),(1 1 1,3 1 1,1 3 1,1 1 1))')); st_asewkt --------------------------------------------------------------- POLYGONM((0 0 0,0 5 0,5 0 0,0 0 0),(1 1 0,3 1 0,1 3 0,1 1 0)) See Also , , , , ST_Force_4D Forces the geometries into XYZM mode. geometry ST_Force_4D geometry geomA Description Forces the geometries into XYZM mode. 0 is tacked on for missing Z and M dimensions. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples --Nothing happens to an already 3D geometry SELECT ST_AsEWKT(ST_Force_4D(ST_GeomFromEWKT('CIRCULARSTRING(1 1 2, 2 3 2, 4 5 2, 6 7 2, 5 6 2)'))); st_asewkt --------------------------------------------------------- CIRCULARSTRING(1 1 2 0,2 3 2 0,4 5 2 0,6 7 2 0,5 6 2 0) SELECT ST_AsEWKT(ST_Force_4D('MULTILINESTRINGM((0 0 1,0 5 2,5 0 3,0 0 4),(1 1 1,3 1 1,1 3 1,1 1 1))')); st_asewkt -------------------------------------------------------------------------------------- MULTILINESTRING((0 0 0 1,0 5 0 2,5 0 0 3,0 0 0 4),(1 1 0 1,3 1 0 1,1 3 0 1,1 1 0 1)) See Also , , , ST_Force_Collection Converts the geometry into a GEOMETRYCOLLECTION. geometry ST_Force_Collection geometry geomA Description Converts the geometry into a GEOMETRYCOLLECTION. This is useful for simplifying the WKB representation. Availability: 1.2.2, prior to 1.3.4 this function will crash with Curves. This is fixed in 1.3.4+ This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsEWKT(ST_Force_Collection('POLYGON((0 0 1,0 5 1,5 0 1,0 0 1),(1 1 1,3 1 1,1 3 1,1 1 1))')); st_asewkt ---------------------------------------------------------------------------------- GEOMETRYCOLLECTION(POLYGON((0 0 1,0 5 1,5 0 1,0 0 1),(1 1 1,3 1 1,1 3 1,1 1 1))) SELECT ST_AsText(ST_Force_Collection('CIRCULARSTRING(220227 150406,2220227 150407,220227 150406)')); st_astext -------------------------------------------------------------------------------- GEOMETRYCOLLECTION(CIRCULARSTRING(220227 150406,2220227 150407,220227 150406)) (1 row) See Also , , , , ST_ForceRHR Forces the orientation of the vertices in a polygon to follow the Right-Hand-Rule. boolean ST_ForceRHR geometry g Description Forces the orientation of the vertices in a polygon to follow the Right-Hand-Rule. In GIS terminology, this means that the area that is bounded by the polygon is to the right of the boundary. In particular, the exterior ring is orientated in a clockwise direction and the interior rings in a counter-clockwise direction. This function supports 3d in that it will not drop the z-index. Examples SELECT ST_AsEWKT( ST_ForceRHR( 'POLYGON((0 0 2, 5 0 2, 0 5 2, 0 0 2),(1 1 2, 1 3 2, 3 1 2, 1 1 2))' ) ); st_asewkt -------------------------------------------------------------- POLYGON((0 0 2,0 5 2,5 0 2,0 0 2),(1 1 2,3 1 2,1 3 2,1 1 2)) (1 row) See Also , , ST_LineMerge Returns a (set of) LineString(s) formed by sewing together a MULTILINESTRING. geometry ST_LineMerge geometry amultilinestring Description Returns a (set of) LineString(s) formed by sewing together the constituent line work of a MULTILINESTRING. Only use with MULTILINESTRING/LINESTRINGs. If you feed a polygon or geometry collection into this function, it will return an empty GEOMETRYCOLLECTION Availability: 1.1.0 requires GEOS >= 2.1.0 Examples SELECT ST_AsText(ST_LineMerge( ST_GeomFromText('MULTILINESTRING((-29 -27,-30 -29.7,-36 -31,-45 -33),(-45 -33,-46 -32))') ) ); st_astext -------------------------------------------------------------------------------------------------- LINESTRING(-29 -27,-30 -29.7,-36 -31,-45 -33,-46 -32) (1 row) --If can't be merged - original MULTILINESTRING is returned SELECT ST_AsText(ST_LineMerge( ST_GeomFromText('MULTILINESTRING((-29 -27,-30 -29.7,-36 -31,-45 -33),(-45.2 -33.2,-46 -32))') ) ); st_astext ---------------- MULTILINESTRING((-45.2 -33.2,-46 -32),(-29 -27,-30 -29.7,-36 -31,-45 -33)) See Also , ST_Multi Returns the geometry as a MULTI* geometry. If the geometry is already a MULTI*, it is returned unchanged. geometry ST_Multi geometry g1 Description Returns the geometry as a MULTI* geometry. If the geometry is already a MULTI*, it is returned unchanged. Examples SELECT ST_AsText(ST_Multi(ST_GeomFromText('POLYGON((743238 2967416,743238 2967450, 743265 2967450,743265.625 2967416,743238 2967416))'))); st_astext -------------------------------------------------------------------------------------------------- MULTIPOLYGON(((743238 2967416,743238 2967450,743265 2967450,743265.625 2967416, 743238 2967416))) (1 row) See Also ST_RemovePoint Removes point from a linestring. Offset is 0-based. geometry ST_RemovePoint geometry linestring integer offset Description Removes point from a linestring. Useful for turning a closed ring into an open line string Availability: 1.1.0 This function supports 3d and will not drop the z-index. Examples --guarantee no LINESTRINGS are closed --by removing the end point. The below assumes the_geom is of type LINESTRING UPDATE sometable SET the_geom = ST_RemovePoint(the_geom, ST_NPoints(the_geom) - 1) FROM sometable WHERE ST_IsClosed(the_geom) = true; See Also , , ST_Reverse Returns the geometry with vertex order reversed. geometry ST_Reverse geometry g1 Description Can be used on any geometry and reverses the order of the vertexes. Examples SELECT ST_AsText(the_geom) as line, ST_AsText(ST_Reverse(the_geom)) As reverseline FROM (SELECT ST_MakeLine(ST_MakePoint(1,2), ST_MakePoint(1,10)) As the_geom) as foo; --result line | reverseline ---------------------+---------------------- LINESTRING(1 2,1 10) | LINESTRING(1 10,1 2) ST_Rotate This is a synonym for ST_RotateZ geometry ST_Rotate geometry geomA float rotZRadians Description This is a synonym for ST_RotateZ.. Rotates geometry rotZRadians about the Z-axis. Availability: 1.1.2. Name changed from Rotate to ST_Rotate in 1.2.2 This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples See Also , , , ST_RotateX Rotate a geometry rotRadians about the X axis. geometry ST_RotateX geometry geomA float rotRadians Description Rotate a geometry geomA - rotRadians about the X axis. ST_RotateX(geomA, rotRadians) is short-hand for ST_Affine(geomA, 1, 0, 0, 0, cos(rotRadians), -sin(rotRadians), 0, sin(rotRadians), cos(rotRadians), 0, 0, 0). Availability: 1.1.2. Name changed from RotateX to ST_RotateX in 1.2.2 This function supports 3d and will not drop the z-index. Examples --Rotate a line 90 degrees along x-axis SELECT ST_AsEWKT(ST_RotateX(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), pi()/2)); st_asewkt --------------------------- LINESTRING(1 -3 2,1 -1 1) See Also , , ST_RotateY Rotate a geometry rotRadians about the Y axis. geometry ST_RotateY geometry geomA float rotRadians Description Rotate a geometry geomA - rotRadians about the y axis. ST_RotateY(geomA, rotRadians) is short-hand for ST_Affine(geomA, cos(rotRadians), 0, sin(rotRadians), 0, 1, 0, -sin(rotRadians), 0, cos(rotRadians), 0, 0, 0). Availability: 1.1.2. Name changed from RotateY to ST_RotateY in 1.2.2 This function supports 3d and will not drop the z-index. Examples --Rotate a line 90 degrees along y-axis SELECT ST_AsEWKT(ST_RotateY(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), pi()/2)); st_asewkt --------------------------- LINESTRING(3 2 -1,1 1 -1) See Also , , , Rotate around Point, Create Ellipse functions ST_RotateZ Rotate a geometry rotRadians about the Z axis. geometry ST_RotateZ geometry geomA float rotRadians Description Rotate a geometry geomA - rotRadians about the Z axis. ST_RotateZ(geomA, rotRadians) is short-hand for SELECT ST_Affine(geomA, cos(rotRadians), -sin(rotRadians), 0, sin(rotRadians), cos(rotRadians), 0, 0, 0, 1, 0, 0, 0). Availability: 1.1.2. Name changed from RotateZ to ST_RotateZ in 1.2.2 Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples --Rotate a line 90 degrees along z-axis SELECT ST_AsEWKT(ST_RotateZ(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), pi()/2)); st_asewkt --------------------------- LINESTRING(-2 1 3,-1 1 1) --Rotate a curved circle around z-axis SELECT ST_AsEWKT(ST_RotateZ(the_geom, pi()/2)) FROM (SELECT ST_LineToCurve(ST_Buffer(ST_GeomFromText('POINT(234 567)'), 3)) As the_geom) As foo; st_asewkt ---------------------------------------------------------------------------------------------------------------------------- CURVEPOLYGON(CIRCULARSTRING(-567 237,-564.87867965644 236.12132034356,-564 234,-569.12132034356 231.87867965644,-567 237)) See Also , , , Rotate around Point, Create Ellipse functions ST_Scale Scales the geometry to a new size by multiplying the ordinates with the parameters. Ie: ST_Scale(geom, Xfactor, Yfactor, Zfactor). geometry ST_Scale geometry geomA float XFactor float YFactor float ZFactor geometry ST_Scale geometry geomA float XFactor float YFactor Description Scales the geometry to a new size by multiplying the ordinates with the parameters. Ie: ST_Scale(geom, Xfactor, Yfactor, Zfactor). ST_Scale(geomA, XFactor, YFactor, ZFactor) is short-hand for ST_Affine(geomA, XFactor, 0, 0, 0, YFactor, 0, 0, 0, ZFactor, 0, 0, 0). Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ Availability: 1.1.0. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples --Version 1: scale X, Y, Z SELECT ST_AsEWKT(ST_Scale(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), 0.5, 0.75, 0.8)); st_asewkt -------------------------------------- LINESTRING(0.5 1.5 2.4,0.5 0.75 0.8) --Version 2: Scale X Y SELECT ST_AsEWKT(ST_Scale(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), 0.5, 0.75)); st_asewkt ---------------------------------- LINESTRING(0.5 1.5 3,0.5 0.75 1) See Also , ST_Segmentize Return a modified geometry having no segment longer than the given distance. Distance computation is performed in 2d only. geometry ST_Segmentize geometry geomA float max_length Description Returns a modified geometry having no segment longer than the given distance. Distance computation is performed in 2d only. Availability: 1.2.2 This will only increase segments. It will not lengthen segments shorter than max length Examples SELECT ST_AsText(ST_Segmentize( ST_GeomFromText('MULTILINESTRING((-29 -27,-30 -29.7,-36 -31,-45 -33),(-45 -33,-46 -32))') ,5) ); st_astext -------------------------------------------------------------------------------------------------- MULTILINESTRING((-29 -27,-30 -29.7,-34.886615700134 -30.758766735029,-36 -31, -40.8809353009198 -32.0846522890933,-45 -33), (-45 -33,-46 -32)) (1 row) SELECT ST_AsText(ST_Segmentize(ST_GeomFromText('POLYGON((-29 28, -30 40, -29 28))'),10)); st_astext ----------------------- POLYGON((-29 28,-29.8304547985374 37.9654575824488,-30 40,-29.1695452014626 30.0345424175512,-29 28)) (1 row) See Also ST_SetPoint Replace point N of linestring with given point. Index is 0-based. geometry ST_SetPoint geometry linestring integer zerobasedposition geometry point Description Replace point N of linestring with given point. Index is 0-based. This is especially useful in triggers when trying to maintain relationship of joints when one vertex moves. Availability: 1.1.0 This function supports 3d and will not drop the z-index. Examples --Change first point in line string from -1 3 to -1 1 SELECT ST_AsText(ST_SetPoint('LINESTRING(-1 2,-1 3)', 0, 'POINT(-1 1)')); st_astext ----------------------- LINESTRING(-1 1,-1 3) ---Change last point in a line string (lets play with 3d linestring this time) SELECT ST_AsEWKT(ST_SetPoint(foo.the_geom, ST_NumPoints(foo.the_geom) - 1, ST_GeomFromEWKT('POINT(-1 1 3)'))) FROM (SELECT ST_GeomFromEWKT('LINESTRING(-1 2 3,-1 3 4, 5 6 7)') As the_geom) As foo; st_asewkt ----------------------- LINESTRING(-1 2 3,-1 3 4,-1 1 3) See Also ,, , ST_SetSRID Sets the SRID on a geometry to a particular integer value. geometry ST_SetSRID geometry geom integer srid Description Sets the SRID on a geometry to a particular integer value. Useful in constructing bounding boxes for queries. This function does not transform the geometry is any way - it simply sets the projection the geometry that it's currently in. Use if you want to transform the geometry into a new projection. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method supports Circular Strings and Curves See Also , , , ST_SnapToGrid Snap all points of the input geometry to the grid defined by its origin and cell size. Remove consecutive points falling on the same cell, eventually returning NULL if output points are not enough to define a geometry of the given type. Collapsed geometries in a collection are stripped from it. Useful for reducing precision. geometry ST_SnapToGrid geometry geomA float originX float originY float sizeX float sizeY geometry ST_SnapToGrid geometry geomA float sizeX float sizeY geometry ST_SnapToGrid geometry geomA float size geometry ST_SnapToGrid geometry geomA geometry pointOrigin float sizeX float sizeY float sizeZ float sizeM Description Variant 1,2,3: Snap all points of the input geometry to the grid defined by its origin and cell size. Remove consecutive points falling on the same cell, eventually returning NULL if output points are not enough to define a geometry of the given type. Collapsed geometries in a collection are stripped from it. Variant 4: Introduced 1.1.0 - Snap all points of the input geometry to the grid defined by its origin (the second argument, must be a point) and cell sizes. Specify 0 as size for any dimension you don't want to snap to a grid. The returned geometry might loose its simplicity (see ). Before release 1.1.0 this function always returned a 2d geometry. Starting at 1.1.0 the returned geometry will have same dimensionality as the input one with higher dimension values untouched. Use the version taking a second geometry argument to define all grid dimensions. Availability: 1.0.0RC1 Availability: 1.1.0 - Z and M support This function supports 3d and will not drop the z-index. Examples --Snap your geometries to a precision grid of 10^-3 UPDATE mytable SET the_geom = ST_SnapToGrid(the_geom, 0.001); SELECT ST_AsText(ST_SnapToGrid( ST_GeomFromText('LINESTRING(1.1115678 2.123, 4.111111 3.2374897, 4.11112 3.23748667)'), 0.001) ); st_astext ------------------------------------- LINESTRING(1.112 2.123,4.111 3.237) --Snap a 4d geometry SELECT ST_AsEWKT(ST_SnapToGrid( ST_GeomFromEWKT('LINESTRING(-1.1115678 2.123 2.3456 1.11111, 4.111111 3.2374897 3.1234 1.1111, -1.11111112 2.123 2.3456 1.1111112)'), ST_GeomFromEWKT('POINT(1.12 2.22 3.2 4.4444)'), 0.1, 0.1, 0.1, 0.01) ); st_asewkt ------------------------------------------------------------------------------ LINESTRING(-1.08 2.12 2.3 1.1144,4.12 3.22 3.1 1.1144,-1.08 2.12 2.3 1.1144) --With a 4d geometry - the ST_SnapToGrid(geom,size) only touches x and y coords but keeps m and z the same SELECT ST_AsEWKT(ST_SnapToGrid(ST_GeomFromEWKT('LINESTRING(-1.1115678 2.123 3 2.3456, 4.111111 3.2374897 3.1234 1.1111)'), 0.01) ); st_asewkt --------------------------------------------------------- LINESTRING(-1.11 2.12 3 2.3456,4.11 3.24 3.1234 1.1111) See Also , , , , ST_Transform Returns a new geometry with its coordinates transformed to the SRID referenced by the integer parameter. geometry ST_Transform geometry g1 integer srid Description Returns a new geometry with its coordinates transformed to spatial reference system referenced by the SRID integer parameter. The destination SRID must exist in the SPATIAL_REF_SYS table. ST_Transform is often confused with ST_SetSRID(). ST_Transform actually changes the coordinates of a geometry from one spatial reference system to another, while ST_SetSRID() simply changes the SRID identifier of the geometry Requires PostGIS be compiled with Proj support. Use to confirm you have proj support compiled in. If using more than one transformation, it is useful to have a functional index on the commonly used transformations to take advantage of index usage. Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 5.1.6 This method supports Circular Strings and Curves Examples Change Mass state plane US feet geometry to WGS 84 long lat SELECT ST_AsText(ST_Transform(ST_GeomFromText('POLYGON((743238 2967416,743238 2967450, 743265 2967450,743265.625 2967416,743238 2967416))',2249),4326)) As wgs_geom; wgs_geom --------------------------- POLYGON((-71.1776848522251 42.3902896512902,-71.1776843766326 42.3903829478009, -71.1775844305465 42.3903826677917,-71.1775825927231 42.3902893647987,-71.177684 8522251 42.3902896512902)); (1 row) --3D Circular String example SELECT ST_AsEWKT(ST_Transform(ST_GeomFromEWKT('SRID=2249;CIRCULARSTRING(743238 2967416 1,743238 2967450 2,743265 2967450 3,743265.625 2967416 3,743238 2967416 4)'),4326)); st_asewkt -------------------------------------------------------------------------------------- SRID=4326;CIRCULARSTRING(-71.1776848522251 42.3902896512902 1,-71.1776843766326 42.3903829478009 2, -71.1775844305465 42.3903826677917 3, -71.1775825927231 42.3902893647987 3,-71.1776848522251 42.3902896512902 4) Example of creating a partial functional index. For tables where you are not sure all the geometries will be filled in, its best to use a partial index that leaves out null geometries which will both conserve space and make your index smaller and more efficient. CREATE INDEX idx_the_geom_26986_parcels ON parcels USING gist (ST_Transform(the_geom, 26986)) WHERE the_geom IS NOT NULL; Configuring transformation behaviour Sometimes coordinate transformation involving a grid-shift can fail, for example if PROJ.4 has not been built with grid-shift files or the coordinate does not lie within the range for which the grid shift is defined. By default, PostGIS will throw an error if a grid shift file is not present, but this behaviour can be configured on a per-SRID basis by altering the proj4text value within the spatial_ref_sys table. For example, the proj4text parameter +datum=NAD87 is a shorthand form for the following +nadgrids parameter: +nadgrids=@conus,@alaska,@ntv2_0.gsb,@ntv1_can.dat The @ prefix means no error is reported if the files are not present, but if the end of the list is reached with no file having been appropriate (ie. found and overlapping) then an error is issued. If, conversely, you wanted to ensure that at least the standard files were present, but that if all files were scanned without a hit a null transformation is applied you could use: +nadgrids=@conus,@alaska,@ntv2_0.gsb,@ntv1_can.dat,null The null grid shift file is a valid grid shift file covering the whole world and applying no shift. So for a complete example, if you wanted to alter PostGIS so that transformations to SRID 4267 that didn't lie within the correct range did not throw an ERROR, you would use the following: UPDATE spatial_ref_sys SET proj4text = '+proj=longlat +ellps=clrk66 +nadgrids=@conus,@alaska,@ntv2_0.gsb,@ntv1_can.dat,null +no_defs' WHERE srid = 4267; See Also , , , ST_Translate Translates the geometry to a new location using the numeric parameters as offsets. Ie: ST_Translate(geom, X, Y) or ST_Translate(geom, X, Y,Z). geometry ST_Translate geometry g1 float deltax float deltay geometry ST_Translate geometry g1 float deltax float deltay float deltaz Description Returns a new geometry whose coordinates are translated delta x,delta y,delta z units. Units are based on the units defined in spatial reference (SRID) for this geometry. Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ Availability: 1.2.2 This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples Move a point 1 degree longitude SELECT ST_AsText(ST_Translate(ST_GeomFromText('POINT(-71.01 42.37)',4326),1,0)) As wgs_transgeomtxt; wgs_transgeomtxt --------------------- POINT(-70.01 42.37) Move a linestring 1 degree longitude and 1/2 degree latitude SELECT ST_AsText(ST_Translate(ST_GeomFromText('LINESTRING(-71.01 42.37,-71.11 42.38)',4326),1,0.5)) As wgs_transgeomtxt; wgs_transgeomtxt --------------------------------------- LINESTRING(-70.01 42.87,-70.11 42.88) Move a 3d point SELECT ST_AsEWKT(ST_Translate(CAST('POINT(0 0 0)' As geometry), 5, 12,3)); st_asewkt --------- POINT(5 12 3) Move a curve and a point SELECT ST_AsText(ST_Translate(ST_Collect('CURVEPOLYGON(CIRCULARSTRING(4 3,3.12 0.878,1 0,-1.121 5.1213,6 7, 8 9,4 3))','POINT(1 3)'),1,2)); st_astext ------------------------------------------------------------------------------------------------------------ GEOMETRYCOLLECTION(CURVEPOLYGON(CIRCULARSTRING(5 5,4.12 2.878,2 2,-0.121 7.1213,7 9,9 11,5 5)),POINT(2 5)) See Also , , ST_TransScale Translates the geometry using the deltaX and deltaY args, then scales it using the XFactor, YFactor args, working in 2D only. geometry ST_TransScale geometry geomA float deltaX float deltaY float XFactor float YFactor Description Translates the geometry using the deltaX and deltaY args, then scales it using the XFactor, YFactor args, working in 2D only. ST_TransScale(geomA, deltaX, deltaY, XFactor, YFactor) is short-hand for ST_Affine(geomA, XFactor, 0, 0, 0, YFactor, 0, 0, 0, 1, deltaX*XFactor, deltaY*YFactor, 0). Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ Availability: 1.1.0. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsEWKT(ST_TransScale(ST_GeomFromEWKT('LINESTRING(1 2 3, 1 1 1)'), 0.5, 1, 1, 2)); st_asewkt ----------------------------- LINESTRING(1.5 6 3,1.5 4 1) --Buffer a point to get an approximation of a circle, convert to curve and then translate 1,2 and scale it 3,4 SELECT ST_AsText(ST_Transscale(ST_LineToCurve(ST_Buffer('POINT(234 567)', 3)),1,2,3,4)); st_astext ------------------------------------------------------------------------------------------------------------------------------ CURVEPOLYGON(CIRCULARSTRING(714 2276,711.363961030679 2267.51471862576,705 2264,698.636038969321 2284.48528137424,714 2276)) See Also , Geometry Outputs ST_AsBinary Return the Well-Known Binary (WKB) representation of the geometry without SRID meta data. bytea ST_AsBinary geometry g1 bytea ST_AsBinary geometry g1 text NDR_or_XDR Description Returns the Well-Known Binary representation of the geometry. There are 2 variants of the function. The first variant takes no endian encoding paramater and defaults to little endian. The second variant takes a second argument denoting the encoding - using little-endian ('NDR') or big-endian ('XDR') encoding. This is useful in binary cursors to pull data out of the database without converting it to a string representation. The WKB spec does not include the SRID. To get the OGC WKB with SRID format use ST_AsEWKB ST_AsBinary is the reverse of . Use to convert to a postgis geometry from ST_AsBinary representation. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.37 Examples SELECT ST_AsBinary(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326)); st_asbinary -------------------------------- \001\003\000\000\000\001\000\000\000\005 \000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000 \000\000\000\360?\000\000\000\000\000\000 \360?\000\000\000\000\000\000\360?\000\000 \000\000\000\000\360?\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000 (1 row) SELECT ST_AsBinary(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326), 'XDR'); st_asbinary -------------------------------- \000\000\000\000\003\000\000\000\001\000\000\000\005\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000 \000?\360\000\000\000\000\000\000?\360\000\000\000\000\000\000?\360\000\000 \000\000\000\000?\360\000\000\000\000\000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000 (1 row) See Also , , , ST_AsEWKB Return the Well-Known Binary (WKB) representation of the geometry with SRID meta data. bytea ST_AsEWKB geometry g1 bytea ST_AsEWKB geometry g1 text NDR_or_XDR Description Returns the Well-Known Binary representation of the geometry with SRID metadata. There are 2 variants of the function. The first variant takes no endian encoding paramater and defaults to little endian. The second variant takes a second argument denoting the encoding - using little-endian ('NDR') or big-endian ('XDR') encoding. This is useful in binary cursors to pull data out of the database without converting it to a string representation. The WKB spec does not include the SRID. To get the OGC WKB format use ST_AsBinary ST_AsEWKB is the reverse of ST_GeomFromEWKB. Use ST_GeomFromEWKB to convert to a postgis geometry from ST_AsEWKB representation. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsEWKB(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326)); st_asewkb -------------------------------- \001\003\000\000 \346\020\000\000\001\000 \000\000\005\000\000\000\000 \000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000 \000\000\360?\000\000\000\000\000\000\360? \000\000\000\000\000\000\360?\000\000\000\000\000 \000\360?\000\000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000\000\000\000 (1 row) SELECT ST_AsEWKB(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326), 'XDR'); st_asewkb -------------------------------- \000 \000\000\003\000\000\020\346\000\000\000\001\000\000\000\005\000\000\000\000\ 000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000? \360\000\000\000\000\000\000?\360\000\000\000\000\000\000?\360\000\000\000\000 \000\000?\360\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000\000 \000\000\000\000\000\000\000\000\000\000\000\000\000 See Also , , , , ST_AsEWKT Return the Well-Known Text (WKT) representation of the geometry with SRID meta data. text ST_AsEWKT geometry g1 Description Returns the Well-Known Text representation of the geometry prefixed with the SRID. The WKT spec does not include the SRID. To get the OGC WKT format use ST_AsText WKT format does not maintain precision so to prevent floating truncation, use ST_AsBinary or ST_AsEWKB format for transport. ST_AsEWKT is the reverse of . Use to convert to a postgis geometry from ST_AsEWKT representation. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsEWKT('0103000020E61000000100000005000000000000 000000000000000000000000000000000000000000000000000000 F03F000000000000F03F000000000000F03F000000000000F03 F000000000000000000000000000000000000000000000000'::geometry); st_asewkt -------------------------------- SRID=4326;POLYGON((0 0,0 1,1 1,1 0,0 0)) (1 row) SELECT ST_AsEWKT('0108000080030000000000000060E30A4100000000785C0241000000000000F03F0000000018 E20A4100000000485F024100000000000000400000000018 E20A4100000000305C02410000000000000840') --st_asewkt--- CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3) See Also , ST_AsGeoJSON Return the geometry as a GeoJSON element. text ST_AsGeoJSON geometry g1 text ST_AsGeoJSON geometry g1 integer max_decimal_digits text ST_AsGeoJSON geometry g1 integer max_decimal_digits integer options text ST_AsGeoJSON integer version geometry g1 text ST_AsGeoJSON integer version geometry g1 integer max_decimal_digits text ST_AsGeoJSON integer version geometry g1 integer max_decimal_digits integer options Description Return the geometry as a Geometry Javascript Object Notation (GeoJSON) element. (Cf GeoJSON specifications 1.0). 2D and 3D Geometries are both supported. GeoJSON only support SFS 1.1 geometry type (no curve support for example). The version parameter, if specified, must be 1. The third argument may be used to reduce the maximum number of decimal places used in output (defaults to 15). The last 'options' argument could be used to add Bbox or Crs in GeoJSON output: 0: means no option (default value) 1: GeoJSON Bbox 2: GeoJSON Short CRS (e.g EPSG:4326) 4: GeoJSON Long CRS (e.g urn:ogc:def:crs:EPSG:4326) Version 1: ST_AsGeoJSON(geom) / precision=15 version=1 options=0 Version 2: ST_AsGeoJSON(geom, precision) / version=1 options=0 Version 3: ST_AsGeoJSON(geom, precision, options) / version=1 Version 4: ST_AsGeoJSON(version, geom) / precision=15 options=0 Version 5: ST_AsGeoJSON(version, geom, precision) /options=0 Version 6: ST_AsGeoJSON(version, geom, precision,options) Availability: 1.3.4 This function supports 3d and will not drop the z-index. Examples GeoJSON format is generally more efficient than other formats for use in ajax mapping. One popular javascript client that supports this is Open Layers. Example of its use is OpenLayers GeoJSON Example SELECT ST_AsGeoJSON(the_geom) from fe_edges limit 1; st_asgeojson ----------------------------------------------------------------------------------------------------------- {"type":"MultiLineString","coordinates":[[[-89.734634999999997,31.492072000000000], [-89.734955999999997,31.492237999999997]]]} (1 row) --3d point SELECT ST_AsGeoJSON('LINESTRING(1 2 3, 4 5 6)'); st_asgeojson ----------------------------------------------------------------------------------------- {"type":"LineString","coordinates":[[1,2,3],[4,5,6]]} ST_AsGML Return the geometry as a GML version 2 or 3 element. text ST_AsGML geometry g1 text ST_AsGML geometry g1 integer precision text ST_AsGML integer version geometry g1 text ST_AsGML integer version geometry g1 integer precision text ST_AsGML integer version geometry g1 integer precision integer options Description Return the geometry as a Geography Markup Language (GML) element. The version parameter, if specified, may be either 2 or 3. If no version parameter is specified then the default is assumed to be 2. The third argument may be used to reduce the maximum number of decimal places used in output (defaults to 15). GML 2 refer to 2.1.2 version, GML 3 to 3.1.1 version The last 'options' argument could be used to define Crs output type in GML output: 1: GML Short CRS (e.g EPSG:4326), default value 2: GML Long CRS (e.g urn:ogc:def:crs:EPSG:4326) Availability: 1.3.2 This function supports 3d and will not drop the z-index. Examples 0,0 0,1 1,1 1,0 0,0]]> ST_AsHEXEWKB Returns a Geometry in HEXEWKB format (as text) using either little-endian (NDR) or big-endian (XDR) encoding. text ST_AsHEXEWKB geometry g1 text NDRorXDR text ST_AsHEXEWKB geometry g1 Description Returns a Geometry in HEXEWKB format (as text) using either little-endian (NDR) or big-endian (XDR) encoding. If no encoding is specified, then NDR is used. Availability: 1.2.2 This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsHEXEWKB(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326)); which gives same answer as SELECT ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326)::text; st_ashexewkb -------- 0103000020E6100000010000000500 00000000000000000000000000000000 00000000000000000000000000000000F03F 000000000000F03F000000000000F03F000000000000F03 F000000000000000000000000000000000000000000000000 ST_AsKML Return the geometry as a KML element. Several variants. Default version=2, default precision=15 text ST_AsKML geometry g1 text ST_AsKML geometry g1 integer precision text ST_AsKML integer version geometry geom1 text ST_AsKML integer version geometry geom1 integer precision Description Return the geometry as a Keyhole Markup Language (KML) element. There are several variants of this function. maximum number of decimal places used in output (defaults to 15) and version default to 2. Version 1: ST_AsKML(geom) / version=2 precision=15 Version 2: ST_AsKML(geom, max_sig_digits) / version=2 Version 3: ST_AsKML(version, geom) / precision=15 Version 4: ST_AsKML(version, geom, precision) Requires PostGIS be compiled with Proj support. Use to confirm you have proj support compiled in. Availability: 1.2.2 - later variants that include version param came in 1.3.2 AsKML output will not work with geometries that do not have an SRID This function supports 3d and will not drop the z-index. Examples 0,0 0,1 1,1 1,0 0,0 --3d linestring SELECT ST_AsKML('SRID=4326;LINESTRING(1 2 3, 4 5 6)'); 1,2,3 4,5,6 ]]> See Also , ST_AsSVG Returns a Geometry in SVG path data. text ST_AsSVG geometry g1 text ST_AsSVG geometry g1 integer rel text ST_AsSVG geometry g1 integer rel integer maxdecimaldigits Description Return the geometry as Scalar Vector Graphics (SVG) path data. Use 1 as second argument to have the path data implemented in terms of relative moves, the default (or 0) uses absolute moves. Third argument may be used to reduce the maximum number of decimal digits used in output (defaults to 15). Point geometries will be rendered as cx/cy when 'rel' arg is 0, x/y when 'rel' is 1. Multipoint geometries are delimited by commas (","), GeometryCollection geometries are delimited by semicolons (";"). Availability: 1.2.2 Examples SELECT ST_AsSVG(ST_GeomFromText('POLYGON((0 0,0 1,1 1,1 0,0 0))',4326)); st_assvg -------- M 0 0 0 -1 1 -1 1 0 Z ST_GeoHash Return a GeoHash representation (geohash.org) of the geometry. text ST_GeoHash geometry g1 text ST_GeoHash geometry g1 integer precision Description Return a GeoHash representation (geohash.org) of the geometry. A GeoHash encodes a point into a text form that is sortable and searchable based on prefixing. A shorter GeoHash is a less precise representation of a point. It can also be thought of as a box, that contains the actual point. The one-parameter variant of ST_GeoHash returns a GeoHash based on the input geometry type. Points return a GeoHash with 20 characters of precision (about enough to hold the full double precision of the input). Other types return a GeoHash with a variable amount of precision, based on the size of the feature. Larger features are represented with less precision, smaller features with more precision. The idea is that the box implied by the GeoHash will always contain the input feature. The two-parameter variant of ST_GeoHash returns a GeoHash with a requested precision. For non-points, the starting point of the calculation is the center of the bounding box of the geometry. Availability: 1.4.0 ST_GeoHash will not work with geometries that are not in geographic (lon/lat) coordinates. This method supports Circular Strings and Curves Examples See Also ST_AsText Return the Well-Known Text (WKT) representation of the geometry without SRID metadata. text ST_AsText geometry g1 Description Returns the Well-Known Text representation of the geometry. The WKT spec does not include the SRID. To get the SRID as part of the data, use the non-standard PostGIS WKT format does not maintain precision so to prevent floating truncation, use ST_AsBinary or ST_AsEWKB format for transport. ST_AsText is the reverse of . Use to convert to a postgis geometry from ST_AsText representation. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.1 This method implements the SQL/MM specification: SQL-MM 3: 5.1.25 This method supports Circular Strings and Curves Examples SELECT ST_AsText('01030000000100000005000000000000000000 000000000000000000000000000000000000000000000000 F03F000000000000F03F000000000000F03F000000000000F03 F000000000000000000000000000000000000000000000000'); st_astext -------------------------------- POLYGON((0 0,0 1,1 1,1 0,0 0)) (1 row) See Also , , , Operators && Returns TRUE if A's bounding box overlaps B's. boolean && geometry A geometry B Description The && operator returns TRUE if the bounding box of geometry A overlaps the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 && tbl2.column2 AS overlaps FROM ( VALUES (1, 'LINESTRING(0 0, 3 3)'::geometry), (2, 'LINESTRING(0 1, 0 5)'::geometry)) AS tbl1, ( VALUES (3, 'LINESTRING(1 2, 4 6)'::geometry)) AS tbl2; column1 | column1 | overlaps ---------+---------+---------- 1 | 3 | t 2 | 3 | f (2 rows) See Also , , , , , &< Returns TRUE if A's bounding box overlaps or is to the left of B's. boolean &< geometry A geometry B Description The &< operator returns TRUE if the bounding box of geometry A overlaps or is to the left of the bounding box of geometry B, or more accurately, overlaps or is NOT to the right of the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 &< tbl2.column2 AS overleft FROM ( VALUES (1, 'LINESTRING(1 2, 4 6)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING(0 0, 3 3)'::geometry), (3, 'LINESTRING(0 1, 0 5)'::geometry), (4, 'LINESTRING(6 0, 6 1)'::geometry)) AS tbl2; column1 | column1 | overleft ---------+---------+---------- 1 | 2 | f 1 | 3 | f 1 | 4 | t (3 rows) See Also , , , &<| Returns TRUE if A's bounding box overlaps or is below B's. boolean &<| geometry A geometry B Description The &<| operator returns TRUE if the bounding box of geometry A overlaps or is below of the bounding box of geometry B, or more accurately, overlaps or is NOT above the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 &<| tbl2.column2 AS overbelow FROM ( VALUES (1, 'LINESTRING(6 0, 6 4)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING(0 0, 3 3)'::geometry), (3, 'LINESTRING(0 1, 0 5)'::geometry), (4, 'LINESTRING(1 2, 4 6)'::geometry)) AS tbl2; column1 | column1 | overbelow ---------+---------+----------- 1 | 2 | f 1 | 3 | t 1 | 4 | t (3 rows) See Also , , , &> Returns TRUE if A' bounding box overlaps or is to the right of B's. boolean &> geometry A geometry B Description The &> operator returns TRUE if the bounding box of geometry A overlaps or is to the right of the bounding box of geometry B, or more accurately, overlaps or is NOT to the left of the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 &> tbl2.column2 AS overright FROM ( VALUES (1, 'LINESTRING(1 2, 4 6)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING(0 0, 3 3)'::geometry), (3, 'LINESTRING(0 1, 0 5)'::geometry), (4, 'LINESTRING(6 0, 6 1)'::geometry)) AS tbl2; column1 | column1 | overright ---------+---------+----------- 1 | 2 | t 1 | 3 | t 1 | 4 | f (3 rows) See Also , , , << Returns TRUE if A's bounding box is strictly to the left of B's. boolean << geometry A geometry B Description The << operator returns TRUE if the bounding box of geometry A is strictly to the left of the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 << tbl2.column2 AS left FROM ( VALUES (1, 'LINESTRING (1 2, 1 5)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (0 0, 4 3)'::geometry), (3, 'LINESTRING (6 0, 6 5)'::geometry), (4, 'LINESTRING (2 2, 5 6)'::geometry)) AS tbl2; column1 | column1 | left ---------+---------+------ 1 | 2 | f 1 | 3 | t 1 | 4 | t (3 rows) See Also , , <<| Returns TRUE if A's bounding box is strictly below B's. boolean <<| geometry A geometry B Description The <<| operator returns TRUE if the bounding box of geometry A is strictly below the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 <<| tbl2.column2 AS below FROM ( VALUES (1, 'LINESTRING (0 0, 4 3)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (1 4, 1 7)'::geometry), (3, 'LINESTRING (6 1, 6 5)'::geometry), (4, 'LINESTRING (2 3, 5 6)'::geometry)) AS tbl2; column1 | column1 | below ---------+---------+------- 1 | 2 | t 1 | 3 | f 1 | 4 | f (3 rows) See Also , , = Returns TRUE if A's bounding box is the same as B's. boolean = geometry A geometry B Description The = operator returns TRUE if the bounding box of geometry A is the same as the bounding box of geometry B. PostgreSQL uses the =, <, and > operators defined for geometries to perform internal orderings and comparison of geometries (ie. in a GROUP BY or ORDER BY clause). This is cause for a lot of confusion. When you compare geometryA = geometryB it will return true even when the geometries are clearly different IF their bounding boxes are the same. To check for true equality use or This operand will NOT make use of any indexes that may be available on the geometries. Examples SELECT 'LINESTRING(0 0, 0 1, 1 0)'::geometry = 'LINESTRING(1 1, 0 0)'::geometry; ?column? ---------- t (1 row) SELECT ST_AsText(column1) FROM ( VALUES ('LINESTRING(0 0, 1 1)'::geometry), ('LINESTRING(1 1, 0 0)'::geometry)) AS foo; st_astext --------------------- LINESTRING(0 0,1 1) LINESTRING(1 1,0 0) (2 rows) -- Note: the GROUP BY uses the "=" to compare for geometry equivalency. SELECT ST_AsText(column1) FROM ( VALUES ('LINESTRING(0 0, 1 1)'::geometry), ('LINESTRING(1 1, 0 0)'::geometry)) AS foo GROUP BY column1; st_astext --------------------- LINESTRING(0 0,1 1) (1 row) See Also , , >> Returns TRUE if A's bounding box is strictly to the right of B's. boolean >> geometry A geometry B Description The >> operator returns TRUE if the bounding box of geometry A is strictly to the right of the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 >> tbl2.column2 AS right FROM ( VALUES (1, 'LINESTRING (2 3, 5 6)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (1 4, 1 7)'::geometry), (3, 'LINESTRING (6 1, 6 5)'::geometry), (4, 'LINESTRING (0 0, 4 3)'::geometry)) AS tbl2; column1 | column1 | right ---------+---------+------- 1 | 2 | t 1 | 3 | f 1 | 4 | f (3 rows) See Also , , @ Returns TRUE if A's bounding box is contained by B's. boolean ~= geometry A geometry B Description The @ operator returns TRUE if the bounding box of geometry A is completely contained by the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 @ tbl2.column2 AS contained FROM ( VALUES (1, 'LINESTRING (1 1, 3 3)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (0 0, 4 4)'::geometry), (3, 'LINESTRING (2 2, 4 4)'::geometry), (4, 'LINESTRING (1 1, 3 3)'::geometry)) AS tbl2; column1 | column1 | contained ---------+---------+----------- 1 | 2 | t 1 | 3 | f 1 | 4 | t (3 rows) See Also , |&> Returns TRUE if A's bounding box overlaps or is above B's. boolean |&> geometry A geometry B Description The |&> operator returns TRUE if the bounding box of geometry A overlaps or is above the bounding box of geometry B, or more accurately, overlaps or is NOT below the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 |&> tbl2.column2 AS overabove FROM ( VALUES (1, 'LINESTRING(6 0, 6 4)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING(0 0, 3 3)'::geometry), (3, 'LINESTRING(0 1, 0 5)'::geometry), (4, 'LINESTRING(1 2, 4 6)'::geometry)) AS tbl2; column1 | column1 | overabove ---------+---------+----------- 1 | 2 | t 1 | 3 | f 1 | 4 | f (3 rows) See Also , , , |>> Returns TRUE if A's bounding box is strictly above B's. boolean |>> geometry A geometry B Description The |>> operator returns TRUE if the bounding box of geometry A is strictly to the right of the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 |>> tbl2.column2 AS above FROM ( VALUES (1, 'LINESTRING (1 4, 1 7)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (0 0, 4 2)'::geometry), (3, 'LINESTRING (6 1, 6 5)'::geometry), (4, 'LINESTRING (2 3, 5 6)'::geometry)) AS tbl2; column1 | column1 | above ---------+---------+------- 1 | 2 | t 1 | 3 | f 1 | 4 | f (3 rows) See Also , , ~ Returns TRUE if A's bounding box contains B's. boolean ~ geometry A geometry B Description The ~ operator returns TRUE if the bounding box of geometry A completely contains the bounding box of geometry B. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 ~ tbl2.column2 AS contains FROM ( VALUES (1, 'LINESTRING (0 0, 3 3)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (0 0, 4 4)'::geometry), (3, 'LINESTRING (1 1, 2 2)'::geometry), (4, 'LINESTRING (0 0, 3 3)'::geometry)) AS tbl2; column1 | column1 | contains ---------+---------+---------- 1 | 2 | f 1 | 3 | t 1 | 4 | t (3 rows) See Also , ~= Returns TRUE if the geometry A is the same as B. boolean ~= geometry A geometry B Description The ~= operator returns TRUE if geometry A is the same as geometry B. It tests actual geometric equality of two features. So if A and B are the same feature, vertex-by-vertex, the operator returns TRUE. This operand will make use of any indexes that may be available on the geometries. Examples SELECT tbl1.column1, tbl2.column1, tbl1.column2 ~= tbl2.column2 AS same FROM ( VALUES (1, 'LINESTRING (0 0, 2 2)'::geometry)) AS tbl1, ( VALUES (2, 'LINESTRING (0 0, 1 1, 2 2)'::geometry), (3, 'LINESTRING (2 2, 0 0)'::geometry), (4, 'LINESTRING (0 0, 2 2)'::geometry)) AS tbl2; column1 | column1 | same ---------+---------+------ 1 | 2 | f 1 | 3 | f 1 | 4 | t (3 rows) See Also , , Spatial Relationships and Measurements ST_Area Returns the area of the geometry if it is a polygon or multi-polygon. float ST_Area geometry g1 Description Returns the area of the geometry if it is a polygon or multi-polygon. Return the area measurement of an ST_Surface or ST_MultiSurface value. Area is in the units of the spatial reference system. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 8.1.2, 9.5.3 Examples Return area in square feet for a plot of Massachusetts land. Note this is in square feet because 2249 is Mass State Plane Feet SELECT ST_Area(ST_GeomFromText('POLYGON((743238 2967416,743238 2967450, 743265 2967450,743265.625 2967416,743238 2967416))',2249)); st_area --------- 928.625 (1 row) --this returns in square meters SELECT ST_Area(ST_Transform(ST_GeomFromText('POLYGON((743238 2967416,743238 2967450, 743265 2967450,743265.625 2967416,743238 2967416))',2249), 26986)); st_area ------------------ 86.2724306061864 See Also , , ST_Azimuth Returns the angle in radians from the horizontal of the vector defined by pointA and pointB float ST_Azimuth geometry pointA geometry pointB Description Returns the azimuth of the segment defined by the given Point geometries, or NULL if the two points are coincident. Return value is in radians. The Azimuth is mathematical concept defined as the angle, in this case measured in radian, between a reference plane and a point Availability: 1.1.0 Azimuth is especially useful in conjunction with ST_Translate for shifting an object along its perpendicular axis. See upgis_lineshift Plpgsqlfunctions PostGIS wiki section for example of this. Examples --Azimuth in degrees SELECT ST_Azimuth(ST_MakePoint(1,2), ST_MakePoint(3,4))/(2*pi())*360 as degAz, ST_Azimuth(ST_MakePoint(3,4), ST_MakePoint(1,2))/(2*pi())*360 As degAzrev degaz degazrev ------ --------- 45 225 See Also , ST_Centroid Returns the geometric center of a geometry. geometry ST_Centroid geometry g1 Description Computes the geometric center of a geometry, or equivalently, the center of mass of the geometry as a POINT. For [MULTI]POINTs, this is computed as the arithmetric mean of the input coordinates. For [MULTI]LINESTRINGs, this is computed as the weighted length of each line segment. For [MULTI]POLYGONs, "weight" is thought in terms of area. If an empty geometry is supplied, an empty GEOMETRYCOLLECTION is returned. If NULL is supplied, NULL is returned. The centroid is equal to the centroid of the set of component Geometries of highest dimension (since the lower-dimension geometries contribute zero "weight" to the centroid). Computation will be more accurate if performed by the GEOS module (enabled at compile time). This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 8.1.4, 9.5.5 Examples In each of the following illustrations, the blue dot represents the centroid of the source geometry. Centroid of a MULTIPOINT Centroid of a LINESTRING Centroid of a POLYGON Centroid of a GEOMETRYCOLLECTION SELECT ST_AsText(ST_Centroid('MULTIPOINT ( -1 0, -1 2, -1 3, -1 4, -1 7, 0 1, 0 3, 1 1, 2 0, 6 0, 7 8, 9 8, 10 6 )')); st_astext ------------------------------------------ POINT(2.30769230769231 3.30769230769231) (1 row) See Also ST_Contains Returns true if and only if no points of B lie in the exterior of A, and at least one point of the interior of B lies in the interior of A. boolean ST_Contains geometry geomA geometry geomB Description Geometry A contains Geometry B if and only if no points of B lie in the exterior of A, and at least one point of the interior of B lies in the interior of A. An important subtlety of this definition is that A does not contain its boundary, but A does contain itself. Contrast that to where geometry A does not Contain Properly itself. Returns TRUE if geometry B is completely inside geometry A. For this function to make sense, the source geometries must both be of the same coordinate projection, having the same SRID. ST_Contains is the inverse of ST_Within. So ST_Contains(A,B) implies ST_Within(B,A) except in the case of invalid geometries where the result is always false regardless or not defined. Performed by the GEOS module Do not call with a GEOMETRYCOLLECTION as an argument Do not use this function with invalid geometries. You will get unexpected results. This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_Contains. NOTE: this is the "allowable" version that returns a boolean, not an integer. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.2 // s2.1.13.3 - same as within(geometry B, geometry A) This method implements the SQL/MM specification: SQL-MM 3: 5.1.31 There are certain subtleties to ST_Contains and ST_Within that are not intuitively obvious. For details check out Subtleties of OGC Covers, Contains, Within Examples --a circle within a circle SELECT ST_Contains(smallc, bigc) As smallcontainsbig, ST_Contains(bigc,smallc) As bigcontainssmall, ST_Contains(bigc, ST_Union(smallc, bigc)) as bigcontainsunion, ST_Equals(bigc, ST_Union(smallc, bigc)) as bigisunion, ST_Covers(bigc, ST_ExteriorRing(bigc)) As bigcoversexterior, ST_Contains(bigc, ST_ExteriorRing(bigc)) As bigcontainsexterior FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo; --Result smallcontainsbig | bigcontainssmall | bigcontainsunion | bigisunion | bigcoversexterior | bigcontainsexterior ------------------+------------------+------------------+------------+-------------------+--------------------- f | t | t | t | t | f --example demonstrating difference between contains and contains properly SELECT ST_GeometryType(geomA) As geomtype, ST_Contains(geomA,geomA) AS acontainsa, ST_ContainsProperly(geomA, geomA) AS acontainspropa, ST_Contains(geomA, ST_Boundary(geomA)) As acontainsba, ST_ContainsProperly(geomA, ST_Boundary(geomA)) As acontainspropba FROM (VALUES ( ST_Buffer(ST_Point(1,1), 5,1) ), ( ST_MakeLine(ST_Point(1,1), ST_Point(-1,-1) ) ), ( ST_Point(1,1) ) ) As foo(geomA); geomtype | acontainsa | acontainspropa | acontainsba | acontainspropba --------------+------------+----------------+-------------+----------------- ST_Polygon | t | f | f | f ST_LineString | t | f | f | f ST_Point | t | t | f | f See Also , , ,, , ST_ContainsProperly Returns true if B intersects the interior of A but not the boundary (or exterior). A does not contain properly itself, but does contain itself. boolean ST_ContainsProperly geometry geomA geometry geomB Description Returns true if B intersects the interior of A but not the boundary (or exterior). A does not contain properly itself, but does contain itself. Every point of the other geometry is a point of this geometry's interior. The DE-9IM Intersection Matrix for the two geometries matches [T**FF*FF*] used in From JTS docs slightly reworded: The advantage to using this predicate over and is that it can be computed efficiently, with no need to compute topology at individual points. An example use case for this predicate is computing the intersections of a set of geometries with a large polygonal geometry. Since intersection is a fairly slow operation, it can be more efficient to use containsProperly to filter out test geometries which lie wholly inside the area. In these cases the intersection is known a priori to be exactly the original test geometry. Availability: 1.4.0 - requires GEOS >= 3.1.0. Do not call with a GEOMETRYCOLLECTION as an argument Do not use this function with invalid geometries. You will get unexpected results. This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_ContainsProperly. Examples --a circle within a circle SELECT ST_ContainsProperly(smallc, bigc) As smallcontainspropbig, ST_ContainsProperly(bigc,smallc) As bigcontainspropsmall, ST_ContainsProperly(bigc, ST_Union(smallc, bigc)) as bigcontainspropunion, ST_Equals(bigc, ST_Union(smallc, bigc)) as bigisunion, ST_Covers(bigc, ST_ExteriorRing(bigc)) As bigcoversexterior, ST_ContainsProperly(bigc, ST_ExteriorRing(bigc)) As bigcontainsexterior FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo; --Result smallcontainspropbig | bigcontainspropsmall | bigcontainspropunion | bigisunion | bigcoversexterior | bigcontainsexterior ------------------+------------------+------------------+------------+-------------------+--------------------- f | t | f | t | t | f --example demonstrating difference between contains and contains properly SELECT ST_GeometryType(geomA) As geomtype, ST_Contains(geomA,geomA) AS acontainsa, ST_ContainsProperly(geomA, geomA) AS acontainspropa, ST_Contains(geomA, ST_Boundary(geomA)) As acontainsba, ST_ContainsProperly(geomA, ST_Boundary(geomA)) As acontainspropba FROM (VALUES ( ST_Buffer(ST_Point(1,1), 5,1) ), ( ST_MakeLine(ST_Point(1,1), ST_Point(-1,-1) ) ), ( ST_Point(1,1) ) ) As foo(geomA); geomtype | acontainsa | acontainspropa | acontainsba | acontainspropba --------------+------------+----------------+-------------+----------------- ST_Polygon | t | f | f | f ST_LineString | t | f | f | f ST_Point | t | t | f | f See Also , , , ,, ,, ST_Covers Returns 1 (TRUE) if no point in Geometry B is outside Geometry A boolean ST_Covers geometry geomA geometry geomB Description Returns 1 (TRUE) if no point in Geometry B is outside Geometry A Performed by the GEOS module Do not call with a GEOMETRYCOLLECTION as an argument Do not use this function with invalid geometries. You will get unexpected results. This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_Covers. Availability: 1.2.2 NOTE: this is the "allowable" version that returns a boolean, not an integer. Not an OGC standard, but Oracle has it too. There are certain subtleties to ST_Contains and ST_Within that are not intuitively obvious. For details check out Subtleties of OGC Covers, Contains, Within Examples --a circle covering a circle SELECT ST_Covers(smallc,smallc) As smallinsmall, ST_Covers(smallc, bigc) As smallcoversbig, ST_Covers(bigc, ST_ExteriorRing(bigc)) As bigcoversexterior, ST_Contains(bigc, ST_ExteriorRing(bigc)) As bigcontainsexterior FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo; --Result smallinsmall | smallcoversbig | bigcoversexterior | bigcontainsexterior --------------+----------------+-------------------+--------------------- t | f | t | f (1 row) See Also , , ST_CoveredBy Returns 1 (TRUE) if no point in Geometry A is outside Geometry B boolean ST_CoveredBy geometry geomA geometry geomB Description Returns 1 (TRUE) if no point in Geometry A is outside Geometry B Performed by the GEOS module Do not call with a GEOMETRYCOLLECTION as an argument Do not use this function with invalid geometries. You will get unexpected results. Availability: 1.2.2 This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_CoveredBy. NOTE: this is the "allowable" version that returns a boolean, not an integer. Not an OGC standard, but Oracle has it too. There are certain subtleties to ST_Contains and ST_Within that are not intuitively obvious. For details check out Subtleties of OGC Covers, Contains, Within Examples --a circle coveredby a circle SELECT ST_CoveredBy(smallc,smallc) As smallinsmall, ST_CoveredBy(smallc, bigc) As smallcoveredbybig, ST_CoveredBy(ST_ExteriorRing(bigc), bigc) As exteriorcoveredbybig, ST_Within(ST_ExteriorRing(bigc),bigc) As exeriorwithinbig FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo; --Result smallinsmall | smallcoveredbybig | exteriorcoveredbybig | exeriorwithinbig --------------+-------------------+----------------------+------------------ t | t | t | f (1 row) See Also , , , ST_Crosses Returns TRUE if the supplied geometries have some, but not all, interior points in common. boolean ST_Crosses geometry g1 geometry g2 Description ST_Crosses takes two geometry objects and returns TRUE if their intersection "spatially cross", that is, the geometries have some, but not all interior points in common. The intersection of the interiors of the geometries must not be the empty set and must have a dimensionality less than the the maximum dimension of the two input geometries. Additionally, the intersection of the two geometries must not equal either of the source geometries. Otherwise, it returns FALSE. In mathematical terms, this is expressed as: TODO: Insert appropriate MathML markup here or use a gif. Simple HTML markup does not work well in both IE and Firefox. The DE-9IM Intersection Matrix for the two geometries is: T*T****** (for Point/Line, Point/Area, and Line/Area situations) T*****T** (for Line/Point, Area/Point, and Area/Line situations) 0******** (for Line/Line situations) For any other combination of dimensions this predicate returns false. The OpenGIS Simple Features Specification defines this predicate only for Point/Line, Point/Area, Line/Line, and Line/Area situations. JTS / GEOS extends the definition to apply to Line/Point, Area/Point and Area/Line situations as well. This makes the relation symmetric. Do not call with a GEOMETRYCOLLECTION as an argument This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. This method implements the OpenGIS Simple Features Implementation Specification for SQL: 1.1: s2.1.13.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.29 Examples The following illustrations all return TRUE. MULTIPOINT / LINESTRING MULTIPOINT / POLYGON LINESTRING / POLYGON LINESTRING / LINESTRING Consider a situation where a user has two tables: a table of roads and a table of highways. CREATE TABLE roads ( id serial NOT NULL, the_geom geometry, CONSTRAINT roads_pkey PRIMARY KEY (road_id) ); CREATE TABLE highways ( id serial NOT NULL, the_gem geometry, CONSTRAINT roads_pkey PRIMARY KEY (road_id) ); To determine a list of roads that cross a highway, use a query similiar to: SELECT roads.id FROM roads, highways WHERE ST_Crosses(roads.the_geom, highways.the_geom); ST_LineCrossingDirection Given 2 linestrings, returns a number between -3 and 3 denoting what kind of crossing behavior. 0 is no crossing. integer ST_LineCrossingDirection geometry linestringA geometry linestringB Description Given 2 linestrings, returns a number between -3 and 3 denoting what kind of crossing behavior. 0 is no crossing. This is only supported for LINESTRING Definition of integer constants is as follows: 0: LINE NO CROSS -1: LINE CROSS LEFT 1: LINE CROSS RIGHT -2: LINE MULTICROSS END LEFT 2: LINE MULTICROSS END RIGHT -3: LINE MULTICROSS END SAME FIRST LEFT 3: LINE MULTICROSS END SAME FIRST RIGHT Availability: 1.4 Examples SELECT ST_CrossingDirection(foo.line1, foo.line2) As linecrossleft , ST_CrossingDirection(foo.line2, foo.line1) As linecrossright FROM (SELECT ST_GeomFromText('LINESTRING(744589 2923929,744521 2923861)') As line1, ST_GeomFromText('LINESTRING(744753 2924117,744563 2923902)') As line2) As foo; linecrossleft | linecrossright ---------------+---------------- -1 | 1 SELECT s1.gid, s2.gid, ST_CrossingDirection(s1.the_geom, s2.the_geom) FROM streets s1 CROSS JOIN streets s2 ON (s1.gid != s2.gid AND s1.the_geom && s2.the_geom ) WHERE ST_CrossingDirection(s1.the_geom, s2.the_geom) > 0; See Also ST_Disjoint Returns TRUE if the Geometries do not "spatially intersect" - if they do not share any space together. boolean ST_Disjoint geometry A geometry B Description Overlaps, Touches, Within all imply geometries are not spatially disjoint. If any of the aforementioned returns true, then the geometries are not spatially disjoint. Disjoint implies false for spatial intersection. Do not call with a GEOMETRYCOLLECTION as an argument Performed by the GEOS module This function call does not use indexes NOTE: this is the "allowable" version that returns a boolean, not an integer. This method implements the OGC SPEC s2.1.1.2 //s2.1.13.3 - a.Relate(b, 'FF*FF****') This method implements the SQL/MM specification: SQL-MM 3: 5.1.26 Examples SELECT ST_Disjoint('POINT(0 0)'::geometry, 'LINESTRING ( 2 0, 0 2 )'::geometry); st_disjoint --------------- t (1 row) SELECT ST_Disjoint('POINT(0 0)'::geometry, 'LINESTRING ( 0 0, 0 2 )'::geometry); st_disjoint --------------- f (1 row) See Also ST_Intersects ST_Distance Returns the 2-dimensional cartesian minimum distance between two geometries in projected units. float ST_Distance geometry g1 geometry g2 Description Returns the 2-dimensional minimum cartesian distance between two geometries in projected units. This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 5.1.23 Examples postgis=# SELECT ST_Distance('POINT(0 0)'::geometry, 'LINESTRING ( 2 0, 0 2 )'::geometry); st_distance ----------------- 1.4142135623731 (1 row) See Also , , , ST_Distance_Sphere Returns linear distance in meters between two lon/lat points. Uses a spherical earth and radius of 6370986 meters. Faster than , but less accurate. Only implemented for points. float ST_Distance_Sphere geometry pointlonlatA geometry pointlonlatB Description Returns linear distance in meters between two lon/lat points. Uses a spherical earth and radius of 6370986 meters. Faster than , but less accurate. Only implemented for points. This function currently does not look at the SRID of a point geometry and will always assume its in WGS 80 long lat. Examples SELECT round(CAST(ST_Distance_Sphere(ST_Centroid(the_geom), ST_GeomFromText('POINT(-118 38)',4326)) As numeric),2) As dist_meters, round(CAST(ST_Distance(ST_Transform(ST_Centroid(the_geom),32611), ST_Transform(ST_GeomFromText('POINT(-118 38)', 4326),32611)) As numeric),2) As dist_utm11_meters, round(CAST(ST_Distance(ST_Centroid(the_geom), ST_GeomFromText('POINT(-118 38)', 4326)) As numeric),5) As dist_degrees, round(CAST(ST_Distance(ST_Transform(the_geom,32611), ST_Transform(ST_GeomFromText('POINT(-118 38)', 4326),32611)) As numeric),2) As min_dist_line_point_meters FROM (SELECT ST_GeomFromText('LINESTRING(-118.584 38.374,-118.583 38.5)', 4326) As the_geom) as foo; dist_meters | dist_utm11_meters | dist_degrees | min_dist_line_point_meters -------------+-------------------+--------------+---------------------------- 70424.47 | 70438.00 | 0.72900 | 65871.18 See Also , ST_Distance_Spheroid Returns linear distance between two lon/lat points given a particular spheroid. Currently only implemented for points. float ST_Distance_Spheroid geometry pointlonlatA geometry pointlonlatB spheroid measurement_spheroid Description Returns linear distance in meters between two lon/lat points given a particular spheroid. See the explanation of spheroids given for . This function currently does not look at the SRID of a point geometry to determine spheroid and will always assume points are along the spheroid given. Examples SELECT round(CAST( ST_Distance_Spheroid(ST_Centroid(the_geom), ST_GeomFromText('POINT(-118 38)',4326), 'SPHEROID["WGS 84",6378137,298.257223563]') As numeric),2) As dist_meters_spheroid, round(CAST(ST_Distance_Sphere(ST_Centroid(the_geom), ST_GeomFromText('POINT(-118 38)',4326)) As numeric),2) As dist_meters_sphere, round(CAST(ST_Distance(ST_Transform(ST_Centroid(the_geom),32611), ST_Transform(ST_GeomFromText('POINT(-118 38)', 4326),32611)) As numeric),2) As dist_utm11_meters FROM (SELECT ST_GeomFromText('LINESTRING(-118.584 38.374,-118.583 38.5)', 4326) As the_geom) as foo; dist_meters_spheroid | dist_meters_sphere | dist_utm11_meters ----------------------+--------------------+------------------- 70454.92 | 70424.47 | 70438.00 See Also , ST_DWithin Returns true if the geometries are within the specified distance of one another boolean ST_DWithin geometry g1 geometry g2 double precision distance Description Returns true if the geometries are within the specified distance of one another. The distance is specified in units defined by the spatial reference system of the geometries. For this function to make sense, the source geometries must both be of the same coorindate projection, having the same SRID. This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. Prior to 1.3, ST_Expand was commonly used in conjunction with && and ST_Distance to achieve the same effect and in pre-1.3.4 this function was basically short-hand for that construct. From 1.3.4, ST_DWithin uses a more short-circuit distance function which should make it more efficient than prior versions for larger buffer regions. This method implements the OpenGIS Simple Features Implementation Specification for SQL. Examples --Find the nearest hospital to each school --that is within 3000 units of the school. -- We do an ST_DWithin search to utilize indexes to limit our search list -- that the non-indexable ST_Distance needs to process --If the units of the spatial reference is meters then units would be meters SELECT DISTINCT ON (s.gid) s.gid, s.school_name, s.the_geom, h.hospital_name FROM schools s LEFT JOIN hospitals h ON ST_DWithin(s.the_geom, h.the_geom, 3000) ORDER BY s.gid, ST_Distance(s.the_geom, h.the_geom); --The schools with no close hospitals --Find all schools with no hospital within 3000 units --away from the school. Units is in units of spatial ref (e.g. meters, feet, degrees) SELECT s.gid, s.school_name FROM schools s LEFT JOIN hospitals h ON ST_DWithin(s.the_geom, h.the_geom, 3000) WHERE h.gid IS NULL; See Also , ST_Equals Returns true if the given geometries represent the same geometry. Directionality is ignored. boolean ST_Equals geometry A geometry B Description Returns TRUE if the given Geometries are "spatially equal". Use this for a 'better' answer than '='. Note by spatially equal we mean ST_Within(A,B) = true and ST_Within(B,A) = true and also mean ordering of points can be different but represent the same geometry structure. To verify the order of points is consistent, use ST_OrderingEquals (it must be noted ST_OrderingEquals is a little more stringent than simply verifying order of points are the same). This function will return false if either geometry is invalid even if they are binary equal. This method implements the OpenGIS Simple Features Implementation Specification for SQL OGC SPEC s2.1.1.2 This method implements the SQL/MM specification: SQL-MM 3: 5.1.24 Examples SELECT ST_Equals(ST_GeomFromText('LINESTRING(0 0, 10 10)'), ST_GeomFromText('LINESTRING(0 0, 5 5, 10 10)')); st_equals ----------- t (1 row) SELECT ST_Equals(ST_Reverse(ST_GeomFromText('LINESTRING(0 0, 10 10)')), ST_GeomFromText('LINESTRING(0 0, 5 5, 10 10)')); st_equals ----------- t (1 row) See Also , , , ST_HasArc Returns true if a geometry or geometry collection contains a circular string boolean ST_HasArc geometry geomA Description Returns true if a geometry or geometry collection contains a circular string Availability: 1.2.3? This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_HasArc(ST_Collect('LINESTRING(1 2, 3 4, 5 6)', 'CIRCULARSTRING(1 1, 2 3, 4 5, 6 7, 5 6)')); st_hasarc -------- t See Also , ST_Intersects Returns TRUE if the Geometries "spatially intersect" - (share any portion of space) and FALSE if they don't (they are Disjoint). boolean ST_Intersects geometry A geometry B Description Overlaps, Touches, Within all imply spatial intersection. If any of the aforementioned returns true, then the geometries also spatially intersect. Disjoint implies false for spatial intersection. Do not call with a GEOMETRYCOLLECTION as an argument Performed by the GEOS module This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. NOTE: this is the "allowable" version that returns a boolean, not an integer. This method implements the OpenGIS Simple Features Implementation Specification for SQL OGC SPEC s2.1.1.2 //s2.1.13.3 - ST_Intersects(g1, g2 ) --> Not (ST_Disjoint(g1, g2 )) This method implements the SQL/MM specification: SQL-MM 3: 5.1.27 Examples SELECT ST_Intersects('POINT(0 0)'::geometry, 'LINESTRING ( 2 0, 0 2 )'::geometry); st_intersects --------------- f (1 row) SELECT ST_Intersects('POINT(0 0)'::geometry, 'LINESTRING ( 0 0, 0 2 )'::geometry); st_intersects --------------- t (1 row) See Also ST_Length Returns the 2d length of the geometry if it is a linestring or multilinestring. float ST_Length geometry a_2dlinestring Description Returns the 2D length of the geometry if it is a linestring, multilinestring, ST_Curve, ST_MultiCurve. 0 is returned for areal geometries. For areal geometries use ST_Perimeter. Measurements are in the units of the spatial reference system of the geometry. Currently this is an alias for ST_Length2D, but this may change to support higher dimensions. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 2.1.5.1 This method implements the SQL/MM specification: SQL-MM 3: 7.1.2, 9.3.4 Examples Return length in feet for line string. Note this is in feet because 2249 is Mass State Plane Feet SELECT SELECT ST_Length(ST_GeomFromText('LINESTRING(743238 2967416,743238 2967450,743265 2967450, 743265.625 2967416,743238 2967416)',2249)); st_length --------- 122.630744000095 (1 row) See Also ST_Length2D Returns the 2-dimensional length of the geometry if it is a linestring or multi-linestring. This is an alias for ST_Length float ST_Length2D geometry a_2dlinestring Description Returns the 2-dimensional length of the geometry if it is a linestring or multi-linestring. This is an alias for ST_Length See Also , ST_Length3D Returns the 3-dimensional or 2-dimensional length of the geometry if it is a linestring or multi-linestring. float ST_Length3D geometry a_3dlinestring Description Returns the 3-dimensional or 2-dimensional length of the geometry if it is a linestring or multi-linestring. For 2-d lines it will just return the 2-d length (same as ST_Length and ST_Length2D) This function supports 3d and will not drop the z-index. Examples Return length in feet for a 3D cable. Note this is in feet because 2249 is Mass State Plane Feet SELECT ST_Length3D(ST_GeomFromText('LINESTRING(743238 2967416 1,743238 2967450 1,743265 2967450 3, 743265.625 2967416 3,743238 2967416 3)',2249)); st_length3d ----------- 122.704716741457 See Also , ST_Length_Spheroid Calculates the 2D or 3D length of a linestring/multilinestring on an ellipsoid. This is useful if the coordinates of the geometry are in longitude/latitude and a length is desired without reprojection. float ST_Length_Spheroid geometry a_linestring spheroid a_spheroid Description Calculates the length of a geometry on an ellipsoid. This is useful if the coordinates of the geometry are in longitude/latitude and a length is desired without reprojection. The ellipsoid is a separate database type and can be constructed as follows: SPHEROID[<NAME>,<SEMI-MAJOR AXIS>,<INVERSE FLATTENING>] SPHEROID["GRS_1980",6378137,298.257222101] Will return 0 for anything that is not a MULTILINESTRING or LINESTRING This function supports 3d and will not drop the z-index. Examples SELECT ST_Length_Spheroid( geometry_column, 'SPHEROID["GRS_1980",6378137,298.257222101]' ) FROM geometry_table; SELECT ST_Length_Spheroid( the_geom, sph_m ) As tot_len, ST_Length_Spheroid(ST_GeometryN(the_geom,1), sph_m) As len_line1, ST_Length_Spheroid(ST_GeometryN(the_geom,2), sph_m) As len_line2 FROM (SELECT ST_GeomFromText('MULTILINESTRING((-118.584 38.374,-118.583 38.5), (-71.05957 42.3589 , -71.061 43))') As the_geom, CAST('SPHEROID["GRS_1980",6378137,298.257222101]' As spheroid) As sph_m) as foo; tot_len | len_line1 | len_line2 ------------------+------------------+------------------ 85204.5207562955 | 13986.8725229309 | 71217.6482333646 --3D SELECT ST_Length_Spheroid( the_geom, sph_m ) As tot_len, ST_Length_Spheroid(ST_GeometryN(the_geom,1), sph_m) As len_line1, ST_Length_Spheroid(ST_GeometryN(the_geom,2), sph_m) As len_line2 FROM (SELECT ST_GeomFromEWKT('MULTILINESTRING((-118.584 38.374 20,-118.583 38.5 30), (-71.05957 42.3589 75, -71.061 43 90))') As the_geom, CAST('SPHEROID["GRS_1980",6378137,298.257222101]' As spheroid) As sph_m) as foo; tot_len | len_line1 | len_line2 ------------------+-----------------+------------------ 85204.5259107402 | 13986.876097711 | 71217.6498130292 See Also , , ST_Length2D_Spheroid Calculates the 2D length of a linestring/multilinestring on an ellipsoid. This is useful if the coordinates of the geometry are in longitude/latitude and a length is desired without reprojection. float ST_Length2D_Spheroid geometry a_linestring spheroid a_spheroid Description Calculates the 2D length of a geometry on an ellipsoid. This is useful if the coordinates of the geometry are in longitude/latitude and a length is desired without reprojection. The ellipsoid is a separate database type and can be constructed as follows: SPHEROID[<NAME>,<SEMI-MAJOR AXIS>,<INVERSE FLATTENING>] SPHEROID["GRS_1980",6378137,298.257222101] Will return 0 for anything that is not a MULTILINESTRING or LINESTRING This is much like and except it will throw away the Z coordinate in calculations. Examples SELECT ST_Length2D_Spheroid( geometry_column, 'SPHEROID["GRS_1980",6378137,298.257222101]' ) FROM geometry_table; SELECT ST_Length2D_Spheroid( the_geom, sph_m ) As tot_len, ST_Length2D_Spheroid(ST_GeometryN(the_geom,1), sph_m) As len_line1, ST_Length2D_Spheroid(ST_GeometryN(the_geom,2), sph_m) As len_line2 FROM (SELECT ST_GeomFromText('MULTILINESTRING((-118.584 38.374,-118.583 38.5), (-71.05957 42.3589 , -71.061 43))') As the_geom, CAST('SPHEROID["GRS_1980",6378137,298.257222101]' As spheroid) As sph_m) as foo; tot_len | len_line1 | len_line2 ------------------+------------------+------------------ 85204.5207562955 | 13986.8725229309 | 71217.6482333646 --3D Observe same answer SELECT ST_Length2D_Spheroid( the_geom, sph_m ) As tot_len, ST_Length2D_Spheroid(ST_GeometryN(the_geom,1), sph_m) As len_line1, ST_Length2D_Spheroid(ST_GeometryN(the_geom,2), sph_m) As len_line2 FROM (SELECT ST_GeomFromEWKT('MULTILINESTRING((-118.584 38.374 20,-118.583 38.5 30), (-71.05957 42.3589 75, -71.061 43 90))') As the_geom, CAST('SPHEROID["GRS_1980",6378137,298.257222101]' As spheroid) As sph_m) as foo; tot_len | len_line1 | len_line2 ------------------+------------------+------------------ 85204.5207562955 | 13986.8725229309 | 71217.6482333646 See Also , , ST_Length3D_Spheroid Calculates the length of a geometry on an ellipsoid, taking the elevation into account. This is just an alias for ST_Length_Spheroid. float ST_Length3D_Spheroid geometry a_linestring spheroid a_spheroid Description Calculates the length of a geometry on an ellipsoid, taking the elevation into account. This is just an alias for ST_Length_Spheroid. Will return 0 for anything that is not a MULTILINESTRING or LINESTRING This functionis just an alias for ST_Length_Spheroid. This function supports 3d and will not drop the z-index. Examples See ST_Length_Spheroid See Also , , ST_Max_Distance Returns the 2-dimensional largest distance between two geometries in projected units. float ST_Max_Distance geometry g1 geometry g2 Description Returns the 2-dimensional maximum cartesian distance between two linestrings in projected units. Examples --ALL EXAMPLES current throw NOT YET IMPLEMENTED See Also ST_OrderingEquals Returns true if the given geometries represent the same geometry and points are in the same directional order. boolean ST_OrderingEquals geometry A geometry B Description ST_OrderingEquals compares two geometries and t (TRUE) if the geometries are equal and the coordinates are in the same order; otherwise it returns f (FALSE). This function is implemented as per the ArcSDE SQL specification rather than SQL-MM. http://edndoc.esri.com/arcsde/9.1/sql_api/sqlapi3.htm#ST_OrderingEquals This method implements the SQL/MM specification: SQL-MM 3: 5.1.43 Examples SELECT ST_OrderingEquals(ST_GeomFromText('LINESTRING(0 0, 10 10)'), ST_GeomFromText('LINESTRING(0 0, 5 5, 10 10)')); st_orderingequals ----------- f (1 row) SELECT ST_OrderingEquals(ST_GeomFromText('LINESTRING(0 0, 10 10)'), ST_GeomFromText('LINESTRING(0 0, 0 0, 10 10)')); st_orderingequals ----------- t (1 row) SELECT ST_OrderingEquals(ST_Reverse(ST_GeomFromText('LINESTRING(0 0, 10 10)')), ST_GeomFromText('LINESTRING(0 0, 0 0, 10 10)')); st_orderingequals ----------- f (1 row) See Also , ST_Overlaps Returns TRUE if the Geometries share space, are of the same dimension, but are not completely contained by each other. boolean ST_Overlaps geometry A geometry B Description Returns TRUE if the Geometries "spatially overlap". By that we mean they intersect, but one does not completely contain another. Performed by the GEOS module Do not call with a GeometryCollection as an argument This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_Overlaps. NOTE: this is the "allowable" version that returns a boolean, not an integer. OGC SPEC s2.1.1.2 // s2.1.13.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.32 Examples --a point on a line is contained by the line and is of a lower dimension, and therefore does not overlap the line nor crosses SELECT ST_Overlaps(a,b) As a_overlap_b, ST_Crosses(a,b) As a_crosses_b, ST_Intersects(a, b) As a_intersects_b, ST_Contains(b,a) As b_contains_a FROM (SELECT ST_GeomFromText('POINT(1 0.5)') As a, ST_GeomFromText('LINESTRING(1 0, 1 1, 3 5)') As b) As foo a_overlap_b | a_crosses_b | a_intersects_b | b_contains_a ------------+-------------+----------------+-------------- f | f | t | t --a line that is partly contained by circle, but not fully is defined as intersecting and crossing, -- but since of different dimension it does not overlap SELECT ST_Overlaps(a,b) As a_overlap_b, ST_Crosses(a,b) As a_crosses_b, ST_Intersects(a, b) As a_intersects_b, ST_Contains(a,b) As a_contains_b FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 0.5)'), 3) As a, ST_GeomFromText('LINESTRING(1 0, 1 1, 3 5)') As b) As foo; a_overlap_b | a_crosses_b | a_intersects_b | a_contains_b -------------+-------------+----------------+-------------- f | t | t | f -- a 2-dimensional bent hot dog (aka puffered line string) that intersects a circle, -- but is not fully contained by the circle is defined as overlapping since they are of the same dimension, -- but it does not cross, because the intersection of the 2 is of the same dimension -- as the maximum dimension of the 2 SELECT ST_Overlaps(a,b) As a_overlap_b, ST_Crosses(a,b) As a_crosses_b, ST_Intersects(a, b) As a_intersects_b, ST_Contains(b,a) As b_contains_a, ST_Dimension(a) As dim_a, ST_Dimension(b) as dim_b, ST_Dimension(ST_Intersection(a,b)) As dima_intersection_b FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 0.5)'), 3) As a, ST_Buffer(ST_GeomFromText('LINESTRING(1 0, 1 1, 3 5)'),0.5) As b) As foo; a_overlap_b | a_crosses_b | a_intersects_b | b_contains_a | dim_a | dim_b | dima_intersection_b -------------+-------------+----------------+--------------+-------+-------+--------------------- t | f | t | f | 2 | 2 | 2 See Also , , , ST_Perimeter Return the length measurement of the boundary of an ST_Surface or ST_MultiSurface value. (Polygon, Multipolygon) float ST_Perimeter geometry g1 Description Returns the 2D perimeter of the geometry if it is a ST_Surface, ST_MultiSurface (Polygon, Multipolygon). 0 is returned for non-areal geometries. For linestrings use ST_Length. Measurements are in the units of the spatial reference system of the geometry. Currently this is an alias for ST_Perimeter2D, but this may change to support higher dimensions. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC 2.1.5.1 This method implements the SQL/MM specification: SQL-MM 3: 8.1.3, 9.5.4 Examples Return perimeter in feet for polygon and multipolygon. Note this is in feet because 2249 is Mass State Plane Feet SELECT ST_Perimeter(ST_GeomFromText('POLYGON((743238 2967416,743238 2967450,743265 2967450, 743265.625 2967416,743238 2967416))', 2249)); st_perimeter --------- 122.630744000095 (1 row) SELECT ST_Perimeter(ST_GeomFromText('MULTIPOLYGON(((763104.471273676 2949418.44119003, 763104.477769673 2949418.42538203, 763104.189609677 2949418.22343004,763104.471273676 2949418.44119003)), ((763104.471273676 2949418.44119003,763095.804579742 2949436.33850239, 763086.132105649 2949451.46730207,763078.452329651 2949462.11549407, 763075.354136904 2949466.17407812,763064.362142565 2949477.64291974, 763059.953961626 2949481.28983009,762994.637609571 2949532.04103014, 762990.568508415 2949535.06640477,762986.710889563 2949539.61421415, 763117.237897679 2949709.50493431,763235.236617789 2949617.95619822, 763287.718121842 2949562.20592617,763111.553321674 2949423.91664605, 763104.471273676 2949418.44119003)))', 2249)); st_perimeter --------- 845.227713366825 (1 row) See Also ST_Perimeter2D Returns the 2-dimensional perimeter of the geometry, if it is a polygon or multi-polygon. This is currently an alias for ST_Perimeter. float ST_Perimeter2D geometry geomA Description Returns the 2-dimensional perimeter of the geometry, if it is a polygon or multi-polygon. This is currently an alias for ST_Perimeter. In future versions ST_Perimeter may return the highest dimension perimeter for a geometry. This is still under consideration See Also ST_Perimeter3D Returns the 3-dimensional perimeter of the geometry, if it is a polygon or multi-polygon. float ST_Perimeter3D geometry geomA Description Returns the 3-dimensional perimeter of the geometry, if it is a polygon or multi-polygon. If the geometry is 2-dimensional, then the 2-dimensional perimeter is returned. This function supports 3d and will not drop the z-index. Examples Perimeter of a slightly elevated polygon in the air in Massachusetts state plane feet SELECT ST_Perimeter3D(the_geom), ST_Perimeter2d(the_geom), ST_Perimeter(the_geom) FROM (SELECT ST_GeomFromEWKT('SRID=2249;POLYGON((743238 2967416 2,743238 2967450 1, 743265.625 2967416 1,743238 2967416 2))') As the_geom) As foo; st_perimeter3d | st_perimeter2d | st_perimeter ------------------+------------------+------------------ 105.465793597674 | 105.432997272188 | 105.432997272188 See Also , , ST_PointOnSurface Returns a POINT guaranteed to lie on the surface. geometry ST_PointOnSurface geometry g1 Description Returns a POINT guaranteed to intersect a surface. This method implements the OpenGIS Simple Features Implementation Specification for SQL: 3.2.14.2, 3.2.18.2 This method implements the SQL/MM specification: SQL-MM 3: 8.1.5, 9.5.6 Examples SELECT ST_AsText(ST_PointOnSurface('POINT(0 5)'::geometry)); st_astext ------------ POINT(0 5) (1 row) SELECT ST_AsText(ST_PointOnSurface('LINESTRING(0 5, 0 10)'::geometry)); st_astext ------------ POINT(0 5) (1 row) SELECT ST_AsText(ST_PointOnSurface('POLYGON((0 0, 0 5, 5 5, 5 0, 0 0))'::geometry)); st_astext ---------------- POINT(2.5 2.5) (1 row) See Also , ST_Relate Returns true if this Geometry is spatially related to anotherGeometry, by testing for intersections between the Interior, Boundary and Exterior of the two geometries as specified by the values in the intersectionMatrixPattern. If no intersectionMatrixPattern is passed in, then returns the maximum intersectionMatrixPattern that relates the 2 geometries. text ST_Relate geometry geomA geometry geomB boolean ST_Relate geometry geomA geometry geomB text intersectionMatrixPattern Description Version 1: Takes geomA, geomB, intersectionMatrix and Returns 1 (TRUE) if this Geometry is spatially related to anotherGeometry, by testing for intersections between the Interior, Boundary and Exterior of the two geometries as specified by the values in the intersectionMatrixPattern. This is especially useful for testing compound checks of intersection, crosses, etc in one step. Do not call with a GeometryCollection as an argument This is the "allowable" version that returns a boolean, not an integer. This is defined in OGC spec This DOES NOT automagically include an index call. The reason for that is some relationships are anti e.g. Disjoint. If you are using a relationship pattern that requires intersection, then include the && index call. Version 2: Takes geomA and geomB and returns the DE-9IM (dimensionally extended nine-intersection matrix) Do not call with a GeometryCollection as an argument not in OGC spec, but implied. see s2.1.13.2 Both Performed by the GEOS module This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.2 // s2.1.13.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.25 Examples --Find all compounds that intersect and not touch a poly (interior intersects) SELECT l.* , b.name As poly_name FROM polys As b INNER JOIN compounds As l ON (p.the_geom && b.the_geom AND ST_Relate(l.the_geom, b.the_geom,'T********')); SELECT ST_Relate(ST_GeometryFromText('POINT(1 2)'), ST_Buffer(ST_GeometryFromText('POINT(1 2)'),2)); st_relate ----------- 0FFFFF212 SELECT ST_Relate(ST_GeometryFromText('LINESTRING(1 2, 3 4)'), ST_GeometryFromText('LINESTRING(5 6, 7 8)')); st_relate ----------- FF1FF0102 SELECT ST_Relate(ST_GeometryFromText('POINT(1 2)'), ST_Buffer(ST_GeometryFromText('POINT(1 2)'),2), '0FFFFF212'); st_relate ----------- t SELECT ST_Relate(ST_GeometryFromText('POINT(1 2)'), ST_Buffer(ST_GeometryFromText('POINT(1 2)'),2), '*FF*FF212'); st_relate ----------- t See Also , , , ST_Touches Returns TRUE if the geometries have at least one point in common, but their interiors do not intersect. boolean ST_Touches geometry g1 geometry g2 Description Returns TRUE if the only points in common between g1 and g2 lie in the union of the boundaries of g1 and g2. The ST_Touches relation applies to all Area/Area, Line/Line, Line/Area, Point/Area and Point/Line pairs of relationships, but not to the Point/Point pair. In mathematical terms, this predicate is expressed as: TODO: Insert appropriate MathML markup here or use a gif. Simple HTML markup does not work well in both IE and Firefox. The allowable DE-9IM Intersection Matrices for the two geometries are: FT******* F**T***** F***T**** Do not call with a GEOMETRYCOLLECTION as an argument This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid using an index, use _ST_Touches instead. This method implements the OpenGIS Simple Features Implementation Specification for SQL: 2.1.1.2, 2.1.13.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.28 Examples The ST_Touches predicate returns TRUE in all the following illustrations. POLYGON / POLYGON POLYGON / POLYGON POLYGON / LINESTRING LINESTRING / LINESTRING LINESTRING / LINESTRING POLYGON / POINT SELECT ST_Touches('LINESTRING(0 0, 1 1, 0 2)'::geometry, 'POINT(1 1)'::geometry); st_touches ------------ f (1 row) SELECT ST_Touches('LINESTRING(0 0, 1 1, 0 2)'::geometry, 'POINT(0 2)'::geometry); st_touches ------------ t (1 row) ST_Within Returns true if the geometry A is completely inside geometry B boolean ST_Within geometry A geometry B Description Returns TRUE if geometry A is completely inside geometry B. For this function to make sense, the source geometries must both be of the same coordinate projection, having the same SRID. It is a given that if ST_Within(A,B) is true and ST_Within(B,A) is true, then the two geometries are considered spatially equal. Performed by the GEOS module Do not call with a GEOMETRYCOLLECTION as an argument Do not use this function with invalid geometries. You will get unexpected results. This function call will automatically include a bounding box comparison that will make use of any indexes that are available on the geometries. To avoid index use, use the function _ST_Within. NOTE: this is the "allowable" version that returns a boolean, not an integer. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.2 // s2.1.13.3 - a.Relate(b, 'T*F**F***') This method implements the SQL/MM specification: SQL-MM 3: 5.1.30 Examples --a circle within a circle SELECT ST_Within(smallc,smallc) As smallinsmall, ST_Within(smallc, bigc) As smallinbig, ST_Within(bigc,smallc) As biginsmall, ST_Within(ST_Union(smallc, bigc), bigc) as unioninbig, ST_Within(bigc, ST_Union(smallc, bigc)) as biginunion, ST_Equals(bigc, ST_Union(smallc, bigc)) as bigisunion FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo; --Result smallinsmall | smallinbig | biginsmall | unioninbig | biginunion | bigisunion --------------+------------+------------+------------+------------+------------ t | t | f | t | t | t (1 row) See Also , , Geometry Processing Functions ST_Buffer Returns a geometry that represents all points whose distance from this Geometry is less than or equal to distance. Calculations are in the Spatial Reference System of this Geometry. The optional third parameter sets the number of segments used to approximate a quarter circle (defaults to 8). geometry ST_Buffer geometry g1 float radius_of_buffer geometry ST_Buffer geometry g1 float radius_of_buffer integer num_seg_quarter_circle Description Returns a geometry that represents all points whose distance from this Geometry is less than or equal to distance. Calculations are in the Spatial Reference System of this Geometry. The optional third parameter sets the number of segments used to approximate a quarter circle (defaults to 8). Units are always measured in units of the spatial reference system. The inputs can be POINTS, MULTIPOINTS, LINESTRINGS, MULTILINESTRINGS, POLYGONS, MULTIPOLYGONS, and GeometryCollections. This function ignores the third dimension (z) and will always give a 2-d buffer even when presented with a 3d-geometry. Performed by the GEOS module. This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.17 People often make the mistake of using this function to try to do radius searches. Creating a buffer to to a radius search is slow and pointless. Use instead. Examples --A buffered point approximates a circle -- A buffered point forcing approximation of -- 4 points per circle is poly with 16 sides SELECT ST_NPoints(ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10)) As promisingcircle_pcount, ST_NPoints(ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10, 4)) As lamecircle_pcount; promisingcircle_pcount | lamecircle_pcount ------------------------+------------------- 33 | 17 --A lighter but lamer circle -- only 2 points per quarter circle is an octagon --Below is a 100 meter octagon -- Note coordinates are in NAD 83 long lat which we transform to Mass state plane meter and then buffer to get measurements in meters; SELECT ST_AsText(ST_Buffer( ST_Transform( ST_SetSRID(ST_MakePoint(-71.063526, 42.35785),4269), 26986) ,100,2)) As octagon; ---------------------- POLYGON((236057.59057465 900908.759918696,236028.301252769 900838.049240578,235 957.59057465 900808.759918696,235886.879896532 900838.049240578,235857.59057465 900908.759918696,235886.879896532 900979.470596815,235957.59057465 901008.759918 696,236028.301252769 900979.470596815,236057.59057465 900908.759918696)) --Buffer is often also used as a poor man's polygon fixer or a sometimes speedier unioner --Sometimes able to fix invalid polygons - using below -- using below on anything but a polygon will result in empty geometry -- and for geometry collections kill anything in the collection that is not a polygon --Poor man's bad poly fixer SELECT ST_IsValid(foo.invalidpoly) as isvalid, ST_IsValid(ST_Buffer(foo.invalidpoly,0.0)) as bufferisvalid, ST_AsText(ST_Buffer(foo.invalidpoly,0.0)) As newpolytextrep FROM (SELECT ST_GeomFromText('POLYGON((-1 2, 3 4, 5 6, -1 2, 5 6, -1 2))') as invalidpoly) As foo NOTICE: Self-intersection at or near point -1 2 isvalid | bufferisvalid | newpolytextrep ---------+---------------+------------------------------ f | t | POLYGON((-1 2,5 6,3 4,-1 2)) --Poor man's polygon unioner SELECT ST_AsText(the_geom) as textorig, ST_AsText(ST_Buffer(foo.the_geom,0.0)) As textbuffer FROM (SELECT ST_Collect('POLYGON((-1 2, 3 4, 5 6, -1 2))', 'POLYGON((-1 2, 2 3, 5 6, -1 2))') As the_geom) as foo; textorig | textbuffer -----------------------------------------------------------+-------------------- MULTIPOLYGON(((-1 2,3 4,5 6,-1 2)),((-1 2,2 3,5 6,-1 2))) | POLYGON((-1 2,5 6,3 4,2 3,-1 2)) See Also , , , , ST_BuildArea Creates an areal geometry formed by the constituent linework of given geometry boolean ST_BuildArea geometry A Description Creates an areal geometry formed by the constituent linework of given geometry. The return type can be a Polygon or MultiPolygon, depending on input. If the input lineworks do not form polygons NULL is returned. The inputs can be LINESTRINGS, MULTILINESTRINGS, POLYGONS, MULTIPOLYGONS, and GeometryCollections. This function will assume all inner geometries represent holes Availability: 1.1.0 - requires GEOS >= 2.1.0. Examples --This will create a donut SELECT ST_BuildArea(ST_Collect(smallc,bigc)) FROM (SELECT ST_Buffer(ST_GeomFromText('POINT(1 2)'), 10) As smallc, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As bigc) As foo --This will create a gaping hole --inside the circle with prongs sticking out SELECT ST_BuildArea(ST_Collect(line,circle)) FROM (SELECT ST_Buffer(ST_MakeLine(ST_MakePoint(21, 22),ST_MakePoint(-19, -18)),1) As line, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As circle) As foo; --this creates the same gaping hole --but using linestrings instead of polygons SELECT ST_AsBinary(ST_BuildArea(ST_Collect(ST_ExteriorRing(line),ST_ExteriorRing(circle)))) FROM (SELECT ST_Buffer(ST_MakeLine(ST_MakePoint(21, 22),ST_MakePoint(-19, -18)),1) As line, ST_Buffer(ST_GeomFromText('POINT(1 2)'), 20) As circle) As foo See Also , wrappers to this function with standard OGC interface ST_Collect Return a specified ST_Geometry value from a collection of other geometries. geometry ST_Collect geometry set g1field geometry ST_Collect geometry g1 geometry g2 geometry ST_Collect geometry[] g1_array Description Output type can be a MULTI* or a GEOMETRYCOLLECTION. Comes in 2 variants. Variant 1 collects 2 geometries. Variant 2 is an aggregate function that takes a set of geometries and collects them into a single ST_Geometry. Aggregate version: This function returns a GEOMETRYCOLLECTION or a MULTI object from a set of geometries. The ST_Collect() function is an "aggregate" function in the terminology of PostgreSQL. That means that it operates on rows of data, in the same way the SUM() and AVG() functions do. For example, "SELECT ST_Collect(GEOM) FROM GEOMTABLE GROUP BY ATTRCOLUMN" will return a separate GEOMETRYCOLLECTION for each distinct value of ATTRCOLUMN. Non-Aggregate version: This function returns a geometry being a collection of two input geometries. Output type can be a MULTI* or a GEOMETRYCOLLECTION. ST_Collect and ST_Union are often interchangeable. ST_Collect is in general orders of magnitude faster than ST_Union because it does not try to dissolve boundaries or validate that a constructed MultiPolgon doesn't have overlapping regions. It merely rolls up single geometries into MULTI and MULTI or mixed geometry types into Geometry Collections. Unfortunately geometry collections are not well-supported by GIS tools. To prevent ST_Collect from returning a Geometry Collection when collecting MULTI geometries, one can use the below trick that utilizes to expand the MULTIs out to singles and then regroup them. Availability: 1.4.0 - ST_Collect(geomarray) was introduced. ST_Collect was enhanced to handle more geometries faster. This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves, but will never return a MULTICURVE or MULTI as one would expect and PostGIS does not currently support those. Examples Aggregate example Thread ref: http://postgis.refractions.net/pipermail/postgis-users/2008-June/020331.html SELECT stusps, ST_Multi(ST_Collect(f.the_geom)) as singlegeom FROM (SELECT stusps, (ST_Dump(the_geom)).geom As the_geom FROM somestatetable ) As f GROUP BY stusps Non-Aggregate example Thread ref: http://postgis.refractions.net/pipermail/postgis-users/2008-June/020331.html SELECT ST_AsText(ST_Collect(ST_GeomFromText('POINT(1 2)'), ST_GeomFromText('POINT(-2 3)') )); st_astext ---------- MULTIPOINT(1 2,-2 3) --Collect 2 d points SELECT ST_AsText(ST_Collect(ST_GeomFromText('POINT(1 2)'), ST_GeomFromText('POINT(1 2)') ) ); st_astext ---------- MULTIPOINT(1 2,1 2) --Collect 3d points SELECT ST_AsEWKT(ST_Collect(ST_GeomFromEWKT('POINT(1 2 3)'), ST_GeomFromEWKT('POINT(1 2 4)') ) ); st_asewkt ------------------------- MULTIPOINT(1 2 3,1 2 4) --Example with curves SELECT ST_AsText(ST_Collect(ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)'), ST_GeomFromText('CIRCULARSTRING(220227 150406,2220227 150407,220227 150406)'))); st_astext ------------------------------------------------------------------------------------ GEOMETRYCOLLECTION(CIRCULARSTRING(220268 150415,220227 150505,220227 150406), CIRCULARSTRING(220227 150406,2220227 150407,220227 150406)) --New ST_Collect array construct SELECT ST_Collect(ARRAY(SELECT the_geom FROM sometable)); SELECT ST_AsText(ST_Collect(ARRAY[ST_GeomFromText('LINESTRING(1 2, 3 4)'), ST_GeomFromText('LINESTRING(3 4, 4 5)')])) As wktcollect; --wkt collect -- MULTILINESTRING((1 2,3 4),(3 4,4 5)) See Also , ST_ConvexHull The convex hull of a geometry represents the minimum convex geometry that encloses all geometries within the set. geometry ST_ConvexHull geometry geomA Description The convex hull of a geometry represents the minimum convex geometry that encloses all geometries within the set. One can think of the convex hull as the geometry you get by wrapping an elastic band around a set of geometries. This is different from a concave hull (not currently supported) which is analogous to shrink-wrapping your geometries. It is usually used with MULTI and Geometry Collections. Although it is not an aggregate - you can use it in conjunction with ST_Collect to get the convex hull of a set of points. ST_ConvexHull(ST_Collect(somepointfield)). It is often used to determine an affected area based on a set of point observations. Performed by the GEOS module This method implements the OpenGIS Simple Features Implementation Specification for SQL OGC SPEC s2.1.1.3 This function supports 3d and will not drop the z-index. This method implements the SQL/MM specification: SQL-MM 3: 5.1.16 Examples SELECT d.disease_type, ST_ConvexHull(ST_Collect(d.the_geom)) As the_geom FROM disease_obs As d GROUP BY d.disease_type; SELECT ST_AsEWKT(ST_ConvexHull( ST_Collect( ST_GeomFromEWKT('LINESTRING(1 2 3,3 4 5)'), ST_MakePoint(0, 2, 0)) )); ---st_asewkt-- POLYGON((0 2 0,3 4 5,1 2 3,0 2 0)) See Also ST_CurveToLine Converts a CIRCULARSTRING/CURVEDPOLYGON to a LINESTRING/POLYGON geometry ST_CurveToLine geometry curveGeom geometry ST_CurveToLine geometry curveGeom integer segments_per_qtr_circle Description Converst a CIRCULAR STRING to regular LINESTRING or CURVEPOLYGON to POLYGON. Useful for outputting to devices that can't support CIRCULARSTRING geometry types Converts a given geometry to a linear geometry. Each curved geometry or segment is converted into a linear approximation using the default value of 32 segments per quarter circle Availability: 1.2.2? This method implements the OpenGIS Simple Features Implementation Specification for SQL. This method implements the SQL/MM specification: SQL-MM 3: 7.1.7 This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsText(ST_CurveToLine(ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)'))); --Result -- LINESTRING(220268 150415,220269.95064912 150416.539364228,220271.823415575 150418.17258804,220273.613787707 150419.895736857, 220275.317452352 150421.704659462,220276.930305234 150423.594998003,220278.448460847 150425.562198489, 220279.868261823 150427.60152176,220281.186287736 150429.708054909,220282.399363347 150431.876723113, 220283.50456625 150434.10230186,220284.499233914 150436.379429536,220285.380970099 150438.702620341,220286.147650624 150441.066277505, 220286.797428488 150443.464706771,220287.328738321 150445.892130112,220287.740300149 150448.342699654, 220288.031122486 150450.810511759,220288.200504713 150453.289621251,220288.248038775 150455.77405574, 220288.173610157 150458.257830005,220287.977398166 150460.734960415,220287.659875492 150463.199479347, 220287.221807076 150465.64544956,220286.664248262 150468.066978495,220285.988542259 150470.458232479,220285.196316903 150472.81345077, 220284.289480732 150475.126959442,220283.270218395 150477.39318505,220282.140985384 150479.606668057, 220280.90450212 150481.762075989,220279.5637474 150483.85421628,220278.12195122 150485.87804878, 220276.582586992 150487.828697901,220274.949363179 150489.701464356,220273.226214362 150491.491836488, 220271.417291757 150493.195501133,220269.526953216 150494.808354014,220267.559752731 150496.326509628, 220265.520429459 150497.746310603,220263.41389631 150499.064336517,220261.245228106 150500.277412127, 220259.019649359 150501.38261503,220256.742521683 150502.377282695,220254.419330878 150503.259018879, 220252.055673714 150504.025699404,220249.657244448 150504.675477269,220247.229821107 150505.206787101, 220244.779251566 150505.61834893,220242.311439461 150505.909171266,220239.832329968 150506.078553494, 220237.347895479 150506.126087555,220234.864121215 150506.051658938,220232.386990804 150505.855446946, 220229.922471872 150505.537924272,220227.47650166 150505.099855856,220225.054972724 150504.542297043, 220222.663718741 150503.86659104,220220.308500449 150503.074365683, 220217.994991777 150502.167529512,220215.72876617 150501.148267175, 220213.515283163 150500.019034164,220211.35987523 150498.7825509, 220209.267734939 150497.441796181,220207.243902439 150496, 220205.293253319 150494.460635772,220203.420486864 150492.82741196,220201.630114732 150491.104263143, 220199.926450087 150489.295340538,220198.313597205 150487.405001997,220196.795441592 150485.437801511, 220195.375640616 150483.39847824,220194.057614703 150481.291945091,220192.844539092 150479.123276887,220191.739336189 150476.89769814, 220190.744668525 150474.620570464,220189.86293234 150472.297379659,220189.096251815 150469.933722495, 220188.446473951 150467.535293229,220187.915164118 150465.107869888,220187.50360229 150462.657300346, 220187.212779953 150460.189488241,220187.043397726 150457.710378749,220186.995863664 150455.22594426, 220187.070292282 150452.742169995,220187.266504273 150450.265039585,220187.584026947 150447.800520653, 220188.022095363 150445.35455044,220188.579654177 150442.933021505,220189.25536018 150440.541767521, 220190.047585536 150438.18654923,220190.954421707 150435.873040558,220191.973684044 150433.60681495, 220193.102917055 150431.393331943,220194.339400319 150429.237924011,220195.680155039 150427.14578372,220197.12195122 150425.12195122, 220198.661315447 150423.171302099,220200.29453926 150421.298535644,220202.017688077 150419.508163512,220203.826610682 150417.804498867, 220205.716949223 150416.191645986,220207.684149708 150414.673490372,220209.72347298 150413.253689397,220211.830006129 150411.935663483, 220213.998674333 150410.722587873,220216.22425308 150409.61738497,220218.501380756 150408.622717305,220220.824571561 150407.740981121, 220223.188228725 150406.974300596,220225.586657991 150406.324522731,220227 150406) --3d example SELECT ST_AsEWKT(ST_CurveToLine(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)'))); Output ------ LINESTRING(220268 150415 1,220269.95064912 150416.539364228 1.0181172856673, 220271.823415575 150418.17258804 1.03623457133459,220273.613787707 150419.895736857 1.05435185700189,....AD INFINITUM .... 220225.586657991 150406.324522731 1.32611114201132,220227 150406 3) --use only 2 segments to approximate quarter circle SELECT ST_AsText(ST_CurveToLine(ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)'),2)); st_astext ------------------------------ LINESTRING(220268 150415,220287.740300149 150448.342699654,220278.12195122 150485.87804878, 220244.779251566 150505.61834893,220207.243902439 150496,220187.50360229 150462.657300346, 220197.12195122 150425.12195122,220227 150406) See Also ST_Difference Returns a geometry that represents that part of geometry A that does not intersect with geometry B. geometry ST_Difference geometry geomA geometry geomB Description Returns a geometry that represents that part of geometry A that does not intersect with geometry B. One can think of this as GeometryA - ST_Intersection(A,B). If A is completely contained in B then an empty geometry collection is returned. Note - order matters. B - A will always return a portion of B Performed by the GEOS module Do not call with a GeometryCollection as an argument This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.20 This function supports 3d and will not drop the z-index. However it seems to only consider x y when doing the difference and tacks back on the Z-Index Examples --Safe for 2d SELECT ST_AsText(ST_Difference(ST_GeomFromText('LINESTRING(1 2, 1 4)'), ST_GeomFromText('LINESTRING(1 2, 1 3)'))) st_astext --------- LINESTRING(1 3,1 4) --When used in 3d doesn't quite do the right thing SELECT ST_AsEWKT(ST_Difference(ST_GeomFromEWKT('MULTIPOINT(-118.58 38.38 5,-118.60 38.329 6,-118.614 38.281 7)'), ST_GeomFromEWKT('POINT(-118.614 38.281 5)'))); st_asewkt --------- MULTIPOINT(-118.6 38.329 6,-118.58 38.38 5) See Also ST_Dump Returns a set of geometry_dump (geom,path) rows, that make up a geometry g1. geometry_dump[]ST_Dump geometry g1 Description This is a set-returning function (SRF). It returns a set of geometry_dump rows, formed by a geometry (geom) and an array of integers (path). When the input geometry is a simple type (POINT,LINESTRING,POLYGON) a single record will be returned with an empty path array and the input geometry as geom. When the input geometry is a collection or multi it will return a record for each of the collection components, and the path will express the position of the component inside the collection. ST_Dump is useful for expanding geometries. It is the reverse of a GROUP BY in that it creates new rows. For example it can be use to expand MULTIPOLYGONS into POLYGONS. Availability: PostGIS 1.0.0RC1. Requires PostgreSQL 7.3 or higher. Prior to 1.3.4, this function crashes if used with geometries that contain CURVES. This is fixed in 1.3.4+ This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT sometable.field1, sometable.field1, (ST_Dump(sometable.the_geom)).geom As the_geom FROM sometable See Also ST_DumpRings Returns a set of geometry_dump rows, representing the exterior and interior rings of a polygon. geometry_dump[] ST_DumpRings geometry a_polygon Description This is a set-returning function (SRF). It returns a set of geometry_dump rows, defined as an integer[] and a geometry, aliased "path" and "geom" respectively. The "path" field holds the polygon ring index containing a single integer: 0 for the shell, >0 for holes. The "geom" field contains the corresponding ring as a polygon. Availability: PostGIS 1.1.3. Requires PostgreSQL 7.3 or higher. This only works for POLYGON geometries. It will not work for MULTIPOLYGONS This function supports 3d and will not drop the z-index. Examples SELECT sometable.field1, sometable.field1, (ST_DumpRings(sometable.the_geom)).geom As the_geom FROM sometableOfpolys; SELECT ST_AsEWKT(geom) As the_geom, path FROM ST_DumpRings( ST_GeomFromEWKT('POLYGON((-8149064 5133092 1,-8149064 5132986 1,-8148996 5132839 1,-8148972 5132767 1,-8148958 5132508 1,-8148941 5132466 1,-8148924 5132394 1, -8148903 5132210 1,-8148930 5131967 1,-8148992 5131978 1,-8149237 5132093 1,-8149404 5132211 1,-8149647 5132310 1,-8149757 5132394 1, -8150305 5132788 1,-8149064 5133092 1), (-8149362 5132394 1,-8149446 5132501 1,-8149548 5132597 1,-8149695 5132675 1,-8149362 5132394 1))') ) as foo; path | the_geom ---------------------------------------------------------------------------------------------------------------- {0} | POLYGON((-8149064 5133092 1,-8149064 5132986 1,-8148996 5132839 1,-8148972 5132767 1,-8148958 5132508 1, | -8148941 5132466 1,-8148924 5132394 1, | -8148903 5132210 1,-8148930 5131967 1, | -8148992 5131978 1,-8149237 5132093 1, | -8149404 5132211 1,-8149647 5132310 1,-8149757 5132394 1,-8150305 5132788 1,-8149064 5133092 1)) {1} | POLYGON((-8149362 5132394 1,-8149446 5132501 1, | -8149548 5132597 1,-8149695 5132675 1,-8149362 5132394 1)) See Also , , ST_Intersection Returns a geometry that represents the shared portion of geomA and geomB geometry ST_Intersection geometry geomA geometry geomB Description Returns a geometry that represents the point set intersection of the Geometries. In other words - that portion of geometry A and geometry B that is shared between the two geometries. If the geometries do not share any space (are disjoint), then an empty geometry collection is returned. ST_Intersection in conjunction with ST_Intersects is very useful for clipping geometries such as in bounding box, buffer, region queries where you only want to return that portion of a geometry that sits in a country or region of interest. Do not call with a GEOMETRYCOLLECTION as an argument Performed by the GEOS module This method implements the OpenGIS Simple Features Implementation Specification for SQL OGC SPEC s2.1.1.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.18 Examples SELECT ST_AsText(ST_Intersection('POINT(0 0)'::geometry, 'LINESTRING ( 2 0, 0 2 )'::geometry)); st_astext --------------- GEOMETRYCOLLECTION EMPTY (1 row) SELECT ST_AsText(ST_Intersection('POINT(0 0)'::geometry, 'LINESTRING ( 0 0, 0 2 )'::geometry)); st_astext --------------- POINT(0 0) (1 row) ---Clip all lines (trails) by country (here we assume country geom are POLYGON or MULTIPOLYGONS) -- NOTE: we are only keeping intersections that result in a LINESTRING or MULTILINESTRING because we don't -- care about trails that just share a point -- the dump is needed to expand a geometry collection into individual single MULT* parts -- the below is fairly generic and will work for polys, etc. by just changing the where clause SELECT clipped.gid, clipped.f_name, clipped_geom FROM (SELECT trails.gid, trails.f_name, (ST_Dump(ST_Intersection(country.the_geom, trails.the_geom))).geom As clipped_geom FROM country INNER JOIN trails ON ST_Intersects(country.the_geom, trails.the_geom)) As clipped WHERE ST_Dimension(clipped.clipped_geom) = 1 ; --For polys e.g. polygon landmarks, you can also use the sometimes faster hack that buffering anything by 0.0 -- except a polygon results in an empty geometry collection --(so a geometry collection containing polys, lines and points) -- buffered by 0.0 would only leave the polygons and dissolve the collection shell SELECT poly.gid, ST_Multi(ST_Buffer( ST_Intersection(country.the_geom, poly.the_geom), 0.0) ) As clipped_geom FROM country INNER JOIN poly ON ST_Intersects(country.the_geom, poly.the_geom) WHERE Not ST_IsEmpty(ST_Buffer(ST_Intersection(country.the_geom, poly.the_geom),0.0)); See Also , , , ST_LineToCurve Converts a LINESTRING/POLYGON to a CIRCULARSTRING, CURVED POLYGON geometry ST_LineToCurve geometry geomANoncircular Description Converts plain LINESTRING/POLYGONS to CIRCULAR STRINGs and Curved Polygons. Note much fewer points are needed to describe the curved equivalent. Availability: 1.2.2? This function supports 3d and will not drop the z-index. This method supports Circular Strings and Curves Examples SELECT ST_AsText(ST_LineToCurve(foo.the_geom)) As curvedastext,ST_AsText(foo.the_geom) As non_curvedastext FROM (SELECT ST_Buffer('POINT(1 3)'::geometry, 3) As the_geom) As foo; curvedatext non_curvedastext ------------------------------------------------------------------| ----------------------------------------------------------------- CURVEPOLYGON(CIRCULARSTRING(4 3,3.12132034355964 0.878679656440359, | POLYGON((4 3,3.94235584120969 2.41472903395162,3.77163859753386 1.85194970290473 1 0,-1.12132034355965 5.12132034355963,4 3)) | ,3.49440883690764 1.33328930094119,3.12132034355964 0.878679656440359, | 2.66671069905881 0.505591163092366,2.14805029709527 0.228361402466141, | 1.58527096604839 0.0576441587903094,1 0, | 0.414729033951621 0.0576441587903077,-0.148050297095264 0.228361402466137, | -0.666710699058802 0.505591163092361,-1.12132034355964 0.878679656440353, | -1.49440883690763 1.33328930094119,-1.77163859753386 1.85194970290472 | --ETC-- ,3.94235584120969 3.58527096604839,4 3)) --3D example SELECT ST_AsEWKT(ST_LineToCurve(ST_GeomFromEWKT('LINESTRING(1 2 3, 3 4 8, 5 6 4, 7 8 4, 9 10 4)'))); st_asewkt ------------------------------------ CIRCULARSTRING(1 2 3,5 6 4,9 10 4) See Also ST_MemUnion Same as ST_Union, only memory-friendly (uses less memory and more processor time). geometry ST_MemUnion geometry set geomfield Description Some useful description here. Same as ST_Union, only memory-friendly (uses less memory and more processor time). This aggregate function works by unioning the geometries one at a time to previous result as opposed to ST_Union aggregate which first creates an array and then unions This function supports 3d and will not drop the z-index, but sometimes does strange things with 3d. Examples See ST_Union See Also ST_MinimumBoundingCircle Returns the smallest circle polygon that can fully contain a geometry. Default uses 48 segments per quarter circle. geometry ST_MinimumBoundingCircle geometry geomA geometry ST_MinimumBoundingCircle geometry geomA integer num_segs_per_qt_circ Description Returns the smallest circle polygon that can fully contain a geometry. The circle is approximated by a polygon with a default of 48 segments per quarter circle. This number can be increased with little performance penalty to obtain a more accurate result. It is often used with MULTI and Geometry Collections. Although it is not an aggregate - you can use it in conjunction with ST_Collect to get the minimum bounding cirlce of a set of geometries. ST_MinimumBoundingCircle(ST_Collect(somepointfield)). The ratio of the area of a polygon divided by the area of its Minimum Bounding Circle is often referred to as the Roeck test. Availability: 1.4.0 - requires GEOS Examples SELECT d.disease_type, ST_MinimumBoundingCircle(ST_Collect(d.the_geom)) As the_geom FROM disease_obs As d GROUP BY d.disease_type; --Only use 8 segs to approximate a quarter circle SELECT ST_AsText(ST_MinimumBoundingCircle( ST_Collect( ST_GeomFromEWKT('LINESTRING(1 2,3 4)'), ST_MakePoint(0, 2)), 8 )) As wktmbc; wktmbc ----------- POLYGON((3.30277563773199 3,3.26813580935709 2.64829592031203,3.16554751341057 2.31010763116856, 2.9989531605735 1.99843151886317,2.7747548783982 1.7252451216018,2.50156848113683 1.50104683942651, 2.18989236883145 1.33445248658943,1.85170407968797 1.23186419064291,1.5 1.19722436226801, 1.14829592031204 1.23186419064291,0.81010763116856 1.33445248658943,0.498431518863177 1.5010468394265, 0.225245121601807 1.7252451216018,0.00104683942650734 1.99843151886317,-0.16554751341057 2.31010763116855, -0.268135809357086 2.64829592031203,-0.302775637731995 2.99999999999999,-0.268135809357088 3.35170407968796, -0.165547513410575 3.68989236883144,0.00104683942650074 4.00156848113682,0.225245121601799 4.27475487839819, 0.498431518863167 4.49895316057349,0.81010763116855 4.66554751341057,1.14829592031203 4.76813580935709, 1.49999999999999 4.80277563773199,1.85170407968796 4.76813580935709,2.18989236883144 4.66554751341057, 2.50156848113682 4.4989531605735,2.77475487839819 4.2747548783982,2.99895316057349 4.00156848113683, 3.16554751341057 3.68989236883145,3.26813580935709 3.35170407968797,3.30277563773199 3)) See Also , ST_Polygonize Aggregate. Creates a GeometryCollection containing possible polygons formed from the constituent linework of a set of geometries. geometry ST_Polygonize geometry set geomfield Description Creates a GeometryCollection containing possible polygons formed from the constituent linework of a set of geometries. Geometry Collections are often difficult to deal with with third party tools, so use ST_Polygonize in conjunction with to dump the polygons out into individual polygons. Availability: 1.0.0RC1 - requires GEOS >= 2.1.0. Examples: Polygonizing single linestrings SELECT ST_AsEWKT(ST_Polygonize(the_geom_4269)) As geomtextrep FROM (SELECT the_geom_4269 FROM ma.suffolk_edges ORDER BY tlid LIMIT 45) As foo; geomtextrep ------------------------------------- SRID=4269;GEOMETRYCOLLECTION(POLYGON((-71.040878 42.285678,-71.040943 42.2856,-71.04096 42.285752,-71.040878 42.285678)), POLYGON((-71.17166 42.353675,-71.172026 42.354044,-71.17239 42.354358,-71.171794 42.354971,-71.170511 42.354855, -71.17112 42.354238,-71.17166 42.353675))) (1 row) --Use ST_Dump to dump out the polygonize geoms into individual polygons SELECT ST_AsEWKT((ST_Dump(foofoo.polycoll)).geom) As geomtextrep FROM (SELECT ST_Polygonize(the_geom_4269) As polycoll FROM (SELECT the_geom_4269 FROM ma.suffolk_edges ORDER BY tlid LIMIT 45) As foo) As foofoo; geomtextrep ------------------------ SRID=4269;POLYGON((-71.040878 42.285678,-71.040943 42.2856,-71.04096 42.285752, -71.040878 42.285678)) SRID=4269;POLYGON((-71.17166 42.353675,-71.172026 42.354044,-71.17239 42.354358 ,-71.171794 42.354971,-71.170511 42.354855,-71.17112 42.354238,-71.17166 42.353675)) (2 rows) See Also ST_Shift_Longitude Reads every point/vertex in every component of every feature in a geometry, and if the longitude coordinate is <0, adds 360 to it. The result would be a 0-360 version of the data to be plotted in a 180 centric map geometry ST_Shift_Longitude geometry geomA Description Reads every point/vertex in every component of every feature in a geometry, and if the longitude coordinate is <0, adds 360 to it. The result would be a 0-360 version of the data to be plotted in a 180 centric map This is only useful for data in long lat e.g. 4326 (WGS 84 long lat) Pre-1.3.4 bug prevented this from working for MULTIPOINT. 1.3.4+ works with MULTIPOINT as well. This function supports 3d and will not drop the z-index. Examples --3d points SELECT ST_AsEWKT(ST_Shift_Longitude(ST_GeomFromEWKT('SRID=4326;POINT(-118.58 38.38 10)'))) As geomA, ST_AsEWKT(ST_Shift_Longitude(ST_GeomFromEWKT('SRID=4326;POINT(241.42 38.38 10)'))) As geomb geomA geomB ---------- ----------- SRID=4326;POINT(241.42 38.38 10) SRID=4326;POINT(-118.58 38.38 10) --regular line string SELECT ST_AsText(ST_Shift_Longitude(ST_GeomFromText('LINESTRING(-118.58 38.38, -118.20 38.45)'))) st_astext ---------- LINESTRING(241.42 38.38,241.8 38.45) See Also , , ST_Simplify Returns a "simplified" version of the given geometry using the Douglas-Peuker algorithm. geometry ST_Simplify geometry geomA float tolerance Description Returns a "simplified" version of the given geometry using the Douglas-Peuker algorithm. Will actually do something only with (multi)lines and (multi)polygons but you can safely call it with any kind of geometry. Since simplification occurs on a object-by-object basis you can also feed a GeometryCollection to this function. Note that returned geometry might loose its simplicity (see ) Note topology may not be preserved and may result in invalid geometries. Use (see ) to preserve topology. Performed by the GEOS module. Availability: 1.2.2 Examples A circle simplified too much becomes a triangle, medium an octagon, SELECT ST_Npoints(the_geom) As np_before, ST_NPoints(ST_Simplify(the_geom,0.1)) As np01_notbadcircle, ST_NPoints(ST_Simplify(the_geom,0.5)) As np05_notquitecircle, ST_NPoints(ST_Simplify(the_geom,1)) As np1_octagon, ST_NPoints(ST_Simplify(the_geom,10)) As np10_triangle, (ST_Simplify(the_geom,100) is null) As np100_geometrygoesaway FROM (SELECT ST_Buffer('POINT(1 3)', 10,12) As the_geom) As foo; -result np_before | np01_notbadcircle | np05_notquitecircle | np1_octagon | np10_triangle | np100_geometrygoesaway -----------+-------------------+---------------------+-------------+---------------+------------------------ 49 | 33 | 17 | 9 | 4 | t See Also , ST_SimplifyPreserveTopology Returns a "simplified" version of the given geometry using the Douglas-Peuker algorithm. Will avoid creating derived geometries (polygons in particular) that are invalid. geometry ST_SimplifyPreserveTopology geometry geomA float tolerance Description Returns a "simplified" version of the given geometry using the Douglas-Peuker algorithm. Will avoid creating derived geometries (polygons in particular) that are invalid. Will actually do something only with (multi)lines and (multi)polygons but you can safely call it with any kind of geometry. Since simplification occurs on a object-by-object basis you can also feed a GeometryCollection to this function. Performed by the GEOS module. Requires GEOS 3.0.0+ Availability: 1.3.3 Examples Same example as Simplify, but we see Preserve Topology prevents oversimplification. The circle can at most become a square. SELECT ST_Npoints(the_geom) As np_before, ST_NPoints(ST_SimplifyPreserveTopology(the_geom,0.1)) As np01_notbadcircle, ST_NPoints(ST_SimplifyPreserveTopology(the_geom,0.5)) As np05_notquitecircle, ST_NPoints(ST_SimplifyPreserveTopology(the_geom,1)) As np1_octagon, ST_NPoints(ST_SimplifyPreserveTopology(the_geom,10)) As np10_square, ST_NPoints(ST_SimplifyPreserveTopology(the_geom,100)) As np100_stillsquare FROM (SELECT ST_Buffer('POINT(1 3)', 10,12) As the_geom) As foo; --result-- np_before | np01_notbadcircle | np05_notquitecircle | np1_octagon | np10_square | np100_stillsquare -----------+-------------------+---------------------+-------------+---------------+------------------- 49 | 33 | 17 | 9 | 5 | 5 See Also ST_SymDifference Returns a geometry that represents the portions of A and B that do not intersect. It is called a symmetric difference because ST_SymDifference(A,B) = ST_SymDifference(B,A). geometry ST_SymDifference geometry geomA geometry geomB Description Returns a geometry that represents the portions of A and B that do not intersect. It is called a symmetric difference because ST_SymDifference(A,B) = ST_SymDifference(B,A). One can think of this as ST_Union(geomA,geomB) - ST_Intersection(A,B). Performed by the GEOS module Do not call with a GeometryCollection as an argument This method implements the OpenGIS Simple Features Implementation Specification for SQL. OGC SPEC s2.1.1.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.21 This function supports 3d and will not drop the z-index. However it seems to only consider x y when doing the difference and tacks back on the Z-Index Examples --Safe for 2d SELECT ST_AsText(ST_SymDifference(ST_GeomFromText('LINESTRING(1 2, 1 4)'), ST_GeomFromText('LINESTRING(1 1, 1 3)'))) st_astext --------- MULTILINESTRING((1 3,1 4),(1 1,1 2)) --When used in 3d doesn't quite do the right thing SELECT ST_AsEWKT(ST_SymDifference(ST_GeomFromEWKT('LINESTRING(1 2 1, 1 4 2)'), ST_GeomFromEWKT('LINESTRING(1 1 3, 1 3 4)'))) st_astext ------------ MULTILINESTRING((1 3 2.75,1 4 2),(1 1 3,1 2 2.25)) See Also ST_Union Returns a geometry that represents the point set union of the Geometries. geometry ST_Union geometry set g1field geometry ST_Union geometry g1 geometry g2 geometry ST_Union geometry[] g1_array Description Output type can be a MULTI* , single geometry, or Geometry Collection. Comes in 2 variants. Variant 1 unions 2 geometries resulting in a new geomety with no intersecting regions. Variant 2 is an aggregate function that takes a set of geometries and unions them into a single ST_Geometry resulting in no intersecting regions. Aggregate version: This function returns a MULTI geometry or NON-MULTI geometry from a set of geometries. The ST_Union() function is an "aggregate" function in the terminology of PostgreSQL. That means that it operates on rows of data, in the same way the SUM() and AVG() functions do. Non-Aggregate version: This function returns a geometry being a union of two input geometries. Output type can be a MULTI* ,NON-MULTI or GEOMETRYCOLLECTION. ST_Collect and ST_Union are often interchangeable. ST_Union is in general orders of magnitude slower than ST_Collect because it tries to dissolve boundaries and reorder geometries to ensure that a constructed Multi* doesn't have intersecting regions. Performed by the GEOS module. NOTE: this function was formerly called GeomUnion(), which was renamed from "Union" because UNION is an SQL reserved word. Availability: 1.4.0 - ST_Union was enhanced. ST_Union(geomarray) was introduced and also faster aggregate collection in PostgreSQL. If you are using GEOS 3.1.0+ ST_Union will use the faster Cascaded Union algorithm described in http://blog.cleverelephant.ca/2009/01/must-faster-unions-in-postgis-14.html This method implements the OpenGIS Simple Features Implementation Specification for SQL: OGC SPEC s2.1.1.3 This method implements the SQL/MM specification: SQL-MM 3: 5.1.19 Aggregate version is not explicitly defined in OGC SPEC. This function supports 3d and will not drop the z-index, but sometimes does something goofy with the z-index (elevation) when polygons are involved. Examples Aggregate example SELECT stusps, ST_Multi(ST_Union(f.the_geom)) as singlegeom FROM sometable As f GROUP BY stusps Non-Aggregate example SELECT ST_AsText(ST_Union(ST_GeomFromText('POINT(1 2)'), ST_GeomFromText('POINT(-2 3)') ) ) st_astext ---------- MULTIPOINT(-2 3,1 2) SELECT ST_AsText(ST_Union(ST_GeomFromText('POINT(1 2)'), ST_GeomFromText('POINT(1 2)') ) ); st_astext ---------- POINT(1 2) --3d example - sort of supports 3d (and with mixed dimensions!) SELECT ST_AsEWKT(st_union(the_geom)) FROM (SELECT ST_GeomFromEWKT('POLYGON((-7 4.2,-7.1 4.2,-7.1 4.3, -7 4.2))') as the_geom UNION ALL SELECT ST_GeomFromEWKT('POINT(5 5 5)') as the_geom UNION ALL SELECT ST_GeomFromEWKT('POINT(-2 3 1)') as the_geom UNION ALL SELECT ST_GeomFromEWKT('LINESTRING(5 5 5, 10 10 10)') as the_geom ) as foo; st_asewkt --------- GEOMETRYCOLLECTION(POINT(-2 3 1),LINESTRING(5 5 5,10 10 10),POLYGON((-7 4.2 5,-7.1 4.2 5,-7.1 4.3 5,-7 4.2 5))); --3d example not mixing dimensions SELECT ST_AsEWKT(st_union(the_geom)) FROM (SELECT ST_GeomFromEWKT('POLYGON((-7 4.2 2,-7.1 4.2 3,-7.1 4.3 2, -7 4.2 2))') as the_geom UNION ALL SELECT ST_GeomFromEWKT('POINT(5 5 5)') as the_geom UNION ALL SELECT ST_GeomFromEWKT('POINT(-2 3 1)') as the_geom UNION ALL SELECT ST_GeomFromEWKT('LINESTRING(5 5 5, 10 10 10)') as the_geom ) as foo; st_asewkt --------- GEOMETRYCOLLECTION(POINT(-2 3 1),LINESTRING(5 5 5,10 10 10),POLYGON((-7 4.2 2,-7.1 4.2 3,-7.1 4.3 2,-7 4.2 2))) --Examples using new Array construct SELECT ST_Union(ARRAY(SELECT the_geom FROM sometable)); SELECT ST_AsText(ST_Union(ARRAY[ST_GeomFromText('LINESTRING(1 2, 3 4)'), ST_GeomFromText('LINESTRING(3 4, 4 5)')])) As wktunion; --wktunion--- MULTILINESTRING((3 4,4 5),(1 2,3 4)) See Also Linear Referencing ST_Line_Interpolate_Point Returns a point interpolated along a line. Second argument is a float8 between 0 and 1 representing fraction of total length of linestring the point has to be located. geometry ST_Line_Interpolate_Point geometry a_linestring float a_fraction Description Returns a point interpolated along a line. First argument must be a LINESTRING. Second argument is a float8 between 0 and 1 representing fraction of total linestring length the point has to be located. See for computing the line location nearest to a Point. Since release 1.1.1 this function also interpolates M and Z values (when present), while prior releases set them to 0.0. Availability: 0.8.2, Z and M supported added in 1.1.1 This function supports 3d and will not drop the z-index. Examples --Return point mid-way of 2d line SELECT ST_AsEWKT(ST_Line_Interpolate_Point(the_line, 0.5)) FROM (SELECT ST_GeomFromEWKT('LINESTRING(1 2, 4 5, 6 7)') as the_line) As foo; st_asewkt ---------------- POINT(3.5 4.5) --Return point mid-way of 3d line SELECT ST_AsEWKT(ST_Line_Interpolate_Point(the_line, 0.5)) FROM (SELECT ST_GeomFromEWKT('LINESTRING(1 2 3, 4 5 6, 6 7 8)') as the_line) As foo; st_asewkt -------------------- POINT(3.5 4.5 5.5) See Also , ST_Line_Locate_Point Returns a float between 0 and 1 representing the location of the closest point on LineString to the given Point, as a fraction of total 2d line length. float ST_Line_Locate_Point geometry a_linestring geometry a_point Description Returns a float between 0 and 1 representing the location of the closest point on LineString to the given Point, as a fraction of total 2d line length. You can use the returned location to extract a Point () or a substring (). This is useful for approximating numbers of addresses Availability: 1.1.0 Examples --Rough approximation of finding the street number of a point along the street --Note the whole foo thing is just to generate dummy data that looks --like house centroids and street --We use ST_DWithin to exclude --houses too far away from the street to be considered on the street SELECT ST_AsText(house_loc) As as_text_house_loc, startstreet_num + CAST( (endstreet_num - startstreet_num) * ST_Line_Locate_Point(street_line, house_loc) As integer) As street_num FROM (SELECT ST_GeomFromText('LINESTRING(1 2, 3 4)') As street_line, ST_MakePoint(x*1.01,y*1.03) As house_loc, 10 As startstreet_num, 20 As endstreet_num FROM generate_series(1,3) x CROSS JOIN generate_series(2,4) As y) As foo WHERE ST_DWithin(street_line, house_loc, 0.2); as_text_house_loc | street_num -------------------+------------ POINT(1.01 2.06) | 10 POINT(2.02 3.09) | 15 POINT(3.03 4.12) | 20 See Also , , , ST_Line_Substring Return a linestring being a substring of the input one starting and ending at the given fractions of total 2d length. Second and third arguments are float8 values between 0 and 1. geometry ST_Line_Substring geometry a_linestring float startfraction float endfraction Description Return a linestring being a substring of the input one starting and ending at the given fractions of total 2d length. Second and third arguments are float8 values between 0 and 1. This only works with LINESTRINGs. To use with contiguous MULTILINESTRINGs use in conjunction with ST_LineMerge. If 'start' and 'end' have the same value this is equivalent to . See for computing the line location nearest to a Point. Since release 1.1.1 this function also interpolates M and Z values (when present), while prior releases set them to unspecified values. Availability: 1.1.0 , Z and M supported added in 1.1.1 This function supports 3d and will not drop the z-index. Examples --Return the approximate 1/3 mid-range part of a linestring SELECT ST_AsText(ST_Line_SubString(ST_GeomFromText('LINESTRING(748130 2919491, 747979 2919630,747895 2919705)'), 0.333, 0.666)); st_astext ------------------------------------------------------------------------------------------------ LINESTRING(748052.127524758 2919562.68393416,747979 2919630,747974.189261348 2919634.29530237) --The below example simulates a while loop in --SQL using PostgreSQL generate_series() to cut all --linestrings in a table to 100 unit segments -- of which no segment is longer than 100 units -- units are measured in the SRID units of measurement -- It also assumes all geometries are LINESTRING or contiguous MULTILINESTRING --and no geometry is longer than 100 units*10000 --for better performance you can reduce the 10000 --to match max number of segments you expect SELECT field1, field2, ST_Line_Substring(the_geom, 100.00*n/length, CASE WHEN 100.00*(n+1) < length THEN 100.00*(n+1)/length ELSE 1 END) As the_geom FROM (SELECT sometable.field1, sometable.field2, ST_LineMerge(sometable.the_geom) AS the_geom, ST_Length(sometable.the_geom) As length FROM sometable ) AS t CROSS JOIN generate_series(0,10000) AS n WHERE n*100.00/length < 1; See Also , , ST_Locate_Along_Measure Return a derived geometry collection value with elements that match the specified measure. Polygonal elements are not supported. geometry ST_Locate_Along_Measure geometry ageom_with_measure float a_measure Description Return a derived geometry collection value with elements that match the specified measure. Polygonal elements are not supported. Semantic is specified by: ISO/IEC CD 13249-3:200x(E) - Text for Continuation CD Editing Meeting Availability: 1.1.0 Use this function only for geometries with an M component This function supports M coordinate. Examples SELECT ST_AsEWKT(the_geom) FROM (SELECT ST_Locate_Along_Measure( ST_GeomFromEWKT('MULTILINESTRINGM((1 2 3, 3 4 2, 9 4 3), (1 2 3, 5 4 5))'),3) As the_geom) As foo; st_asewkt ----------------------------------------------------------- GEOMETRYCOLLECTIONM(MULTIPOINT(1 2 3,9 4 3),POINT(1 2 3)) --Geometry collections are difficult animals so dump them --to make them more digestable SELECT ST_AsEWKT((ST_Dump(the_geom)).geom) FROM (SELECT ST_Locate_Along_Measure( ST_GeomFromEWKT('MULTILINESTRINGM((1 2 3, 3 4 2, 9 4 3), (1 2 3, 5 4 5))'),3) As the_geom) As foo; st_asewkt --------------- POINTM(1 2 3) POINTM(9 4 3) POINTM(1 2 3) See Also , ST_Locate_Between_Measures Return a derived geometry collection value with elements that match the specified range of measures inclusively. Polygonal elements are not supported. geometry ST_Locate_Between_Measures geometry geomA float measure_start float measure_end Description Return a derived geometry collection value with elements that match the specified range of measures inclusively. Polygonal elements are not supported. Semantic is specified by: ISO/IEC CD 13249-3:200x(E) - Text for Continuation CD Editing Meeting Availability: 1.1.0 This function supports M coordinate. Examples SELECT ST_AsEWKT(the_geom) FROM (SELECT ST_Locate_Between_Measures( ST_GeomFromEWKT('MULTILINESTRINGM((1 2 3, 3 4 2, 9 4 3), (1 2 3, 5 4 5))'),1.5, 3) As the_geom) As foo; st_asewkt ----------------------------------------------------------------- GEOMETRYCOLLECTIONM(LINESTRING(1 2 3,3 4 2,9 4 3),POINT(1 2 3)) --Geometry collections are difficult animals so dump them --to make them more digestable SELECT ST_AsEWKT((ST_Dump(the_geom)).geom) FROM (SELECT ST_Locate_Between_Measures( ST_GeomFromEWKT('MULTILINESTRINGM((1 2 3, 3 4 2, 9 4 3), (1 2 3, 5 4 5))'),1.5, 3) As the_geom) As foo; st_asewkt -------------------------------- LINESTRINGM(1 2 3,3 4 2,9 4 3) POINTM(1 2 3) See Also , ST_LocateBetweenElevations Return a derived geometry (collection) value with elements that intersect the specified range of elevations inclusively. Only 3D, 4D LINESTRINGS and MULTILINESTRINGS are supported. geometry ST_LocateBetweenElevations geometry geom_mline float elevation_start float elevation_end Description Return a derived geometry (collection) value with elements that intersect the specified range of elevations inclusively. Only 3D, 3DM LINESTRINGS and MULTILINESTRINGS are supported. Availability: 1.4.0 This function supports 3d and will not drop the z-index. Examples SELECT ST_AsEWKT(ST_LocateBetweenElevations( ST_GeomFromEWKT('LINESTRING(1 2 3, 4 5 6)'),2,4)) As ewelev; ewelev ---------------------------------------------------------------- MULTILINESTRING((1 2 3,2 3 4)) SELECT ST_AsEWKT(ST_LocateBetweenElevations( ST_GeomFromEWKT('LINESTRING(1 2 6, 4 5 -1, 7 8 9)'),6,9)) As ewelev; ewelev ---------------------------------------------------------------- GEOMETRYCOLLECTION(POINT(1 2 6),LINESTRING(6.1 7.1 6,7 8 9)) --Geometry collections are difficult animals so dump them --to make them more digestable SELECT ST_AsEWKT((ST_Dump(the_geom)).geom) FROM (SELECT ST_LocateBetweenElevations( ST_GeomFromEWKT('LINESTRING(1 2 6, 4 5 -1, 7 8 9)'),6,9) As the_geom) As foo; st_asewkt -------------------------------- POINT(1 2 6) LINESTRING(6.1 7.1 6,7 8 9) See Also Long Transactions Support This module and associated pl/pgsql functions have been implemented to provide long locking support required by Web Feature Service specification. Users must use serializable transaction level otherwise locking mechanism would break. AddAuth Add an authorization token to be used in current transaction. boolean AddAuth text auth_token Description Add an authorization token to be used in current transaction. Creates/adds to a temp table called temp_lock_have_table the current transaction identifier and authorization token key. Availability: 1.1.3 Examples SELECT LockRow('towns', '353', 'priscilla'); BEGIN TRANSACTION; SELECT AddAuth('joey'); UPDATE towns SET the_geom = ST_Translate(the_geom,2,2) WHERE gid = 353; COMMIT; ---Error-- ERROR: UPDATE where "gid" = '353' requires authorization 'priscilla' See Also CheckAuth Creates trigger on a table to prevent/allow updates and deletes of rows based on authorization token. integer CheckAuth text a_schema_name text a_table_name text a_key_column_name integer CheckAuth text a_table_name text a_key_column_name Description Creates trigger on a table to prevent/allow updates and deletes of rows based on authorization token. Identify rows using <rowid_col> column. If a_schema_name is not passed in, then searches for table in current schema. If an authorization trigger already exists on this table function errors. If Transaction support is not enabled, function throws an exception. Availability: 1.1.3 Examples SELECT CheckAuth('public', 'towns', 'gid'); result ------ 0 See Also DisableLongTransactions Disable long transaction support. This function removes the long transaction support metadata tables, and drops all triggers attached to lock-checked tables. text DisableLongTransactions Description Disable long transaction support. This function removes the long transaction support metadata tables, and drops all triggers attached to lock-checked tables. Drops meta table called authorization_table and a view called authorized_tables and all triggers called checkauthtrigger Availability: 1.1.3 Examples SELECT DisableLongTransactions(); --result-- Long transactions support disabled See Also EnableLongTransactions Enable long transaction support. This function creates the required metadata tables, needs to be called once before using the other functions in this section. Calling it twice is harmless. text EnableLongTransactions Description Enable long transaction support. This function creates the required metadata tables, needs to be called once before using the other functions in this section. Calling it twice is harmless. Creates a meta table called authorization_table and a view called authorized_tables Availability: 1.1.3 Examples SELECT EnableLongTransactions(); --result-- Long transactions support enabled See Also LockRow Set lock/authorization for specific row in table integer LockRow text a_schema_name text a_table_name text a_row_key text an_auth_token timestamp expire_dt integer LockRow text a_table_name text a_row_key text an_auth_token timestamp expire_dt integer LockRow text a_table_name text a_row_key text an_auth_token Description Set lock/authorization for specific row in table <authid> is a text value, <expires> is a timestamp defaulting to now()+1hour. Returns 1 if lock has been assigned, 0 otherwise (already locked by other auth) Availability: 1.1.3 Examples SELECT LockRow('public', 'towns', '2', 'joey'); LockRow ------- 1 --Joey has already locked the record and Priscilla is out of luck SELECT LockRow('public', 'towns', '2', 'priscilla'); LockRow ------- 0 See Also UnlockRows Remove all locks held by specified authorization id. Returns the number of locks released. integer UnlockRows text auth_token Description Remove all locks held by specified authorization id. Returns the number of locks released. Availability: 1.1.3 Examples SELECT LockRow('towns', '353', 'priscilla'); SELECT LockRow('towns', '2', 'priscilla'); SELECT UnLockRows('priscilla'); UnLockRows ------------ 2 See Also Miscellaneous Functions ST_Accum Aggregate. Constructs an array of geometries. geometry[] ST_Accum geometry set geomfield Description Aggregate. Constructs an array of geometries. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT (ST_Accum(the_geom)) As all_em, ST_AsText((ST_Accum(the_geom))[1]) As grabone, (ST_Accum(the_geom))[2:4] as grab_rest FROM (SELECT ST_MakePoint(a*CAST(random()*10 As integer), a*CAST(random()*10 As integer), a*CAST(random()*10 As integer)) As the_geom FROM generate_series(1,4) a) As foo; all_em|grabone | grab_rest -------------------------------------------------------------------------------+ {0101000080000000000000144000000000000024400000000000001040: 0101000080000000000 00018400000000000002C400000000000003040: 0101000080000000000000354000000000000038400000000000001840: 010100008000000000000040400000000000003C400000000000003040} | POINT(5 10) | {010100008000000000000018400000000000002C400000000000003040: 0101000080000000000000354000000000000038400000000000001840: 010100008000000000000040400000000000003C400000000000003040} (1 row) See Also ST_Box2D Returns a BOX2D representing the maximum extents of the geometry. box2d ST_Box2D geometry geomA Description Returns a BOX2D representing the maximum extents of the geometry. This method supports Circular Strings and curves Examples SELECT ST_Box2D(ST_GeomFromText('LINESTRING(1 2, 3 4, 5 6)')); st_box2d --------- BOX(1 2,5 6) SELECT ST_Box2D(ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)')); st_box2d -------- BOX(220186.984375 150406,220288.25 150506.140625) See Also , ST_Box3D Returns a BOX3D representing the maximum extents of the geometry. box3d ST_Box3D geometry geomA Description Returns a BOX3D representing the maximum extents of the geometry. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_Box3D(ST_GeomFromEWKT('LINESTRING(1 2 3, 3 4 5, 5 6 5)')); st_box3d --------- BOX3D(1 2 3,5 6 5) SELECT ST_Box3D(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 1,220227 150406 1)')); st_box3d -------- BOX3D(220227 150406 1,220268 150415 1) See Also , ST_Estimated_Extent Return the 'estimated' extent of the given spatial table. The estimated is taken from the geometry column's statistics. The current schema will be used if not specified. box2d ST_Estimated_Extent text schema_name text table_name text geocolumn_name box2d ST_Estimated_Extent text table_name text geocolumn_name Description Return the 'estimated' extent of the given spatial table. The estimated is taken from the geometry column's statistics. The current schema will be used if not specified. For PostgreSQL>=8.0.0 statistics are gathered by VACUUM ANALYZE and resulting extent will be about 95% of the real one. For PostgreSQL<8.0.0 statistics are gathered by update_geometry_stats() and resulting extent will be exact. This method supports Circular Strings and curves Examples SELECT ST_Estimated_extent('ny', 'edges', 'the_geom'); --result-- BOX(-8877653 4912316,-8010225.5 5589284) SELECT ST_Estimated_Extent('feature_poly', 'the_geom'); --result-- BOX(-124.659652709961 24.6830825805664,-67.7798080444336 49.0012092590332) See Also ST_Expand Returns bounding box expanded in all directions from the bounding box of the input geometry geometry ST_Expand geometry g1 float units_to_expand box2d ST_Expand box2d g1 float units_to_expand box3d ST_Expand box3d g1 float units_to_expand Description This function returns a bounding box expanded in all directions from the bounding box of the input geometry, by an amount specified in the second argument. Very useful for distance() queries, or bounding box queries to add an index filter to the query. There are 3 variants of this. The one that takes a geometry will return a POLYGON geometry representation of the bounding box and is the most commonly used variant. ST_Expand is similar in concept to ST_Buffer except while buffer expands the geometry in all directions, ST_Expand expands the bounding box an x,y,z unit amount. Units are in the units of the spatial reference system in use denoted by the SRID Pre 1.3, ST_Expand was used in conjunction with distance to do indexable queries. Something of the form the_geom && ST_Expand('POINT(10 20)', 10) AND ST_Distance(the_geom, 'POINT(10 20)') < 10 Post 1.2, this was replaced with the easier ST_DWithin construct. Bounding boxes of all geometries are currently 2-d even if they are 3-dimensional geometries. Examples Examples below use US National Atlas Equal Area (SRID=2163) which is a meter projection --10 meter expanded box around bbox of a linestring SELECT CAST(ST_Expand(ST_GeomFromText('LINESTRING(2312980 110676,2312923 110701,2312892 110714)', 2163),10) As box2d); st_expand ------------------------------------ BOX(2312882 110666,2312990 110724) --10 meter expanded 3d box of a 3d box SELECT ST_Expand(CAST('BOX3D(778783 2951741 1,794875 2970042.61545891 10)' As box3d),10) st_expand ----------------------------------------------------- BOX3D(778773 2951731 -9,794885 2970052.61545891 20) --10 meter geometry astext rep of a expand box around a point geometry SELECT ST_AsEWKT(ST_Expand(ST_GeomFromEWKT('SRID=2163;POINT(2312980 110676)'),10)); st_asewkt ------------------------------------------------------------------------------------------------- SRID=2163;POLYGON((2312970 110666,2312970 110686,2312990 110686,2312990 110666,2312970 110666)) See Also , , , ,, ST_Extent an aggregate function that returns the bounding box that bounds rows of geometries. box2d ST_Extent geometry set geomfield Description ST_Extent returns a bounding box that encloses a set of geometries. The ST_Extent function is an "aggregate" function in the terminology of SQL. That means that it operates on lists of data, in the same way the SUM() and AVG() functions do. Since it returns a bounding box, the spatial Units are in the units of the spatial reference system in use denoted by the SRID ST_Extent is similar in concept to Oracle Spatial/Locator's SDO_AGGR_MBR Since ST_Extent returns a bounding box, the SRID meta-data is lost. Use ST_SetSRID to force it back into a geometry with SRID meta data. The coordinates are in the units of the spatial ref of the orginal geometries. Bounding boxes of all geometries are currently 2-d even if they are 3-dimensional geometries. Examples Examples below use Massachusetts State Plane ft (SRID=2249) SELECT ST_Extent(the_geom) as bextent FROM sometable; st_bextent ------------------------------------ BOX(739651.875 2908247.25,794875.8125 2970042.75) --Return extent of each category of geometries SELECT ST_Extent(the_geom) as bextent FROM sometable GROUP BY category ORDER BY category; bextent | name ----------------------------------------------------+---------------- BOX(778783.5625 2951741.25,794875.8125 2970042.75) | A BOX(751315.8125 2919164.75,765202.6875 2935417.25) | B BOX(739651.875 2917394.75,756688.375 2935866) | C --Force back into a geometry -- and render the extended text representation of that geometry SELECT ST_SetSRID(ST_Extent(the_geom),2249) as bextent FROM sometable; bextent -------------------------------------------------------------------------------- SRID=2249;POLYGON((739651.875 2908247.25,739651.875 2970042.75,794875.8125 2970042.75, 794875.8125 2908247.25,739651.875 2908247.25)) See Also , , ST_Extent3D an aggregate function that returns the box3D bounding box that bounds rows of geometries. box3d ST_Extent3D geometry set geomfield Description ST_Extent3D returns a box3d (includes Z coordinate) bounding box that encloses a set of geometries. The ST_Extent3D function is an "aggregate" function in the terminology of SQL. That means that it operates on lists of data, in the same way the SUM() and AVG() functions do. Since it returns a bounding box, the spatial Units are in the units of the spatial reference system in use denoted by the SRID Since ST_Extent3D returns a bounding box, the SRID meta-data is lost. Use ST_SetSRID to force it back into a geometry with SRID meta data. The coordinates are in the units of the spatial ref of the orginal geometries. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_Extent3D(foo.the_geom) As b3extent FROM (SELECT ST_MakePoint(x,y,z) As the_geom FROM generate_series(1,3) As x CROSS JOIN generate_series(1,2) As y CROSS JOIN generate_series(0,2) As Z) As foo; b3extent -------------------- BOX3D(1 1 0,3 2 2) --Get the extent of various elevated circular strings SELECT ST_Extent3D(foo.the_geom) As b3extent FROM (SELECT ST_Translate(ST_Force_3DZ(ST_LineToCurve(ST_Buffer(ST_MakePoint(x,y),1))),0,0,z) As the_geom FROM generate_series(1,3) As x CROSS JOIN generate_series(1,2) As y CROSS JOIN generate_series(0,2) As Z) As foo; b3extent -------------------- BOX3D(1 0 0,4 2 2) See Also , Find_SRID The syntax is find_srid(<db/schema>, <table>, <column>) and the function returns the integer SRID of the specified column by searching through the GEOMETRY_COLUMNS table. integer Find_SRID varchar a_schema_name varchar a_table_name varchar a_geomfield_name Description The syntax is find_srid(<db/schema>, <table>, <column>) 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. Examples SELECT Find_SRID('public', 'tiger_us_state_2007', 'the_geom_4269'); find_srid ---------- 4269 See Also ST_Mem_Size Returns the amount of space (in bytes) the geometry takes. integer ST_Mem_Size geometry geomA Description Returns the amount of space (in bytes) the geometry takes. This is a nice compliment to PostgreSQL built in functions pg_size_pretty, pg_relation_size, pg_total_relation_size. pg_relation_size which gives the byte size of a table may return byte size lower than ST_Mem_Size. This is because pg_relation_size does not add toasted table contribution and large geometries are stored in TOAST tables. pg_total_relation_size - includes, the table, the toasted tables, and the indexes. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples --Return how much byte space Boston takes up in our Mass data set SELECT pg_size_pretty(SUM(ST_Mem_Size(the_geom))) as totgeomsum, pg_size_pretty(SUM(CASE WHEN town = 'BOSTON' THEN st_mem_size(the_geom) ELSE 0 END)) As bossum, CAST(SUM(CASE WHEN town = 'BOSTON' THEN st_mem_size(the_geom) ELSE 0 END)*1.00 / SUM(st_mem_size(the_geom))*100 As numeric(10,2)) As perbos FROM towns; totgeomsum bossum perbos ---------- ------ ------ 1522 kB 30 kB 1.99 SELECT ST_Mem_Size(ST_GeomFromText('CIRCULARSTRING(220268 150415,220227 150505,220227 150406)')); --- 73 --What percentage of our table is taken up by just the geometry SELECT pg_total_relation_size('public.neighborhoods') As fulltable_size, sum(ST_Mem_Size(the_geom)) As geomsize, sum(ST_Mem_Size(the_geom))*1.00/pg_total_relation_size('public.neighborhoods')*100 As pergeom FROM neighborhoods; fulltable_size geomsize pergeom ------------------------------------------------ 262144 96238 36.71188354492187500000 See Also ST_Point_Inside_Circle Is the point geometry insert circle defined by center_x, center_y , radius boolean ST_Point_Inside_Circle geometry a_point float center_x float center_y float radius Description The syntax for this functions is point_inside_circle(<geometry>,<circle_center_x>,<circle_center_y>,<radius>). Returns the true if the geometry is a point and is inside the circle. Returns false otherwise. This only works for points as the name suggests Examples SELECT ST_Point_Inside_Circle(ST_Point(1,2), 0.5, 2, 3); st_point_inside_circle ------------------------ t See Also ST_XMax Returns X maxima of a bounding box 2d or 3d or a geometry. float ST_XMax box3d aGeomorBox2DorBox3D Description Returns X maxima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_XMax('BOX3D(1 2 3, 4 5 6)'); st_xmax ------- 4 SELECT ST_XMax(ST_GeomFromText('LINESTRING(1 3 4, 5 6 7)')); st_xmax ------- 5 SELECT ST_XMax(CAST('BOX(-3 2, 3 4)' As box2d)); st_xmax ------- 3 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_XMax('LINESTRING(1 3, 5 6)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_XMax(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_xmax -------- 220288.248780547 See Also , , , , ST_XMin Returns X minima of a bounding box 2d or 3d or a geometry. float ST_XMin box3d aGeomorBox2DorBox3D Description Returns X minima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_XMin('BOX3D(1 2 3, 4 5 6)'); st_xmin ------- 1 SELECT ST_XMin(ST_GeomFromText('LINESTRING(1 3 4, 5 6 7)')); st_xmin ------- 1 SELECT ST_XMin(CAST('BOX(-3 2, 3 4)' As box2d)); st_xmin ------- -3 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_XMin('LINESTRING(1 3, 5 6)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_XMin(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_xmin -------- 220186.995121892 See Also , , , , ST_YMax Returns Y maxima of a bounding box 2d or 3d or a geometry. float ST_YMax box3d aGeomorBox2DorBox3D Description Returns Y maxima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_YMax('BOX3D(1 2 3, 4 5 6)'); st_ymax ------- 5 SELECT ST_YMax(ST_GeomFromText('LINESTRING(1 3 4, 5 6 7)')); st_ymax ------- 6 SELECT ST_YMax(CAST('BOX(-3 2, 3 4)' As box2d)); st_ymax ------- 4 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_YMax('LINESTRING(1 3, 5 6)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_YMax(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_ymax -------- 150506.126829327 See Also , , , , ST_YMin Returns Y minima of a bounding box 2d or 3d or a geometry. float ST_YMin box3d aGeomorBox2DorBox3D Description Returns Y minima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_YMin('BOX3D(1 2 3, 4 5 6)'); st_ymin ------- 2 SELECT ST_YMin(ST_GeomFromText('LINESTRING(1 3 4, 5 6 7)')); st_ymin ------- 3 SELECT ST_YMin(CAST('BOX(-3 2, 3 4)' As box2d)); st_ymin ------- 2 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_YMin('LINESTRING(1 3, 5 6)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_YMin(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_ymin -------- 150406 See Also , , , , , ST_ZMax Returns Z minima of a bounding box 2d or 3d or a geometry. float ST_ZMax box3d aGeomorBox2DorBox3D Description Returns Z maxima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_ZMax('BOX3D(1 2 3, 4 5 6)'); st_zmax ------- 6 SELECT ST_ZMax(ST_GeomFromEWKT('LINESTRING(1 3 4, 5 6 7)')); st_zmax ------- 7 SELECT ST_ZMax('BOX3D(-3 2 1, 3 4 1)' ); st_zmax ------- 1 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_ZMax('LINESTRING(1 3 4, 5 6 7)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_ZMax(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_zmax -------- 3 See Also , , , , , ST_ZMin Returns Z minima of a bounding box 2d or 3d or a geometry. float ST_ZMin box3d aGeomorBox2DorBox3D Description Returns Z minima of a bounding box 2d or 3d or a geometry. Although this function is only defined for box3d, it will work for box2d and geometry because of the auto-casting behavior defined for geometries and box2d. However you can not feed it a geometry or box2d text represenation, since that will not auto-cast. This function supports 3d and will not drop the z-index. This method supports Circular Strings and curves Examples SELECT ST_ZMin('BOX3D(1 2 3, 4 5 6)'); st_zmin ------- 3 SELECT ST_ZMin(ST_GeomFromEWKT('LINESTRING(1 3 4, 5 6 7)')); st_zmin ------- 4 SELECT ST_ZMin('BOX3D(-3 2 1, 3 4 1)' ); st_zmin ------- 1 --Observe THIS DOES NOT WORK because it will try to autocast the string representation to a BOX3D SELECT ST_ZMin('LINESTRING(1 3 4, 5 6 7)'); --ERROR: BOX3D parser - doesnt start with BOX3D( SELECT ST_ZMin(ST_GeomFromEWKT('CIRCULARSTRING(220268 150415 1,220227 150505 2,220227 150406 3)')); st_zmin -------- 1 See Also , , , , , , Exceptional Functions These functions are rarely used functions that should only be used if your data is corrupted in someway. They are used for troubleshooting corruption and also fixing things that should under normal circumstances, never happen. ST_AddBBox Add bounding box to the geometry. geometry ST_AddBBox geometry geomA Description Add bounding box to the geometry. This would make bounding box based queries faster, but will increase the size of the geometry. Bounding boxes are automatically added to geometries so in general this is not needed unless the generated bounding box somehow becomes corrupted or you have an old install that is lacking bounding boxes. Then you need to drop the old and readd. This method supports Circular Strings and curves Examples UPDATE sometable SET the_geom = ST_AddBBox(the_geom) WHERE ST_HasBBox(the_geom) = false; See Also , ST_DropBBox Drop the bounding box cache from the geometry. geometry ST_DropBBox geometry geomA Description Drop the bounding box cache from the geometry. This reduces geometry size, but makes bounding-box based queries slower. It is also used to drop a corrupt bounding box. A tale-tell sign of a corrupt cached bounding box is when your ST_Intersects and other relation queries leave out geometries that rightfully should return true. Bounding boxes are automatically added to geometries and improve speed of queries so in general this is not needed unless the generated bounding box somehow becomes corrupted or you have an old install that is lacking bounding boxes. Then you need to drop the old and readd. This kind of corruption has been observed in 8.3-8.3.6 series whereby cached bboxes were not always recalculated when a geometry changed and upgrading to a newer version without a dump reload will not correct already corrupted boxes. So one can manually correct using below and readd the bbox or do a dump reload. This method supports Circular Strings and curves Examples --This example drops bounding boxes where the cached box is not correct --The force to ST_AsBinary before applying ST_box2D forces a recalculation of the box, and ST_Box2D applied to the table geometry always -- returns the cached bounding box. UPDATE sometable SET the_geom = ST_DropBBox(the_geom) WHERE Not (ST_Box2D(ST_AsBinary(the_geom)) = ST_Box2D(the_geom)); UPDATE sometable SET the_geom = ST_AddBBox(the_geom) WHERE Not ST_HasBBOX(the_geom); See Also , , ST_HasBBox Returns TRUE if the bbox of this geometry is cached, FALSE otherwise. boolean ST_HasBBox geometry geomA Description Returns TRUE if the bbox of this geometry is cached, FALSE otherwise. Use and to control caching. This method supports Circular Strings and curves Examples SELECT the_geom FROM sometable WHERE ST_HasBBox(the_geom) = false; See Also ,