After populating spatial columns with values, you are ready to query and analyze them. MySQL provides a set of functions to perform various operations on spatial data. These functions can be grouped into four major categories according to the type of operation they perform:
Functions that convert geometries between various formats
Functions that provide access to qualitative or quantitative properties of a geometry
Functions that describe relations between two geometries
Functions that create new geometries from existing ones
Spatial analysis functions can be used in many contexts, such as:
Any interactive SQL program, such as mysql or MySQLCC
Application programs written in any language that supports a MySQL client API
MySQL supports the following functions for converting geometry values between internal format and either WKT or WKB format:
Converts a value in internal geometry format to its WKB representation and returns the binary result.
Converts a value in internal geometry format to its WKT representation and returns the string result.
mysql> SET @g = 'LineString(1 1,2 2,3 3)'; mysql> SELECT AsText(GeomFromText(@g)); +--------------------------+ | AsText(GeomFromText(@G)) | +--------------------------+ | LINESTRING(1 1,2 2,3 3) | +--------------------------+
Converts a string value from its WKT representation into internal geometry format and returns the result. A number of type-specific functions are also supported, such as PointFromText() and LineFromText(); see the section called “Creating Geometry Values Using WKT Functions”.
Converts a binary value from its WKB representation into internal geometry format and returns the result. A number of type-specific functions are also supported, such as PointFromWKB() and LineFromWKB(); see the section called “Creating Geometry Values Using WKB Functions”.
Each function that belongs to this group takes a geometry value as its argument and returns some quantitative or qualitative property of the geometry. Some functions restrict their argument type. Such functions return NULL if the argument is of an incorrect geometry type. For example, Area() returns NULL if the object type is neither Polygon nor MultiPolygon.
The functions listed in this section do not restrict their argument and accept a geometry value of any type.
Returns the inherent dimension of the geometry value g. The result can be −1, 0, 1, or 2. (The meaning of these values is given in the section called “Class Geometry”.)
mysql> SELECT Dimension(GeomFromText('LineString(1 1,2 2)')); +------------------------------------------------+ | Dimension(GeomFromText('LineString(1 1,2 2)')) | +------------------------------------------------+ | 1 | +------------------------------------------------+
Returns the Minimum Bounding Rectangle (MBR) for the geometry value g. The result is returned as a Polygon value.
mysql> SELECT AsText(Envelope(GeomFromText('LineString(1 1,2 2)'))); +-------------------------------------------------------+ | AsText(Envelope(GeomFromText('LineString(1 1,2 2)'))) | +-------------------------------------------------------+ | POLYGON((1 1,2 1,2 2,1 2,1 1)) | +-------------------------------------------------------+
The polygon is defined by the corner points of the bounding box:
POLYGON((MINX MINY, MAXX MINY, MAXX MAXY, MINX MAXY, MINX MINY))
Returns as a string the name of the geometry type of which the geometry instance g is a member. The name will correspond to one of the instantiable Geometry subclasses.
mysql> SELECT GeometryType(GeomFromText('POINT(1 1)')); +------------------------------------------+ | GeometryType(GeomFromText('POINT(1 1)')) | +------------------------------------------+ | POINT | +------------------------------------------+
Returns an integer indicating the Spatial Reference System ID for the geometry value g.
mysql> SELECT SRID(GeomFromText('LineString(1 1,2 2)',101)); +-----------------------------------------------+ | SRID(GeomFromText('LineString(1 1,2 2)',101)) | +-----------------------------------------------+ | 101 | +-----------------------------------------------+
The OpenGIS specification also defines the following functions, which MySQL does not implement:
Returns a geometry that is the closure of the combinatorial boundary of the geometry value g.
Returns 1 if the geometry value g is the empty geometry, 0 if it is not empty, and −1 if the argument is NULL. If the geometry is empty, it represents the empty point set.
Currently, this function is a placeholder and should not be used. If implemented, its behavior will be as described in the next paragraph.
Returns 1 if the geometry value g has no anomalous geometric points, such as self-intersection or self-tangency. IsSimple() returns 0 if the argument is not simple, and −1 if it is NULL.
The description of each instantiable geometric class given earlier in the chapter includes the specific conditions that cause an instance of that class to be classified as not simple.
A Point consists of X and Y coordinates, which may be obtained using the following functions:
Returns the X-coordinate value for the point p as a double-precision number.
mysql> SELECT X(GeomFromText('Point(56.7 53.34)')); +--------------------------------------+ | X(GeomFromText('Point(56.7 53.34)')) | +--------------------------------------+ | 56.7 | +--------------------------------------+
Returns the Y-coordinate value for the point p as a double-precision number.
mysql> SELECT Y(GeomFromText('Point(56.7 53.34)')); +--------------------------------------+ | Y(GeomFromText('Point(56.7 53.34)')) | +--------------------------------------+ | 53.34 | +--------------------------------------+
A LineString consists of Point values. You can extract particular points of a LineString, count the number of points that it contains, or obtain its length.
Returns the Point that is the end point of the LineString value ls.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT AsText(EndPoint(GeomFromText(@ls))); +-------------------------------------+ | AsText(EndPoint(GeomFromText(@ls))) | +-------------------------------------+ | POINT(3 3) | +-------------------------------------+
Returns as a double-precision number the length of the LineString value ls in its associated spatial reference.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT GLength(GeomFromText(@ls)); +----------------------------+ | GLength(GeomFromText(@ls)) | +----------------------------+ | 2.8284271247462 | +----------------------------+
Returns 1 if the LineString value ls is closed (that is, its StartPoint() and EndPoint() values are the same). Returns 0 if ls is not closed, and −1 if it is NULL.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT IsClosed(GeomFromText(@ls)); +-----------------------------+ | IsClosed(GeomFromText(@ls)) | +-----------------------------+ | 0 | +-----------------------------+
Returns the number of points in the LineString value ls.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT NumPoints(GeomFromText(@ls)); +------------------------------+ | NumPoints(GeomFromText(@ls)) | +------------------------------+ | 3 | +------------------------------+
Returns the n-th point in the Linestring value ls. Point numbers begin at 1.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT AsText(PointN(GeomFromText(@ls),2)); +-------------------------------------+ | AsText(PointN(GeomFromText(@ls),2)) | +-------------------------------------+ | POINT(2 2) | +-------------------------------------+
Returns the Point that is the start point of the LineString value ls.
mysql> SET @ls = 'LineString(1 1,2 2,3 3)'; mysql> SELECT AsText(StartPoint(GeomFromText(@ls))); +---------------------------------------+ | AsText(StartPoint(GeomFromText(@ls))) | +---------------------------------------+ | POINT(1 1) | +---------------------------------------+
The OpenGIS specification also defines the following function, which MySQL does not implement:
Returns as a double-precision number the length of the MultiLineString value mls. The length of mls is equal to the sum of the lengths of its elements.
mysql> SET @mls = 'MultiLineString((1 1,2 2,3 3),(4 4,5 5))'; mysql> SELECT GLength(GeomFromText(@mls)); +-----------------------------+ | GLength(GeomFromText(@mls)) | +-----------------------------+ | 4.2426406871193 | +-----------------------------+
Returns 1 if the MultiLineString value mls is closed (that is, the StartPoint() and EndPoint() values are the same for each LineString in mls). Returns 0 if mls is not closed, and −1 if it is NULL.
mysql> SET @mls = 'MultiLineString((1 1,2 2,3 3),(4 4,5 5))'; mysql> SELECT IsClosed(GeomFromText(@mls)); +------------------------------+ | IsClosed(GeomFromText(@mls)) | +------------------------------+ | 0 | +------------------------------+
Returns as a double-precision number the area of the Polygon value poly, as measured in its spatial reference system.
mysql> SET @poly = 'Polygon((0 0,0 3,3 0,0 0),(1 1,1 2,2 1,1 1))'; mysql> SELECT Area(GeomFromText(@poly)); +---------------------------+ | Area(GeomFromText(@poly)) | +---------------------------+ | 4 | +---------------------------+
Returns the exterior ring of the Polygon value poly as a LineString.
mysql> SET @poly = -> 'Polygon((0 0,0 3,3 3,3 0,0 0),(1 1,1 2,2 2,2 1,1 1))'; mysql> SELECT AsText(ExteriorRing(GeomFromText(@poly))); +-------------------------------------------+ | AsText(ExteriorRing(GeomFromText(@poly))) | +-------------------------------------------+ | LINESTRING(0 0,0 3,3 3,3 0,0 0) | +-------------------------------------------+
Returns the n-th interior ring for the Polygon value poly as a LineString. Ring numbers begin at 1.
mysql> SET @poly = -> 'Polygon((0 0,0 3,3 3,3 0,0 0),(1 1,1 2,2 2,2 1,1 1))'; mysql> SELECT AsText(InteriorRingN(GeomFromText(@poly),1)); +----------------------------------------------+ | AsText(InteriorRingN(GeomFromText(@poly),1)) | +----------------------------------------------+ | LINESTRING(1 1,1 2,2 2,2 1,1 1) | +----------------------------------------------+
Returns the number of interior rings in the Polygon value poly.
mysql> SET @poly = -> 'Polygon((0 0,0 3,3 3,3 0,0 0),(1 1,1 2,2 2,2 1,1 1))'; mysql> SELECT NumInteriorRings(GeomFromText(@poly)); +---------------------------------------+ | NumInteriorRings(GeomFromText(@poly)) | +---------------------------------------+ | 1 | +---------------------------------------+
Returns as a double-precision number the area of the MultiPolygon value mpoly, as measured in its spatial reference system.
mysql> SET @mpoly = -> 'MultiPolygon(((0 0,0 3,3 3,3 0,0 0),(1 1,1 2,2 2,2 1,1 1)))'; mysql> SELECT Area(GeomFromText(@mpoly)); +----------------------------+ | Area(GeomFromText(@mpoly)) | +----------------------------+ | 8 | +----------------------------+
The OpenGIS specification also defines the following functions, which MySQL does not implement:
Returns the n-th geometry in the GeometryCollection value gc. Geometry numbers begin at 1.
mysql> SET @gc = 'GeometryCollection(Point(1 1),LineString(2 2, 3 3))'; mysql> SELECT AsText(GeometryN(GeomFromText(@gc),1)); +----------------------------------------+ | AsText(GeometryN(GeomFromText(@gc),1)) | +----------------------------------------+ | POINT(1 1) | +----------------------------------------+
Returns the number of geometries in the GeometryCollection value gc.
mysql> SET @gc = 'GeometryCollection(Point(1 1),LineString(2 2, 3 3))'; mysql> SELECT NumGeometries(GeomFromText(@gc)); +----------------------------------+ | NumGeometries(GeomFromText(@gc)) | +----------------------------------+ | 2 | +----------------------------------+
In the section the section called “Geometry Functions”, we've already discussed some functions that can construct new geometries from the existing ones:
Envelope(g)
StartPoint(ls)
EndPoint(ls)
PointN(ls,n)
ExteriorRing(poly)
InteriorRingN(poly,n)
GeometryN(gc,n)
OpenGIS proposes a number of other functions that can produce geometries. They are designed to implement spatial operators.
These functions are not implemented in MySQL. They may appear in future releases.
Returns a geometry that represents all points whose distance from the geometry value g is less than or equal to a distance of d.
Returns a geometry that represents the convex hull of the geometry value g.
Returns a geometry that represents the point set difference of the geometry value g1 with g2.
Returns a geometry that represents the point set intersection of the geometry values g1 with g2.
Returns a geometry that represents the point set symmetric difference of the geometry value g1 with g2.
Returns a geometry that represents the point set union of the geometry values g1 and g2.
The functions described in these sections take two geometries as input parameters and return a qualitative or quantitative relation between them.
MySQL provides some functions that can test relations between minimal bounding rectangles of two geometries g1 and g2. They include:
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangle of g1 contains the Minimum Bounding Rectangle of g2.
mysql> SET @g1 = GeomFromText('Polygon((0 0,0 3,3 3,3 0,0 0))'); mysql> SET @g2 = GeomFromText('Point(1 1)'); mysql> SELECT MBRContains(@g1,@g2), MBRContains(@g2,@g1); ----------------------+----------------------+ | MBRContains(@g1,@g2) | MBRContains(@g2,@g1) | +----------------------+----------------------+ | 1 | 0 | +----------------------+----------------------+
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangles of the two geometries g1 and g2 are disjoint (do not intersect).
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangles of the two geometries g1 and g2 are the same.
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangles of the two geometries g1 and g2 intersect.
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangles of the two geometries g1 and g2 overlap.
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangles of the two geometries g1 and g2 touch.
Returns 1 or 0 to indicate whether or not the Minimum Bounding Rectangle of g1 is within the Minimum Bounding Rectangle of g2.
mysql> SET @g1 = GeomFromText('Polygon((0 0,0 3,3 3,3 0,0 0))'); mysql> SET @g2 = GeomFromText('Polygon((0 0,0 5,5 5,5 0,0 0))'); mysql> SELECT MBRWithin(@g1,@g2), MBRWithin(@g2,@g1); +--------------------+--------------------+ | MBRWithin(@g1,@g2) | MBRWithin(@g2,@g1) | +--------------------+--------------------+ | 1 | 0 | +--------------------+--------------------+
The OpenGIS specification defines the following functions. Currently, MySQL does not implement them according to the specification. Those that are implemented return the same result as the corresponding MBR-based functions. This includes functions in the following list other than Distance() and Related().
These functions may be implemented in future releases with full support for spatial analysis, not just MBR-based support.
The functions operate on two geometry values g1 and g2.
Returns 1 or 0 to indicate whether or not g1 completely contains g2.
Returns 1 if g1 spatially crosses g2. Returns NULL if g1 is a Polygon or a MultiPolygon, or if g2 is a Point or a MultiPoint. Otherwise, returns 0.
The term spatially crosses denotes a spatial relation between two given geometries that has the following properties:
The two geometries intersect
Their intersection results in a geometry that has a dimension that is one less than the maximum dimension of the two given geometries
Their intersection is not equal to either of the two given geometries
Returns 1 or 0 to indicate whether or not g1 is spatially disjoint from (does not intersect) g2.
Returns as a double-precision number the shortest distance between any two points in the two geometries.
Returns 1 or 0 to indicate whether or not g1 is spatially equal to g2.
Returns 1 or 0 to indicate whether or not g1 spatially intersects g2.
Returns 1 or 0 to indicate whether or not g1 spatially overlaps g2. The term spatially overlaps is used if two geometries intersect and their intersection results in a geometry of the same dimension but not equal to either of the given geometries.
Returns 1 or 0 to indicate whether or not the spatial relationship specified by pattern_matrix exists between g1 and g2. Returns −1 if the arguments are NULL. The pattern matrix is a string. Its specification will be noted here if this function is implemented.
Returns 1 or 0 to indicate whether or not g1 spatially touches g2. Two geometries spatially touch if the interiors of the geometries do not intersect, but the boundary of one of the geometries intersects either the boundary or the interior of the other.
Returns 1 or 0 to indicate whether or not g1 is spatially within g2.