Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    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
    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.

SDO2GeoJSON

Monday August 01 2011 at 03:38

KeywordsgeoJSON sdo sdo2geojson
Summary

A function that creates geoJSON snippets for an Oracle Sdo_Geometry object.

Recently, like many before me, I had need to create a function that converted a single SDO_GEOMETRY object to GeoJSON.

The function I created is below.

Note that this function:

  • Does not support attributes (it could do via passing in a refCursor or table of record);
  • Nor does nor does it address how to create a whole GeoJSON document from a collection of SDO_GEOMETRY records.

The latter could be done via a function that processed a SQL statement or refCursor with the appropriate parameters (filename etc).

One thing about GeoJSON is that it is uses the same keywords over and over again within a FeatureCollection. This could mean that a GeoJSON collection would repeat keywords eg MultiLineString as many times as there were records in the SQL statement. This would mean the collection would use more network bandwidth for communication. One approach could be to replace the keywords with unique short-name tags. I have done this in this function even though it is non-standard.

Additionally, I have wondered if some improvement in size could be won if the each geometry’s mbr is applied to the coordinates in order to make them “relative”, perhaps saving space. This non-standard idea is included as an “idea”.

  1. CREATE OR REPLACE
  2. FUNCTION sdo2geojson(p_geometry       IN sdo_geometry,
  3.                      p_decimal_places IN pls_integer DEFAULT 2,
  4.                      p_compress_tags  IN pls_integer DEFAULT 0,
  5.                      p_relative2mbr   IN pls_integer DEFAULT 0,
  6.                      p_num_fmt        IN varchar2    DEFAULT '999.9999999')
  7. RETURN CLOB deterministic
  8.   /* Note: Does not support curved geometries.
  9.    *        If required, stroke geometry before calling function.
  10.    * If Compressed apply bbox to coordinates.....
  11.    * { "type": "Feature",
  12.    *   "bbox": [-180.0, -90.0, 180.0, 90.0],
  13.    *   "geometry": {
  14.    *   "type": "Polygon",
  15.    *   "coordinates": [[ [-180.0, 10.0], [20.0, 90.0], [180.0, -5.0], [-30.0, -90.0] ]]
  16.    *  }
  17.    *  ...
  18.    * }
  19.   */
  20. AS
  21.   v_relative      BOOLEAN := CASE WHEN p_relative2mbr<>0  THEN TRUE ELSE FALSE END;
  22.   v_result        CLOB;
  23.   v_type          varchar2(50);
  24.   v_compress_tags BOOLEAN       := CASE WHEN p_compress_tags<>0 THEN TRUE ELSE FALSE END;
  25.   v_feature_key   varchar2(100) := CASE WHEN v_compress_tags THEN 'F'  ELSE '"Feature"'      END;
  26.   v_bbox_tag      varchar2(100) := CASE WHEN v_compress_tags THEN 'b:' ELSE '"bbox":'        END;
  27.   v_coord_tag     varchar2(100) := CASE WHEN v_compress_tags THEN 'c:' ELSE '"coordinates":' END;
  28.   v_geometry_tag  varchar2(100) := CASE WHEN v_compress_tags THEN 'g:' ELSE '"Geometry":'    END;
  29.   v_type_tag      varchar2(100) := CASE WHEN v_compress_tags THEN 't:' ELSE '"type":'        END;
  30.   v_temp_string   varchar2(30000);
  31.   v_precision     pls_integer  := nvl(p_decimal_places,2);
  32.   v_i             pls_integer;
  33.   v_num_rings     pls_integer;
  34.   v_num_elements  pls_integer;
  35.   v_element_no    pls_integer;
  36.   v_vertices      mdsys.vertex_set_type;
  37.   v_element       mdsys.sdo_geometry;
  38.   v_ring          mdsys.sdo_geometry;
  39.   v_mbr           mdsys.sdo_geometry;
  40.   v_rGeom         mdsys.sdo_geometry;
  41.   v_dims          pls_integer;
  42.   FUNCTION hasRectangles( p_elem_info IN mdsys.sdo_elem_info_array  )
  43.     RETURN Pls_Integer
  44.   IS
  45.      v_rectangle_count NUMBER := 0;
  46.      v_etype           pls_integer;
  47.      v_interpretation  pls_integer;
  48.      v_elements        pls_integer;
  49.   BEGIN
  50.      IF ( p_elem_info IS NULL ) THEN
  51.         RETURN 0;
  52.      END IF;
  53.      v_elements := ( ( p_elem_info.COUNT / 3 ) - 1 );
  54.      <<element_extraction>>
  55.      FOR v_i IN 0 .. v_elements LOOP
  56.        v_etype := p_elem_info(v_i * 3 + 2);
  57.        v_interpretation := p_elem_info(v_i * 3 + 3);
  58.        IF  ( v_etype IN (1003,2003) AND v_interpretation = 3  ) THEN
  59.            v_rectangle_count := v_rectangle_count + 1;
  60.        END IF;
  61.      END loop element_extraction;
  62.      RETURN v_rectangle_Count;
  63.   END hasRectangles;
  64.   FUNCTION hasCircularArcs(p_elem_info IN mdsys.sdo_elem_info_array)
  65.      RETURN BOOLEAN
  66.    IS
  67.      v_elements  NUMBER;
  68.    BEGIN
  69.      v_elements := ( ( p_elem_info.COUNT / 3 ) - 1 );
  70.      <<element_extraction>>
  71.      FOR v_i IN 0 .. v_elements LOOP
  72.         IF ( ( /* etype */         p_elem_info(v_i * 3 + 2) = 2 AND
  73.                /* interpretation*/ p_elem_info(v_i * 3 + 3) = 2 )
  74.              OR
  75.              ( /* etype */         p_elem_info(v_i * 3 + 2) IN (1003,2003) AND
  76.                /* interpretation*/ p_elem_info(v_i * 3 + 3) IN (2,4) ) ) THEN
  77.                RETURN TRUE;
  78.         END IF;
  79.      END loop element_extraction;
  80.      RETURN FALSE;
  81.   END hasCircularArcs;
  82.   FUNCTION GetNumRings( p_geometry  IN mdsys.sdo_geometry,
  83.                         p_ring_type IN INTEGER DEFAULT 0 /* 0 = ALL; 1 = OUTER; 2 = INNER */ )
  84.     RETURN NUMBER
  85.   IS
  86.      v_ring_count NUMBER := 0;
  87.      v_ring_type  NUMBER := p_ring_type;
  88.      v_elements   NUMBER;
  89.      v_etype      pls_integer;
  90.   BEGIN
  91.      IF ( p_geometry IS NULL ) THEN
  92.         RETURN 0;
  93.      END IF;
  94.      IF ( p_geometry.sdo_elem_info IS NULL ) THEN
  95.         RETURN 0;
  96.      END IF;
  97.      IF ( v_ring_type NOT IN (0,1,2) ) THEN
  98.         v_ring_type := 0;
  99.      END IF;
  100.      v_elements := ( ( p_geometry.sdo_elem_info.COUNT / 3 ) - 1 );
  101.      <<element_extraction>>
  102.      FOR v_i IN 0 .. v_elements LOOP
  103.        v_etype := p_geometry.sdo_elem_info(v_i * 3 + 2);
  104.        IF  ( v_etype IN (1003,1005,2003,2005) AND 0 = v_ring_type )
  105.         OR ( v_etype IN (1003,1005)           AND 1 = v_ring_type )
  106.         OR ( v_etype IN (2003,2005)           AND 2 = v_ring_type ) THEN
  107.            v_ring_count := v_ring_count + 1;
  108.        END IF;
  109.      END loop element_extraction;
  110.      RETURN v_ring_count;
  111.   END GetNumRings;
  112.   PROCEDURE ADD_Coordinate( p_ordinates  IN OUT nocopy mdsys.sdo_ordinate_array,
  113.                             p_dim        IN NUMBER,
  114.                             p_x_coord    IN NUMBER,
  115.                             p_y_coord    IN NUMBER,
  116.                             p_z_coord    IN NUMBER,
  117.                             p_m_coord    IN NUMBER,
  118.                             p_measured   IN BOOLEAN := FALSE,
  119.                             p_duplicates IN BOOLEAN := FALSE)
  120.     IS
  121.       FUNCTION Duplicate
  122.         RETURN BOOLEAN
  123.       IS
  124.       BEGIN
  125.         RETURN CASE WHEN p_ordinates IS NULL OR p_ordinates.COUNT = 0
  126.                     THEN FALSE
  127.                     ELSE CASE p_dim
  128.                               WHEN 2
  129.                               THEN ( p_ordinates(p_ordinates.COUNT)   = p_y_coord
  130.                                      AND
  131.                                      p_ordinates(p_ordinates.COUNT-1) = p_x_coord )
  132.                               WHEN 3
  133.                               THEN ( p_ordinates(p_ordinates.COUNT)   =  CASE WHEN p_measured THEN p_m_coord ELSE p_z_coord END
  134.                                      AND
  135.                                      p_ordinates(p_ordinates.COUNT-1) = p_y_coord
  136.                                      AND
  137.                                      p_ordinates(p_ordinates.COUNT-2) = p_x_coord )
  138.                               WHEN 4
  139.                               THEN ( p_ordinates(p_ordinates.COUNT)   = p_m_coord
  140.                                      AND
  141.                                      p_ordinates(p_ordinates.COUNT-1) = p_z_coord
  142.                                      AND
  143.                                      p_ordinates(p_ordinates.COUNT-2) = p_y_coord
  144.                                      AND
  145.                                      p_ordinates(p_ordinates.COUNT-3) = p_x_coord )
  146.                           END
  147.                   END;
  148.       END Duplicate;
  149.   BEGIN
  150.     IF ( p_ordinates IS NULL ) THEN
  151.        p_ordinates := NEW mdsys.sdo_ordinate_array(NULL);
  152.        p_ordinates.DELETE;
  153.     END IF;
  154.     IF ( p_duplicates OR NOT Duplicate() ) THEN
  155.       IF ( p_dim >= 2 ) THEN
  156.         p_ordinates.extend(2);
  157.         p_ordinates(p_ordinates.count-1) := p_x_coord;
  158.         p_ordinates(p_ordinates.COUNT  ) := p_y_coord;
  159.       END IF;
  160.       IF ( p_dim >= 3 ) THEN
  161.         p_ordinates.extend(1);
  162.         p_ordinates(p_ordinates.COUNT)   := CASE WHEN p_dim = 3 AND p_measured
  163.                                                  THEN p_m_coord
  164.                                                  ELSE p_z_coord
  165.                                             END;
  166.       END IF;
  167.       IF ( p_dim = 4 ) THEN
  168.         p_ordinates.extend(1);
  169.         p_ordinates(p_ordinates.COUNT)   := p_m_coord;
  170.       END IF;
  171.     END IF;
  172.   END ADD_Coordinate;
  173.   FUNCTION Rectangle2Polygon(p_geometry IN mdsys.sdo_geometry)
  174.     RETURN mdsys.sdo_geometry
  175.   AS
  176.     v_dims      pls_integer;
  177.     v_ordinates mdsys.sdo_ordinate_array := NEW mdsys.sdo_ordinate_array(NULL);
  178.     v_vertices  mdsys.vertex_set_type;
  179.     v_etype     pls_integer;
  180.     v_start_coord mdsys.vertex_type;
  181.     v_end_coord   mdsys.vertex_type;
  182.   BEGIN
  183.       v_ordinates.DELETE;
  184.       v_dims        := p_geometry.get_dims();
  185.       v_etype       := p_geometry.sdo_elem_info(2);
  186.       v_vertices    := sdo_util.getVertices(p_geometry);
  187.       v_start_coord := v_vertices(1);
  188.       v_end_coord   := v_vertices(2);
  189.       -- First coordinate
  190.       ADD_Coordinate( v_ordinates, v_dims, v_start_coord.x, v_start_coord.y, v_start_coord.z, v_start_coord.w );
  191.       -- Second coordinate
  192.       IF ( v_etype = 1003 ) THEN
  193.         ADD_Coordinate(v_ordinates,v_dims,v_end_coord.x,v_start_coord.y,(v_start_coord.z + v_end_coord.z) /2, v_start_coord.w);
  194.       ELSE
  195.         ADD_Coordinate(v_ordinates,v_dims,v_start_coord.x,v_end_coord.y,(v_start_coord.z + v_end_coord.z) /2,
  196.             (v_end_coord.w - v_start_coord.w) * ((v_end_coord.x - v_start_coord.x) /
  197.            ((v_end_coord.x - v_start_coord.x) + (v_end_coord.y - v_start_coord.y)) ));
  198.       END IF;
  199.       -- 3rd or middle coordinate
  200.       ADD_Coordinate(v_ordinates,v_dims,v_end_coord.x,v_end_coord.y,v_end_coord.z,v_end_coord.w);
  201.       -- 4th coordinate
  202.       IF ( v_etype = 1003 ) THEN
  203.         ADD_Coordinate(v_ordinates,v_dims,v_start_coord.x,v_end_coord.y,(v_start_coord.z + v_end_coord.z) /2,v_start_coord.w);
  204.       ELSE
  205.         Add_Coordinate(v_ordinates,v_dims,v_end_coord.x,v_start_coord.y,(v_start_coord.z + v_end_coord.z) /2,
  206.             (v_end_coord.w - v_start_coord.w) * ((v_end_coord.x - v_start_coord.x) /
  207.            ((v_end_coord.x - v_start_coord.x) + (v_end_coord.y - v_start_coord.y)) ));
  208.       END IF;
  209.       -- Last coordinate
  210.       ADD_Coordinate(v_ordinates,v_dims,v_start_coord.x,v_start_coord.y,v_start_coord.z,v_start_coord.w);
  211.       RETURN mdsys.sdo_geometry(p_geometry.sdo_gtype,p_geometry.sdo_srid,NULL,mdsys.sdo_elem_info_array(1,v_etype,1),v_ordinates);
  212.   END Rectangle2Polygon;
  213.   FUNCTION formatCoord(p_x        IN NUMBER,
  214.                        p_y        IN NUMBER,
  215.                        p_relative IN BOOLEAN)
  216.     RETURN varchar2
  217.   AS
  218.   BEGIN
  219.       RETURN '[' ||
  220.              CASE WHEN p_relative
  221.                   THEN TRIM(to_char(round(p_x - v_mbr.sdo_ordinates(1),v_precision),p_num_fmt)) || ',' ||
  222.                        TRIM(to_char(round(p_y - v_mbr.sdo_ordinates(2),v_precision),p_num_fmt))
  223.                   ELSE TRIM(to_char(round(p_x,v_precision),p_num_fmt)) || ',' ||
  224.                        TRIM(to_char(round(p_y,v_precision),p_num_fmt))
  225.               END ||
  226.               ']';
  227.   END formatCoord;
  228. BEGIN
  229.    IF ( p_geometry IS NULL ) THEN
  230.       RETURN NULL;
  231.   END IF;
  232.   -- Currently, we do not support compound objects
  233.   --
  234.   IF ( p_geometry.get_gtype() NOT IN (1,2,3,5,6,7) ) THEN
  235.     RETURN NULL;
  236.   END IF;
  237.   DBMS_LOB.createtemporary (lob_loc => v_result, cache => TRUE);
  238.   v_type := CASE WHEN v_compress_tags
  239.                  THEN CASE p_geometry.get_gtype()
  240.                            WHEN 1 THEN 'P'
  241.                            WHEN 2 THEN 'LS'
  242.                            WHEN 3 THEN 'PG'
  243.                            WHEN 5 THEN 'MP'
  244.                            WHEN 6 THEN 'MLS'
  245.                            WHEN 7 THEN 'MPG'
  246.                        END
  247.                  ELSE CASE p_geometry.get_gtype()
  248.                            WHEN 1 THEN '"Point"'
  249.                            WHEN 2 THEN '"LineString"'
  250.                            WHEN 3 THEN '"Polygon"'
  251.                            WHEN 5 THEN '"MultiPoint"'
  252.                            WHEN 6 THEN '"MultiLineString"'
  253.                            WHEN 7 THEN '"MultiPolygon"'
  254.                        END
  255.              END;
  256.   v_temp_string := '{';
  257.   IF ( p_geometry.get_gtype() = 1 ) THEN
  258.       v_temp_string := v_temp_string || v_type_tag || v_type || ',' || v_coord_tag;
  259.       IF (p_geometry.SDO_POINT IS NOT NULL ) THEN
  260.           v_temp_string := v_temp_string || '[' ||
  261.                            TRIM(to_char(round(p_geometry.SDO_POINT.X,v_precision),p_num_fmt)) || ',' ||
  262.                            TRIM(to_char(round(p_geometry.SDO_POINT.Y,v_precision),p_num_fmt)) || ']}';
  263.       ELSE
  264.           v_temp_string := v_temp_string || '[' ||
  265.                            TRIM(to_char(round(p_geometry.sdo_ordinates(1),v_precision),p_num_fmt)) || ',' ||
  266.                            TRIM(to_char(round(p_geometry.sdo_ordinates(2),v_precision),p_num_fmt)) || ']}';
  267.       END IF;
  268.       DBMS_LOB.WRITE(lob_loc => v_result,
  269.                      amount => LENGTH (v_temp_string),
  270.                      offset => 1,
  271.                      buffer => v_temp_string );
  272.       RETURN v_result;
  273.   END IF;
  274.   IF ( v_relative ) THEN
  275.      v_mbr := SDO_GEOM.SDO_MBR(p_geometry);
  276.      IF ( v_mbr IS NOT NULL ) THEN
  277.          v_temp_string := v_temp_string ||
  278.                           v_type_tag || v_feature_key || ',' ||
  279.                           v_bbox_tag || '[' ||
  280.                           v_mbr.sdo_ordinates(1) || ',' ||
  281.                           v_mbr.sdo_ordinates(2) || ',' ||
  282.                           v_mbr.sdo_ordinates(3) || ',' ||
  283.                           v_mbr.sdo_ordinates(4) || ',' ||
  284.                           '],' || v_geometry_tag || '{';
  285.      END IF;
  286.   END IF;
  287.   IF p_geometry.get_gtype() IN (5,6,7) THEN
  288.    v_temp_string := v_temp_string || v_type_tag || v_type || ',' || v_coord_tag || '[';
  289.   ELSE  
  290.   v_temp_string := v_temp_string || v_type_tag || v_type || ',' || v_coord_tag;
  291.   END IF;
  292.   -- Write header
  293.   DBMS_LOB.WRITE(lob_loc => v_result,
  294.                  amount => LENGTH (v_temp_string),
  295.                  offset => 1,
  296.                  buffer => v_temp_string);
  297.   IF ( hasCircularArcs(p_geometry.sdo_elem_info) ) THEN
  298.       RETURN NULL;
  299.   END IF;
  300.   v_num_elements := mdsys.sdo_util.GetNumElem(p_geometry);
  301.   <<for_all_elements>>
  302.   FOR v_element_no IN 1..v_num_elements LOOP
  303.      v_element := mdsys.sdo_util.EXTRACT(p_geometry,v_element_no);   -- Extract element with all sub-elements
  304.      IF ( v_element.get_gtype() IN (1,2,5) ) THEN
  305.         IF (v_element_no = 1) THEN
  306.            v_temp_string := '[';
  307.         elsif ( v_element.get_gtype() = 2 ) THEN
  308.            v_temp_string := '],[';
  309.         END IF;
  310.         DBMS_LOB.WRITE(lob_loc => v_result,
  311.                        amount => LENGTH (v_temp_string),
  312.                        offset => DBMS_LOB.GETLENGTH(v_result)+1,
  313.                        buffer => v_temp_string );
  314.         v_vertices := mdsys.sdo_util.getVertices(v_element);
  315.         v_temp_string := formatCoord(v_vertices(1).x,v_vertices(1).y,v_relative);
  316.         DBMS_LOB.WRITE(lob_loc => v_result,
  317.                        amount => LENGTH (v_temp_string),
  318.                        offset => DBMS_LOB.GETLENGTH(v_result)+1,
  319.                        buffer => v_temp_string );
  320.         <<for_all_vertices>>
  321.         FOR j IN 2..v_vertices.COUNT loop
  322.             v_temp_string := ',' || formatCoord(v_vertices(j).x,v_vertices(j).y,v_relative);
  323.             DBMS_LOB.WRITE(lob_loc => v_result,
  324.                            amount => LENGTH (v_temp_string),
  325.                            offset => DBMS_LOB.GETLENGTH(v_result)+1,
  326.                            buffer => v_temp_string );
  327.         END loop for_all_vertices;
  328.      ELSE
  329.         IF (v_element_no = 1) THEN
  330.            v_temp_string := '[';
  331.         ELSE
  332.            v_temp_string := '],[';
  333.         END IF;
  334.         DBMS_LOB.WRITE(lob_loc => v_result,
  335.                        amount => LENGTH (v_temp_string),
  336.                        offset => DBMS_LOB.GETLENGTH(v_result)+1,
  337.                        buffer => v_temp_string );
  338.         v_num_rings := GetNumRings(v_element);
  339.         <<for_all_rings>>
  340.         FOR v_ring_no IN 1..v_num_rings Loop
  341.           v_ring := MDSYS.SDO_UTIL.EXTRACT(p_geometry,v_element_no,v_ring_no);  -- Extract ring from element .. must do it this way, can't correctly extract from v_element.
  342.           IF ( v_ring_no > 1 ) THEN -- inner ring needs reversing
  343.               v_rGeom := Sdo_Geometry(v_dims*1000+2,v_ring.Sdo_Srid,NULL,Sdo_Elem_Info_Array(1,2,1),v_ring.Sdo_Ordinates);
  344.               v_ring.Sdo_Ordinates := Mdsys.Sdo_Util.Reverse_Linestring(v_rGeom).Sdo_Ordinates;
  345.           END IF;
  346.           IF (hasRectangles(v_ring.sdo_elem_info)>0) THEN
  347.              v_ring := Rectangle2Polygon(v_ring);
  348.           END IF;
  349.           IF ( v_ring_no > 1 ) THEN
  350.              v_temp_string := ',';
  351.              DBMS_LOB.WRITE(lob_loc => v_result,
  352.                             amount => LENGTH (v_temp_string),
  353.                             offset => DBMS_LOB.GETLENGTH(v_result)+1,
  354.                             buffer => v_temp_string );
  355.           END IF;
  356.           v_vertices := mdsys.sdo_util.getVertices(v_ring);
  357.           v_temp_string := '[' || formatCoord(v_vertices(1).x,v_vertices(1).y,v_relative);
  358.           DBMS_LOB.WRITE(lob_loc => v_result,
  359.                          amount => LENGTH (v_temp_string),
  360.                          offset => DBMS_LOB.GETLENGTH(v_result)+1,
  361.                          buffer => v_temp_string );
  362.           <<for_all_vertices>>
  363.           FOR j IN 2..v_vertices.COUNT loop
  364.               v_temp_string := ',' || formatCoord(v_vertices(j).x,v_vertices(j).y,v_relative);
  365.               DBMS_LOB.WRITE(lob_loc => v_result,
  366.                              amount => LENGTH (v_temp_string),
  367.                              offset => DBMS_LOB.GETLENGTH(v_result)+1,
  368.                              buffer => v_temp_string );
  369.           END loop for_all_vertices;
  370.           v_temp_string := ']';  -- Close Ring
  371.           DBMS_LOB.WRITE(lob_loc => v_result,
  372.                          amount => LENGTH (v_temp_string),
  373.                          offset => DBMS_LOB.GETLENGTH(v_result)+1,
  374.                          buffer => v_temp_string );
  375.         END Loop for_all_rings;
  376.      END IF;
  377.   END LOOP for_all_elements;
  378.   -- Closing tag
  379.   IF p_geometry.get_gtype() IN (5,6,7) THEN
  380.    v_temp_string := ']]}';
  381.   ELSE    
  382.   v_temp_string := ']}';
  383.   END IF;
  384.   IF ( v_relative AND p_geometry.get_gtype() <> 1 ) THEN
  385.       v_temp_string := v_temp_string || '}';
  386.   END IF;
  387.   DBMS_LOB.WRITE(lob_loc => v_result,
  388.                  amount => LENGTH (v_temp_string),
  389.                  offset => DBMS_LOB.GETLENGTH(v_result)+1,
  390.                  buffer => v_temp_string );
  391.   RETURN v_result;
  392. END Sdo2GeoJson;

I tested this with the following.

  1. SELECT CFLAG,
  2.        CASE WHEN iscompress=0 THEN 'Ordinary' ELSE 'Compressed' END AS CFLAGTTYPE,
  3.        geojson
  4.   FROM (SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2001,NULL,sdo_point_type(3312345,5212345,NULL),NULL,NULL),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  5.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2001,NULL,NULL,sdo_elem_info_array(1,1,1),            sdo_ordinate_array(312345,5212345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  6.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2005,NULL,NULL,sdo_elem_info_array(1,1,4),            sdo_ordinate_array(312345,5212345,322345,5222345,332345,5232345,342345,5242345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  7.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2002,NULL,NULL,sdo_elem_info_array(1,2,1),            sdo_ordinate_array(312345,5212345,322345,5222345,332345,5232345,342345,5242345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  8.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2006,NULL,NULL,sdo_elem_info_array(1,2,1,5,2,1),      sdo_ordinate_array(312345,5212345,322345,5222345,332345,5232345,342345,5242345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  9.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2003,NULL,NULL,sdo_elem_info_array(1,1003,3,5,2003,3),sdo_ordinate_array(312345,5212345,322345,5222345,332345,5232345,342345,5242345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  10.         UNION ALL SELECT (level-1) AS iscompress, sdo2geojson(sdo_geometry(2007,NULL,NULL,sdo_elem_info_array(1,1003,3,5,1003,3),sdo_ordinate_array(312345,5212345,322345,5222345,332345,5232345,342345,5242345)),1,(level-1),(level-1)) AS geojson FROM dual CONNECT BY level < 3
  11.         );
  12. -- Results
  13. CFLAG CFLAGTTYPE GEOJSON
  14. ----- ---------- -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  15. 0     Ordinary     {"type":"Point","coordinates":[3312345,5212345]}
  16. 1     Compressed   {t:P,c:[3312345,5212345]}
  17. 0     Ordinary     {"type":"Point","coordinates":[312345,5212345]}
  18. 1     Compressed   {t:P,c:[312345,5212345]}
  19. 0     Ordinary     {"type":"MultiPoint","coordinates":[[312345,5212345],[322345,5222345],[332345,5232345],[342345,5242345]]}
  20. 1     Compressed   {t:F,b:[312345,5212345,342345,5242345,],g:{t:MP,c:[[0,0],[10000,10000],[20000,20000],[30000,30000]]}}
  21. 0     Ordinary     {"type":"LineString","coordinates":[[312345,5212345],[322345,5222345],[332345,5232345],[342345,5242345]]}
  22. 1     Compressed   {t:F,b:[312345,5212345,342345,5242345,],g:{t:LS,c:[[0,0],[10000,10000],[20000,20000],[30000,30000]]}}
  23. 0     Ordinary     {"type":"MultiLineString","coordinates":[[312345,5212345],[322345,5222345]],[[332345,5232345],[342345,5242345]]}
  24. 1     Compressed   {t:F,b:[312345,5212345,342345,5242345,],g:{t:MLS,c:[[0,0],[10000,10000]],[[20000,20000],[30000,30000]]}}
  25. 0     Ordinary     {"type":"Polygon","coordinates":[[[312345,5212345],[322345,5212345],[322345,5222345],[312345,5222345],[312345,5212345]],[[332345,5232345],[342345,5232345],[342345,5242345],[332345,5242345],[332345,5232345]]]}
  26. 1     Compressed   {t:F,b:[312345,5212345,342345,5242345,],g:{t:PG,c:[[[0,0],[10000,0],[10000,10000],[0,10000],[0,0]],[[20000,20000],[30000,20000],[30000,30000],[20000,30000],[20000,20000]]]}}
  27. 0     Ordinary     {"type":"MultiPolygon","coordinates":[[[312345,5212345],[322345,5212345],[322345,5222345],[312345,5222345],[312345,5212345]]],[[[332345,5232345],[342345,5232345],[342345,5242345],[332345,5242345],[332345,5232345]]]}
  28. 1     Compressed   {t:F,b:[312345,5212345,342345,5242345,],g:{t:MPG,c:[[[0,0],[10000,0],[10000,10000],[0,10000],[0,0]]],[[[20000,20000],[30000,20000],[30000,30000],[20000,30000],[20000,20000]]]}}
  29.  14 ROWS selected

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

Hi Simon !
Thank you for your very helpful function !

I added a line to alter the session nls_numeric_characters parameter into the body of “formatCoord” function :

—alter nls_numeric_characters for decimal point separator
EXECUTE IMMEDIATE;

I haved to add this because in France the decimal separator is a comma and the geojson specification says it must be a point.
I hope it will be helpful.

— Julien LEURIDANT · 22 February 2013, 15:35 · #

Hello, I think your Multipolygon Json output is wrong.
Could you fix this problem ?

— John · 14 May 2013, 09:52 · #

John,

How about something more than “your Multipolygon Json output is wrong”.

Can you provide some data? What is it you say is wrong in the output?

I am away consulting at the moment and could not look at this for you for at least a month and a half. I suggest you have a closer look and provide me with more information, or, perhaps, have a go at fixing it yourself.

regards
Simon

— Simon Greener · 20 May 2013, 00:37 · #

Hi Simon,

I wanted to thank you for making this function available, I’ve found it very helpful with a web-mapping project I’m working on at the moment.

I was also experiencing the issue with MultiPolygon output, but identified and fixed it.
The “coordinates” array for MultiPolygon features simple requires an additional set of square brackets wrapping around it.
I’d share my code with the issue fixed but it’s incredibly hacky and is rather specific to my one use.

Thanks,
Michael

— Michael Loughlin · 20 June 2013, 15:07 · #

{“type”: “Feature”, “geometry”: {“type”:“MultiLineString”,“coordinates”:[[104.149606,15.795742],[104.149606,15.795742],[104.149589,15.795728],[104.149522,15.795674],[104.149501,15.795657],[104.149125,15.79536],[104.148738,15.795034],[104.148406,15.794766],[104.147956,15.794393],[104.147819,15.794285],[104.147507,15.794029],[104.147503,15.794025]],[[104.150437,15.796414],[104.150436,15.796414]],[[104.150009,15.796092],[104.150009,15.796093]],[[104.151455,15.797189],[104.151446,15.797183],[104.151446,15.797182],[104.151445,15.797182],[104.150967,15.796825],[104.150931,15.796797],[104.15093,15.796797],[104.150849,15.796734],[104.150849,15.796734],[104.150783,15.796683],[104.150509,15.79647],[104.150485,15.796451],[104.150484,15.79645]],[[104.152108,15.797662],[104.1521,15.797657],[104.152053,15.797623],[104.151645,15.797329],[104.151514,15.797233],[104.151498,15.797221]],[[104.150485,15.796451],[104.150478,15.796445],[104.150436,15.796414],[104.15001,15.796093],[104.150009,15.796093],[104.149976,15.796065],[104.149967,15.796057],[104.149673,15.795798],[104.149673,15.795798],[104.149673,15.795798],[104.149607,15.795743]]}}

there is a mistake for multiline ( I think also multipolygon also)

it miss a [ at the beginning and ] end.

this is correct one.

{ “type”: “Feature”, “geometry”: { “type”: “MultiLineString”, “coordinates”: [ [ [ 104.149606, 15.795742 ], [ 104.149606, 15.795742 ], [ 104.149589, 15.795728 ], [ 104.149522, 15.795674 ], [ 104.149501, 15.795657 ], [ 104.149125, 15.79536 ], [ 104.148738, 15.795034 ], [ 104.148406, 15.794766 ], [ 104.147956, 15.794393 ], [ 104.147819, 15.794285 ], [ 104.147507, 15.794029 ], [ 104.147503, 15.794025 ] ], [ [ 104.150437, 15.796414 ], [ 104.150436, 15.796414 ] ], [ [ 104.150009, 15.796092 ], [ 104.150009, 15.796093 ] ], [ [ 104.151455, 15.797189 ], [ 104.151446, 15.797183 ], [ 104.151446, 15.797182 ], [ 104.151445, 15.797182 ], [ 104.150967, 15.796825 ], [ 104.150931, 15.796797 ], [ 104.15093, 15.796797 ], [ 104.150849, 15.796734 ], [ 104.150849, 15.796734 ], [ 104.150783, 15.796683 ], [ 104.150509, 15.79647 ], [ 104.150485, 15.796451 ], [ 104.150484, 15.79645 ] ], [ [ 104.152108, 15.797662 ], [ 104.1521, 15.797657 ], [ 104.152053, 15.797623 ], [ 104.151645, 15.797329 ], [ 104.151514, 15.797233 ], [ 104.151498, 15.797221 ] ], [ [ 104.150485, 15.796451 ], [ 104.150478, 15.796445 ], [ 104.150436, 15.796414 ], [ 104.15001, 15.796093 ], [ 104.150009, 15.796093 ], [ 104.149976, 15.796065 ], [ 104.149967, 15.796057 ], [ 104.149673, 15.795798 ], [ 104.149673, 15.795798 ], [ 104.149673, 15.795798 ], [ 104.149607, 15.795743 ] ] ] }
}

— art · 25 July 2013, 14:04 · #

Thanks. How about giving me the Pl/sql changes? SImon

— Simon Greener · 25 July 2013, 23:54 · #

Hi Simon, fyi, created a package for this which will also bring in the attributes. See https://mapoholic.wordpress.com/2015/08/30/convert-oracle-spatial-data-to-geojson/

Cheers,
Pano

— Pano Voudouris · 4 September 2015, 18:28 · #

This code has an error. For polygons or multipolygons with holes (inner rings) orientation of latlngs must be clockwise, but we have counterclockwise in result.
This is happens because of this – Extracting Inner Rings Changed Ordinate Ordering (
https://spatialdbadvisor.com/oracle_spatial_tips_tricks/333/extracting-inner-rings-a-trap-for-players-who-don-t-read-documentation)

— Andy V · 1 September 2016, 14:56 · #

Andy,

Thanks for pointing this out.

Have you modified the code to reverse the coordinate order for the inner rings?

Would you care to share your changes, or do you want me to modify this code to reverse the linestring?

regards
Simon

— Simon Greener · 1 September 2016, 16:50 · #

Simon,
I have no changes to fix this problem.
So, could you fix this?

— Andy V · 1 September 2016, 16:59 · #