A View Inside My Head

Jason's Random Thoughts of Interest
posts - 81, comments - 172, trackbacks - 19

SQL Server 2008: Spatial Data, Part 5

In the previous part of this series, I demonstrated instance methods that transformed a single Geometry type into another useful Geometry. In this post, we'll go a step further and show methods that allow two or more instances to interact with one another in order to produce a new Geometry.

For my baseline, I'll use two Polygons that overlap each other:

DECLARE @g geometry 
        = 'POLYGON((10 10, 40 10, 40 40, 10 40, 10 10))'
DECLARE @h geometry 
        = 'POLYGON((30 30, 50 30, 50 50, 30 50, 30 30))'

Spatial_5_1

STDifference


STDifference() returns a new instance consisting of all points from the base instance that do not contain points from the parameter instance.

SELECT @g.STDifference(@h).ToString();
Result:
POLYGON ((10 10, 40 10, 40 30, 30 30, 30 40, 10 40, 10 10))

Spatial_5_2

STIntersection


STIntersection() returns a new instance containing only the points that are in common between the base instance and the parameter instance.

SELECT @g.STIntersection(@h).ToString();
Result:
POLYGON ((30 30, 40 30, 40 40, 30 40, 30 30))

Spatial_5_3

STSymDifference


STSymDifference() returns a new instance containing only the points that are unique to both the base instance and the parameter instance (i.e., it excludes the points that STIntersection() would return).

In this case, the set of points is actually two different Polygons. Because STSymDifference() needs to return a single instance of something, it will wrap those two Polygons into a collection (MultiPolygon).

SELECT @g.STSymDifference(@h).ToString();
Result:
MULTIPOLYGON (((40 30, 50 30, 50 50, 30 50, 30 40, 40 40, 40 30)), 
              ((10 10, 40 10, 40 30, 30 30, 30 40, 10 40, 10 10)))

Spatial_5_4

STUnion


STUnion() returns a new instance containing all of the points of the base instance and the parameter instance merged together.

SELECT @g.STUnion(@h).ToString();
Results:
POLYGON ((10 10, 40 10, 40 30, 50 30, 50 50, 30 50, 
30 40, 10 40, 10 10))

Spatial_5_5

Blended Types


The instance methods described above do not work just for Polygons. You can actually use them on different types, or even collections of different types.

For instance, if we look at the results of using a LineString as the base instance and a Polygon as the parameter instance, STDifference() will return a MultiLineString constisting of the points from the original LineString that do not lie within the Polygon:

DECLARE @g geometry = 'LINESTRING(9 9, 40 40)'
DECLARE @h geometry = 'POLYGON((15 15, 15 30, 30 30, 30 15, 15 15))'
SELECT @g.STDifference(@h).ToString();
Results:
MULTILINESTRING ((40 40, 30 30), (15 15, 9 9))

Spatial_5_6

STIntersection() will return the points from the original LineString that do lie within the Polygon:

SELECT @g.STIntersection(@h).ToString();
Results:
LINESTRING (30 30, 15 15)

Spatial_5_7

STUnion() cannot determine a single common Geometry type, so it will return a mixed collection of types:

SELECT @g.STUnion(@h).ToString();
Results:
GEOMETRYCOLLECTION 
(
     LINESTRING (40 40, 30 30), 
     POLYGON ((15 15, 30 15, 30 30, 15 30, 15 15)), 
     LINESTRING (15 15, 9 9)
)

Spatial_5_8

SQL Server 2008: Spatial Data, Part 1

SQL Server 2008: Spatial Data, Part 2

SQL Server 2008: Spatial Data, Part 3

SQL Server 2008: Spatial Data, Part 4

(next part) SQL Server 2008: Spatial Data, Part 6

SQL Server 2008: Spatial Data, Part 7

SQL Server 2008: Spatial Data, Part 8

Print | posted on Monday, April 07, 2008 11:51 AM | Filed Under [ Articles .NET SQL Spatial ]

Feedback

# re: SQL Server 2008: Spatial Data, Part 5

This is pretty cool stuff! Have you been able to mash this stuff with Live Maps? That would be very interesting.

Good blog!
4/9/2008 11:35 AM | Gert-Jan van der Kamp

# re: SQL Server 2008: Spatial Data, Part 5

Hi,
What is the best way for this.
i want to know whot is the range (STEnvelope) of a query
Example
select geom.ToString() as geom from poligonos
POLYGON ((504634.979 -789541.098, 504632.426 -789548.707, 504632.636 -789548.857, 504631.477 -789553.921, 504629.977 -789558.307, 504629.976 -789558.307, 504628.156 -789561.707, 504627.936 -789561.667, 504625.178 -789569.802, 504612.266 -789565.407, 504612.266 -789565.407, 504606.156 -789563.327, 504615.95 -789534.519, 504615.95 -789534.519, 504634.976 -789541.097, 504634.979 -789541.098))
POLYGON ((504625.636 -789506.027, 504631.923 -789508.056, 504632.176 -789507.347, 504644.896 -789511.797, 504642.056 -789520.277, 504642.276 -789520.437, 504640.972 -789526.156, 504640.021 -789528.936, 504637.816 -789533.407, 504637.566 -789533.387, 504634.979 -789541.098, 504634.976 -789541.097, 504622.078 -789536.638, 504615.95 -789534.519, 504615.95 -789534.519, 504625.636 -789506.027))
POLYGON ((505273.126 -789028.777, 505283.926 -789030.567, 505284.675 -789024.74, 505293.554 -789025.881, 505290.846 -789045.957, 505282.246 -789044.677, 505282.926 -789039.037, 505271.696 -789037.427, 505273.126 -789028.777))

I want the range (STEnvelope) of the three.
6/18/2009 5:19 AM | Salvador
Gravatar

# re: SQL Server 2008: Spatial Data, Part 5

I would perhaps try to build this query up in stages (i.e., nested queries)

First, you could STEnvelope() each shape individually to get the bounding rectangle for each row.

Then, in the second pass, extract the min/max X/Y values from the polygons in the first pass as scalar values.

A third pass would use SQL aggregate functions to find the absolute min/max X,Y values from across all rows, and if needed, a fourth pass could create the new geometry from those X,Y values which would represent the bounding rectangle that surrounds all of the shapes from all of the rows.
6/18/2009 7:06 AM | Jason
Comments have been closed on this topic.

Powered by: