MBR) is presented. Useful for generating statistics.

" /> Random Spatial Search Procedure
Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    GeoRaptor 4.x Update 2 (Project has Stalled)
    Tip: Drop that Spatial Index!
    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
    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.

Random Spatial Search Procedure

Friday September 16 2011 at 07:19

Keywordsrandom search window index test mbr spatial
Summary

A search procedure that allows the random searching a geometry column via a set of spatial windows (MBR) is presented. Useful for generating statistics.

I have had the need, over the years, to produce statistics that helped me decide how effective a change to a property of a spatial table or index might be. Back in the old days of the Quad Tree index, I used a procedure like the following, to work out the best properties for a (hybrid) index. Nowadays I use it to discover how much a change to coordinate precision or table compression might have on performance.

Anyway, here is the procedure (also available in the TOOLS package).

  1. define defaultSchema='&1'
  2. -- Create Required Window Type
  3. CREATE OR REPLACE TYPE WindowSetType IS TABLE OF NUMBER;
  4. -- Now create the function.
  5.    /** @function    RandomSearchByExtent
  6.    *   @description Procedure that can help for independent testing of the performance of a table/geometry column
  7.    *                perhaps when spatially indexing, re-organising data, rounding ordinates etc.
  8.    *   @param       p_schema          : varchar2 : Schema that owns the object to be searched.
  9.    *   @param       p_table_name      : varchar2 : The object containing the spatal data for which we want to gather stats.
  10.    *   @param       p_column_name     : varchar2 : The sdo_geometry column to be searched.
  11.    *   @param       p_number_searches : number : Number of times to execute each search.
  12.    *   @param       p_window_set      : WindowSetType : Set of search "windows"
  13.    *   @param       p_no_zeros        : boolean : TRUE => zero features searches ignored
  14.    *   @param       p_sdo_anyinteract : boolean : Use Sdo_AnyInteract rather than SDO_FILTER
  15.    *   @param       p_count_vertices  : boolean : Force code to actually process geometry data.
  16.    *   @param       p_debug_detail    : boolean : Don't bother displaying individual search stats
  17.    *   @param       p_min_pixel_size  : number  : Include min_resolution=p_min_pixel_size in search (only when SDO_FILTERing)
  18.    **/
  19. CREATE OR REPLACE
  20. PROCEDURE RandomSearchByExtent( p_schema          IN VarChar2,
  21.                                 p_table_name      IN VarChar2,
  22.                                 p_column_name     IN VarChar2,
  23.                                 p_number_searches IN NUMBER  := 100,
  24.                                 p_window_set      IN CODESYS.WindowSetType := CODESYS.WindowSetType(500,1000,2000,3000,4000,5000,10000,20000,50000),
  25.                                 p_no_zeros        IN BOOLEAN := TRUE,
  26.                                 p_sdo_anyinteract IN BOOLEAN := FALSE,
  27.                                 p_count_vertices  IN BOOLEAN := FALSE,
  28.                                 p_debug_detail    IN BOOLEAN := FALSE,
  29.                                 p_min_pixel_size  IN NUMBER  := NULL )
  30. AUTHID CURRENT_USER
  31.    IS
  32.      v_srid              NUMBER := NULL;
  33.      v_rand_x            NUMBER := 0;
  34.      v_rand_y            NUMBER := 0;
  35.      v_searchWindowList  CODESYS.WindowSetType := p_window_set;
  36.      v_searchWindowSize  NUMBER;
  37.      v_search_geometry   varchar2(200) := 'MDSYS.SDO_GEOMETRY(2003,:1,NULL,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3),MDSYS.SDO_ORDINATE_ARRAY(:2,:3,:4,:5))';
  38.      v_diminfo           mdsys.sdo_dim_array;
  39.      v_lower_x           NUMBER;
  40.      v_lower_y           NUMBER;
  41.      v_upper_x           NUMBER;
  42.      v_upper_y           NUMBER;
  43.      v_range_x           NUMBER;
  44.      v_range_y           NUMBER;
  45.      v_ll_x              NUMBER;
  46.      v_ll_y              NUMBER;
  47.      v_ur_x              NUMBER;
  48.      v_ur_y              NUMBER;
  49.      v_Start_Time        NUMBER;
  50.      v_End_Time          NUMBER;
  51.      v_totalFeatures     NUMBER;
  52.      v_totalVertices     NUMBER;
  53.      v_totalSeconds      NUMBER;
  54.      v_fcount            NUMBER;
  55.      v_vcount            NUMBER;
  56.      v_seconds           NUMBER;
  57.      v_schema_table      varchar2(100);
  58.      v_sql               varchar2(4000);
  59.    BEGIN
  60.      IF ( p_schema IS NULL ) THEN
  61.         v_schema_table := UPPER(p_table_name);
  62.      ELSE
  63.         V_schema_table := UPPER(p_schema) || '.' || UPPER(p_table_name);
  64.      END IF;
  65.      DBMS_OUTPUT.ENABLE ( 1000000 );
  66.      BEGIN
  67.        SELECT diminfo, srid
  68.          INTO v_diminfo, v_srid
  69.          FROM all_sdo_geom_metadata
  70.         WHERE TABLE_NAME  = UPPER(p_table_name)
  71.           AND column_name = UPPER(p_column_name)
  72.           AND owner       = UPPER(p_schema);
  73.        v_lower_x := v_diminfo(1).SDO_LB;
  74.        v_upper_x := v_diminfo(1).SDO_UB;
  75.        v_lower_y := v_diminfo(2).SDO_LB;
  76.        v_upper_y := v_diminfo(2).SDO_UB;
  77.        EXCEPTION
  78.          WHEN NO_DATA_FOUND
  79.          THEN
  80.               IF ( p_debug_detail ) THEN
  81.                  dbms_output.put_line('No metadata record found for '||v_schema_table||'.'||p_column_name || ' manually computing MBR and SRID');
  82.               END IF;
  83.               EXECUTE immediate 'select min(t.x),min(t.y), max(t.x),max(t.y)
  84.                                   from table(sdo_util.getVertices((SELECT sdo_aggr_mbr(' || p_column_name || ') from ' || v_schema_table || '))) t'
  85.                           INTO v_lower_x,v_lower_y,v_upper_x,v_upper_y;
  86.               EXECUTE immediate 'select a.' || p_column_name || '.sdo_srid from ' || v_schema_table || ' a where a.' || p_column_name || ' is not null and rownum < 2'
  87.                           INTO v_srid;
  88.      END;
  89.      v_range_x := v_upper_x - v_lower_x;
  90.      v_range_y := v_upper_y - v_lower_y;
  91.      IF ( p_count_vertices ) THEN
  92.         v_sql := 'SELECT count(*), sum(mdsys.sdo_util.getNumVertices(a.' || p_column_name || ')) FROM '||v_schema_table||' A WHERE ';
  93.      ELSE
  94.         v_sql := 'SELECT count(*), 0 FROM '||v_schema_table||' A WHERE ';
  95.      END IF;
  96.      IF ( p_Sdo_AnyInteract ) THEN
  97.        v_sql := v_sql || 'MDSYS.SDO_RELATE(A.'||p_column_name||',' || v_search_geometry || ',''mask=ANYINTERACT ';
  98.      ELSE
  99.        v_sql := v_sql || 'MDSYS.SDO_FILTER(A.'||p_column_name||',' || v_search_geometry || ',''';
  100.      END IF;
  101.      IF p_min_pixel_size IS NOT NULL THEN
  102.        v_sql := v_sql || ' min_resolution=' || p_min_pixel_size ;
  103.      END IF;
  104.      v_sql := v_sql || ' querytype=WINDOW'') = ''TRUE''';
  105.      IF ( p_debug_detail ) THEN
  106.         dbms_output.put_line(SUBSTR('Search SQL = ' || v_Sql,1,255));
  107.      END IF;
  108.      dbms_output.put_line('SearchWindow,Searches,TotalFeatures,TotalSeconds,FeaturesPerSecond' || CASE WHEN p_count_vertices THEN ',TotalVertices' ELSE '' END);
  109.      FOR searchSizeCounter IN v_searchWindowList.FIRST..v_searchWindowList.LAST LOOP
  110.        v_totalFeatures := 0;
  111.        v_totalVertices := 0;
  112.        v_totalSeconds  := 0;
  113.        v_searchWindowSize := v_searchWindowList(searchSizeCounter);
  114.        FOR r IN 1..p_number_searches LOOP
  115.          v_fcount := -1;
  116.          -- Loop until we get a valid search
  117.          IF ( p_debug_detail ) THEN
  118.            dbms_output.put_line('RandX,RandY,Count,Seconds');
  119.          END IF;
  120.          WHILE ( v_fcount = -1 ) OR ( v_fcount = 0 AND p_no_zeros ) LOOP
  121.            v_rand_x := dbms_random.VALUE(v_lower_x,v_upper_x);
  122.            v_rand_y := dbms_random.VALUE(v_lower_y,v_upper_y);
  123.            v_ll_x := v_rand_x - ( v_searchWindowSize / 2 );
  124.            v_ll_y := v_rand_y - ( v_searchWindowSize / 2 );
  125.            v_ur_x := v_rand_x + ( v_searchWindowSize / 2 );
  126.            v_ur_y := v_rand_y + ( v_searchWindowSize / 2 );
  127.            v_Start_Time := dbms_utility.get_time;
  128.            BEGIN
  129.                EXECUTE IMMEDIATE v_sql
  130.                             INTO v_fcount, v_vcount
  131.                            USING v_srid,v_ll_X,v_ll_y,v_ur_x,v_ur_y;
  132.                EXCEPTION
  133.                    WHEN OTHERS THEN
  134.                         dbms_output.put_line('ERROR (' || SQLCODE ||') executing SQL ' || v_sql || ' with sdo_ordinate_array(' || v_ll_X||','||v_ll_y||','||v_ur_x||','||v_ur_y||')');
  135.                         RETURN;
  136.            END;
  137.            v_End_Time := dbms_utility.get_time;
  138.          END LOOP;
  139.          v_totalFeatures := v_totalFeatures + v_fcount;
  140.          v_totalVertices := v_totalVertices + v_vcount;
  141.          v_seconds       := ( v_End_Time - v_Start_Time ) / 100;
  142.          v_totalSeconds  := v_totalSeconds + v_seconds;
  143.          IF ( p_debug_detail ) THEN
  144.            dbms_output.put_line(round(v_rand_x,3)||','||round(v_rand_y,3)||','||round(v_fcount,1)||','||TO_CHAR(round(v_seconds,2),'FM99999.99'));
  145.          END IF;
  146.        END LOOP;
  147.        dbms_output.put_line(v_schema_table || ',' ||
  148.                             SUBSTR(v_searchWindowSize || ',' ||
  149.                             p_number_Searches || ',' ||
  150.                             TRIM(TO_CHAR(v_totalFeatures,'FM9999999999')) || ',' ||
  151.                             round(v_Totalseconds,2) || ',' ||
  152.                             TRIM(TO_CHAR(round(v_totalFeatures / v_TotalSeconds,1),'FM999999999.9')),1,255) ||
  153.                             CASE WHEN p_count_vertices THEN ',' || TO_CHAR(v_totalVertices,'FM9999999999999') ELSE '' END );
  154.      END LOOP;
  155.    END RandomSearchByExtent;

Updated:

  1. Changed handling of null p_schema.
  2. Changed method of providing SDO_GEOMETRY to search function. Now only parameters are the 4 ordinate values that define the rectangle.

Here is an example of how to use the procedure and the results of an invocation.

  1. SET serveroutput ON SIZE unlimited
  2. BEGIN
  3.   RandomSearchByExtent(p_schema          => 'GIS',
  4.                        p_table_name      => 'ADMINISTRATION_B',
  5.                        p_column_name     => 'GEOMETRY',
  6.                        p_number_searches => 100,
  7.                        p_window_set      => &&defaultSchema..WindowSetType(2500,5000,10000,20000,50000),
  8.                        p_no_zeros        => TRUE,
  9.                        p_sdo_anyinteract => TRUE,
  10.                        p_count_vertices  => TRUE,
  11.                        p_debug_detail    => FALSE,
  12.                        p_min_pixel_size  => NULL );
  13. END;
  14. /
  15. SearchWindow,Searches,TotalFeatures,TotalSeconds,FeaturesPerSecond,AverageVertices
  16. 2500,100,704,1.12,628.6,538.5
  17. 5000,100,1978,1.6,1236.3,331.6
  18. 10000,100,5731,2.43,2358.4,243.8
  19. 20000,100,17801,6.85,2598.7,259.2
  20. 50000,100,72346,13.36,5415.1,215.3

I hope this is useful 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