STVectorize: Break Linestring/Polygon elements into 2 point vectors (or 3 point circular curves)

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).

 USE [GISDB]  -- Change this to your database
 GO
 IF EXISTS (
     SELECT * FROM sysobjects WHERE id = object_id(N'STVECTORIZE')
     AND xtype IN (N'FN', N'IF', N'TF')
 )
     DROP FUNCTION [dbo].[STVECTORIZE];
 GO
 CREATE FUNCTION [dbo].[STVECTORIZE]( @p_geom geometry )
   RETURNS @Vectors TABLE
    (id INT,
     sx FLOAT,
     sy FLOAT,
     sz FLOAT,
     sm FLOAT,
     ex FLOAT,
     ey FLOAT,
     ez FLOAT,
     em FLOAT)
 AS
 BEGIN
   DECLARE
     @v_GeometryType VARCHAR(1000),
   @vector         INT,
     @ringn          INT,
     @geomn          INT,
     @FIRST          INT,
     @SECOND         INT,
     @geom           geometry,
     @start_geom     geometry,
     @end_geom       geometry;
   BEGIN
     IF ( @p_geom IS NULL )
       RETURN;
     SET @v_GeometryType = @p_geom.STGeometryType();
     IF ( @v_GeometryType IN ('Point','MultiPoint','GeometryCollection') )
       RETURN;
   SET @vector = 0;
     IF ( @v_GeometryType = 'LineString' )
     BEGIN
       SET @FIRST  = 1;
       SET @SECOND = 2;
       WHILE ( @SECOND <= @p_geom.STNumPoints() )
       BEGIN
         SET @start_geom = @p_geom.STPointN(@FIRST);
         SET @FIRST      = @FIRST  + 1;
         SET @end_geom   = @p_geom.STPointN(@SECOND);
         SET @SECOND     = @SECOND + 1;
     SET @vector     = @vector + 1;
         INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
                VALUES ( @vector,
                   @start_geom.STX,@start_geom.STY, @start_geom.Z,@start_geom.M,
                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,  @end_geom.M  );
       END;
       RETURN;
     END;
     IF ( @v_GeometryType = 'MultiLineString' )
     BEGIN
       SET @geomn  = 1;
       WHILE ( @geomn <= @p_geom.STNumGeometries() )
       BEGIN
         SET @geom   = @p_geom.STGeometryN(@geomn);
         SET @FIRST  = 1;
         SET @SECOND = 2;
         WHILE ( @SECOND <= @geom.STNumPoints() )
         BEGIN
           SET @start_geom = @geom.STPointN(@FIRST);
           SET @FIRST      = @FIRST  + 1;
           SET @end_geom   = @geom.STPointN(@SECOND);
           SET @SECOND     = @SECOND + 1;
           SET @vector     = @vector + 1;
           INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
                VALUES ( @vector,
                   @start_geom.STX,@start_geom.STY, @start_geom.Z,@start_geom.M,
                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,  @end_geom.M );
         END;
         SET @geomn = @geomn + 1;
       END;
       RETURN;
     END;
     IF ( @v_GeometryType = 'Polygon' )
     BEGIN
       SET @ringn  = 0;
       WHILE ( @ringn < ( 1 + @p_geom.STNumInteriorRing() ) )
       BEGIN
         IF ( @ringn = 0 )
           SET @geom = @p_geom.STExteriorRing()
         ELSE
           SET @geom = @p_geom.STInteriorRingN(@ringn);
         SET @FIRST  = 1;
         SET @SECOND = 2;
         WHILE ( @SECOND <= @geom.STNumPoints() )
         BEGIN
           SET @start_geom = @geom.STPointN(@FIRST);
           SET @FIRST      = @FIRST  + 1;
           SET @end_geom   = @geom.STPointN(@SECOND);
           SET @SECOND     = @SECOND + 1;
           SET @vector     = @vector + 1;
           INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
                VALUES ( @vector,
                   @start_geom.STX,@start_geom.STY, @start_geom.Z, @start_geom.M,
                           @end_geom.STX,  @end_geom.STY,   @end_geom.Z,   @end_geom.M );
         END;
         SET @ringn = @ringn + 1;
       END;
       RETURN;
     END;
     IF ( @v_GeometryType = 'MultiPolygon' )
     BEGIN
       SET @geomn  = 1;
       WHILE ( @geomn <= @p_geom.STNumGeometries() )
       BEGIN
         SET @geom   = @p_geom.STGeometryN(@geomn);
         SET @ringn  = 0;
         WHILE ( @ringn < ( 1 + @geom.STNumInteriorRing() ) )
         BEGIN
           IF ( @ringn = 0 )
             SET @geom = @geom.STExteriorRing()
           ELSE
             SET @geom = @geom.STInteriorRingN(@ringn);
           SET @FIRST  = 1;
           SET @SECOND = 2;
           WHILE ( @SECOND <= @geom.STNumPoints() )
           BEGIN
             SET @start_geom = @geom.STPointN(@FIRST);
             SET @FIRST      = @FIRST  + 1;
             SET @end_geom   = @geom.STPointN(@SECOND);
             SET @SECOND     = @SECOND + 1;
             SET @vector     = @vector + 1;
             INSERT INTO @Vectors ( [id],[sx],[sy],[sz],[sm],[ex],[ey],[ez],[em] )
                  VALUES ( @vector,
                     @start_geom.STX, @start_geom.STY, @start_geom.Z, @start_geom.M,
                             @end_geom.STX,   @end_geom.STY,   @end_geom.Z,   @end_geom.M );
           END;
           SET @ringn = @ringn + 1;
         END;
         SET @geomn = @geomn + 1;
       END;
       RETURN;
     END;
   END;
   RETURN;
 END;
 GO

Testing

Here’s a bunch of tests.

 SELECT v.*
   FROM dbo.STVectorize(geometry::STGeomFromText(
 '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
 SELECT v.*
   FROM dbo.STVectorize(geometry::STGeomFromText(
 '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
 -- Ordinary polygon
 --
 SELECT v.*
   FROM dbo.STVectorize(geometry::STGeomFromText(
 '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
 -- Polygon with a hole
 --
 SELECT v.*
   FROM dbo.STVectorize(geometry::STGeomFromText(
 'POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
 (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
 -- MultiPolygon With a hole
 --
 SELECT v.*
   FROM dbo.STVectorize(geometry::STGeomFromText(
 'MULTIPOLYGON(((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
 (326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0)),
 ((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?

 -- Get as points
 --
 SELECT geometry::Point(v.sx,v.sy,0).STAsText() AS startPoint,
        geometry::Point(v.ex,v.ey,0).STAsText() AS endPoint
   FROM dbo.STVectorize(geometry::STGeomFromText(
 '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)?

 -- Get as linestring
 --
 SELECT geometry::STGeomFromText(
 'LINESTRING(' +
 CAST(v.sx AS VARCHAR(10)) + ' ' + CAST(v.sy AS VARCHAR(10)) + ',' +
 CAST(v.ex AS VARCHAR(10)) +' ' + CAST(v.ey AS VARCHAR(10)) + ')',0).STAsText() AS vLine
   FROM dbo.STVectorize(geometry::STGeomFromText(
 '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