Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    STGeometryTypes: Extracting all geometry type string values from complex geometry
    STDensify: Densify (m)LineString or (m)Polygon geometry objects
    STInsertN: Insert single vertex into a geometry
    STUpdateN: Update (replace) a single vertex within a geometry object.
    STUpdate: Replace all points equal to the supplied point with replacement point.
    STDeleteN: Delete single vertex from geometry
    STDelete: Deleting vertices in geometry objects
    STFlipVectors: Normalize direction of linestring vectors
    STConvertToLineString: Extract LineStrings in GeometryCollection to create LineString
    STLine2Cogo: Converting LineStrings to COGO XML
    STCogo2Line: Creating (Multi)LineStrings geometries from COGO XML instructions
    STVectorize: Break Linestring/Polygon elements into 2 point vectors (or 3 point circular curves)
    STScale: Function to Scale a geometry object
    TSQL String Tokenizer Function for SQL Server
    STGeometry2MBR/STGeography2MBR: Compute and return MBR ordinates
    generate_series for SQL Server 2008
    STExtractPolygon: Extract Polygons from result of STIntersection in SQL Server Spatial
    STRound: Function to round ordinates of a SQL Server Spatial geometry object
    STExtract: Extract elements of a geometry object
    STNumRings: Counting number of polygon rings
    STFilterRings: Removing rings from Polygon based on area.
    STMove: Function to Move a geometry object in SQL Server Spatial
    STCentroid*: Alternate Functions for Compute a Centroid
    STRotate: Function to rotate a geometry object in SQL Server Spatial
    STVertices: Wrapper over STDumpPoints
    STMorton: Creating a Morton number Space Key value for grid square
    Gridding a geometry or geography object (SQL Server Denali)
    On hinting spatial indexes
    RandomSearchByExtent: Random Search Procedure (2008 Spatial)
    COGO: Convert DMS String to decimal degrees floating point number.
    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
    CheckRadii: 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
    STisGeo: Checking if a column in a table or a view is of type geometry or geography
    Vectorising geometry objects in SQL Server 2008
    STMBR2Geometry/STMBR2Geography 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
    STDumpPoints: A Function that Dumps the Vertices/Points in a geometry
    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.

STScale: Function to Scale a geometry object

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