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.

Valid conversion unit values for Oracle sdo_geom.sdo_length()

Thursday May 12 2011 at 05:53

The SDO_LENGTH function within SDO_GEOM package can be called with an optional unit parameter as in the following call signature:

SDO_GEOM.SDO_LENGTH(
     geom IN SDO_GEOMETRY,
     tol IN NUMBER
     [, unit IN VARCHAR2]
     [, count_shared_edges IN NUMBER]
     ) RETURN NUMBER;

But what are a valid list of values for the unit parameter?

For a start, if the SDO_GEOMETRY has a NULL SDO_SRID value then the unit parameter can’t be used at all! For other cases, let’s see what we can find out.

The documentation describes the unit parameter as:

Unit of measurement: a quoted string with unit= and an SDO_UNIT value from the MDSYS.SDO_DIST_UNITS table (for example, ‘unit=KM’). See Section 2.10 for more information about unit of measurement specification.

If this parameter is not specified, the unit of measurement associated with the data is assumed. For geodetic data, the default unit of measurement is meters.

Section 2.10 says about the SDO_UNIT value that:

The unit parameter must be enclosed in single quotation marks and contain the string unit= and a valid UNIT_OF_MEAS_NAME value from the SDO_UNITS_OF_MEASURE table.

However, there is a serious inconsistency here related to the SDO_LENGTH documentation saying that the unit= parameter must use a valid value from the SDO_UNIT column in the SDO_DIST_UNITS (is not a table but a view defined over the table SDO_UNITS_OF_MEASURE) defined as:

CREATE OR REPLACE FORCE VIEW "MDSYS"."SDO_DIST_UNITS" 
("SDO_UNIT", "UNIT_NAME", "CONVERSION_FACTOR")
AS
  SELECT SHORT_NAME          "SDO_UNIT",
         UNIT_OF_MEAS_NAME   "UNIT_NAME",
         (FACTOR_B/FACTOR_C) "CONVERSION_FACTOR"
    FROM MDSYS.SDO_UNITS_OF_MEASURE
   WHERE lower(UNIT_OF_MEAS_TYPE)='length';

Yet, Section 2.10 say that “unit= [should use] … a valid UNIT_OF_MEAS_NAME value from the SDO_UNITS_OF_MEASURE table”. Yet this is the texual UNIT_NAME column in SDO_DIST_UNITS!

Let’s test this.

First, what is SDO_UNIT values in SDO_DIST_UNITS are valid? The view does contain NULL SDO_UNIT values which are incorrect so we will ignore them. Also, the SDO_UNIT codeds as “British foot (1936)” doesn’t work either.

SELECT mdsys.sdo_geom.sdo_length(a.geom,0.05,'unit='||b.sdo_unit) as length
  FROM (SELECT MDSYS.SDO_GEOMETRY(2003, 8307, NULL, 
                  MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,1), 
                  MDSYS.SDO_ORDINATE_ARRAY(1,1,5,1,5,7,1,7,1,1)) as geom 
          FROM dual) a,
          sdo_dist_units b
 WHERE sdo_unit = 'British foot (1936)';
 
ORA-13291: conversion error between the specified unit and standard unit
ORA-06512: at "MDSYS.SDO_3GL", line 1766
ORA-06512: at "MDSYS.SDO_GEOM", line 1668
ORA-06512: at "MDSYS.SDO_GEOM", line 1610
ORA-06512: at line 1

OK, so cutting this one out and trying all the rest gives us:

SELECT b.sdo_unit,
       mdsys.sdo_geom.sdo_length(a.geom,0.05,'unit='||b.sdo_unit) as length
  FROM (SELECT MDSYS.SDO_GEOMETRY(2003, 8307, NULL, 
                  MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,1), 
                  MDSYS.SDO_ORDINATE_ARRAY(1,1,5,1,5,7,1,7,1,1)) as geom 
          FROM dual) a,
        sdo_dist_units b
  WHERE sdo_unit is not null
    AND sdo_unit <> unit_name  -- gets rid of 'British foot (1936)'
  ORDER BY sdo_unit;

SDO_UNIT LENGTH
CENTIMETER 221415834.03459
CHAIN 110065.136619437
CHN_BEN 110065.232398119
CHN_SRS 110065.327450371
CL_FT 7264364.19798508
CM 221415834.03459
FATHOM 1210716.50281381
FOOT 7264299.01688287
INCH 87171588.2025944
IND_FT 7264310.50464533
IND_YARD 2421436.83488178
KILOMETER 2214.1583403459
KM 2214.1583403459
LINK 11006612.4211895
LINK_BEN 11006523.2398119
LINK_SRS 11006532.7450371
M 2214158.3403459
METER 2214158.3403459
MILE 1375.81420774297
MILLIMETER 2214158340.3459
MM 2214158340.3459
MOD_USFT 7264007.00321731
NAUT_MILE 1195.549859798
ROD 440260.546477749
SRS_YARD 2421437.20390817
SURVEY_FOOT 7264284.48828529
YARD 2421433.00562762


So, they all work.

Now, let’s try the “valid UNIT_OF_MEAS_NAME value[s] from the SDO_UNITS_OF_MEASURE”:

DECLARE
   conversion_error EXCEPTION;
   PRAGMA EXCEPTION_INIT(conversion_error, -13291);
   geom   mdsys.sdo_geometry := MDSYS.SDO_GEOMETRY(2002, 8307, NULL, 
                  MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1), 
                  MDSYS.SDO_ORDINATE_ARRAY(1,1,2,1));
   len number;
   uom varchar2(1000);
BEGIN
  FOR rec IN (SELECT b.UNIT_OF_MEAS_NAME, 
                     NVL(b.SHORT_NAME,'NULL') || '|' || NVL(b.DATA_SOURCE,'ORA') SHORT_DATA_SOURCE
                FROM SDO_UNITS_OF_MEASURE b
               WHERE b.unit_of_meas_type = 'length' 
                 AND b.UNIT_OF_MEAS_NAME is not null
            ORDER BY b.UNIT_OF_MEAS_NAME) LOOP
    BEGIN
       uom := rec.UNIT_OF_MEAS_NAME;
       len := mdsys.sdo_geom.sdo_length(geom,0.05,'unit='||rec.UNIT_OF_MEAS_NAME);
       dbms_output.put_line('Passed: ' || UOM || ' (' || rec.SHORT_DATA_SOURCE || ') = ' || len);
       EXCEPTION 
         WHEN conversion_error THEN
            dbms_output.put_line('Failed: ' || UOM|| ' (' || rec.SHORT_DATA_SOURCE || ')');
    END;
  END LOOP;
END;
/

Failed: Bin width 12.5 metres (NULL|EPSG)
Failed: Bin width 165 US survey feet (NULL|EPSG)
Failed: Bin width 25 metres (NULL|EPSG)
Failed: Bin width 3.125 metres (NULL|EPSG)
Failed: Bin width 330 US survey feet (NULL|EPSG)
Failed: Bin width 37.5 metres (NULL|EPSG)
Failed: Bin width 6.25 metres (NULL|EPSG)
Failed: Bin width 82.5 US survey feet (NULL|EPSG)
Failed: British chain (Benoit 1895 A) (NULL|EPSG)
Failed: British chain (Benoit 1895 B) (NULL|EPSG)
Failed: British chain (Sears 1922) (NULL|EPSG)
Failed: British foot (1865) (NULL|EPSG)
Failed: British foot (1936) (British foot (1936)|EPSG)
Failed: British foot (Benoit 1895 A) (NULL|EPSG)
Failed: British foot (Benoit 1895 B) (NULL|EPSG)
Failed: British foot (Sears 1922) (NULL|EPSG)
Failed: British link (Benoit 1895 A) (NULL|EPSG)
Failed: British link (Benoit 1895 B) (NULL|EPSG)
Failed: British link (Sears 1922) (NULL|EPSG)
Failed: British yard (Benoit 1895 A) (NULL|EPSG)
Failed: British yard (Benoit 1895 B) (NULL|EPSG)
Failed: British yard (Sears 1922) (NULL|EPSG)
Passed: Centimeter (CENTIMETER|ORA) = 11130264.9339446
Passed: Centimeter (CM|ORA) = 11130264.9339446
Passed: Chain (CHAIN|ORA) = 5532.82079353803
Failed: Chain (Benoit) (CHN_BEN|ORA)
Failed: Chain (Sears) (CHN_SRS|ORA)
Passed: Clarke’s Foot (CL_FT|ORA) = 365166.17237351
Passed: Clarke’s chain (NULL|EPSG) = 5532.82079353803
Passed: Clarke’s foot (NULL|EPSG) = 365166.17237351
Passed: Clarke’s link (NULL|EPSG) = 553287.043843245
Passed: Clarke’s yard (NULL|EPSG) = 121722.057457837
Passed: Fathom (FATHOM|ORA) = 60861.0287289183
Failed: Foot (International) (FOOT|ORA)
Failed: German legal metre (NULL|EPSG)
Passed: Gold Coast foot (NULL|EPSG) = 365166.17237351
Passed: Inch (INCH|ORA) = 4381994.06848212
Passed: Indian Foot (IND_FT|ORA) = 365166.17237351
Passed: Indian foot (NULL|EPSG) = 365166.17237351
Failed: Indian foot (1937) (NULL|EPSG)
Failed: Indian foot (1962) (NULL|EPSG)
Failed: Indian foot (1975) (NULL|EPSG)
Passed: Indian yard (NULL|EPSG) = 121722.057457837
Failed: Indian yard (1937) (NULL|EPSG)
Failed: Indian yard (1962) (NULL|EPSG)
Failed: Indian yard (1975) (NULL|EPSG)
Passed: Kilometer (KM|ORA) = 111.302649339446
Passed: Kilometer (KILOMETER|ORA) = 111.302649339446
Passed: Link (LINK|ORA) = 553287.043843245
Failed: Link (Benoit) (LINK_BEN|ORA)
Failed: Link (Sears) (LINK_SRS|ORA)
Passed: Meter (M|ORA) = 111302.649339446
Passed: Meter (METER|ORA) = 111302.649339446
Passed: Mile (MILE|ORA) = 69.1602599192254
Passed: Millimeter (MM|ORA) = 111302649.339446
Passed: Millimeter (MILLIMETER|ORA) = 111302649.339446
Passed: Modified American Foot (MOD_USFT|ORA) = 365166.17237351
Passed: Nautical Mile (NAUT_MILE|ORA) = 69.1602599192254
Passed: Rod (ROD|ORA) = 22131.2831741521
Passed: Statute mile (NULL|EPSG) = 69.1602599192254
Passed: U.S. Foot (SURVEY_FOOT|ORA) = 365166.17237351
Passed: US survey chain (NULL|EPSG) = 5532.82079353803
Passed: US survey foot (NULL|EPSG) = 365166.17237351
Passed: US survey link (NULL|EPSG) = 553287.043843245
Passed: US survey mile (NULL|EPSG) = 69.1602599192254
Passed: USER-HALF-METER (NULL|USER_DEFINED) = 222605.298678892
Passed: Yard (YARD|ORA) = 121722.057457837
Failed: Yard (Indian) (IND_YARD|ORA)
Failed: Yard (Sears) (SRS_YARD|ORA)
Passed: fathom (NULL|EPSG) = 60861.0287289183
Passed: foot (NULL|EPSG) = 365166.17237351
Failed: kilometre (NULL|EPSG)
Failed: metre (NULL|EPSG)
Passed: nautical mile (NULL|EPSG) = 69.1602599192254

So, I think my observation that they are inconsistent is correct up to a point. The inconsistency is that one says “use SDO_UNIT which is based on SHORT_NAME SHORT_NAME” while the other says “use the SDO_UNITS_OF_MEASURE table’s UNIT_OF_MEAS_NAME”.

The answer appears to me to be that the SDO_UNIT/SDO_DIST_UNIT approach is pre the alignment of the Oracle SDO_CS functionality with EPSG while the UNIT_OF_MEAS_NAME/SDO_UNITS_OF_MEASURE.

I have not yet discovered what defines a “valid” UNIT_OF_MEAS_NAME. When I find out I will extend this blog article.

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 [1]

Note: There is still a bug in 11gR2 that occurs when you pass in a 3D geometry. It indicates that you need to set count_shared_edges to NULL for 2D geometries, which of course makes no sense in that context.

— Bryan Hall · 7 September 2011, 19:29 · #