Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    Convert Single Geometry to Multi-part Geometry in Oracle Spatial
    Optimized Rectangle to 5 Point Polygon
    Centroid Package now supports Y ordinate seeding
    Convert GeoJSON document to Sdo_Geometry objects
    Implementation Of Travelling Salesman Problem
    Create Polygon From Bearings And Distances
    Function That Returns a Compass Point From a Whole Circle Bearing
    Playing around with Centroids by using different seed values
    GeoRaptor 4.x Update 2
    Simple Oracle C Sprintf or Java String.format
    Some Oriented Point Functions
    Extracting Inner Rings Changed Ordinate Ordering: A Trap For Players Who Don't Read Documentation!
    PLS-00306: wrong number or types of arguments in call to 'SDO_GEOMETRY'
    Converting Google Earth Formatted Longitude/Latitude points to decimal degrees
    Oracle Business Intelligence Warehousing and Analytics - Spatial Summit
    How far inside, is inside? Measuring actual distance.
    Noding and building a polygon from single, overlapping linestrings
    Analyzing Spatial Query Performance Improvements in Oracle Spatial and Graph 12c Through Cross-Vendor Comparison
    ST_VertexN / ST_PointN - Extracting a specific point from any geometry
    Convert Single Point stored in SDO_ORDINATES to SDO_POINT_TYPE
    Aggregate APPEND Islands and XOR polygons
    Circular Arcs in Geodetic Polygons
    Some SDO_GEOMETRY/DIMINFO handling functions
    Applying And Extending Oracle Spatial - Book Released
    Changing all DIMINFO sdo_tolerance values for all metadata records in one go.
    Building Polygons from Incomplete Linestrings using ST_PolygonBuilder
    Computing Cardinal Directions to nearby geometries
    Intersecting two aggregated polygon layers with SC4O
    Spatial and Oracle 12c
    Update Triggers and SDO_GEOMETRY Equality
    Duplicate Geometry data and Data Models
    CENTROID package update
    How to calculate cumulative length of a linestring
    Useful Package of Wrapper Functions for Sdo_Util.AffineTransforms
    Compute Location from known Lat/Long point using delta easting and northing in miles
    SDO_AGGR_SET_UNION
    Sorting SDO_GEOMETRY data using the ORDER BY clause of a SELECT statement
    Creating linestrings from points
    Rounding Coordinates or Ordinates in SDO_GEOMETRY
    Effects of Sdo_Geometry Ordinate Precision on Performance
    Effects of Sdo_Geometry Ordinate Precision on Storage
    The Spatial filtering of geometries: The effect of tolerances on relationships
    Application of Delaunay Triangulation and Inverse Distance Weighting (IDW) in Oracle for Soils Interpolation
    Selecting all SDO_GTYPE values for all tables/sdo_geometry columns in a schema
    CENTROID package - Tips for Use
    Announcing the Spatial Companion For Oracle (SC4O)
    Filtering Rings (Oracle Spatial)
    Splitting a polygon using one or more linestrings
    isValid, isSimple, Dimension and CoordDim methods for SDO_Geometry
    Line Merging or Collecting lines together: ST_LineMerger
    ST_DeleteVertex for Oracle SDO_Geometry based on Jaspa/JTS
    3D/4D and SRID aware Conversion functions for SDO_Geometry: WKT and EWKT
    Topological vs Non-Topological Simplification/Generalization of Aggregated Area Geometies in Oracle
    Filtering very short linestrings via bitmap function index
    CENTROID For Oracle
    Gridding a sdo_geometry line/polygon object (Oracle)
    Finding centre and radius of a circular geometry
    Constraining geometry type for sdo_geometry column in a table.
    CASE Statements and SDO_GEOMETRY
    The Power of Constraints and Indexes for Spatial Constraints: stopping duplicate points
    Replacement for SDO_GEOM.RELATE - ST_Relate based on JTS
    Changing Oracle Spatial Index Parameters on existing index
    Writing Excel Spreadsheets files from within the Oracle database using Java and PL/SQL
    Writing xSV (eg csv) files from within the Oracle database using Java and PL/SQL
    A simple spike finder for Spatial/Locator
    JTS Java class compilation for 11g and above
    Random Spatial Search Procedure
    Geometry Snapping using JTS in Oracle
    Exposing JTS's MinimumBoundingCircle functionality
    Exposing JTS's Densifier functionality
    Using JTS's Comparison Functions - HausdorffSimilarityMeasure & AreaSimilarityMeasure with SDO_GEOMETRY
    Free JTS-based Area/Length Functions
    Handy way of systematically fixing polygon geometries with 13349 and other errors
    Standalone CENTROID package now available for download
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 4 Processing Geodetic data
    Configurable Buffer: JTS and Oracle
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 3
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 2
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 1
    Building Lines into Polygons in Oracle Locator / Spatial
    Finding Intersection Points between Line and Polygon
    SDO2GeoJSON
    Free version of sdo_length
    Alternative to my SQL based GetNumRings function
    External Tables and SDO_Geometry data.
    layer_gtype keyword issue when indexing linear data on 11g
    String Tokenizer for Oracle
    Free Aggregate Method for Concatenating 2D Lines in Oracle Locator 10g
    Reducing 5 Vertex Polygon to Optimized Rectangle
    Square Buffer
    Converting decimal seconds to string
    SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT - 13356 Issues
    Valid conversion unit values for Oracle sdo_geom.sdo_length()
    Removing Steps in Gridded Vector Data - SmoothGrid for Oracle
    Oracle Spatial DISJOINT search/filtering
    Creating SDO_Geometry from geometric data recorded in the columns of a table
    Concave Hull Geometries in Oracle 11gR2
    Projecting SDO_GEOM_METADATA DIMINFO XY ordinates
    Instantiating MDSYS.VERTEX_TYPE
    New PL/SQL Packages - Rotate oriented point
    GeoRaptor Development Team
    Fast Refreshing Materialized View Containing SDO_GEOMETRY and SDO_GEOM.SDO_AREA function
    Performance of PL/SQL Functions using SQL vs Pure Code
    Implementing the BEST VicGrid Projection in Oracle 10gR2
    Making Sdo Geometry Metadata Update Generic Code
    ORA-13011 errors when using SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT()
    Extract Polygons from Compound Polygon
    Detecting sdo_geometries with compound (3-point Arcs) segments
    GEOMETRY_COLUMNS for Oracle Spatial
    Convert GML to SDO_Geometry in Oracle 10gR2
    Spatial Sorting of Data via Morton Key
    Swapping Ordinates in an SDO_GEOMETRY object
    New To_3D Function
    Extend (Reduce/Contract/Skrink) Function for Oracle
    Loading and Processing GPX 1.1 files using Oracle XMLDB
    Loading Spatial Data from an external CSV file in Oracle
    Calling the Oracle Spatial shapefile loader from within the Oracle database itself
    Implementing SDO_VertexUpdate/ST_VertexUpdate for Oracle
    Implementing SDO_RemovePoint/ST_RemovePoint for Oracle
    Implementing SDO_AddPoint/ST_AddPoint for Oracle
    ESRI ArcSDE Exverted and Inverted Polygons and Oracle Spatial
    Funky Fix Ordinates By Formula
    Implementing a SetPoint/ST_SetPoint function in Oracle
    Implementing an ST_SnapToGrid (PostGIS) function for Oracle Spatial
    Generating random point data
    Implementing an Affine/ST_Affine function for Oracle Spatial
    Implementing a Scale/ST_Scale function for Oracle Spatial
    Implementing a Parallel/ST_Parallel function for linestring data for Oracle Spatial
    Implementing a Rotate/ST_Rotate function for Oracle Spatial
    Limiting table list returned when connecting to Oracle Database using ODBC
    ST_Azimuth for Oracle: AKA Cogo.Bearing
    Implementing a Translate/ST_Translate/Move function for Oracle Spatial
    Elem_Info_Array Processing: An alternative to SDO_UTIL.GetNumRings and querying SDO_ELEM_INFO itself
    Minumum Bounding Rectangle (MBR) Object Type for Oracle
    How to extract elements from the result of an sdo_intersection of two polygons.
    How to restart a database after failed parameter change
    Fixing failed spatial indexes after import using data pump
    generate_series: an Oracle implementation in light of SQL Design Patterns
    Multi-Centroid Shootout
    Oracle Spatial Centroid Shootout
    On the use of ROLLUP in Oracle SELECT statements
    Surrounding Parcels
    Spatial Pipelining
    Using Oracle's SDO_NN Operator - Some examples
    Converting distances and units of measure in Oracle Locator
    Split Sdo_Geometry Linestring at a known point
    Forcing an Sdo_Geometry object to contain only points, lines or areas
    Unpacking USER_SDO_GEOM_METADATA's DIMINFO structure using SQL
    Generating multi-points from single point records in Oracle Spatial
    Object Tables of Sdo_Geometry
    Oracle Locator vs Oracle Spatial: A Reflection on Oracle Licensing of the SDO_GEOM Package
    FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns
    Australian MGA/AMG Zone Calculation from geographic (longitude/latitude) data
    Loading Shapefiles (SHP) into Oracle Spatial
    Oracle Spatial Mapping and Map Rendering Performance Tips
    The significance of sdo_lb/sdo_ub in USER_SDO_GEOM_METDATA: Do I need it?
    Oracle Spatial Forum - Melbourne April 2007
    Layer_GTypes for spatial indexes
    Oracle's SQL/MM Compliant Types
    Tips and Tricks

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

Wednesday February 04 2009 at 00:42

This article, written November 9th 2006, has been updated to reflect the fact that Luc Van Linden emailed me with a potential solution to my original question:

I tried to combine the two SQL statements (the one generating the windows) with the one creating the points for inserting but I failed. If anyone can show me how to do this I would be greatly appreciative!

His solution, combined with some improvements of my own, has now been integrated into this, updated article.

Article

There are many times when we need to generate some point data for use with Oracle Spatial.

Certainly I have had to do this many, many times.

I have often taken different approaches but I thought I would share one approach (that uses the hierarchical “CONNECT BY” clause) to doing this.

The following code first asks for the complete extent of the area for which points are needed to be added. The properties of a number of internal windows are asked for as well: minimum width/height and maximum width/height; maximum number of points for each window etc. A width/height for each window is generated as a random number between the minimums and maximums for each window. Similarly for the number of points.

When finished the sorts of possible spread of points is as per this image.

Possible point spread from algorithm.

Be aware that this approach has been created for projected data. It could be used for generating geodetic data with some simple modifications.


set timing on
set linesize 120
set pagesize 1000
set serveroutput on size 1000000

DROP SEQUENCE my_points_seq;
CREATE SEQUENCE my_points_seq;

DROP TABLE my_points;
Prompt Create a table to hold our point data maximising its use of database blocks so it uses as little space as possible
CREATE TABLE my_points ( 
  point_id     Integer primary key,
  window_id    Integer,
  sub_point_id Integer,
  geometry     mdsys.sdo_geometry
) PCTUSED 99;

Accept minx number default 100000  prompt 'Enter minimum X coordinate of whole area for which points are needed (100000): '

Accept miny number default 5000000 prompt 'Enter minimum Y coordinate of whole area for which points are needed (5000000): '

Accept maxx number default 400000  prompt 'Enter Maximum X coordinate of whole area for which points are needed (4000000): '

Accept maxy number default 6000000 prompt 'Enter Maximum Y coordinate of whole area for which points are needed (6000000): '

Accept InternalWindows number default 5    prompt 'Enter number of internal windows (5): '

Accept PointsPerWindow number default 5000 prompt 'Enter possible maximum number of points per window (5000): '

Accept minWidth   number default 500    prompt 'Enter Minimum width of an internal window (500): '

Accept maxWidth   number default 100000 prompt 'Enter Maximum width of an internal window (100000): '

Accept minHeight  number default 500    prompt 'Enter Minimum Height of an internal window (500): '

Accept maxHeight  number default 100000 prompt 'Enter Maximum Height of an internal window (100000): '

Accept sdoTolerance number default 0.05 prompt 'Enter SDO_TOLERANCE metadata (0.05): '

INSERT /*+APPEND*/ INTO my_points (point_id,window_id,sub_point_id,geometry)
SELECT rownum as point_id,
       w.Window_Id,
       s.COLUMN_VALUE as PointN, 
       mdsys.sdo_geometry(2001,NULL,
                   MDSYS.SDO_POINT_TYPE(
                         ROUND(dbms_random.value(w.x - ( w.WinWidth  / 2 ),  
                                                 w.x + ( w.WinWidth  / 2 )),ROUND(log(10,1/&sdotolerance.))+1),
                         ROUND(dbms_random.value(w.y - ( w.WinHeight / 2 ), 
                                                 w.y + ( w.WinHeight / 2 )),ROUND(log(10,1/&sdotolerance.))+1),
                         NULL),
                   NULL,NULL) as geometry
 FROM ( SELECT rownum As Window_ID, 
               p.PointCount, 
               p.X, 
               p.Y, 
               p.WinHeight, 
               p.WinWidth
          FROM ( SELECT ( &minx. + &maxx. ) / 2                         as X,
                        ( &miny. + &maxy. ) / 2                         as y,
                        ( &maxy. - &miny. )                             as WinHeight,
                        ( &maxx. - &minx. )                             as WinWidth,
                        trunc(dbms_random.value(1,&PointsPerWindow.),0) as PointCount
                   FROM DUAL 
                 UNION ALL 
                 SELECT dbms_random.value(&minx.,&maxx.)                as X,
                        dbms_random.value(&miny.,&maxy.)                as Y,
                        dbms_random.value(&minHeight.,&maxHeight.)      as WinHeight,
                        dbms_random.value(&minWidth.,&maxWidth.)        as WinWidth,
                        trunc(dbms_random.value(1,&PointsPerWindow.),0) as PointCount
                   FROM dual
                 CONNECT BY LEVEL <= &InternalWindows. 
               ) p
      ) w,
      TABLE(CAST(MULTISET(select level from dual connect by level <= w.PointCount) as SYS.UTL_NLA_ARRAY_INT)) s;

Prompt Let's sample some of the created data... 
SELECT myp.geometry.sdo_point.x,
       myp.geometry.sdo_point.y,
       window_id
  FROM my_points sample (2) myp;

Prompt Let's summary what was inserted into the table...
SELECT 'For Window ' || window_id || ' ' || count(*) || ' points were stored' As Result
  FROM my_points
GROUP BY window_id;

Prompt Create Oracle Metadata Entry...
DELETE FROM user_sdo_geom_metadata WHERE table_name = 'MY_POINTS';
COMMIT;
INSERT INTO user_sdo_geom_metadata 
SELECT 'MY_POINTS','GEOMETRY', 
       MDSYS.SDO_DIM_ARRAY( 
             MDSYS.SDO_DIM_ELEMENT('X', minx, maxx, &sdoTolerance.), 
             MDSYS.SDO_DIM_ELEMENT('Y', miny, maxy, &sdoTolerance.)), NULL
  FROM ( SELECT TRUNC( MIN( a.geometry.sdo_point.x ) - 1,0) as minx,
                ROUND( MAX( a.geometry.sdo_point.x ) + 1,0) as maxx,
                TRUNC( MIN( a.geometry.sdo_point.y ) - 1,0) as miny,
                ROUND( MAX( a.geometry.sdo_point.y ) + 1,0) as maxy
           FROM my_points a);

Prompt Create RTree index on point data ...
DROP INDEX my_points_geometry;
CREATE INDEX my_points_geometry ON my_points(geometry) 
INDEXTYPE IS MDSYS.SPATIAL_INDEX 
PARAMETERS('sdo_indx_dims=2, layer_gtype=point');

All the “heavy lifting” for creating the points is done by the clever use of the CONNECT BY LEVEL clause is down to Tom Kyte.

Download the source code for this tip here

I hope this is of use 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 [2]

I recently came across your blog and have been reading along. I thought I would leave my first comment. I don’t know what to say except that I have enjoyed reading. Nice blog. I will keep visiting this blog very often.

Susan

http://dclottery.info

Susan · 10 September 2009, 14:57 · #

Susan,

Thank you for your kind comments. I am pleased that you find my blog articles useful. If you can think of a topic that might be of use don’t hesitate to contact me.

regards
Simon

Simon · 11 September 2009, 06:48 · #