MySQL :: MySQL 8.0 Reference Manual :: 14.16.8 Spatial Operator Functions (original) (raw)

14.16.8 Spatial Operator Functions

OpenGIS proposes a number of functions that can produce geometries. They are designed to implement spatial operators. These functions support all argument type combinations except those that are inapplicable according to theOpen Geospatial Consortium specification.

MySQL also implements certain functions that are extensions to OpenGIS, as noted in the function descriptions. In addition,Section 14.16.7, “Geometry Property Functions”, discusses several functions that construct new geometries from existing ones. See that section for descriptions of these functions:

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

These spatial operator functions are available:

mysql> SET @pt = ST_GeomFromText('POINT(0 0)');  
mysql> SELECT ST_AsText(ST_Buffer(@pt, 0));  
+------------------------------+  
| ST_AsText(ST_Buffer(@pt, 0)) |  
+------------------------------+  
| POINT(0 0)                   |  
+------------------------------+  

If the geometry argument is in a Cartesian SRS:

mysql> SET @pt = ST_GeomFromText('POINT(0 0)');  
mysql> SET @pt_strategy = ST_Buffer_Strategy('point_square');  
mysql> SELECT ST_AsText(ST_Buffer(@pt, 2, @pt_strategy));  
+--------------------------------------------+  
| ST_AsText(ST_Buffer(@pt, 2, @pt_strategy)) |  
+--------------------------------------------+  
| POLYGON((-2 -2,2 -2,2 2,-2 2,-2 -2))       |  
+--------------------------------------------+  
mysql> SET @ls = ST_GeomFromText('LINESTRING(0 0,0 5,5 5)');  
mysql> SET @end_strategy = ST_Buffer_Strategy('end_flat');  
mysql> SET @join_strategy = ST_Buffer_Strategy('join_round', 10);  
mysql> SELECT ST_AsText(ST_Buffer(@ls, 5, @end_strategy, @join_strategy))  
+---------------------------------------------------------------+  
| ST_AsText(ST_Buffer(@ls, 5, @end_strategy, @join_strategy))   |  
+---------------------------------------------------------------+  
| POLYGON((5 5,5 10,0 10,-3.5355339059327373 8.535533905932738, |  
| -5 5,-5 0,0 0,5 0,5 5))                                       |  
+---------------------------------------------------------------+  
mysql> SET @g = 'MULTIPOINT(5 0,25 0,15 10,15 25)';  
mysql> SELECT ST_AsText(ST_ConvexHull(ST_GeomFromText(@g)));  
+-----------------------------------------------+  
| ST_AsText(ST_ConvexHull(ST_GeomFromText(@g))) |  
+-----------------------------------------------+  
| POLYGON((5 0,25 0,15 25,5 0))                 |  
+-----------------------------------------------+  
mysql> SET @g1 = Point(1,1), @g2 = Point(2,2);  
mysql> SELECT ST_AsText(ST_Difference(@g1, @g2));  
+------------------------------------+  
| ST_AsText(ST_Difference(@g1, @g2)) |  
+------------------------------------+  
| POINT(1 1)                         |  
+------------------------------------+  
mysql> SET @g1 = ST_GeomFromText('LineString(1 1, 3 3)');  
mysql> SET @g2 = ST_GeomFromText('LineString(1 3, 3 1)');  
mysql> SELECT ST_AsText(ST_Intersection(@g1, @g2));  
+--------------------------------------+  
| ST_AsText(ST_Intersection(@g1, @g2)) |  
+--------------------------------------+  
| POINT(2 2)                           |  
+--------------------------------------+  
mysql> SET @ls1 = ST_GeomFromText('LINESTRING(0 0,0 5,5 5)');  
mysql> SELECT ST_AsText(ST_LineInterpolatePoint(@ls1, .5));  
+----------------------------------------------+  
| ST_AsText(ST_LineInterpolatePoint(@ls1, .5)) |  
+----------------------------------------------+  
| POINT(0 5)                                   |  
+----------------------------------------------+  
mysql> SELECT ST_AsText(ST_LineInterpolatePoint(@ls1, .75));  
+-----------------------------------------------+  
| ST_AsText(ST_LineInterpolatePoint(@ls1, .75)) |  
+-----------------------------------------------+  
| POINT(2.5 5)                                  |  
+-----------------------------------------------+  
mysql> SELECT ST_AsText(ST_LineInterpolatePoint(@ls1, 1));  
+---------------------------------------------+  
| ST_AsText(ST_LineInterpolatePoint(@ls1, 1)) |  
+---------------------------------------------+  
| POINT(5 5)                                  |  
+---------------------------------------------+  
mysql> SELECT ST_AsText(ST_LineInterpolatePoints(@ls1, .25));  
+------------------------------------------------+  
| ST_AsText(ST_LineInterpolatePoints(@ls1, .25)) |  
+------------------------------------------------+  
| MULTIPOINT((0 2.5),(0 5),(2.5 5),(5 5))        |  
+------------------------------------------------+  

ST_LineInterpolatePoints() is a MySQL extension to OpenGIS. This function was added in MySQL 8.0.24.

g1 symdifference g2 := (g1 union g2) difference (g1 intersection g2)  

Or, in function call notation:

ST_SymDifference(g1, g2) = ST_Difference(ST_Union(g1, g2), ST_Intersection(g1, g2))  

The result is in the same SRS as the geometry arguments.
As of MySQL 8.0.27,ST_SymDifference() permits arguments in either a Cartesian or a geographic SRS. Prior to MySQL 8.0.27,ST_SymDifference() permits arguments in a Cartesian SRS only; for arguments in a geographic SRS, anER_NOT_IMPLEMENTED_FOR_GEOGRAPHIC_SRS error occurs.
ST_SymDifference() handles its arguments as described in the introduction to this section.

mysql> SET @g1 = ST_GeomFromText('MULTIPOINT(5 0,15 10,15 25)');  
mysql> SET @g2 = ST_GeomFromText('MULTIPOINT(1 1,15 10,15 25)');  
mysql> SELECT ST_AsText(ST_SymDifference(@g1, @g2));  
+---------------------------------------+  
| ST_AsText(ST_SymDifference(@g1, @g2)) |  
+---------------------------------------+  
| MULTIPOINT((1 1),(5 0))               |  
+---------------------------------------+  
mysql> SET @p = ST_GeomFromText('POINT(52.381389 13.064444)', 4326);  
mysql> SELECT ST_AsText(@p);  
+----------------------------+  
| ST_AsText(@p)              |  
+----------------------------+  
| POINT(52.381389 13.064444) |  
+----------------------------+  
mysql> SET @p = ST_Transform(@p, 4230);  
mysql> SELECT ST_AsText(@p);  
+---------------------------------------------+  
| ST_AsText(@p)                               |  
+---------------------------------------------+  
| POINT(52.38208611407426 13.065520672345304) |  
+---------------------------------------------+  
mysql> SET @g1 = ST_GeomFromText('LineString(1 1, 3 3)');  
mysql> SET @g2 = ST_GeomFromText('LineString(1 3, 3 1)');  
mysql> SELECT ST_AsText(ST_Union(@g1, @g2));  
+--------------------------------------+  
| ST_AsText(ST_Union(@g1, @g2))        |  
+--------------------------------------+  
| MULTILINESTRING((1 1,3 3),(1 3,3 1)) |  
+--------------------------------------+