Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    SQL Server Spatial: STFlipVectors
    SQL Server Spatial: Extract LineStrings in GeometryCollection to create LineString
    SQL Server Spatial: Converting a LineString to COGO XML
    SQL Server Spatial: Creating (Multi)LineStrings geometries from COGO XML instructions
    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.

SQL Server Spatial: STFlipVectors

Wednesday August 01 2018 at 15:51

Keywordsflip vector segment polygon linestring normalise direction remove duplicates
Summary

Normalise vectors or segments of a line by aligning in same direction. Called flipping. Remove common segments of shared polygons.

In the past I have found use for the ability to “flip” vectors in a polygon in order to provide an independent check on the topological integrity of planar enforced polygons.

What I mean by topological integrity is that there are no gaps or overlaps between adjacent polygons.

A simple method for doing this relies on the fact that if a linestring is part of a shared boundary there will be two versions of it: one in one polygon and one in the other.
If they are exactly the same then there cannot be a gap or an overlap.
With normal ring ordering (anticlockwise/clockwise vertex order for their outer/inner rings), the segments that define a specific part of a the polygon boundary will have different direction.

This can be seen in the following diagram.

Two segments with different direction will not be metrically equal because their start and end points are different due to their different directions.
To make them the same requires a process that will normalize the direction.

I call this Flipping.

This flipping is different from simply reversing the coordinate order of a linestring segment.
After all, if we flip each of the two segments with different direction, we will still end up with two segments with different direction!
Hence we need a process that provides that all segments are flipped to the same direction.

This is what STFlipVectors() does, whose call signature is:

  1. CREATE FUNCTION [dbo].[STFlipVectors]
  2. (
  3.   @p_line_collection geometry
  4. )
  5. RETURNS geometry
  6. AS
  7. BEGIN
  8.  ...
  9. END

Its documentation can be seen see here.

Here are some examples of how to use it:

  1. -- Process geometry extracting segments with no flipping
  2. WITH gc AS (
  3. SELECT geometry::STGeomFromText(
  4. 'GEOMETRYCOLLECTION(
  5. POLYGON((10 0,20 0,20 20,10 20,10 0)),
  6. POLYGON((20 0,30 0,30 20,20 20,20 0)),
  7. POINT(0 0))',0) AS geom
  8. )
  9. SELECT v.sx,v.sy,v.ex,v.ey,COUNT(*) AS shareCount
  10.   FROM gc AS a
  11.        CROSS apply
  12.      [dbo].[STVectorize](a.geom) AS v
  13. GROUP BY v.sx,v.sy,v.ex,v.ey
  14. GO

Note: 8 Rows Produced

sx sy ex ey shareCount
10 0 20 0 1
10 20 10 0 1
20 0 20 20 1
20 0 30 0 1
20 20 10 20 1
20 20 20 0 1
30 0 30 20 1
30 20 20 20 1
  1. -- Process geometry extracting segments with flipping
  2. --
  3. WITH gc AS (
  4. SELECT geometry::STGeomFromText(
  5. 'GEOMETRYCOLLECTION(
  6. POLYGON((10 0,20 0,20 20,10 20,10 0)),
  7. POLYGON((20 0,30 0,30 20,20 20,20 0)),
  8. POINT(0 0))',0) AS geom
  9. )
  10. SELECT v.sx,v.sy,v.ex,v.ey,COUNT(*) AS shareCount
  11.   FROM gc AS a
  12.        CROSS apply
  13.             [dbo].[STVectorize] (
  14.                 [dbo].[STFlipVectors] ( a.geom )
  15.               ) AS v
  16. GROUP BY v.sx,v.sy,v.ex,v.ey
  17. GO

Note: 7 Rows Produced

sx sy ex ey shareCount
10 0 10 20 1
10 0 20 0 1
10 20 20 20 1
20 0 20 20 2
20 0 30 0 1
20 20 30 20 1
30 0 30 20 1

Note that one segment, the shared boundary, is recorded as existing twice.

What can we do with such information?

There are many things one can do, for example provide an independent check that data editing has not created gaps or overlaps at particular tolerances.

But we will concentrate here on a simple implementation of a boundary “dissolve” operation.
(Yes this can be done via STUnion() but here we are simple demonstrating a use for flipped vector processing.)

  1. WITH gc AS (
  2. SELECT geometry::STGeomFromText(
  3. 'GEOMETRYCOLLECTION(
  4. POLYGON((10 0,20 0,20 20,10 20,10 0)),
  5. POLYGON((20 0,30 0,30 20,20 20,20 0)),
  6. POINT(0 0))',0) AS geom
  7. )
  8. SELECT geometry::STGeomFromText(
  9.          REPLACE(
  10.             geometry::UnionAggregate(vector).STAsText(),
  11.                'LINESTRING (' COLLATE DATABASE_DEFAULT,
  12.                'POLYGON (('   COLLATE DATABASE_DEFAULT
  13.          )
  14.          +  
  15.          ')' COLLATE DATABASE_DEFAULT,
  16.          0).STAsText() AS polygon
  17.   FROM (SELECT [dbo].[STMakeLine] (
  18.                   geometry::Point(v.sx,v.sy,0),
  19.                   geometry::Point(v.ex,v.ey,0),
  20.                   3,2
  21.                ) AS vector
  22.          FROM gc AS a
  23.               CROSS apply
  24.               [dbo].[STVectorize] (
  25.                 [dbo].[STFlipVectors] ( a.geom )
  26.               ) AS v
  27.         GROUP BY v.sx,v.sy,v.ex,v.ey
  28.        HAVING COUNT(*) = 1  /* Get rid of duplicate lines */
  29.      ) AS f
  30. GO

Result.

polygon
POLYGON ((10 0, 20 0, 30 0, 30 20, 20 20, 10 20, 10 0))

I hope this function is of interest 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