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.

STInsertN: Insert single vertex into a geometry

Saturday April 27 2019 at 16:04

KeywordsSTInsertN insert single vertex geometry
Summary

This function allows a single vertex to be inserted into a geometry object at a nominated position.

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 ST_InsertN function, which inserts a new coordinate in a supplied geometry at specific position.

  1. CREATE FUNCTION [dbo].[STInsertN]
  2. (
  3.   @p_geometry geometry,
  4.   @p_point    geometry,
  5.   @p_position INTEGER,
  6.   @p_round_xy INT   = 3,
  7.   @p_round_zm INT   = 2
  8. )
  9. RETURNS geometry
  10. AS
  11. BEGIN
  12.   -- Implementation details in source code.
  13. END
  14. GO

Description

Function that inserts the coordinate p_point into position p_position in the supplied geometry.
p_position Values: 1. null -> defaults to 1; 2. -1 -> maximum number of points ie STNumPoints(p_geometry) 3. Greater than STNumPoints(p_geometry) -> maximum number of points ie STNumPoints(p_geometry) The inserted coordinate's ordinates are rounded to p_round_xy number of decimal digits of precision.

Arguments

  1. @p_geometry (geometry) - Supplied geometry OF any TYPE.
  2. @p_point    (geometry) - INSERT coordinate
  3. @p_position (INT)      - Coordinate POSITION IN @p_geometry: BETWEEN 1 AND STNumPoints.
  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. -- Null p_geometry Parameter returns p_point
  2. SELECT 1 AS testid,
  3.        [dbo].[STInsertN](NULL,
  4.                           geometry::Point(9,9,0) /* 2D */,
  5.                           1,3,NULL).AsTextZM() AS geom
  6. GO
  7. testid  geom
  8. 1 POINT (9 9)
  9. -- Null p_geometry Parameter returns p_point
  10. SELECT 2 AS testid,
  11.        [dbo].[STInsertN](NULL,
  12.                           geometry::STPointFromText('POINT(9 9 0)',0) /* 3D */,
  13.                           1,3,2).AsTextZM() AS geom
  14. GO
  15. testid  geom
  16. 2 POINT (9 9 0)
  17. -- No point to add so return geometry
  18. SELECT 3 AS testid,
  19.        [dbo].[STInsertN](geometry::STGeomFromText('LINESTRING(0 0, 10 0)',0),
  20.                       NULL,
  21.                       1,3,2).AsTextZM() AS geom
  22. GO
  23. testid  geom
  24. 3 LINESTRING (0 0, 10 0)
  25. -- Geometry Collections not supported, so is returned.
  26. SELECT 4 AS testid,
  27.        [dbo].[STInsertN](geometry::STGeomFromText('GEOMETRYCOLLECTION(POINT(2 3 4),LINESTRING(2 3 4,3 4 5))',0),
  28.                           geometry::Point(9,9,0),
  29.                           1,3,2).AsTextZM() AS geom
  30. GO
  31. testid  geom
  32. 4 GEOMETRYCOLLECTION (POINT (2 3 4), LINESTRING (2 3 4, 3 4 5))
  33. -- p_point must be point, so geometry is returned.
  34. SELECT 5 AS testid,
  35.        [dbo].[STInsertN](geometry::STGeomFromText('LINESTRING(0 0, 10 0)',0),
  36.                          geometry::STGeomFromText('POLYGON((1 1, 1 6, 11 6, 11 1, 1 1))',0),
  37.                          1,3,2).AsTextZM() AS geom
  38. GO
  39. testid  geom
  40. 5 LINESTRING (0 0, 10 0)
  41. -- Insert from begining to end
  42. SELECT 6 AS testid,
  43.        a.IntValue AS insert_position,
  44.        [dbo].[STInsertN](geometry::STGeomFromText('LINESTRING(0 0, 10 0)',0),
  45.                           geometry::Point(9,9,0),
  46.                           a.IntValue,
  47.                           0,
  48.                           2).AsTextZM() AS geom
  49.   FROM [dbo].[generate_series](-1,4,1) a
  50. GO
  51. testid  insert_position geom
  52. 6 -1  LINESTRING (0 0, 10 0, 9 9)
  53. 6 0 LINESTRING (9 9, 0 0, 10 0)
  54. 6 1 LINESTRING (9 9, 0 0, 10 0)
  55. 6 2 LINESTRING (0 0, 9 9, 10 0)
  56. 6 3 LINESTRING (0 0, 10 0, 9 9)
  57. 6 4 LINESTRING (0 0, 10 0, 9 9)
  58. SELECT 7 AS testid,
  59.        [dbo].[STInsertN](geometry::STGeomFromText('MULTILINESTRING((0 0,1 1,1 2),(2 3,3 2,5 4))',0),
  60.                               geometry::Point(0.5,0.5,0),
  61.                               2,
  62.                               3,2).AsTextZM() AS geom;
  63. GO
  64. testid  geom
  65. 7 MULTILINESTRING ((0 0, 0.5 0.5, 1 1, 1 2), (2 3, 3 2, 5 4))
  66. -- Add point to start of multipoint
  67. SELECT 8 AS testid,
  68.        [dbo].[STInsertN](geometry::STGeomFromText('MULTIPOINT(1 2 3)',0), /* 3D */
  69.                           geometry::Point(9.4,9.7,0), /* 2D */
  70.                           1,
  71.                           3,
  72.                           2).AsTextZM() AS geom
  73. GO
  74. testid  geom
  75. 8 MULTIPOINT ((9.4 9.7), (1 2 3))
  76. -- Add point to end of multipoint
  77. SELECT 9 AS testid,
  78.        [dbo].[STInsertN](geometry::STGeomFromText('MULTIPOINT(1 2 3)',0),
  79.                           geometry::Point(9.4,9.7,0),
  80.                           -1,
  81.                           3,
  82.                           2).AsTextZM() AS geom
  83. GO
  84. testid  geom
  85. 9 MULTIPOINT ((1 2 3), (9.4 9.7))
  86. -- Point -> Multipoint from two points
  87. SELECT 10 AS testid,
  88.        t.intValue AS POSITION,
  89.        [dbo].[STInsertN](geometry::STGeomFromText('POINT(0 0 0)',  0),
  90.                          geometry::STGeomFromText('POINT(3 3 2 2)',0),
  91.                          t.IntValue,
  92.                          1,2).AsTextZM() AS geom
  93.   FROM dbo.Generate_Series(-1,1,1) AS t
  94.  WHERE t.IntValue <> 0
  95. GO
  96. testid  POSITION  geom
  97. 10  -1  MULTIPOINT ((0 0 0), (3 3 2))
  98. 10  1 MULTIPOINT ((3 3 2), (0 0 0))
  99. WITH geoms AS (
  100.           SELECT 1 AS id, geometry::Point(16394506.234,-5283738.5676878,3857)  AS p_point,
  101.                  0 AS p_insert_point, 2 AS p_precision
  102. UNION ALL SELECT 2 AS id, geometry::STGeomFromText('MULTIPOINT(1 2 3)',3857)   AS p_point,
  103.                  1 AS p_insert_point, 0 AS p_precision
  104. UNION ALL SELECT 3 AS id, geometry::STGeomFromText('MULTIPOINT(1 2 3 4)',3857) AS p_point,
  105.                  2 AS p_insert_point, 0 AS p_precision
  106. )
  107. SELECT 11 AS testid,
  108.        [dbo].[STInsertN](a.p_point,
  109.                           geometry::Point(1111111.234,-222222222.567,3857),
  110.                           a.p_insert_point,
  111.                           a.p_precision,
  112.                           2).AsTextZM() AS geom
  113.  FROM geoms a
  114. GO
  115. testid  geom
  116. 11  MULTIPOINT ((1111111.23 -222222222.57), (16394506.23 -5283738.57))
  117. 11  MULTIPOINT ((1111111 -222222223), (1 2 3))
  118. 11  MULTIPOINT ((1 2 3 4), (1111111 -222222223))
  119. -- Insert Point with NULL Z ordinates
  120. SELECT 12 AS testid,
  121.        a.IntValue AS InsertPosn,
  122.        [dbo].[STInsertN](geometry::STGeomFromText('LINESTRING (63.29 914.361 NULL 1, 73.036 899.855 NULL 18.48, 80.023 897.179 NULL 25.96, 79.425 902.707 NULL 31.52, 91.228 903.305 NULL 43.34, 79.735 888.304 NULL 62.23, 98.4 883.584 NULL 81.49, 115.73 903.305 NULL 107.74, 102.284 923.026 NULL 131.61, 99.147 899.271 NULL 155.57, 110.8 902.707 NULL 167.72, 90.78 887.02 NULL 193.15, 96.607 926.911 NULL 233.47, 95.71 926.313 NULL 234.55, 95.412 928.554 NULL 236.81, 101.238 929.002 NULL 242.65, 119.017 922.279 NULL 261.66)',0),
  123.                          geometry::STGeomFromText('POINT (80.5823 901.3054 NULL 30)',0),
  124.                          a.IntValue,
  125.                          1,2).AsTextZM() AS geom
  126.   FROM [dbo].[generate_series](-1,4,1) a
  127. GO
  128. testid  InsertPosn  geom
  129. 12  -1  LINESTRING (63.3 914.4 NULL 1, 73 899.9 NULL 18.48, 80 897.2 NULL 25.96, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66, 80.6 901.3 NULL 30)
  130. 12  0 LINESTRING (80.6 901.3 NULL 30, 63.3 914.4 NULL 1, 73 899.9 NULL 18.48, 80 897.2 NULL 25.96, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66)
  131. 12  1 LINESTRING (80.6 901.3 NULL 30, 63.3 914.4 NULL 1, 73 899.9 NULL 18.48, 80 897.2 NULL 25.96, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66)
  132. 12  2 LINESTRING (63.3 914.4 NULL 1, 80.6 901.3 NULL 30, 73 899.9 NULL 18.48, 80 897.2 NULL 25.96, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66)
  133. 12  3 LINESTRING (63.3 914.4 NULL 1, 73 899.9 NULL 18.48, 80.6 901.3 NULL 30, 80 897.2 NULL 25.96, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66)
  134. 12  4 LINESTRING (63.3 914.4 NULL 1, 73 899.9 NULL 18.48, 80 897.2 NULL 25.96, 80.6 901.3 NULL 30, 79.4 902.7 NULL 31.52, 91.2 903.3 NULL 43.34, 79.7 888.3 NULL 62.23, 98.4 883.6 NULL 81.49, 115.7 903.3 NULL 107.74, 102.3 923 NULL 131.61, 99.1 899.3 NULL 155.57, 110.8 902.7 NULL 167.72, 90.8 887 NULL 193.15, 96.6 926.9 NULL 233.47, 95.7 926.3 NULL 234.55, 95.4 928.6 NULL 236.81, 101.2 929 NULL 242.65, 119 922.3 NULL 261.66)

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