Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    STGeometryTypes: Extracting all geometry type string values from complex geometry
    STDensify: Densify (m)LineString or (m)Polygon geometry objects
    STInsertN: Insert single vertex into a geometry
    STUpdateN: Update (replace) a single vertex within a geometry object.
    STUpdate: Replace all points equal to the supplied point with replacement point.
    STDeleteN: Delete single vertex from geometry
    STDelete: Deleting vertices in geometry objects
    STFlipVectors: Normalize direction of linestring vectors
    STConvertToLineString: Extract LineStrings in GeometryCollection to create LineString
    STLine2Cogo: Converting LineStrings to COGO XML
    STCogo2Line: Creating (Multi)LineStrings geometries from COGO XML instructions
    STVectorize: Break Linestring/Polygon elements into 2 point vectors (or 3 point circular curves)
    STScale: Function to Scale a geometry object
    TSQL String Tokenizer Function for SQL Server
    STGeometry2MBR/STGeography2MBR: Compute and return MBR ordinates
    generate_series for SQL Server 2008
    STExtractPolygon: Extract Polygons from result of STIntersection in SQL Server Spatial
    STRound: Function to round ordinates of a SQL Server Spatial geometry object
    STExtract: Extract elements of a geometry object
    STNumRings: Counting number of polygon rings
    STFilterRings: Removing rings from Polygon based on area.
    STMove: Function to Move a geometry object in SQL Server Spatial
    STCentroid*: Alternate Functions for Compute a Centroid
    STRotate: Function to rotate a geometry object in SQL Server Spatial
    STVertices: Wrapper over STDumpPoints
    STMorton: Creating a Morton number Space Key value for grid square
    Gridding a geometry or geography object (SQL Server Denali)
    On hinting spatial indexes
    RandomSearchByExtent: Random Search Procedure (2008 Spatial)
    COGO: Convert DMS String to decimal degrees floating point number.
    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
    CheckRadii: 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
    STisGeo: Checking if a column in a table or a view is of type geometry or geography
    Vectorising geometry objects in SQL Server 2008
    STMBR2Geometry/STMBR2Geography 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
    STDumpPoints: A Function that Dumps the Vertices/Points in a geometry
    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.

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