Go to content Go to navigation and search

Home

Current SQL Server Blog Articles


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.

Gridding a geometry or geography object (SQL Server Denali)

Tuesday December 20 2011 at 08:49

Keywordsgrid gridding raster vector chopping intersection boundary clip
Summary

A vector-to-raster algorithm generating tiles covering (multi-)line/polygon geometries. Boundary tiles are clipped forming non-square tiles.

A common question that comes up in the various database forums (PostGIS, SQL Server, Oracle) is how to “grid” a linear or polygonal object.

By “grid” one means work out the square pixels (rectangular polygons) that cover or define a vector geometry.

Here is some SQL for doing this for SQL Server 2008 Denali. Denali has spatial aggregates built in which is why it was used for this blog article. It can be done for SQL Server 2008 R1 and R2 but it needs the Codeplex extensions to be installed and enabled.

The gridding method requires two functions Morton and REGULARGRIDXY. THe Morton key function is provided in another blog article.

The other required function, REGULARGRIDXY ensures that the gridding takes place according to a commonly defined MBR so that the grids generated across multiple geometries align. This function is provided here:

  1. CREATE FUNCTION [dbo].[REGULARGRIDXY]
  2. (
  3.   @p_ll_x       FLOAT,
  4.   @p_ll_y       FLOAT,
  5.   @p_ur_x       FLOAT,
  6.   @p_ur_y       FLOAT,
  7.   @p_TileSize_X FLOAT,
  8.   @p_TileSize_Y FLOAT,
  9.   @p_srid       INT
  10. )
  11. RETURNS @TABLE TABLE
  12. (
  13.   col   INT,
  14.   ROW   INT,
  15.   geom  geometry
  16. )
  17. AS
  18. BEGIN
  19.    DECLARE
  20.      @v_loCol INT,
  21.      @v_hiCol INT,
  22.      @v_loRow INT,
  23.      @v_hiRow INT,
  24.      @v_col   INT,
  25.      @v_row   INT;
  26.    BEGIN
  27.      SET @v_loCol = FLOOR(   @p_LL_X / @p_TileSize_X );
  28.      SET @v_hiCol = CEILING( @p_UR_X / @p_TileSize_X ) - 1;
  29.      SET @v_loRow = FLOOR(   @p_LL_Y / @p_TileSize_Y );
  30.      SET @v_hiRow = CEILING( @p_UR_Y / @p_TileSize_Y ) - 1;
  31.      SET @v_col = @v_loCol;
  32.      WHILE ( @v_col <= @v_hiCol )
  33.      BEGIN
  34.        SET @v_row = @v_loRow;
  35.        WHILE ( @v_row <= @v_hiRow )
  36.        BEGIN
  37.          INSERT INTO @TABLE (col,ROW,geom)
  38.          VALUES(@v_col, @v_row,
  39.                 geometry::STGeomFromText('POLYGON((' +
  40.                       LTRIM(STR((@v_col * @p_TileSize_X),24,12)) + ' ' + LTRIM(STR((@v_row * @p_TileSize_Y),24,12)) + ',' +
  41.                       LTRIM(STR(((@v_col * @p_TileSize_X)+@p_TileSize_X),24,12)) + ' ' + LTRIM(STR((@v_row * @p_TileSize_Y),24,12)) + ',' +
  42.                       LTRIM(STR(((@v_col * @p_TileSize_X)+@p_TileSize_X),24,12)) + ' ' + LTRIM(STR(((@v_row * @p_TileSize_Y)+@p_TileSize_Y),24,12)) + ',' +
  43.                       LTRIM(STR((@v_col * @p_TileSize_X),24,12)) + ' ' + LTRIM(STR(((@v_row * @p_TileSize_Y)+@p_TileSize_Y),24,12)) + ',' +
  44.                       LTRIM(STR((@v_col * @p_TileSize_X),24,12)) + ' ' + LTRIM(STR((@v_row * @p_TileSize_Y),24,12)) + '))',@p_srid)
  45.                );
  46.          SET @v_row = @v_row + 1;
  47.        END;
  48.        SET @v_col = @v_col + 1;
  49.      END;
  50.      RETURN;
  51.    END;
  52. END
  53. GO

Here is the gridding method for a single geometry.

  1. -- The following should be changed to the database name in which you have installed the Morton and RegularGridXY functions
  2. --
  3. USE [GISDB]
  4. GO
  5. -- Single geometry processing
  6. --
  7. WITH geomQuery AS (
  8. SELECT g.geom.STEnvelope().STPointN(1).STX AS minx, g.geom.STEnvelope().STPointN(1).STY AS miny,
  9.        g.geom.STEnvelope().STPointN(3).STX AS maxx, g.geom.STEnvelope().STPointN(3).STY AS maxy,
  10.        g.geom, 0.050 AS gridX, 0.050 AS gridY, 0 AS loCol, 0 AS loRow        
  11.   FROM (SELECT a.geom.STBuffer(1.000).STSymDifference(a.geom.STBuffer(0.500)) AS geom
  12.           FROM (SELECT geometry::STGeomFromText('MULTIPOINT((09.25 10.00),(10.75 10.00),(10.00 10.75),(10.00 9.25))',0) AS geom ) a
  13.        ) g
  14. )
  15. SELECT f.mKey, f.col, f.ROW, f.geom
  16.   FROM (SELECT [GISDB].[dbo].Morton((c.col - a.loCol),(c.ROW - a.loRow)) AS mKey,
  17.                c.col, c.ROW,
  18.          CASE WHEN UPPER(a.geom.STGeometryType()) IN ('POLYGON','MULTIPOLYGON')
  19.               THEN a.geom.STIntersection(c.geom)
  20.           ELSE a.geom
  21.         END AS geom
  22.           FROM geomQuery a
  23.                CROSS APPLY
  24.                [GISDB].[dbo].REGULARGRIDXY(a.minx, a.miny, a.maxx, a.maxy,a.gridX,a.gridY, a.geom.STSrid) c
  25.          WHERE a.geom.STIntersects(c.geom) = 1
  26.        ) f
  27.  WHERE UPPER(f.geom.STGeometryType()) IN ('POLYGON','MULTIPOLYGON') /* Don't want point or line tiles */
  28.  ORDER BY f.mKey;

The result of this looks like.

For multiple geometries, the following needs to be executed.

  1. -- Query for more than one geometry
  2. --
  3. WITH geomQuery AS (SELECT g.rid,
  4.                           MIN(g.geom.STEnvelope().STPointN(1).STX) OVER (partition BY g.pid) AS minx,
  5.                           MIN(g.geom.STEnvelope().STPointN(1).STY) OVER (partition BY g.pid) AS miny,
  6.                           MAX(g.geom.STEnvelope().STPointN(3).STX) OVER (partition BY g.pid) AS maxx,
  7.                           MAX(g.geom.STEnvelope().STPointN(3).STY) OVER (partition BY g.pid) AS maxy,
  8.                           g.geom, 0.050 AS gridX, 0.050 AS gridY, 0 AS loCol, 0 AS loRow        
  9.                      FROM (SELECT 1 AS pid, a.rid, a.geom.STBuffer(1.000).STSymDifference(a.geom.STBuffer(0.750)) AS geom
  10.                              FROM (SELECT 1 AS rid, geometry::STGeomFromText('POINT(09.50 10.00)',0) AS geom
  11.                          UNION ALL SELECT 2 AS rid, geometry::STGeomFromText('POINT(10.50 10.00)',0) AS geom
  12.              UNION ALL SELECT 3 AS rid, geometry::STGeomFromText('POINT(10.00 10.50)',0) AS geom
  13.                          UNION ALL SELECT 4 AS rid, geometry::STGeomFromText('POINT(10.00 09.50)',0) AS geom ) a
  14.              ) g
  15.                   )
  16. SELECT ROW_NUMBER() OVER (ORDER BY f.col, f.ROW) AS tid,
  17.        [GISDB].[dbo].Morton((f.col - f.loCol),(f.ROW - f.loRow)) AS mKey,
  18.        f.col,
  19.        f.ROW,
  20.        COUNT(*) AS UnionedTileCount,
  21.        geometry::UnionAggregate(f.geom) AS geom
  22.   FROM (SELECT c.col, c.ROW, a.loCol, a.loRow,
  23.            CASE WHEN UPPER(a.geom.STGeometryType()) IN ('POLYGON','MULTIPOLYGON')
  24.               THEN a.geom.STIntersection(c.geom)
  25.           ELSE a.geom
  26.         END AS geom
  27.           FROM geomQuery a
  28.                CROSS APPLY
  29.                [GISDB].[dbo].REGULARGRIDXY(a.minx,a.miny,a.maxx,a.maxy,a.gridX,a.gridY,a.geom.STSrid) c
  30.          WHERE a.geom.STIntersects(c.geom) = 1
  31.        ) f
  32.  WHERE UPPER(f.geom.STGeometryType()) IN ('POLYGON','MULTIPOLYGON') /* Don't want point or line tiles */
  33.  GROUP BY f.col, f.ROW, f.loCol, f.loRow
  34.  ORDER BY 2;

That looks like this.

I hope this is of use to SQL Server Denali users
A common question that comes up in the various database forums (PostGIS, SQL Server, Oracle) is how to

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 [1]

Hi, Simon

your article is the only one that is functional and completed for SQL, extremely helpful for me

— Marc · 10 February 2015, 18:58 · #