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.

Vectorize/Segmentize SQL Server 2012

Monday October 17 2016 at 18:55

KeywordsSQL Server 2012 Vectorize Segmentize linear polygon geometry
Summary

Vectorize/Segmentize linear and polygon geometries.

I demonstrated in this article the usefulness of having a vectorising function in one’s spatial database kitbag (there are Vectorize functions in my CENTROID and GEOM packages – in particular the Vectorize function is vital to the implementation of the algorithm in my CENTROID.ST_CENTROID function).

So, I have also added one to my SQL Server 2008 kitbag and to SQL Server 2012.

This function, as against the PostGIS and Oracle implementation, does not use any object types due to limitations in the SQL Server 2012 TSQL system (my implementation deliberately does not use the CLR system).

  1. USE [GISDB]  -- Change this to your database
  2. GO
  3. IF EXISTS (
  4.     SELECT * FROM sysobjects WHERE id = object_id(N'STVECTORIZE')
  5.     AND xtype IN (N'FN', N'IF', N'TF')
  6. )
  7.     DROP FUNCTION [dbo].[STVECTORIZE];
  8. GO
  9. CREATE FUNCTION [dbo].[STVECTORIZE]( @p_geom geometry )
  10.   RETURNS @Vectors TABLE
  11.    (id INT,
  12.     sx FLOAT,
  13.     sy FLOAT,
  14.     sz FLOAT,
  15.     sm FLOAT,
  16.     ex FLOAT,
  17.     ey FLOAT,
  18.     ez FLOAT,
  19.     em FLOAT)  
  20. AS
  21. BEGIN
  22.   DECLARE
  23.     @v_GeometryType VARCHAR(1000),
  24.   @vector         INT,
  25.     @ringn          INT,
  26.     @geomn          INT,
  27.     @FIRST          INT,
  28.     @SECOND         INT,
  29.     @geom           geometry,
  30.     @start_geom     geometry,
  31.     @end_geom       geometry;
  32.   BEGIN
  33.     IF ( @p_geom IS NULL )
  34.       RETURN;
  35.     SET @v_GeometryType = @p_geom.STGeometryType();
  36.     IF ( @v_GeometryType IN ('Point','MultiPoint','GeometryCollection') )
  37.       RETURN;
  38.   SET @vector = 0;
  39.     IF ( @v_GeometryType = 'LineString' )
  40.     BEGIN
  41.       SET @FIRST  = 1;
  42.       SET @SECOND = 2;
  43.       WHILE ( @SECOND <= @p_geom.STNumPoints() )
  44.       BEGIN
  45.         SET @start_geom = @p_geom.STPointN(@FIRST);
  46.         SET @FIRST      = @FIRST  + 1;
  47.         SET @end_geom   = @p_geom.STPointN(@SECOND);
  48.         SET @SECOND     = @SECOND + 1;
  49.     SET @vector     = @vector + 1;
  50.         INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
  51.                VALUES ( @vector,
  52.                   @start_geom.STX,@start_geom.STY, @start_geom.Z,@start_geom.M,
  53.                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,  @end_geom.M  );
  54.       END;  
  55.       RETURN;
  56.     END;
  57.     IF ( @v_GeometryType = 'MultiLineString' )
  58.     BEGIN
  59.       SET @geomn  = 1;
  60.       WHILE ( @geomn <= @p_geom.STNumGeometries() )
  61.       BEGIN
  62.         SET @geom   = @p_geom.STGeometryN(@geomn);
  63.         SET @FIRST  = 1;
  64.         SET @SECOND = 2;
  65.         WHILE ( @SECOND <= @geom.STNumPoints() )
  66.         BEGIN
  67.           SET @start_geom = @geom.STPointN(@FIRST);
  68.           SET @FIRST      = @FIRST  + 1;
  69.           SET @end_geom   = @geom.STPointN(@SECOND);
  70.           SET @SECOND     = @SECOND + 1;
  71.           SET @vector     = @vector + 1;
  72.           INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
  73.                VALUES ( @vector,
  74.                   @start_geom.STX,@start_geom.STY, @start_geom.Z,@start_geom.M,
  75.                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,  @end_geom.M );
  76.         END;
  77.         SET @geomn = @geomn + 1;
  78.       END;
  79.       RETURN;
  80.     END;
  81.     IF ( @v_GeometryType = 'Polygon' )
  82.     BEGIN
  83.       SET @ringn  = 0;
  84.       WHILE ( @ringn < ( 1 + @p_geom.STNumInteriorRing() ) )
  85.       BEGIN
  86.         IF ( @ringn = 0 )
  87.           SET @geom = @p_geom.STExteriorRing()
  88.         ELSE
  89.           SET @geom = @p_geom.STInteriorRingN(@ringn);
  90.         SET @FIRST  = 1;
  91.         SET @SECOND = 2;
  92.         WHILE ( @SECOND <= @geom.STNumPoints() )
  93.         BEGIN
  94.           SET @start_geom = @geom.STPointN(@FIRST);
  95.           SET @FIRST      = @FIRST  + 1;
  96.           SET @end_geom   = @geom.STPointN(@SECOND);
  97.           SET @SECOND     = @SECOND + 1;
  98.           SET @vector     = @vector + 1;
  99.           INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
  100.                VALUES ( @vector,
  101.                   @start_geom.STX,@start_geom.STY, @start_geom.Z, @start_geom.M,
  102.                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,   @end_geom.M );
  103.         END;
  104.         SET @ringn = @ringn + 1;
  105.       END;
  106.       RETURN;
  107.     END;
  108.     IF ( @v_GeometryType = 'MultiPolygon' )
  109.     BEGIN
  110.       SET @geomn  = 1;
  111.       WHILE ( @geomn <= @p_geom.STNumGeometries() )
  112.       BEGIN
  113.         SET @geom   = @p_geom.STGeometryN(@geomn);
  114.         SET @ringn  = 0;
  115.         WHILE ( @ringn < ( 1 + @geom.STNumInteriorRing() ) )
  116.         BEGIN
  117.           IF ( @ringn = 0 )
  118.             SET @geom = @geom.STExteriorRing()
  119.           ELSE
  120.             SET @geom = @geom.STInteriorRingN(@ringn);
  121.           SET @FIRST  = 1;
  122.           SET @SECOND = 2;
  123.           WHILE ( @SECOND <= @geom.STNumPoints() )
  124.           BEGIN
  125.             SET @start_geom = @geom.STPointN(@FIRST);
  126.             SET @FIRST      = @FIRST  + 1;
  127.             SET @end_geom   = @geom.STPointN(@SECOND);
  128.             SET @SECOND     = @SECOND + 1;
  129.             SET @vector     = @vector + 1;
  130.             INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
  131.                  VALUES ( @vector,
  132.                     @start_geom.STX, @start_geom.STY, @start_geom.Z, @start_geom.M,
  133.                             @end_geom.STX,   @end_geom.STY,   @end_geom.Z,   @end_geom.M );
  134.           END;
  135.           SET @ringn = @ringn + 1;
  136.         END;
  137.         SET @geomn = @geomn + 1;
  138.       END;
  139.       RETURN;
  140.     END;
  141.   END;
  142.   RETURN;
  143. END;
  144. GO

Testing

Here’s a bunch of tests.

  1. SELECT v.*
  2.   FROM dbo.STVectorize(geometry::STGeomFromText(
  3. 'LINESTRING(0 0 10 10, 1 1 10 20, 2 2 10 30, 3 3 10 40)',0)) AS v;

Result Is:

id sx sy sz sm ex ey ez em
1 0 0 10 10 1 1 10 20
2 1 1 10 20 2 2 10 30
3 2 2 10 30 3 3 10 40
  1. SELECT v.*
  2.   FROM dbo.STVectorize(geometry::STGeomFromText(
  3. 'MULTILINESTRING((0 0,1 1,1 2),(2 3,3 2,5 4))',0)) AS v;

Result Is:

id sx sy sz sm ex ey ez em
1 0 0 NULL NULL 1 1 NULL NULL
2 1 1 NULL NULL 1 2 NULL NULL
3 2 3 NULL NULL 3 2 NULL NULL
4 3 2 NULL NULL 5 4 NULL NULL
  1. -- Ordinary polygon
  2. --
  3. SELECT v.*
  4.   FROM dbo.STVectorize(geometry::STGeomFromText(
  5. 'POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0))',0)) AS v;

Result Is:

id sx sy sz sm ex ey ez em
1 326000 5455000 NULL NULL 327000 5455000 NULL NULL
2 327000 5455000 NULL NULL 326500 5456000 NULL NULL
3 326500 5456000 NULL NULL 326000 5455000 NULL NULL
  1. -- Polygon with a hole
  2. --
  3. SELECT v.*
  4.   FROM dbo.STVectorize(geometry::STGeomFromText(
  5. 'POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
  6. (326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0))',0)) AS v;

Result is:

id sx sy sz sm ex ey ez em
1 326000 5455000 NULL NULL 327000 5455000 NULL NULL
2 327000 5455000 NULL NULL 326500 5456000 NULL NULL
3 326500 5456000 NULL NULL 326000 5455000 NULL NULL
4 326500 5455500 NULL NULL 326550 5455200 NULL NULL
5 326550 5455200 NULL NULL 326450 5455200 NULL NULL
6 326450 5455200 NULL NULL 326500 5455500 NULL NULL
  1. -- MultiPolygon With a hole
  2. --
  3. SELECT v.*
  4.   FROM dbo.STVectorize(geometry::STGeomFromText(
  5. 'MULTIPOLYGON(((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
  6. (326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0)),
  7. ((321000.0 5450000.0,322000.0 5450000.0,321500.0 5451000.0,321000.0 5450000.0)))',0))  AS v;

Result is:

id sx sy sz sm ex ey ez em
1 326000 5455000 NULL NULL 327000 5455000 NULL NULL
2 327000 5455000 NULL NULL 326500 5456000 NULL NULL
3 326500 5456000 NULL NULL 326000 5455000 NULL NULL
4 326500 5455500 NULL NULL 326550 5455200 NULL NULL
5 326550 5455200 NULL NULL 326450 5455200 NULL NULL
6 326450 5455200 NULL NULL 326500 5455500 NULL NULL
7 321000 5450000 NULL NULL 322000 5450000 NULL NULL
8 322000 5450000 NULL NULL 321500 5451000 NULL NULL
9 321500 5451000 NULL NULL 321000 5450000 NULL NULL

But what if you want the start and end of the vector to be geometry points?

  1. -- Get as points
  2. --
  3. SELECT geometry::Point(v.sx,v.sy,0).STAsText() AS startPoint,
  4.        geometry::Point(v.ex,v.ey,0).STAsText() AS endPoint
  5.   FROM dbo.STVectorize(geometry::STGeomFromText(
  6. 'LINESTRING(0 0 10 10, 1 1 10 20, 2 2 10 30, 3 3 10 40)',0)) AS v;

Result is:

startPoint endPoint
POINT (0 0) POINT (1 1)
POINT (1 1) POINT (2 2)
POINT (2 2) POINT (3 3)

Finally, what if you want each vector to be represented as a single linestring and not a individual ordinates (sx,sy, …. ,ez,em)?

  1. -- Get as linestring
  2. --
  3. SELECT geometry::STGeomFromText(
  4. 'LINESTRING(' +
  5. CAST(v.sx AS VARCHAR(10)) + ' ' + CAST(v.sy AS VARCHAR(10)) + ',' +
  6. CAST(v.ex AS VARCHAR(10)) +' ' + CAST(v.ey AS VARCHAR(10)) + ')',0).STAsText() AS vLine
  7.   FROM dbo.STVectorize(geometry::STGeomFromText(
  8. 'LINESTRING(0 0 10 10, 1 1 10 20, 2 2 10 30, 3 3 10 40)',0)) AS v;

Result is:

vLine
LINESTRING (0 0, 1 1)
LINESTRING (1 1, 2 2)
LINESTRING (2 2, 3 3)

I hope this is useful to someone.

The function is available in the package of SQL Server functions downloadable from my website’s download page’s SQL Server Spatial TSQL Functions link

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