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.

STUpdate: Replace all points equal to the supplied point with replacement point.

Friday April 26 2019 at 14:30

KeywordsSTUpdate replace or update vertices or coordinates in a geometry object.
Summary

Update or replace vertices in a geometry

SQL Server Spatial, unlike spatial database type systems such as PostGIS, does not provide coordinate editing functions:

  • STAddPoint
  • STUpdatePoint
  • STDeletePoint

These functions are not a part of either the SQL or OGC standards. In fact neither provide an API for the SQL editing of geometry objects. If one wishes to do so, one must program replacement functions. For SQL based solutions (eg based on TSQL) one must manipulate a geometry’s Well Know Text (WKT) description. This is pretty ugly (unless you are an Oracle Locator/Spatial user and so can access the array holding the ordinate values), so to wrap such access in specific SQL accessible functions is of use.

This article introduces the STUpdate function, which updates (replaces) all geometry points that are equal to the supplied point with the replacement point.

  1. CREATE FUNCTION [$(owner)].[STUpdate]
  2. (
  3.   @p_geometry    geometry,
  4.   @p_original_pt geometry,
  5.   @p_replace_pt  geometry,
  6.   @p_round_xy    INT = 3,
  7.   @p_round_zm    INT = 2
  8. )
  9.   RETURNS geometry
  10. AS
  11. BEGIN
  12.     -- Implementation
  13. END
  14. GO

Description

Function that updates all coordinates that equal p_point with the supplied p_replace_point.
The p_round_xy value is used when comparing geometry point's XY ordinates to p_point’s.
The updated coordinate’s XY ordinates are rounded to p_round_xy number of decimal digits of precision. The updated coordinate's ZM ordinates are rounded to p_round_ZM number of decimal digits of precision.

Arguments

  1. @p_geometry      (geometry) - supplied geometry OF any TYPE.
  2. @p_point         (geometry) - Original coordinate TO be replaced.
  3. @p_replace_point (geometry) - Replacement coordinate
  4. @p_round_xy      (INT)      - DECIMAL degrees OF PRECISION TO which calculated XY ordinates are rounded.
  5. @p_round_zm      (INT)      - DECIMAL degrees OF PRECISION TO which calculated ZM ordinates are rounded.

Examples

  1. SELECT [dbo].[STUpdate](geometry::STGeomFromText('POINT(0 0 1 1)',0),
  2.                         geometry::STGeomFromText('POINT(0 0 1 1)',0),
  3.                         geometry::STGeomFromText('POINT(1 1 1 1)',0),2,1).AsTextZM() AS WKT
  4. GO
  5. WKT
  6. POINT (1 1 1 1)
  7. SELECT [dbo].[STUpdate](geometry::STGeomFromText('MULTIPOINT((1 1 1 1),(2 2 2 2),(3 3 3 3))',0),
  8.                         geometry::STGeomFromText('POINT(2 2 2 2)',0),
  9.                         geometry::STGeomFromText('POINT(2.1 2.1 2 2)',0),2,1).AsTextZM() AS WKT
  10. GO
  11. WKT
  12. MULTIPOINT ((1 1 1 1), (2.1 2.1 2 2), (3 3 3 3))
  13. SELECT [dbo].[STUpdate](geometry::STGeomFromText('LINESTRING(1 1, 2 2, 3 3, 4 4)',0),
  14.                         geometry::STGeomFromText('POINT(3 3)',0),
  15.                         geometry::STGeomFromText('POINT(2.1 2.5)',0),2,1).AsTextZM() AS WKT
  16. GO
  17. WKT
  18. LINESTRING (1 1, 2 2, 2.1 2.5, 4 4)
  19. SELECT [dbo].[STUpdate](geometry::STGeomFromText('MULTILINESTRING((1 1,2 2,3 3),(4 4,5 5,6 6))',0),
  20.                         geometry::STGeomFromText('POINT(3 3)',0),
  21.                         geometry::STGeomFromText('POINT(3.1 3.3)',0),2,1).AsTextZM() AS WKT
  22. GO
  23. WKT
  24. MULTILINESTRING ((1 1, 2 2, 3.1 3.3), (4 4, 5 5, 6 6))
  25. SELECT [dbo].[STUpdate](geometry::STGeomFromText('COMPOUNDCURVE(CIRCULARSTRING(9.962 -0.872,10.1 0,9.962 0.872),(9.962 0.872,0 0,9.962 -0.872))',0),
  26.                         geometry::STGeomFromText('POINT(9.962 0.872)',0),
  27.                         geometry::STGeomFromText('POINT(9.9 0.9)',0),2,1).AsTextZM() AS WKT
  28. GO
  29. WKT
  30. COMPOUNDCURVE (CIRCULARSTRING (9.962 -0.872, 10.1 0, 9.9 0.9), (9.9 0.9, 0 0, 9.962 -0.872))
  31. -- 'Polygon - First and lat point of ring update.
  32. SELECT [dbo].[STUpdate](geometry::STGeomFromText('POLYGON((1 1,10 1,10 10,1 10,1 1),(2 2,9 2,9 9,2 9,2 2))',0),
  33.                         geometry::STGeomFromText('POINT(1 1)',0),
  34.                         geometry::STGeomFromText('POINT(1.1 1.1)',0),2,1).AsTextZM() AS WKT
  35. GO
  36. WKT
  37. POLYGON ((1.1 1.1, 10 1, 10 10, 1 10, 1.1 1.1), (2 2, 9 2, 9 9, 2 9, 2 2))
  38. SELECT [dbo].[STUpdate](geometry::STGeomFromText('POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0))',28355),
  39.                         geometry::STGeomFromText('POINT(326000.0 5455000.0)',28355),
  40.                         geometry::STGeomFromText('POINT(326100.0 5455100.0)',28355),2,1).AsTextZM() AS WKT
  41. GO
  42. WKT
  43. POLYGON ((326100 5455100, 327000 5455000, 326500 5456000, 326100 5455100))
  44. SELECT [dbo].[STUpdate](geometry::STGeomFromText('GEOMETRYCOLLECTION(POINT(2 3 4),LINESTRING(2 3 4,3 4 5),POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0)))',0),
  45.                         geometry::STGeomFromText('POINT(3 4 5)',0),
  46.                         geometry::STGeomFromText('POINT(3.1 4.1 5.1)',0),2,1).AsTextZM() AS WKT
  47. GO
  48. WKT
  49. GEOMETRYCOLLECTION (POINT (2 3 4), LINESTRING (2 3 4, 3.1 4.1 5.1), POLYGON ((326000 5455000, 327000 5455000, 326500 5456000, 326000 5455000)))

The function can be downloaded from here

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