New Spatial Features in SQL Server Code-Named “Denali”
SQL Server Code-Named “Denali” introduces several significant enhancements to spatial types, such as support for new subtypes of circular arcs, new and updated methods and aggregates for all subtypes, improved precision, and updates to the geography type.
Authors: Ed Katibah (Microsoft) and Milan Stojic (Microsoft)
Technical Reviewers: Marko Tintor (Microsoft), Michael Kallay (Microsoft), Michael Rys (Microsoft) and Bob Beauchemin (SQLSkills)
Note: you may download this document as a Microsoft Word file from sqlcat.com*.
*
Introduction
This document covers the new additions in spatial data support, introduced in Microsoft SQL Server 2008, for the SQL Server Code-Named “Denali” Community Technology Preview 1 (CTP1) and Community Technology Preview 3 (CTP3) releases. These new features are organized into the following major sections:
- “Spatial Type Improvements”
- “Performance Improvements”
- “Other Spatial Improvements”
Note that SQL Azure, starting with the SU3 release in June 2010, supports spatial data at a level of functionality equivalent to SQL Server 2008.
In order to fully digest this document the reader should be familiar with spatial data support in SQL Server 2008. Additionally, sections which include new CTP3-based content are identified in the section heading name by adding: “(enhanced behavior in CTP3)” or “(new CTP3 content)”. Specific new CTP3 content is further identified by adding “(new CTP3 content)” where they occur within the section itself.
Note*: The Spatial results tab in SQL Server Management Studio has not been updated to handle the new spatial features present in SQL Server* Code-Named “Denali” CTP1. Consequently, the Spatial results tab has been disabled and is not currently available in SQL Server Management Studio for the SQL Server Code-Named “Denali” CTP1 build. You can, however, use SQL Server Management Studio from an existing installation based on SQL Server 2008 or SQL Server 2008 R2 to connect to an instance of SQL Server Code-Named “Denali.” The Spatial results tab is available for spatial query visualization, in this case, but it does not support some of the spatial features that are new with SQL Server Code-Named “Denali” CTP1, such as FullGlobe geography type support and circular arcs. Additionally, note that side-by-side installations of SQL Server Code-Named “Denali” CTP1 and CTP3 are not supported with existing SQL Server 2008 installations.
For SQL Server Code-Named “Denali” CTP3, the Spatial results tab is available and handles the new features which SQL Server Code-Named “Denali” CTP1 introduced (FullGlobe, circular arcs, etc.) (new CTP3 content).
Spatial Type Improvements
SQL Server Code-Named “Denali” CTP1 introduces several significant enhancements to spatial types, such as support for new subtypes of circular arcs, new and updated methods and aggregates for all subtypes, improved precision, and updates to the geography type.
Circular Arcs: Support for Three New Subtypes (enhanced behavior in CTP3)
Circular arcs are new to CTP1 and are based on the ISO SQL/MM, Part 3: Spatial standard. Circular arcs can be defined by themselves or they can be combined with line segments. Circular arcs can also be the basis for a new type of polygon that contains one or more curve components. For example, parallels on the globe (line of latitude) can be expressed as geography circular arcs. CTP3 updates circular arcs with increased precision for the geography type (new CTP3 content). Sample circular arcs are illustrated here.
Circular arcs are supported by geometry and geography and can be defined using Well-known Text (WKT), Well-known Binary (WKB), and Geography Markup Language (GML) in SQL Server Code-Named “Denali.”
CircularString
Circular strings are the basic curve subtype, corresponding to a LineString for linear data. Three points are used to define a segment with the start (first point) and end (third point) points and another point (second point) anywhere along the circular arc. Circular strings can be linked together where the last point of the previous curve becomes the first point of the next curve. Valid circular strings will always have an odd number of points, three or greater.
DECLARE @g GEOGRAPHY;
SET @g = GEOGRAPHY::STGeomFromText('
CIRCULARSTRING(0 -23.43778, 0 0, 0 23.43778)
',4326);
CompoundCurve
Compound curves enable you to define new curves that can be composed of circular strings only, or circular strings and linear strings. The end point of every component must be identical to the starting point of the next component.
Here is an example of a CompoundCurve made up of circular strings only.
DECLARE @g GEOGRAPHY;
SET @g = GEOGRAPHY::STGeomFromText('
**COMPOUNDCURVE(
CIRCULARSTRING(0 -23.43778, 0 0, 0 23.43778),
CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),
CIRCULARSTRING(-90 23.43778, -90 0, -90 -23.43778),
CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778))
**',4326);
Here is an example of a CompoundCurve made up of circular strings and linear strings. Note that linear strings do not contain a keyword.
DECLARE @g GEOGRAPHY;
SET @g = GEOGRAPHY::STGeomFromText('
COMPOUNDCURVE(
(0 -23.43778, 0 23.43778), ** --Linear Segment*
CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),
(-90 23.43778, -90 -23.43778),** --Linear Segment***
CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778))
** ',4326);
*Note: You must remove the SQL comments (in green) from this example before it will execute correctly in Transact-SQL.
CurvePolygon
Curve polygons are similar to polygons, having at least one ring and zero or more holes (inner rings). Curve polygons are composed of linear strings, circular strings, and/or compound curves. Within a given ring, the first point as defined in a curve polygon component must be identical to the last point in a curve polygon component, just like standard polygon rings.
Here is an example of a CurvePolygon made up of compound curves, themselves made up of circular strings and linear strings.
DECLARE @g GEOGRAPHY;
SET @g = GEOGRAPHY::STGeomFromText('
CURVEPOLYGON(
COMPOUNDCURVE(
(0 -23.43778, 0 23.43778),
CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),
(-90 23.43778, -90 -23.43778),
CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778)
)
)
',4326);
Collections of Curved Objects
In order to create a collection of curved objects with objects without curves, a geometry collection must be used.
DECLARE @g GEOGRAPHY
SET @g = GEOGRAPHY::STGeomFromText('
GEOMETRYCOLLECTION(
COMPOUNDCURVE(
CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),
(-90 23.43778, -90 -23.43778)
),
COMPOUNDCURVE(
CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778),
(0 -23.43778, 0 23.43778)
)
**)
**',4326);
The following illustration shows the difference between circular arcs and linear strings for the same set of coordinates.
CIRCULARSTRING(0 50, 90 50, 180 50, 270 50, 0 50) -- RED LINE
and
LINESTRING (0 50, 90 50, 180 50, 270 50, 0 50) –- YELLOW LINE
Note*: The circular string defined in the previous example represents a circle on the globe, defined by five points in which the first and last coordinates are the same. You can create this feature as a curve polygon as follows.*
DECLARE @g GEOGRAPHY
SET @g = GEOGRAPHY::STGeomFromText('
**CURVEPOLYGON(
CIRCULARSTRING(0 50, 90 50, 180 50, 270 50, 0 50)
)
**',4326);
Existing Spatial Methods and Curved Objects
All existing methods work on circular objects (STIntersects is illustrated here).
New Methods for Circular Arcs (enhanced behavior in CTP3) BufferWithCurves() uses circular arcs to construct buffered object with greatly reduced number of points compared to STBuffer().
In CTP3, BufferWithCurves()of a point object constructs a curve polygon consisting of only 2 arcs, compared to 3 arcs in CTP1 (enhanced behavior in CTP3).
STNumCurves() and STCurveN() are used for iteration through the list of the circular arc edges.
STCurveToLine() and CurveToLineWithTolerance() are used for approximating circular arcs with line segments within default and user specific tolerance.
Note*: STCurveToLine and CurveToLineWithTolerance can be used to convert both LineStrings/MultiLineStrings and Polygons/MultiPolygons that have circular arc components to linear representations of the same dimensionality. This can use useful for:*
- Spatial object representation in visualization programs
- Backward compatibility with earlier versions of SQL Server that have spatial data support
New and Updated Methods and Aggregates for Both Spatial Types (enhanced behavior in CTP3)
IsValidDetailed() returns a message that can help in identifying validity issues with a spatial object. Only the first error found is returned unless the object is valid, in which case a value of 24400 is returned (new to CTP3).
Messages:
- 24400: Valid
- 24401: Not valid, reason unknown.
- 24402: Not valid because point ({0}) is an isolated point, which is not valid in this type of object.
- 24403: Not valid because some pair of polygon edges overlap.
- 24404: Not valid because polygon ring ({0}) intersects itself or some other ring.
- 24405: Not valid because some polygon ring intersects itself or some other ring.
- 24406: Not valid because curve ({0}) degenerates to a point.
- 24407: Not valid because polygon ring ({0}) collapses to a line at point ({1}).
- 24408: Not valid because polygon ring ({0}) is not closed.
- 24409: Not valid because some portion of polygon ring ({0}) lies in the interior of a polygon.
- 24410: Not valid because ring ({0}) is the first ring in a polygon of which it is not the exterior ring.
- 24411: Not valid because ring ({0}) lies outside the exterior ring ({1}) of its polygon.
- 24412: Not valid because the interior of a polygon with rings ({0}) and ({1}) is not connected.
- 24413: Not valid because of two overlapping edges in curve ({0}).
- 24414: Not valid because an edge of curve ({0}) overlaps an edge of curve ({1}).
- 24415: Not valid some polygon has an invalid ring structure.
- 24416: Not valid because in curve ({0}) the edge that starts at point ({1}) is either a line or a degenerate arc with antipodal endpoints.
The following example of an invalid spatial object illustrates how the new IsValidDetailed() methods behaves.
DECLARE @p GEOGRAPHY = 'Polygon((2 2, 4 4, 4 2, 2 4, 2 2))'
SELECT @p.**IsValidDetailed()
**--Returns: 24409: Not valid because some portion of polygon ring (1) lies in the interior
--of a polygon.
HasZ returns 1 if spatial objects contains at least one Z value, otherwise 0 is returned (new to CTP3).
DECLARE @p GEOGRAPHY = 'Point(1 1 1 1)'
SELECT @p.**HasZ**
--Returns: 1 (true)
HasM returns 1 if spatial objects contains at least one M value, otherwise 0 is returned (new to CTP3).
DECLARE @p GEOGRAPHY = 'Point(1 1 1 1)'
SELECT @p.**HasM**
--Returns: 1 (true)
**AsBinaryZM()**adds support for Z and M values to the OGC WKB format (new to CTP3).
DECLARE @g1 GEOMETRY = 'Point(1 1 2 3)';
SELECT @g1.STAsBinary();
-- Returns: 0x0101000000000000000000F03F000000000000F03F
SELECT @g1.**AsBinaryZM()**;
--Returns: 0x01B90B0000000000000000F03F000000000000F03F00000000000000400000000000000840
ShortestLineTo() returns a LineString that represents the shortest distance between two objects. The resulting LineString does not have to touch either parent object on a shape-defining vertex point.
The following example is not related to the previous graphic:
DECLARE @a GEOGRAPHY = 'LineSTring(-118 34, -119 35)'
DECLARE @b GEOGRAPHY = 'Polygon((-120 22, -119 22, -119 23, -120 23, -120 22))'
SELECT @a.**ShortestLineTo(@b)**.STAsText()
--Returns: LINESTRING (-118.00000000000001 34.000000000000007, -119 23.000000000000004)
The following aggregates are now available. They are exposed as static methods on geography and geometry types:
- UnionAggregate
- EnvelopeAggregate
- CollectionAggregate
- ConvexHullAggregate
Note*: The new aggregates are exposed in SQL Server only and are not exposed in the underlying spatial library.*
UnionAggregate() combines multiple spatial objects into a single spatial object, removing interior boundaries, where applicable.
SELECT Geography::UnionAggregate(geog) FROM Counties
WHERE name = 'Washington';
EnvelopeAggregate() for the geography type returns a bounding circular object as a CurvePolygon which encloses one or more spatial objects.
SELECT Geography::EnvelopeAggregate(geog) FROM Counties
WHERE name = 'Washington';
Note*: Geography::EnvelopeAggregate() returns a CurvePolygon. To convert this object to a “traditional” polygon, use the STCurveToLine() method.*
EnvelopeAggregate() for the geometry type returns a 5 point polygon (rectangle) which encloses one or more spatial objects.
SELECT Geometry::EnvelopeAggregate(geom) FROM Counties
WHERE name = 'Washington';
*
*
CollectionAggregate() returns a geometry collection with one geometry part for each spatial object(s) in the selection set.
SELECT Geography::CollectionAggregate(geog) FROM Counties
WHERE name = 'Washington';
ConvexHullAggregate() returns a convex hull polygon which encloses one or more spatial objects
SELECT Geography::ConvexHullAggregate(geog) FROM Counties
WHERE name = 'Washington'
STLength() has been updated an now works on both valid and invalid LineStrings. This was done for LineStrings because the MakeValid method can remove overlapping parts. Typically a LineString is invalid due to overlapping segments, which may be caused by anomalies such as inaccurate GPS traces. Note: STLength() does not remove overlapping/invalid segments. Additionally, STLength() includes overlapping and invalid segments in the length value it returns. MinDbCompatibilityLevel() is a new method is used for backward compatibility. It indicates whether spatial objects can be recognized by SQL Server 2008 and SQL Server 2008 R2. DECLARE @C GEOMETRY DECLARE @L GEOMETRY Note: You can set the compatibility level of the database with the following Transact-SQL statement. --Set database compatibility level to SQL Server Code-Named "Denali" --Set database compatibility level to SQL Server 2008 Improved PrecisionAll constructions and relations are now done with 48 bits of precision, compared to 27 bits used in SQL Server 2008 and SQL Server 2008 R2. This can reduce the error caused by rounding of floating point coordinates for original vertex points by the internal computation. For example, consider the following coordinate, which was processed using the STUnion() method in SQL Server 2008 but which was not involved in the resulting geometry. Original Vertex Coordinate Original Vertex Coordinate After Computation Original Vertex Coordinate Original Vertex Coordinate After Computation 82.339026 29.661245 82.339026 29.662145 Sample code illustrating the improved precision in SQL Server Code-Named “Denali” compared to SQL Server 2008 (SQL Server 2008 R2): DECLARE @g1 GEOMETRY = 'POLYGON(( Note that the highlighted coordinate did not change its apparent precision after the union operation when executed on the SQL Server Code-Named “Denali” instance, illustrating the effect of the improved precision in the new server. Geography Type EnhancementsFullGlobe: Support for Geography Objects Larger Than a Logical HemisphereThe SQL Server Code-Named “Denali” Spatial Library supports objects that are larger than a logical hemisphere. Restricted to slightly less than a logical hemisphere in SQL Server 2008, geography featuresin SQL Server Code-Named “Denali” can now be as big as entire globe. A new type of object, called FULLGLOBE, can be constructed or received as a result of an operation. You can also construct objects that are “small holes” (see the following picture), because the interior for geography objects is defined by the orientation of its rings. There is no difference between exterior and interior rings in the geography data type. Here is a simple example that constructs a new FullGlobe object and executes a method on that object. DECLARE @g GEOGRAPHY = GEOGRAPHY::STGeomFromText('FULLGLOBE',4326); The specified input does not represent a valid geography instance because it exceeds a single hemisphere. Each geography instance must fit inside a single hemisphere. A common reason for this error is that a polygon has the wrong ring orientation. For the SQL Server geography data type, ring order is defined by the left-foot rule. The left-foot rule specifies the interior region of the polygon (when you “walk” the boundary of a polygon, your left foot is always inside). Traditional outer ring/inner ring (hole) relationships can be modeled on the closed surface of the globe by using this definition.Note: The term “left-foot rule” is used in deference to the term “left-hand rule,” which is already in use by physicists and mathematicians to describe phenomena other than polygon ring order. DECLARE @R GEOGRAPHY; The following Transact-SQL changes the coordinate order of the polygon ring to the opposite direction of the previous example. DECLARE @R GEOGRAPHY; The resulting object is now the “rest of the globe.” There are several other considerations which need to be taken into account with the FullGlobe enhancements to the geography type:
|
New Methods for the geography Type
The geography type now allows invalid objects to be inserted into a table. The following new methods deal with such objects.
STIsValid() and MakeValid() allow invalid geography objects to be detected and corrected in a similar fashion to the geometry type.
Geography polygons can now be accommodated without regard to ring orientation. This can lead to unintended behavior. The following new method allows such polygons to be reoriented.
**ReorientObject()**can be used to reorient polygon rings for cases where they are constructed with the wrong orientation. LineStrings, curves and points will not be touched.
Here is an example.
DECLARE @R GEOGRAPHY = GEOGRAPHY::Parse('Polygon((-10 -10, -10 10, 10 10,
10 -10, -10 -10))');
SELECT @R.**ReorientObject()**.STAsText();
--Result: POLYGON ((10 10, -10 10, -10 -10, 10 -10, 10 10))
STWithin(), STContains(), STOverlaps(), and STConvexHull() methods have been added for the geography type, previously available only for the geometry type. With the exception of STConvexHull(), these new methods are supported by spatial indexes.
New SRID (new to CTP3)A new spatial reference id (SRID), 104001, has been added to the sys.spatial_reference_systems view. This new SRID is an Earth unit sphere (a sphere of radius 1) and can be used with the geography type to perform optimized numerical computations when more precise ellipsoidal mathematics are not required. Furthermore, Distance(), Length() and ShortestLineTo() methods are optimized to run faster on the unit sphere than their counterparts on the ellipsoid. To compute measures, such as length and area, on a given sphere (as defined by its radius), simply multiply results by the radius of the desired sphere:
The following examples illustrate how to work with unit sphere on the geography type. -- LineString length along the Prime Meridian from the Equator to the -- LineString length on the WGS84 Sphere (major radius = 6378137 meters)… -- Area of the FULLGLOBE on the unit sphere… -- To return the area of the WGS84 Sphere (major radius = |
Performance Improvements (enhanced behavior in CTP3)
SQL Server Code-Named “Denali” CTP1 includes features and enhancements that improve performance. These include new spatial indexes, a spatial index hint, compression, improved index build time, and a new query plan. Additionally, CTP3 provides further performance enhancements at the spatial library level for Distance() and ShortestLineTo() methods with corresponding performance improvements at the SQL level for methods which are based on them including STDistance() and ShortestLineTo() (new CTP3 content).
Spatial Index Improvements
New spatial indexes provide further levels of tuning, and a new hint helps you fine-tune query performance.
New Spatial Indexes: Geometry Auto Grid and Geography Auto Grid
A new auto grid spatial index is available for both spatial types (geometry_auto_grid and geography_auto_grid). The GRIDS parameter is no longer valid or needed when this index type is used. The new auto grid actually uses a different strategy to pick the right tradeoff between performance and efficiency. It uses eight levels (instead of four) for better approximation of objects of various sizes. The older style spatial index with four user-specified levels is still supported and is now referred to as a “manual grid” spatial index.
The new geography auto grid also eliminates the performance penalty on queries using a geography manual grid index when the indexed geography column contains EMPTY or NULL spatial data. Here are some examples that use the new auto grid for the geography data type. CREATE SPATIAL INDEX idxGeog or CREATE SPATIAL INDEX idxGeog If an index type is not specified in the CREATE SPATIAL INDEX DDL, the appropriate auto grid for the specified spatial column data type is used by default. In the following example, if the spatial column data type is geography, the GEOGRAPHY_AUTO_GRID is used by default. CREATE SPATIAL INDEX idxGeog The following figure illustrates spatial object approximation with 64, 128, and 256 cells_per_object, respectively, on the new eight-level auto grid. New auto grid spatial indexes have better continuous coverage and higher precision. The default number of cells per object for the new auto grid is 8 for geometry and 12 for geography. For original GEOMETRY_GRID and GEOGRAPHY_GRID indexes, the default for CELLS_PER_OBJECT remains the same as previous at 16. Note: The CELLS_PER_OBJECT parameter is not used for point objects. It is used for all other objects, including multipoint objects. SPATIAL_WINDOW_MAX_CELLS: New Spatial Index HintThis new spatial hint is critical for fine-tuning query performance using a spatial index. Dense spatial data often requires a higher SPATIAL_WINDOW_MAX_CELLS, whereas sparse spatial data often demands a lower SPATIAL_WINDOW_MAX_CELLS for optimum performance. This hint can be used as follows. SELECT * SPATIAL_WINDOW_MAX_CELLS hint does not guarantee that spatial index would be used in the query plan. However, if it is used hint will override the default WINDOW_MAX_CELLS parameter. The default WINDOW_MAX_CELLS parameter is 512 for geometry and 768 for geography. Higher values make the spatial index more efficient, but the primary filter is slower. Lower values make the primary filter faster, but more time is spent in the secondary filter due to potentially poorer index efficiency, with the optimum somewhere in between. For example, in the following illustration, 256 cells is the optimum query window. This chart shows query execution time (in milliseconds) compared to the old configurations (HHHH, HHMM, and MMMM in the three left-hand columns). Total times are combined primary filter times and secondary filter times. Making spatial indexes more precise improves overall performance until the tipping point is reached. Note: For SQL Server 2008, this parameter was always set to 1024 and was not modifiable. Compression for Spatial IndexesCompression can be enabled on spatial indexes with Transact-SQL DDL. CREATE SPATIAL INDEX idxGeom On the basis of internal tests, spatial indexes with compression are 40-50 percent smaller, with a 5-10 percent performance overhead. Improved “Create Spatial Index” Build Time for Point DataSpatial index build time for point data can be as much as four to five times faster than it is under similar conditions in SQL Server 2008. New Nearest Neighbor Query PlanA nearest neighbor query plan can be expressed as follows (the query elements highlighted in red are required for making the query optimizer process queries using a nearest neighbor query plan). SELECT TOP(5) * It can also be expressed with limited maximum distance via the @max_range variable, below. SELECT TOP(5) * This enhancement uses a spatial index to filter out rows and speed up query execution. With a spatial index, nearest neighbor execution time is up to two orders of magnitude faster (10 to 30 times) than a counterpart query in SQL Server 2008. Other Performance ImprovementsThe methods STIntersects(), STWithin(), STContains(), and STOverlaps() are now optimized when at least one of the operands is a point. STDistance() performance between two points has been optimized. STBuffer() has been optimized and improved for all cases. It’s faster and has lower memory footprint, especially for large and complex objects. Other ImprovementsSQL Server Code-Named “Denali” also introduces other improvements to the way spatial data is handled. These improvements include two new stored procedures, general engine improvements, and client-side library changes. Spatial Helper Stored ProceduresTwo new helper stored procedures are available:
These routines can be used to evaluate the distribution of spatial data within a table over a given spatial column. For example, the following query uses the sp_help_spatial_geography_histogram stored procedure to return information about the distribution of spatial data in the Mexico table for the geography column. EXEC sp_help_spatial_geography_histogram Mexico,geography,1000,100 Arguments: <table name>, <spatial column>, <cell size>, <sample %> Here is sample output from the previous query. With some additional programming, data from these stored procedures can be used for external visualization, shown over Bing Maps. General Engine Improvements That Affect Spatial TypesSQL Server Code-Named “Denali” CTP1 includes support for persisted computed columns and improved CLR UDT performance. Support for Persisted Computed ColumnsUDTs and spatial types can now be persisted in computed columns as shown in the following example. CREATE TABLE location ( Improved CLR UDT Aggregate Performance Client-Side Library ChangesNew sink interfaces, IGeometrySink110 and IGeographySink110, are available, and you should plan to use them in your future programming. They must be used for the following types of objects, which are incompatible with SQL Server 2008:
However, the old sinks will continue to work for SQL Server 2008 compatible objects. Geometry and Geography builders (SqlGeometryBuilder and SqlGeographyBuilder) now support circular arc constructions. A new method, Deserialize, has been added on the client library to both types. This method simplifies deserialization. The following code shows how to use it to deserialize SqlBytes. using (SqlConnection con = new SqlConnection("...")) ConclusionThe new spatial features in SQL Server Code-Named “Denali” CTP1 and CTP3 represent a significant milestone in the evolution of SQL Server spatial data support. The ability to support full globe spatial objects and circular arcs on the ellipsoid are industry firsts for relational database systems. The geography data type has achieved parity relative to the function and variety of methods that support the geometry data type. Overall performance, from spatial indexes to methods, has been significantly increased. These and other improvements to spatial promise a significant step forward in spatial prowess of the next generation of SQL Server. Appendix I – Spatial Methods and AggregatesEntries in black type indicate methods/aggregates which were present in SQL Server 2008 and SQL Server 2008 R2. Green and blue cells indicate methods/aggregates which are new to SQL Server Code-named “Denali”. Where these occur in table, below, the third column, Denali CTP, indicates in which Denali Community Technology Preview they first appeared in for SQL Server Code-Named “Denali”. Blank entries indicate no current method/aggregate. Entries with “na” indicate not applicable. There are 83 Geography and 89 Geometry methods.
Note that all methods prefixed with “ST” are OGC-compatible. Appendix II – Spatial Type ClassesEntries in black type indicate classes which were present in SQL Server 2008 and SQL Server 2008 R2. Red type indicates classes which are new to SQL Server Code-Named “Denali”. Where these occur in table, below, the third column, Denali CTP, indicates in which Denali Community Technology Preview they first appeared. Entries with “na” indicate not applicable.
Note that all classes are OGC-compatible with the exception of FullGlobe, which is a new concept.
|