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.

Generating random point data for SQL Server 2008 Spatial

Friday December 24 2010 at 06:11

There is often a need for all sorts of reasons, for the generation of spatial data within a database like SQL Server 2008.

I have blogged on this before for Oracle Locator/Spatial but the tricks to doing this in SQL Server 2008 are very much different from what is achievable in Oracle. This is to do with the different architectures and functional differences in the two products.

Two will suffice:

  1. Oracle’s dbms_random.value() function is truly deterministic in that each and every call will return a different value. In SQL Server this is not the case as it doesn’t matter how many times RAND() is called within a SQL statement it always returns the same value. There are many tricks to get around this in SQL Server, I have opted for the one in the SQL below, that is use of the CHECKSUM(NEWID()) trick. NEWID() produces a new value each and every call and CHECKSUM makes this useful to RAND.
  2. Oracle’s hierarchical query capability (CONNECT BY) is not available in SQL Server. But I have gotten around this via use of the generate_series() function I blogged on previously.

This implementation is deliberately simpler than its Oracle cousin.

Here it is (note that my database is “GISDB”, change this to yours).

use GISDB
 
DROP   TABLE ProjPoint2D;
CREATE TABLE ProjPoint2D (id int not null, angleDegrees int, geom geometry );
 
---- Create the variables for the random number generation
DECLARE @UpperX INT;
DECLARE @LowerX INT;
DECLARE @UpperY INT;
DECLARE @LowerY INT;
DECLARE @RangeX INT;
DECLARE @RangeY INT;
DECLARE @NumberPoints INT = 100000;
SET @LowerX = 358880  - ( 100000 / 2 );
SET @UpperX = 358880  + ( 100000 / 2 );
SET @RangeX = @UpperX - @LowerX;
SET @LowerY = 5407473 - (  50000 / 2 );
SET @UpperY = 5407473 + (  50000 / 2 );
SET @RangeY = @UpperY - @LowerY;
SELECT @LowerX, @LowerY, @UpperX, @UpperY, @RangeX, @RangeY;
 
INSERT INTO ProjPoint2D (id, angleDegrees, geom)
SELECT f.id, 
       CONVERT(INT,ROUND(RAND(CHECKSUM(NEWID())) * 1000,0)) % 360 as angleDegrees,
       geometry::Point(f.x,f.y,0 /* SRID */ )  as geom
  FROM ( SELECT sa.IntValue as id,
                ROUND(@RangeX * RAND(CHECKSUM(NEWID())) + @LowerX,2) as x,
                ROUND(@RangeY * RAND(CHECKSUM(NEWID())) + @LowerY,2) as y
           FROM dbo.generate_series(1, @NumberPoints, 1) sa
        ) f;
 
SELECT 'Inserted ' + convert(varchar,count(*)) + ' records into ProjPoint2D' FROM ProjPoint2D;
 
ALTER TABLE ProjPoint2D
ADD CONSTRAINT [PK_ProjPoint2D_ID]
PRIMARY KEY CLUSTERED ( [ID] ASC );
 
SELECT MIN(geom.STX), MIN(geom.STY), MAX(geom.STX), MAX(geom.STY)
  FROM ProjPoint2D;
 
/****** Object:  Index [ProjPoint2D_Geom]    Script Date: 12/18/2010 14:09:38 ******/
CREATE SPATIAL INDEX [ProjPoint2D_Geom] ON [dbo].[ProjPoint2D] 
( [geom] ) USING  GEOMETRY_GRID 
WITH ( BOUNDING_BOX =(308880, 5382473, 408880, 5432473), 
       GRIDS =(LEVEL_1 = MEDIUM,LEVEL_2 = MEDIUM,LEVEL_3 = MEDIUM,LEVEL_4 = MEDIUM), 
       CELLS_PER_OBJECT = 16, PAD_INDEX  = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) 
       ON [PRIMARY]
GO
 
select mbr.STAsText(), COUNT(*) as pointsWithin
  from (select dbo.MBR2GEOMETRY(llX,llY,llX+windowX,llY+windowY,0) as mbr
          from (select ROUND(@RangeX * RAND(CHECKSUM(NEWID())) + @LowerX,2) as llX,
                       ROUND(@RangeY * RAND(CHECKSUM(NEWID())) + @LowerY,2) as llY,
                       ROUND(1000    * RAND(CHECKSUM(NEWID())),2) as windowX,
                       ROUND(700     * RAND(CHECKSUM(NEWID())),2) as WindowY
                  from dbo.generate_series(1,100,1)
               ) as gs
         where windowX <> 0.0 
           and WindowY <> 0.0
       ) w
       left outer join
       ProjPoint2D pp
       on pp.geom.STIntersects(mbr) = 1
 group by mbr.STAsText();

I hope this helps someone out there.
Simon

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