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.

Reducing 5 Vertex Polygon to Optimized Rectangle

Tuesday June 21 2011 at 06:15

I had occasion to convert a set of 5 vertex polygons that defined grid squares to their optimized rectangle equivalent.

To do this I created a simple function as follows.

create or replace
function Polygon2Rectangle( p_geometry in mdsys.sdo_geometry ) 
return mdsys.sdo_geometry deterministic as 
   v_vertices mdsys.vertex_set_type;
   v_id       pls_integer;
   v_ords     mdsys.sdo_ordinate_array :=  new mdsys.sdo_ordinate_array(null);
begin
   v_ords.DELETE;
   v_vertices := mdsys.sdo_util.getVertices(p_geometry);
   if ( v_vertices.COUNT <> 5 ) Then
      return p_geometry;
   End If;
   <<for_all_vectors>>
   FOR v_id in v_vertices.FIRST..(v_vertices.LAST-1) LOOP
       if ( v_id in (1,3) ) then
          v_ords.EXTEND(2);
          v_ords(v_ords.COUNT-1) := v_vertices(v_id).x;
          v_ords(v_ords.COUNT)   := v_vertices(v_id).y;
       end if;
   END LOOP for_all_vectors;
   return mdsys.sdo_geometry(p_geometry.sdo_gtype,
                             p_geometry.sdo_srid,
                             p_geometry.sdo_point,
                             mdsys.sdo_elem_info_array(1,1003,3),
                             v_ords);
end Polygon2Rectangle;

Which can then used as follows:

select polygon2rectangle(sdo_geometry(2003,null,null,
                                      sdo_elem_info_array(1,1003,1),
                                      sdo_ordinate_array(1,1,10,1,10,10,1,10,1,1))) 
        as optimised_rectangle
  from dual;
 
OPTIMISED_RECTANGLE 
-----------------------------
MDSYS.SDO_GEOMETRY(2003,NULL,NULL,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3),MDSYS.SDO_ORDINATE_ARRAY(1,1,10,10))

Update
On the basis of the excellent comments made by Farid Cheraghi, I have included his rectangle check (which could also have been done as a check of the diagonals of the rectangle), I have updated the function adding support for more complex sdo_geometry objects.

Note: The Oracle sdo_util.extract function, when it extracts inner rings (2003) renames them to 1003. Also, a complex element’s sdo_elem_info needs to be processed more carefully than is evident in the Oracle pl/sql functions.

create or replace
Function Polygon2Rectangle( p_geometry  in mdsys.sdo_geometry,
                            p_tolerance in number default 0.005 ) 
  Return mdsys.sdo_geometry DETERMINISTIC 
AS 
   v_vertices        mdsys.vertex_set_type;
   v_ords            mdsys.sdo_ordinate_array :=  new mdsys.sdo_ordinate_array(null);
   v_num_elems       pls_integer;
   v_actual_etype    pls_integer;
   v_ring_elem_count pls_integer := 0;
   v_ring            mdsys.sdo_geometry;
   v_num_rings       pls_integer;
   v_out_geom        mdsys.sdo_geometry;
 
  Function GetETypeAt(
    p_geometry  in mdsys.sdo_geometry,
    p_element   in pls_integer)
    Return pls_integer
  Is
    v_num_elems number;
  Begin
    If ( p_geometry is not null ) Then
      v_num_elems := ( ( p_geometry.sdo_elem_info.COUNT / 3 ) - 1 );
      <<element_extraction>>
      for v_i IN 0 .. v_num_elems LOOP
         if ( (v_i+1) = p_element ) then 
            RETURN p_geometry.sdo_elem_info(v_i * 3 + 2);
        End If;
        end loop element_extraction;
    End If;
    Return NULL;
  End GetETypeAt;
 
  Function GetNumRings( p_geometry  in mdsys.sdo_geometry,
                        p_ring_type in integer /* 0 = ALL; 1 = OUTER; 2 = INNER */ )
    Return Number
  Is
    v_elements   pls_integer := 0;
    v_ring_count pls_integer := 0;
    v_etype      pls_integer;
    v_ring_type  pls_integer := case when ( p_ring_type is null OR 
                                            p_ring_type not in (0,1,2) ) 
                                     Then 0
                                     Else p_ring_type 
                                 End;
  Begin
    If ( p_geometry is not null ) Then
      v_elements := ( ( p_geometry.sdo_elem_info.COUNT / 3 ) - 1 );
      <<element_extraction>>
      FOR v_i IN 0 .. v_elements LOOP
        v_etype := p_geometry.sdo_elem_info(v_i * 3 + 2);
        If ( ( v_etype in (1003,1005,2003,2005) and 0 = v_ring_type )
          OR ( v_etype in (1003,1005)           and 1 = v_ring_type )
          OR ( v_etype in (2003,2005)           and 2 = v_ring_type ) ) Then
           v_ring_count := v_ring_count + 1;
        End If;
      END LOOP element_extraction;
    End If;
    Return v_ring_count;
  End GetNumRings;
 
BEGIN
   IF ( p_geometry is null ) THEN
      RETURN p_geometry;
   END IF;
   -- Is polygon?
   IF ( p_geometry.get_gtype() not in (3,7) ) THEN
      RETURN p_geometry;
   END IF;
 
   v_num_elems := MDSYS.SDO_UTIL.GETNUMELEM(p_geometry);
   <<all_elements>>
   FOR v_elem_no IN 1..v_num_elems LOOP
       -- Need to process and check all inner rings
       --
       -- Process all rings in the extracted single - 2003 - polygon 
       v_num_rings := GetNumRings(MDSYS.SDO_UTIL.EXTRACT(p_geometry,v_elem_no),0);
       <<All_Rings>>
       FOR v_ring_no IN 1..v_num_rings LOOP
           v_ring := MDSYS.SDO_UTIL.EXTRACT(p_geometry,v_elem_no,v_ring_no);
           v_actual_etype := GetEtypeAt(p_geometry,(v_ring_elem_count+1));
           v_ring_elem_count := v_ring_elem_count + v_ring.sdo_elem_info.COUNT / 3;
           IF ( v_ring is not null ) THEN
             IF ( v_ring.sdo_elem_info(2) = 1003 AND
                  v_ring.sdo_elem_info(2) <> v_actual_etype ) THEN
                -- Replace etype as Oracle extracts 2003 as 1003
                v_ring.sdo_elem_info(2) := v_actual_etype;
             End If;
             v_vertices := mdsys.sdo_util.getVertices(v_ring);
             IF ( v_vertices.COUNT = 5 ) THEN
               -- Do the five vertices form a rectangle? 
               -- inner product of two consequent vector must equals to zero   
               IF ( (v_vertices(1).x-v_vertices(2).x) * (v_vertices(2).x-v_vertices(3).x) + 
                    (v_vertices(1).y-v_vertices(2).y) * (v_vertices(2).y-v_vertices(3).y) = 0 AND
                    (v_vertices(3).x-v_vertices(4).x) * (v_vertices(4).x-v_vertices(5).x) +
                    (v_vertices(3).y-v_vertices(4).y) * (v_vertices(4).y-v_vertices(5).y) = 0 ) THEN
                  v_ring.sdo_elem_info(1) := 1;
                  v_ring.sdo_elem_info(3) := 3;
                  v_ords.DELETE;
                  v_ords.EXTEND(4);
                  v_ords(1) := v_vertices(1).x;
                  v_ords(2) := v_vertices(1).y;
                  v_ords(3) := v_vertices(3).x;
                  v_ords(4) := v_vertices(3).y;
                  v_ring := mdsys.sdo_geometry(v_ring.sdo_gtype,
                                               v_ring.sdo_srid,
                                               v_ring.sdo_point,
                                               v_ring.sdo_elem_info,
                                               v_ords);
               END IF;
             END IF;
             IF ( v_out_geom is null ) THEN
               v_out_geom := v_ring;
             ELSE
               v_out_geom := mdsys.sdo_util.APPEND(v_out_geom,v_ring);
             END IF;
           END IF;
       END LOOP All_Rings;
   END LOOP all_elements;
   RETURN mdsys.sdo_geometry(p_geometry.sdo_gtype,
                             p_geometry.sdo_srid,
                             p_geometry.sdo_point,
                             v_out_geom.sdo_elem_info,
                             v_out_geom.sdo_ordinates);
END Polygon2Rectangle;

Testing…..

select sdo_geom.validate_geometry(a.geometry,0.005) as valid,
       polygon2rectangle(a.geometry) as optimised
  from (select sdo_geometry(2003,null,null, sdo_elem_info_array(1,1003,1), sdo_ordinate_array(1,1,10,1,10,10,1,10,1,1)) as geometry from dual
        union all select sdo_geometry(2007,null,null,sdo_elem_info_array(1,1003,1,11,1003,1,21,2003,3), sdo_ordinate_array(1,1,10,1,10,10,1,10,1,1, 15,15,25,15,25,25,15,25,15,15, 18,18,20,20)) as geometry from dual
        union all select sdo_geometry(2007,null,null,sdo_elem_info_array(1,1003,1,11,1003,1,21,2003,1), sdo_ordinate_array(1,1,10,1,10,10,1,10,1,1, 15,15,25,15,25,25,15,25,15,15, 16,16,16,24,24,24,24,16,16,16)) as geometry from dual
        union all select sdo_geometry(2003,null,null,sdo_elem_info_array(1,1005,2, 1,2,1, 5,2,2, 11, 2003, 1), sdo_ordinate_array(6,10, 10,1, 14,10, 10,14, 6,10, 8,8,8,12,12,12,12,8,8,8)) as geometry from dual
        union all select sdo_geometry(2003,null,null,sdo_elem_info_array(1,1003,2,11,2003,1), sdo_ordinate_array(15.0, 115.0, 20.0, 118.0, 15.0, 120.0, 10.0, 118.0, 15.0, 115.0,  13.6,116.7,13.6,118.3,16.3,118.3,16.3,116.7,13.6,116.7)) as geometry from dual
      ) a;
 
Valid Optimised
----- ---------
TRUE  MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3),MDSYS.SDO_ORDINATE_ARRAY(1,1,10,10))
TRUE  MDSYS.SDO_GEOMETRY(2007,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3,5,1003,3,9,2003,3),MDSYS.SDO_ORDINATE_ARRAY(1,1,10,10,15,15,25,25,18,18,20,20))
TRUE  MDSYS.SDO_GEOMETRY(2007,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3,5,1003,3,9,2003,3),MDSYS.SDO_ORDINATE_ARRAY(1,1,10,10,15,15,25,25,16,16,24,24))
TRUE  MDSYS.SDO_GEOMETRY(2003,NULL,NULL,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,2,1,2,1,5,2,2,11,2003,3),MDSYS.SDO_ORDINATE_ARRAY(6,10,10,1,14,10,10,14,6,10,8,8,12,12))
TRUE  MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,2,11,2003,3),MDSYS.SDO_ORDINATE_ARRAY(15,115,20,118,15,120,10,118,15,115,13.6,116.7,16.3,118.3))

I hope this function helps 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 [9]

Thnx 4 the post,but
this function doesn’t check for the geometries with 5 vertices which are not rectangles.
so We cannot apply it to a column of a table blindly.

— Farid · 21 June 2011, 09:01 · #

Modified Version

CREATE OR REPLACE FUNCTION "POLYGON2RECTANGLE" ( p_geometry in mdsys.sdo_geometry )
RETURN mdsys.sdo_geometry DETERMINISTIC
AS
v_vertices mdsys.vertex_set_type;
v_id pls_integer;
v_ords mdsys.sdo_ordinate_array := new mdsys.sdo_ordinate_array(null);
BEGIN
v_ords.DELETE;
v_vertices := mdsys.sdo_util.getVertices(p_geometry);
IF ( v_vertices.COUNT <> 5 ) THEN
RETURN p_geometry;
END IF;
--inner product of two consequent vector must equals to zero
IF ( (v_vertices(1).x-v_vertices(2).x) * (v_vertices(2).x-v_vertices(3).x) +
(v_vertices(1).y-v_vertices(2).y) * (v_vertices(2).y-v_vertices(3).y) = 0 AND
(v_vertices(3).x-v_vertices(4).x) * (v_vertices(4).x-v_vertices(5).x) +
(v_vertices(3).y-v_vertices(4).y) * (v_vertices(4).y-v_vertices(5).y) = 0 ) THEN
v_ords.EXTEND(4);
v_ords(1) := v_vertices(1).x;
v_ords(2) := v_vertices(1).y;
v_ords(3) := v_vertices(3).x;
v_ords(4) := v_vertices(3).y;
RETURN mdsys.sdo_geometry(p_geometry.sdo_gtype,
p_geometry.sdo_srid,
p_geometry.sdo_point,
mdsys.sdo_elem_info_array(1,1003,3),
V_ORDS);
ELSE
RETURN p_geometry;
END IF;
END Polygon2Rectangle;

— Farid Cheraghi · 23 June 2011, 23:47 · #

Farid,
You are quite right.
The initial post was only about a syntactic transformation with no semantic checks.
Prepared to offer a modified version?
Simon

Simon Greener · 25 June 2011, 01:38 · #

Hi Simon,
better than this impossible! I think the next move will be to make this function 3D enabled!
for the error, oracle says:

ORA-13366 Invalid combination of interior exterior rings

Cause: In the Spatial geometry, interior and exterior rings are not used consistently. ACTION: MAKE SURE THAT THE INTERIOR RINGS CORRESPONDING TO AN EXTERIOR RING FOLLOW THE EXTERIOR RING IN THE ORDINATE ARRAY.

but it’s not relevant to what i did to make it Valid. I think in oracle spatial compound features must be followed by simple features. So I changed the order of sdo_elem_info s and the geometry is now valid! (and not to miss the part that the GTYPE and Etype of the invalid geometry isn’t correct! 2003 => 2007 and 2003 => 1003

SELECT MDSYS.SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT(VALID_GM,0.005), valid_gm FROM
(SELECT MDSYS.SDO_GEOMETRY(2007,NULL,NULL,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,1,11,1005,2,11,2,1,15,2,2),MDSYS.SDO_ORDINATE_ARRAY(16,24,16,16,24,16,24,24,16,24,6,10,10,1,14,10,10,14,6,10)) VALID_GM
FROM DUAL )

— Farid Cheraghi · 26 June 2011, 11:44 · #

Farid,

Found the problem.

It is now fixed.

regards
Simon

Simon Greener · 5 July 2011, 10:21 · #

It is possible to use inverse Optimized Rectangle to 5 vertex?

— Cesar Corsico · 30 November 2016, 05:16 · #

Cesar,

Yes, see: http://spatialdbadvisor.com/oracle_spatial_tips_tricks/347/optimized-rectangle-to-5-point-polygon

Simon

— Simon Greener · 30 November 2016, 20:53 · #

Hi,

I have a dot feature on a map window,i want to scale that dot feature according to requriment..we did this functinality in .net ..but now we want to do in oracle..please help us ..how we can do that?

In .net we did translate the point to origin and scaleing again translation…

Thanks.

— Sithara · 7 April 2017, 20:27 · #

Sithara,
I can’t help if you don’t provide me with some data.
However, your description indicates that you want some transformation functions. These are available in my downloadable plsql packages.
Simon

— Simon Greener · 7 April 2017, 20:36 · #