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.

Filtering very short linestrings via bitmap function index

Thursday January 05 2012 at 02:16

Keywordsbitmap index function sdo_length short lines filtering large table
Summary

This article presents a method, using a function based bitmap index, for identifying and fast filtering short lines.

A colleague wrote to me today asking:

I’m looking for a way to improve a query to detect all line geometries which are shorter then 10 mm.

It takes days to check all our lines (full tabel scans on millions of rows);

Can’t I use the domain index to filter out the desired lines?

  1. DROP   TABLE Test10MM  PURGE;
  2. -- table TEST10MM dropped.
  3. CREATE TABLE Test10MM ( id INTEGER, geom mdsys.sdo_geometry );
  4. -- table TEST10MM created.
  5. INSERT INTO Test10MM (id, geom)
  6.      SELECT rownum,
  7.             mdsys.sdo_geometry(2002,NULL,NULL,
  8.                                 MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),
  9.                                 MDSYS.SDO_ORDINATE_ARRAY(
  10.                                    ROUND(dbms_random.VALUE(0,0.1),3),
  11.                                    ROUND(dbms_random.VALUE(0,0.1),3),
  12.                                    ROUND(dbms_random.VALUE(0,0.1),3),
  13.                                    ROUND(dbms_random.VALUE(0,0.1),3)))
  14.       FROM DUAL
  15.    CONNECT BY LEVEL <= 5000;
  16. -- 5,000 rows inserted.
  17. COMMIT;
  18. -- commited.
  19. SELECT 'Inserted '||COUNT(*)||' records into Test10MM' AS RecCount FROM Test10MM;
  20. -- RECCOUNT                                                                
  21. -- -----------------------------------------------------------------------
  22. -- Inserted 5000 records into Test10MM                                    
  23. DELETE FROM USER_SDO_GEOM_METADATA WHERE TABLE_NAME = 'TEST10MM';
  24. -- 1 rows deleted.
  25. DECLARE
  26.   v_shape mdsys.sdo_geometry;
  27. BEGIN
  28.   SELECT SDO_AGGR_MBR(geom) INTO v_shape FROM Test10MM;
  29.   INSERT INTO USER_SDO_GEOM_METADATA(TABLE_NAME,COLUMN_NAME,DIMINFO,SRID)
  30.     VALUES ('TEST10MM','GEOM',MDSYS.SDO_DIM_ARRAY(
  31.     MDSYS.SDO_DIM_ELEMENT('X',V_SHAPE.SDO_ORDINATES(1),V_SHAPE.SDO_ORDINATES(2),0.05),
  32.     MDSYS.SDO_DIM_ELEMENT('Y',V_SHAPE.SDO_ORDINATES(3),V_SHAPE.SDO_ORDINATES(4),0.05)),NULL);
  33. END;
  34. /
  35. SHOW ERRORS
  36. -- anonymous block completed
  37. -- No Errors.
  38. COMMIT;
  39. -- commited.
  40. CREATE INDEX Test10MM_GEOM ON Test10MM(geom)
  41.        INDEXTYPE IS mdsys.spatial_index
  42.        parameters('sdo_indx_dims=2, layer_gtype=line');
  43. -- index TEST10MM_GEOM created.
  44. EXEC dbms_stats.gather_table_stats(ownname => 'CODESYS', tabname => 'TEST10MM', estimate_percent => 100, method_opt => 'for all indexed columns size auto' )
  45. -- anonymous block completed
  46. -- Normal filtering without index
  47. --
  48. SET autotrace ON EXPLAIN
  49. -- Autotrace Enabled
  50. -- Displays the execution plan only.
  51. SELECT COUNT(*) AS LenTo10mmCount
  52.   FROM Test10MM a
  53.  WHERE round(sdo_geom.sdo_length(a.geom,0.0005),2) <= 0.01;
  54. /*
  55. LENTO10MMCOUNT
  56. --------------
  57. 308
  58. Plan hash value: 2043904050
  59. -------------------------------------------------------------------------------
  60. | Id  | Operation          | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
  61. -------------------------------------------------------------------------------
  62. |   0 | SELECT STATEMENT   |          |     1 |     8 |    26   (4)| 00:00:01 |
  63. |   1 |  SORT AGGREGATE    |          |     1 |     8 |            |          |
  64. |*  2 |   TABLE ACCESS FULL| TEST10MM |   250 |  2000 |    26   (4)| 00:00:01 |
  65. -------------------------------------------------------------------------------
  66. Predicate Information (identified by operation id):
  67. ---------------------------------------------------
  68.   2 - filter(ROUND("SDO_GEOM"."SDO_LENGTH"("A"."GEOM",0.0005),2)<=0.01)
  69. */
  70. -- Another method of identifying lines with length < 10mm
  71. --
  72. SELECT COUNT(*) AS tenmmcount
  73.   FROM Test10MM a
  74.  WHERE CASE WHEN round(sdo_geom.sdo_length(a.geom,0.0005),2) * 100 <= 1 THEN 1 ELSE 0 END = 1;
  75. /*
  76. TENMMCOUNT            
  77. ----------------------
  78. 308                    
  79. Plan hash value: 2043904050
  80. -------------------------------------------------------------------------------
  81. | Id  | Operation          | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
  82. -------------------------------------------------------------------------------
  83. |   0 | SELECT STATEMENT   |          |     1 |     8 |    26   (4)| 00:00:01 |
  84. |   1 |  SORT AGGREGATE    |          |     1 |     8 |            |          |
  85. |*  2 |   TABLE ACCESS FULL| TEST10MM |   250 |  2000 |    26   (4)| 00:00:01 |
  86. -------------------------------------------------------------------------------
  87. Predicate Information (identified by operation id):
  88. ---------------------------------------------------
  89.    2 - filter(ROUND("SDO_GEOM"."SDO_LENGTH"("A"."GEOM",0.0005),2)*100<=1)
  90. */
  91. -- Can we create a function based index on this predicate?
  92. --
  93. CREATE bitmap INDEX Test10MM_10mm_idx ON Test10MM(CASE WHEN round(sdo_geom.sdo_length(geom,0.0005),2) * 100 <= 1 THEN 1 ELSE 0 END);
  94. /*
  95. SQL Error: ORA-30553: The function is not deterministic
  96. 30553. 00000 -  "The function is not deterministic"
  97. *Cause:    The function on which the index is defined is not deterministic
  98. *Action:   If the function is deterministic, mark it DETERMINISTIC.  If it
  99.            is not deterministic (it depends on package state, database state,
  100.            current time, or anything other than the function inputs) then
  101.            do not create the index.  The values returned by a deterministic
  102.            function should not change even when the function is rewritten or
  103.            recompiled.
  104. */
  105. -- No We can't
  106. -- Even if we could the use of functional index requires one to use the exact predicate in the query where clause!!!
  107. -- Let's wrap the predicate in a deterministic function
  108. --
  109. CREATE OR REPLACE FUNCTION is10mm(p_geom IN mdsys.sdo_geometry)
  110. RETURN NUMBER deterministic
  111. IS
  112. BEGIN
  113.   RETURN CASE WHEN round(sdo_geom.sdo_length(p_geom,0.0005),2) * 100 <= 1 THEN 1 ELSE 0 END;
  114. END is10mm;
  115. /
  116. SHOW errors
  117. -- FUNCTION is10mm compiled
  118. -- No Errors.
  119. -- Now create a bitmap index on the function
  120. --
  121. CREATE bitmap INDEX Test10MM_10mm_idx ON Test10MM(is10mm(geom));
  122. -- bitmap index TEST10MM_10MM_IDX created.
  123. -- Gather stats on it.
  124. --
  125. EXEC dbms_stats.gather_index_stats(ownname => 'CODESYS', indname => 'TEST10MM_10MM_IDX', estimate_percent => 100);
  126. -- anonymous block completed
  127. SET autotrace ON EXPLAIN
  128. -- Autotrace Enabled
  129. -- Displays the execution plan only.
  130. SELECT COUNT(*)
  131.   FROM Test10MM a
  132.  WHERE is10MM(geom) = 1;
  133. SET autotrace ON EXPLAIN
  134. -- Autotrace Enabled
  135. -- Displays the execution plan only.
  136. SELECT COUNT(*)
  137.   FROM Test10MM a
  138.  WHERE is10MM(geom) = 1;
  139. /*
  140. COUNT(*)              
  141. ----------------------
  142. 308                    
  143. Plan hash value: 577608402
  144. ---------------------------------------------------------------------------------------------------
  145. | Id  | Operation                     | Name              | Rows  | Bytes | Cost (%CPU)| Time     |
  146. ---------------------------------------------------------------------------------------------------
  147. |   0 | SELECT STATEMENT              |                   |     1 |     8 |     1   (0)| 00:00:01 |
  148. |   1 |  SORT AGGREGATE               |                   |     1 |     8 |            |          |
  149. |   2 |   BITMAP CONVERSION COUNT     |                   |    50 |   400 |     1   (0)| 00:00:01 |
  150. |*  3 |    BITMAP INDEX FAST FULL SCAN| TEST10MM_10MM_IDX |       |       |            |          |
  151. ---------------------------------------------------------------------------------------------------
  152. Predicate Information (identified by operation id):
  153. ---------------------------------------------------
  154.    3 - filter("CODESYS"."IS10MM"("GEOM")=1)
  155. */

Note that the query now correctly uses the bitmap index to speed the query achieving that which we set out to do.

The result is that a suitable function can be created that identifies small lines that can be used to execute fast queries against large tables. Of course, the result of the function is10MM could be cached or persisted in its own column and kept up to date via a trigger, but that is about implementation not the validity of the method.

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