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 Scale a geometry object for SQL Server Spatial

Friday April 13 2012 at 05:32

KeywordsScale ST_Scale STScale ordinate scaling geometry SQL Server Spatial
Summary

This article presents a simple function that allows for the scaling of the ordinates of a geometry object in Sql Server Spatial.

Here is a simple scaling function for use with SQL Server Spatial’s geometry data type.

  1. USE [GISDB] -- Change this to your database
  2. GO
  3. -- Drop function if exists
  4. --
  5. IF EXISTS (SELECT *
  6.              FROM dbo.sysobjects
  7.             WHERE id = object_id (N'[dbo].[STScale]'))
  8. DROP FUNCTION [dbo].[STScale]
  9. GO
  10. -- Now create the function
  11. --
  12. CREATE FUNCTION [dbo].[STScale](@p_geometry  geometry,
  13.                                 @p_xFactor   FLOAT,
  14.                                 @p_yFactor   FLOAT,
  15.                                 @p_zFactor   FLOAT,
  16.                 @p_mFactor   FLOAT,
  17.                 @p_round_x   INT = 3,
  18.                 @p_round_y   INT = 3,
  19.                 @p_round_z   INT = 2,
  20.                 @p_round_m   INT = 2)
  21.   RETURNS geometry
  22. BEGIN
  23.   DECLARE
  24.      @v_xFactor        FLOAT = CASE WHEN @p_xFactor IS NULL THEN 1.0 ELSE @p_xFactor END,
  25.      @v_yFactor        FLOAT = CASE WHEN @p_yFactor IS NULL THEN 1.0 ELSE @p_yFactor END,
  26.      @v_zFactor        FLOAT = CASE WHEN @p_zFactor IS NULL THEN 1.0 ELSE @p_zFactor END,
  27.      @v_mFactor        FLOAT = CASE WHEN @p_mFactor IS NULL THEN 1.0 ELSE @p_mFactor END,
  28.      @v_coord          INT = 0,
  29.      @v_wkt            VARCHAR(MAX) = '',
  30.    @v_token          VARCHAR(MAX),
  31.    @v_delim          VARCHAR(MAX),
  32.    @v_geometry       geometry,
  33.      @v_x              FLOAT = 0.0,
  34.      @v_y              FLOAT = 0.0,
  35.    @v_z              FLOAT = NULL,
  36.    @v_m              FLOAT = NULL;
  37.   BEGIN
  38.     IF ( @p_geometry IS NULL )
  39.       RETURN NULL;
  40.     IF ( @p_xFactor IS NULL AND @p_yFactor IS NULL AND @p_zFactor IS NULL AND @p_mFactor IS NULL )
  41.      RETURN CAST('One of scale factors X,Y,Z and M must not be NULL.' AS VARCHAR(MAX)); -- geometry);
  42.     SET @v_coord = 0;
  43.     DECLARE Tokens CURSOR FAST_FORWARD FOR
  44.     SELECT t.token, t.separator
  45.       FROM dbo.Tokenizer(@p_geometry.AsTextZM(),' ,()') AS t;
  46.   OPEN Tokens;
  47.     FETCH NEXT FROM Tokens INTO @v_token, @v_delim;
  48.     WHILE @@FETCH_STATUS = 0
  49.     BEGIN
  50.      IF ( @v_token IS NULL )  -- double delimiter
  51.      BEGIN
  52.           SET @v_wkt = @v_wkt + @v_delim
  53.      END
  54.        ELSE
  55.      BEGIN
  56.         IF ( @v_token NOT LIKE '[-0-9]%' )
  57.       BEGIN
  58.              SET @v_wkt = @v_wkt + @v_token + LTRIM(@v_delim)
  59.           END
  60.       ELSE -- @v_token LIKE '[0-9]%' )
  61.           BEGIN
  62.              SET @v_coord = @v_coord + 1;
  63.              IF ( @v_coord = 1 ) SET @v_x = CAST(@v_token AS FLOAT)
  64.              IF ( @v_coord = 2 ) SET @v_y = CAST(@v_token AS FLOAT)
  65.              IF ( @v_coord = 3 ) SET @v_z = CAST(@v_token AS FLOAT)
  66.              IF ( @v_coord = 4 ) SET @v_m = CAST(@v_token AS FLOAT)
  67.              IF ( @v_delim IN (',',')') )
  68.              BEGIN
  69.                 SET @v_wkt = @v_wkt +
  70.                  LTRIM(STR(round(@v_x * @v_xFactor, @p_round_x),24,@p_round_x)) + ' ' +
  71.                    LTRIM(STR(round(@v_y * @v_yFactor, @p_round_y),24,@p_round_y)) +
  72.                  CASE WHEN @v_z IS NULL THEN '' ELSE ' ' + LTRIM(STR(round(@v_z * @v_zFactor, @p_round_z),24,@p_round_z)) END +
  73.                  CASE WHEN @v_m IS NULL THEN '' ELSE ' ' + LTRIM(STR(round(@v_m * @v_mFactor, @p_round_m),24,@p_round_m)) END + @v_delim;
  74.                 SET @v_coord = 0;
  75.              END;
  76.            END;
  77.        END;
  78.        FETCH NEXT FROM Tokens INTO @v_token, @v_delim;
  79.   END;
  80.     CLOSE Tokens
  81.     DEALLOCATE Tokens
  82.     SET @v_geometry = geometry::STGeomFromText(@v_wkt,@p_geometry.STSrid);
  83.   RETURN @v_geometry;
  84.   END
  85. END
  86. GO

Now some tests.

  1. SELECT a.stype, a.geom.AsTextZM() AS geomWKT
  2.   FROM (SELECT 'Scaled2D' AS stype, dbo.STScale(geometry::STGeomFromText('LINESTRING (1 2 3, 1 1 1)',0), 0.5,0.75,NULL,NULL, 2,2,2,2) AS geom
  3.         UNION ALL
  4.         SELECT 'Original' AS stype, geometry::STGeomFromText('LINESTRING (1 2 3, 1 1 1)',0) AS geom ) a;

Results

sType geomWKT
Scaled2D LINESTRING (0.5 1.5 3, 0.5 0.75 1)
Original LINESTRING (1 2 3, 1 1 1)
  1. SELECT a.stype, a.geom.AsTextZM() AS geomWKT
  2.   FROM (SELECT 'Scaled3D' AS stype, dbo.STScale(geometry::STGeomFromText('LINESTRING (1 2 3, 1 1 1)',0), 0.5, 0.75, 0.8,NULL, 2,2,2,2) AS geom
  3.         UNION ALL
  4.         SELECT 'Original' AS stype, geometry::STGeomFromText('LINESTRING (1 2 3, 1 1 1)',0) AS geom ) a;

Results

sType geomWKT
Scaled3D LINESTRING (0.5 1.5 2.4, 0.5 0.75 0.8)
Original LINESTRING (1 2 3, 1 1 1)

Finally, a polygon.

  1. SELECT a.stype, a.geom.AsTextZM() AS geomWKT
  2.   FROM (SELECT 'Original' AS stype, geometry::STGeomFromText('POLYGON ((1 1, 2 1, 2 2, 1 2, 1 1))',0) AS geom
  3.         UNION ALL
  4.         SELECT 'Scaled2D' AS stype, dbo.STScale(geometry::STGeomFromText('POLYGON ((1 1, 2 1, 2 2, 1 2, 1 1))',0), 2.0, 2.0, NULL,NULL, 2,2,2,2) AS geom
  5.         UNION ALL
  6.         SELECT 'ScaledYOnly' AS stype, dbo.STScale(geometry::STGeomFromText('POLYGON ((1 1, 2 1, 2 2, 1 2, 1 1))',0), NULL, 2.0, NULL,NULL, 2,2,2,2) AS geom ) a;

Results

sType geomWKT
Original POLYGON ((1 1, 2 1, 2 2, 1 2, 1 1))
Scaled2D POLYGON ((2 2, 4 2, 4 4, 2 4, 2 2))
ScaledYOnly POLYGON ((1 2, 2 2, 2 4, 1 4, 1 2))

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