Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 43.2Mb
PDF (A4) - 43.3Mb
Man Pages (TGZ) - 296.3Kb
Man Pages (Zip) - 401.6Kb
Info (Gzip) - 4.3Mb
Info (Zip) - 4.3Mb
Excerpts from this Manual

MySQL 8.0 Reference Manual  /  ...  /  Spatial Convenience Functions

14.16.13 Spatial Convenience Functions

The functions in this section provide convenience operations on geometry values.

Unless otherwise specified, functions in this section handle their geometry arguments as follows:

  • If any argument is NULL, the return value is NULL.

  • If any geometry argument is not a syntactically well-formed geometry, an ER_GIS_INVALID_DATA error occurs.

  • If any geometry argument is a syntactically well-formed geometry in an undefined spatial reference system (SRS), an ER_SRS_NOT_FOUND error occurs.

  • For functions that take multiple geometry arguments, if those arguments are not in the same SRS, an ER_GIS_DIFFERENT_SRIDS error occurs.

  • Otherwise, the return value is non-NULL.

These convenience functions are available:

  • ST_Distance_Sphere(g1, g2 [, radius])

    Returns the minimum spherical distance between Point or MultiPoint arguments on a sphere, in meters. (For general-purpose distance calculations, see the ST_Distance() function.) The optional radius argument should be given in meters.

    If both geometry parameters are valid Cartesian Point or MultiPoint values in SRID 0, the return value is shortest distance between the two geometries on a sphere with the provided radius. If omitted, the default radius is 6,370,986 meters, Point X and Y coordinates are interpreted as longitude and latitude, respectively, in degrees.

    If both geometry parameters are valid Point or MultiPoint values in a geographic spatial reference system (SRS), the return value is the shortest distance between the two geometries on a sphere with the provided radius. If omitted, the default radius is equal to the mean radius, defined as (2a+b)/3, where a is the semi-major axis and b is the semi-minor axis of the SRS.

    ST_Distance_Sphere() handles its arguments as described in the introduction to this section, with these exceptions:

    mysql> SET @pt1 = ST_GeomFromText('POINT(0 0)');
    mysql> SET @pt2 = ST_GeomFromText('POINT(180 0)');
    mysql> SELECT ST_Distance_Sphere(@pt1, @pt2);
    +--------------------------------+
    | ST_Distance_Sphere(@pt1, @pt2) |
    +--------------------------------+
    |             20015042.813723423 |
    +--------------------------------+
  • ST_IsValid(g)

    Returns 1 if the argument is geometrically valid, 0 if the argument is not geometrically valid. Geometry validity is defined by the OGC specification.

    The only valid empty geometry is represented in the form of an empty geometry collection value. ST_IsValid() returns 1 in this case. MySQL does not support GIS EMPTY values such as POINT EMPTY.

    ST_IsValid() handles its arguments as described in the introduction to this section, with this exception:

    mysql> SET @ls1 = ST_GeomFromText('LINESTRING(0 0,-0.00 0,0.0 0)');
    mysql> SET @ls2 = ST_GeomFromText('LINESTRING(0 0, 1 1)');
    mysql> SELECT ST_IsValid(@ls1);
    +------------------+
    | ST_IsValid(@ls1) |
    +------------------+
    |                0 |
    +------------------+
    mysql> SELECT ST_IsValid(@ls2);
    +------------------+
    | ST_IsValid(@ls2) |
    +------------------+
    |                1 |
    +------------------+
  • ST_MakeEnvelope(pt1, pt2)

    Returns the rectangle that forms the envelope around two points, as a Point, LineString, or Polygon.

    Calculations are done using the Cartesian coordinate system rather than on a sphere, spheroid, or on earth.

    Given two points pt1 and pt2, ST_MakeEnvelope() creates the result geometry on an abstract plane like this:

    • If pt1 and pt2 are equal, the result is the point pt1.

    • Otherwise, if (pt1, pt2) is a vertical or horizontal line segment, the result is the line segment (pt1, pt2).

    • Otherwise, the result is a polygon using pt1 and pt2 as diagonal points.

    The result geometry has an SRID of 0.

    ST_MakeEnvelope() handles its arguments as described in the introduction to this section, with these exceptions:

    mysql> SET @pt1 = ST_GeomFromText('POINT(0 0)');
    mysql> SET @pt2 = ST_GeomFromText('POINT(1 1)');
    mysql> SELECT ST_AsText(ST_MakeEnvelope(@pt1, @pt2));
    +----------------------------------------+
    | ST_AsText(ST_MakeEnvelope(@pt1, @pt2)) |
    +----------------------------------------+
    | POLYGON((0 0,1 0,1 1,0 1,0 0))         |
    +----------------------------------------+
  • ST_Simplify(g, max_distance)

    Simplifies a geometry using the Douglas-Peucker algorithm and returns a simplified value of the same type.

    The geometry may be any geometry type, although the Douglas-Peucker algorithm may not actually process every type. A geometry collection is processed by giving its components one by one to the simplification algorithm, and the returned geometries are put into a geometry collection as result.

    The max_distance argument is the distance (in units of the input coordinates) of a vertex to other segments to be removed. Vertices within this distance of the simplified linestring are removed.

    According to Boost.Geometry, geometries might become invalid as a result of the simplification process, and the process might create self-intersections. To check the validity of the result, pass it to ST_IsValid().

    ST_Simplify() handles its arguments as described in the introduction to this section, with this exception:

    • If the max_distance argument is not positive, or is NaN, an ER_WRONG_ARGUMENTS error occurs.

    mysql> SET @g = ST_GeomFromText('LINESTRING(0 0,0 1,1 1,1 2,2 2,2 3,3 3)');
    mysql> SELECT ST_AsText(ST_Simplify(@g, 0.5));
    +---------------------------------+
    | ST_AsText(ST_Simplify(@g, 0.5)) |
    +---------------------------------+
    | LINESTRING(0 0,0 1,1 1,2 3,3 3) |
    +---------------------------------+
    mysql> SELECT ST_AsText(ST_Simplify(@g, 1.0));
    +---------------------------------+
    | ST_AsText(ST_Simplify(@g, 1.0)) |
    +---------------------------------+
    | LINESTRING(0 0,3 3)             |
    +---------------------------------+
  • ST_Validate(g)

    Validates a geometry according to the OGC specification. A geometry can be syntactically well-formed (WKB value plus SRID) but geometrically invalid. For example, this polygon is geometrically invalid: POLYGON((0 0, 0 0, 0 0, 0 0, 0 0))

    ST_Validate() returns the geometry if it is syntactically well-formed and is geometrically valid, NULL if the argument is not syntactically well-formed or is not geometrically valid or is NULL.

    ST_Validate() can be used to filter out invalid geometry data, although at a cost. For applications that require more precise results not tainted by invalid data, this penalty may be worthwhile.

    If the geometry argument is valid, it is returned as is, except that if an input Polygon or MultiPolygon has clockwise rings, those rings are reversed before checking for validity. If the geometry is valid, the value with the reversed rings is returned.

    The only valid empty geometry is represented in the form of an empty geometry collection value. ST_Validate() returns it directly without further checks in this case.

    As of MySQL 8.0.13, ST_Validate() handles its arguments as described in the introduction to this section, with these exceptions:

    Prior to MySQL 8.0.13, ST_Validate() handles its arguments as described in the introduction to this section, with these exceptions:

    mysql> SET @ls1 = ST_GeomFromText('LINESTRING(0 0)');
    mysql> SET @ls2 = ST_GeomFromText('LINESTRING(0 0, 1 1)');
    mysql> SELECT ST_AsText(ST_Validate(@ls1));
    +------------------------------+
    | ST_AsText(ST_Validate(@ls1)) |
    +------------------------------+
    | NULL                         |
    +------------------------------+
    mysql> SELECT ST_AsText(ST_Validate(@ls2));
    +------------------------------+
    | ST_AsText(ST_Validate(@ls2)) |
    +------------------------------+
    | LINESTRING(0 0,1 1)          |
    +------------------------------+