Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    New Version of Package of TSQL Spatial Functions
    Vectorize/Segmentize SQL Server 2012
    Coordinate Editing Functions for SQL Server Spatial
    Function to Scale a geometry object for SQL Server Spatial
    TSQL String Tokenizer Function for SQL Server
    geography/geometry to MBR helper functions
    generate_series for SQL Server 2008
    Extract Polygons from result of STIntersection in SQL Server Spatial
    Function to round ordinates of a SQL Server Spatial geometry object
    Extract elements of SQL Server Spatial geometry object
    Counting number of polygon rings SQL Server Spatial
    Filtering Polygon Rings in SQL Server Spatial
    Function to Move a geometry object in SQL Server Spatial
    Alternate Centroid Functions for SQL Server Spatial
    Function to Rotate geometry objects in SQL Server Spatial
    A GetVertices wrapper for DumpPoints in SQL Server 2008 Spatial
    Creating a Morton number Space Key generator for SQL Server
    Gridding a geometry or geography object (SQL Server Denali)
    On hinting spatial indexes
    Random Search Procedure (SQL Server 2008 Spatial)
    COGO: Converting (Google Earth) Formatted Longitude/Latitude points to decimal degrees (SQL Server)
    COGO: Convert Degrees, Minutes and Seconds values to Decimal Degrees
    COGO: DD2DMS Formatting a latitude/longitude decimal degree value
    COGO: Create point from bearing and distance
    COGO: Compute number of vertices required to stroke circle or circular arc
    COGO: Calculating the bearing between two points (SQL Server 2008 Spatial)
    COGO: Compute arc length subtended by angle centre of circle
    COGO: Compute chord length of segment of a circle (arc)
    COGO: Computing Arc To Chord (Arc2Chord) Separation
    COGO: Creating a stroked polygon from a circle's centre x,y and radius
    COGO: Finding centre and radius of a curve defined by three points: FindCircle function
    Identifying Tight Radius Curves sections within LineString geometry data
    Generating random point data for SQL Server 2008 Spatial
    New Presentation on Active (Searchable) Spatial Metadata for SQL Server 2008 Spatial and FreeText
    Checking is a column in a table or a view is of type geometry or geography
    Extracting geometry type string values from geometry/geography objects in SQL Server 2008 Spatial
    Vectorising geometry objects in SQL Server 2008
    MBR to geography/geometry helper functions
    Extracting geometry types from geometry/geography objects in SQL Server 2008
    Getting the number of coordinate dimensions of a geometry/geography object in SQL Server 2008
    A Dump Points Function for SQL Server 2008 Spatial
    toGeography and toGeography Conversion Functions for SQL Server 2008 Spatial
    Write text file with spatial data from SQL Server 2008
    Loading Shapefiles into Geography type column in SQL Server 2008
    Tip #6: Correcting invalid geometries
    Tip #5: Where or where has my little column gone
    Tip #4: What Coordinate System is that?
    Tip #3: What object is that?
    Tip #2: Spatial Indexing and Primary Keys
    Tip #1: SQL Server 2008 "Katmai" - Setting SRIDs

Search

    Browse

RSS / Atom

Email me

textpattern

Creative Commons License
All Blog Articles, Data Models and Free Source Code by Simon Greener, The SpatialDB Advisor is licensed under a Creative Commons Attribution-ShareAlike 3.0 Unported License.

Function to Rotate geometry objects in SQL Server Spatial

Friday December 30 2011 at 06:47

Keywordsrotate sql server denali spatial geometry polygon linestring point TSQL
Summary

A T-Sql based function for rotating a Sql Server Spatial geometry object around an arbitrary point.

If you have need for a TSQL based function for rotating geometry objects in SQL Server Spatial (Denali is required), here is a function you might find useful.

  1. USE [GISDB] -- Change this to your database
  2. GO
  3. -- Create Function
  4. --
  5. CREATE FUNCTION dbo.Rotate(@p_geometry  geometry,
  6.                        @p_X         FLOAT,
  7.                        @p_Y         FLOAT,
  8.                        @p_rotation  INT = 0,  -- 0 to 360 degrees
  9.                        @p_round_x   INT = 3,
  10.                        @p_round_y   INT = 3)
  11.   RETURNS geometry
  12. BEGIN
  13.   DECLARE
  14.      @v_coord          INT = 0,
  15.      @v_rows           INT = 0,
  16.      @v_wkt            VARCHAR(MAX) = '',
  17.      @v_token          VARCHAR(MAX),
  18.      @v_delim          VARCHAR(MAX),
  19.      @v_rx             FLOAT,   -- Rotation Point X ordinate
  20.      @v_ry             FLOAT,   -- Rotation Point Y ordinate
  21.      @v_cos_angle      FLOAT,
  22.      @v_sin_angle      FLOAT,
  23.      @v_geometry       geometry,
  24.      @v_x              FLOAT = 0,
  25.      @v_y              FLOAT = 0,
  26.      @v_z              VARCHAR(MAX) = '',
  27.      @v_m              VARCHAR(MAX) = '',
  28.      @v_gtype          nvarchar(100);
  29.   BEGIN
  30.     IF ( @p_geometry IS NULL )
  31.       RETURN NULL;
  32.     IF ( @p_X IS NULL OR @p_Y IS NULL )
  33.        RETURN CAST('Rotation X and Y must both not be NULL.' AS VARCHAR(MAX)); -- geometry);
  34.     IF ( @p_rotation IS NULL ) OR ( @p_rotation NOT BETWEEN -360 AND 360 )
  35.        RETURN CAST('Rotation value must be supplied and must be between 0 and 360.' AS VARCHAR(MAX)); -- geometry);
  36.     SET @v_gtype = @p_geometry.STGeometryType();
  37.     SET @v_cos_angle = COS(@p_rotation * PI()/180);
  38.     SET @v_sin_angle = SIN(@p_rotation * PI()/180);
  39.     IF ( @v_gtype = 'Point' )
  40.     BEGIN
  41.         -- x' = x Cos(¸) - y Sin(¸)
  42.         -- y' = x Sin(¸) + y Cos(¸)
  43.         SET @v_x = (@p_x + (
  44.                    ((@p_geometry.STX - @p_x) * @v_cos_angle) -
  45.                    ((@p_geometry.STY - @p_y) * @v_sin_angle)
  46.                    ));
  47.         SET @v_y = (@p_y + (
  48.                    ((@p_geometry.STX - @p_x) * @v_sin_angle) +
  49.                    ((@p_geometry.STY - @p_y) * @v_cos_angle)
  50.                    ));
  51.         SET @v_geometry = geometry::Point(round(@v_x, @p_round_x),
  52.                                           round(@v_y, @p_round_y),
  53.                                           @p_geometry.STSrid);
  54.     END
  55.     ELSE
  56.     BEGIN
  57.       IF ( @p_X IS NULL OR @p_Y IS NULL )
  58.       BEGIN
  59.         -- Get Center of shape's MBR as point around which to rotate
  60.         -- Should extend geometry package to return center of MBR (called ENVELOPE in geometry)
  61.         SELECT @v_rx = (a.minx + a.maxx / 2.0),
  62.                @v_ry = a.miny
  63.           FROM dbo.GEOMETRY2MBR(@p_geometry) AS a;
  64.       END
  65.       ELSE
  66.       BEGIN
  67.         SET @v_coord = 0;
  68.         SET @v_rows  = 0;
  69.         DECLARE Tokens CURSOR FAST_FORWARD FOR
  70.           SELECT t.token, t.separator
  71.             FROM dbo.Tokenizer(@p_geometry.AsTextZM(),' ,()') AS t;
  72.         OPEN Tokens;
  73.         FETCH NEXT FROM Tokens INTO @v_token, @v_delim;
  74.         WHILE @@FETCH_STATUS = 0
  75.         BEGIN
  76.            IF ( @v_token IS NULL )  -- double delimiter
  77.            BEGIN
  78.              SET @v_wkt = @v_wkt + @v_delim
  79.            END
  80.            ELSE
  81.            BEGIN
  82.               IF ( @v_token NOT LIKE '[-0-9]%' )
  83.               BEGIN
  84.                 SET @v_wkt = @v_wkt + @v_token + LTRIM(@v_delim)
  85.               END
  86.               ELSE -- @v_token LIKE '[0-9]%' )  
  87.               BEGIN
  88.                 SET @v_coord = @v_coord + 1;
  89.                 IF ( @v_coord = 1 ) SET @v_x = CAST(@v_token AS FLOAT)
  90.                 IF ( @v_coord = 2 ) SET @v_y = CAST(@v_token AS FLOAT)
  91.                 IF ( @v_coord = 3 ) SET @v_z = @v_token
  92.                 IF ( @v_coord = 4 ) SET @v_m = @v_token
  93.                 IF ( @v_delim IN (',',')') )
  94.                 BEGIN
  95.                    SET @v_wkt = @v_wkt +
  96.                                LTRIM(STR(round(((@v_x - @p_x) * @v_cos_angle - (@v_y - @p_y) * @v_sin_angle) + @p_x,@p_round_x),24,@p_round_x)) + ' ' +
  97.                                LTRIM(STR(round(((@v_x - @p_x) * @v_sin_angle + (@v_y - @p_y) * @v_cos_angle) + @p_y,@p_round_y),24,@p_round_y)) +
  98.                                CASE WHEN LEN(@v_z)=0 THEN '' ELSE ' ' + @v_z END +
  99.                                CASE WHEN LEN(@v_m)=0 THEN '' ELSE ' ' + @v_m END + @v_delim;
  100.                   SET @v_coord = 0;
  101.                 END;
  102.               END;
  103.            END;
  104.            FETCH NEXT FROM Tokens INTO @v_token, @v_delim;
  105.         END
  106.         CLOSE Tokens
  107.         DEALLOCATE Tokens
  108.        END;
  109.        SET @v_geometry = geometry::STGeomFromText(@v_wkt,@p_geometry.STSrid);
  110.     END;
  111.     RETURN @v_geometry;
  112.   END
  113. END
  114. GO

Now for some tests

Rotate rectangle about itself and the origin

  1. SELECT '' AS name, geometry::STGeomFromText('POLYGON((1 1, 1 6, 11 6, 11 1, 1 1))',0) AS geom
  2. UNION ALL
  3. SELECT '45' + CHAR(176) + ' rotate about 0,0' AS name, dbo.Rotate(geometry::STGeomFromText('POLYGON((1 1, 1 6, 11 6, 11 1, 1 1))',0),0.0,0.0,45,3,3) AS geomO
  4. UNION ALL
  5. SELECT '45' + CHAR(176) + ' rotate about MBR centre' AS name, dbo.Rotate(geometry::STGeomFromText('POLYGON((1 1, 1 6, 11 6, 11 1, 1 1))',0),(a.minx + a.maxx) / 2.0,(a.miny + a.maxy) / 2.0,45,3,3) AS geom
  6.   FROM dbo.geometry2mbr(geometry::STGeomFromText('POLYGON((1 1, 1 6, 11 6, 11 1, 1 1))',0) ) AS a;

The result looks like this (the background light blue rectangle is the original):

Point

  1. SELECT a.intValue AS oid,
  2.        CAST(a.intValue AS VARCHAR) + CHAR(176) AS label,
  3.        dbo.Rotate(geometry::STGeomFromText('POINT(0 10 0)',0),0,0,a.IntValue,3,3).STBuffer(1) AS geom
  4.   FROM dbo.generate_series(0,350,10) a;

The result looks like this:

Linestring

  1. SELECT a.intValue AS oid,
  2.        CAST(a.intValue AS VARCHAR) + CHAR(176) AS label,
  3.        dbo.Rotate(geometry::STGeomFromText('LINESTRING(0 0, 10 0)',0),0,0,a.IntValue,3,3).STBuffer(0.05) AS geom
  4.   FROM dbo.generate_series(0,350,10) a;

The result looks like this:

Curved polygon

  1. SELECT a.intValue AS deg,
  2.        CAST(a.intValue AS VARCHAR) + CHAR(176) AS label,
  3.        dbo.Rotate(geometry::STGeomFromText('CURVEPOLYGON(COMPOUNDCURVE(CIRCULARSTRING(9.962 -0.872,10.1 0,9.962 0.872),(9.962 0.872,0 0,9.962 -0.872)))',0),0,0,a.IntValue,3,3).STBuffer(0.00001) AS geom
  4.   FROM dbo.generate_series(0,350,10) a;

The result looks like this:

I hope this is of use to someone

Creative Commons License

post this at del.icio.uspost this at Diggpost this at Technoratipost this at Redditpost this at Farkpost this at Yahoo! my webpost this at Windows Livepost this at Google Bookmarkspost this to Twitter

Comment