Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles


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.

Oracle Locator vs Oracle Spatial: A Reflection on Oracle Licensing of the SDO_GEOM Package

Monday September 24 2007 at 04:50

Keywordslocator vs spatial licensing
Summary

A reflection on Locator versus Spatial licensing and some suggestions as to how to use “spatial” processing with Locator. The Spatial Companion For Oracle is introduced.

UPDATED: Spatial Companion For Oracle (SC4O) – see end of this article.

This reflection has come about because of the many times I have gone to sites running Oracle Standard Edition (SE or SE1) that are, accidently, using some of the “geoprocessing” functions in the SDO_GEOM package that are licensed only for use with Enterprise Edition (EE). Oracle XE adds to this confusion as it is shipped with the complete SDO_GEOM package. And, finally, the recent release of Oracle 11g continues the restricted use of certain SDO_GEOM package “geoprocessing” functions and their use in the related ST_* functions of the SQL3/MM (or OGC) type library.

1. Licensing.

1.1 Introduction.

Oracle Locator is a cut down version of Oracle Spatial Standard Edition (SE/SE1) database installations.

From Appendix B of the Spatial User Guide we see:

Oracle Locator (also referred to as Locator) is a feature of Oracle Database 10g Standard Edition. Locator provides core features and services available in Oracle Spatial. It provides significant capabilities typically required to support Internet and wireless service-based applications and partner-based GIS solutions. Locator is not designed to be a solution for geographic information system (GIS) applications requiring complex spatial data management. If you need capabilities such as linear referencing, spatial functions, or coordinate system transformations, use Oracle Spatial instead of Locator.

Locator is available with both the Standard and Enterprise Editions of Oracle Database 10g. Spatial is a priced option available only with Oracle Database 10g Enterprise Edition. Spatial includes all Locator features as well as other features that are not available with Locator.

The installation of Locator depends on the successful and proper installation of Oracle interMedia. interMedia is installed and configured with Oracle Database 10g, although you can install interMedia manually if necessary, as documented in Oracle interMedia User’s Guide. During the installation of interMedia, Locator is installed.

In general, Locator includes the data types, operators, and indexing capabilities of Oracle Spatial, along with a limited set of the functions and procedures of Spatial. The Locator features include the following:

  • An object type (SDO_GEOMETRY) that describes and supports any type of geometry
  • A spatial indexing capability that lets you create spatial indexes on geometry data
  • Spatial operators (described in Chapter 11) that use the spatial index for performing spatial queries
  • Some geometry functions and the SDO_AGGR_MBR spatial aggregate function
  • Coordinate system support for explicit geometry and layer transformations (SDO_CS.TRANSFORM function and SDO_CS.TRANSFORM_LAYER procedure, described in Chapter 13)
  • Tuning functions and procedures (SDO_TUNE package, described in Chapter 19)
  • Spatial utility functions (SDO_UTIL package, described in Chapter 20)
  • Integration with Oracle Application Server 10g

Much confusion exists about what is licensed and what is not wrt Locator. What is actually licensed is clearly documented in Appendix B of the Spatial User guide. Because, this article concentrates on the SDO_GEOM package functions and procedures, we note that only those functions listed in Table B-1 are licensed. These are:

SDO_GEOM.SDO_DISTANCE()
SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT()
SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT()

There is no confusion about the other, self-contained, packages as these are only installed for Enterprise Edition. These packages are:

  • Linear referencing system (LRS) support
  • Spatial analysis and mining functions and procedures (SDO_SAM package)
  • Geocoding support (SDO_GCDR package)
  • GeoRaster support
  • Topology data model
  • Network data model

1.2 Why confusion?

Why is there such confusion about the user of the SDO_GEOM function other than the three mentioned above in Standard Edition databases?

Simply put, when an SE database is created using Oracle’s DataBase Configuration Assistant (DBCA), all the functions and procedures in SDO_GEOM are installed: not just the actual three that are licensed for SE (see above). (The installer should be fixed to ensure that these are not installed.)

Coupled to this is the fact that very few day-to-day practitioners read the documentation and most certainly do not read or are a party to the license agreements negotiated and signed by management. Users simply connect to the installed software and start using it. When one of these users describes the SDO_GEOM package in SqlPlus (DESCRIBE MDSYS.SDO_GEOM) all SDO_GEOM functions are displayed: they therefore assume that use of these must be allowed. Finally, much/most commercial software used in the GIS world is keycoded to stop use of unlicensed components: that Oracle doesn’t do this is not widely known and contributes to the unintentional breaking of the license agreement.

1.3 A way out of this?

Is there a way out of this problem?

Well, certainly, users should try and familiarise themselves with the license and try and conform to it. After all, Oracle owns the software and has the right to set whatever terms they want with respect to the licensing and use of their software.

I personally have a view that some of the “geoprocessing” functions in the SDO_GEOM package are not “geoprocessing” functions at all but properties of a spatial object and should be free of license restrictions. Specifically:

MDSYS.SDO_GEOM.SDO_AREA()
MDSYS.SDO_GEOM.SDO_LENGTH()
MDSYS.SDO_GEOM.SDO_MBR()
MDSYS.SDO_GEOM.SDO_MIN_MBR_ORDINATE()
MDSYS.SDO_GEOM.SDO_MAX_MBR_ORDINATE()

With respect to the other functions, eg SDO_UNION, SDO_INTERSECTION etc, while these are “geoprocessing” functions they are a necessary part of the OGC and SQL3/MM standard for an implementation of a spatial type that that Oracle should allow their use within Locator for no additional charge. However, they have decided otherwise and I respect that decision: perhaps they could consider licensing these functions independently of other Enterprise Edition Spatial features (eg LRS etc)? Certainly, most of the Locator users I know would happily part with $1,000 per cpu to be able to use these functions.

However, until such a thing happens, I will now outline some of the common SDO_GEOM functions that are illegally used in Locator installations demonstrating how they can be replaced by SQL or functions that are licensed for use.

2. MBR Functions.

2.1 SDO_GEOM Functions.

The SDO_GEOM package contains the following functions:

MDSYS.SDO_GEOM.SDO_MBR
MDSYS.SDO_GEOM.SDO_MIN_MBR_ORDINATE
MDSYS.SDO_GEOM.SDO_MAX_MBR_ORDINATE

The SDO_MBR SDO_MBR function returns an optimized rectangle SDO_GEOMETRY object:


gis@XE>SELECT sdo_geom.sdo_mbr(geom) as MBR_Geometry
  2      FROM transport
  3     WHERE oid = 100000
  4  /
MBR_GEOMETRY(SDO_GTYPE, SDO_SRID, SDO_POINT(X, Y, Z), SDO_ELEM_INFO, SDO_ORDINATES)
----------------------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2003, 82468, NULL, SDO_ELEM_INFO_ARRAY(1, 1003, 3), SDO_ORDINATE_ARRAY(489588.734, 5442823.66, 489666.972, 5442858.68))

To access the actual optimized rectangle ordinates one can do this:


gis@XE>SELECT o.*
  2      FROM transport t,
  3           TABLE(sdo_geom.sdo_mbr(t.geom).sdo_ordinates) o
  4     WHERE t.oid = 100000
  5 /
COLUMN_VALUE
------------
  489588.734
  5442823.66
  489666.972
  5442858.68

To “flatten” this into a single row, one could use the Locator licensed SDO_UTIL package’s GetVertices function as follows:


gis@XE>SELECT min(o.x) as minx,
  2           max(o.x) as maxx,
  3           min(o.y) as miny,
  4           max(o.y) as maxy
  5      FROM TRANSPORT t,
  6           TABLE(sdo_util.GetVertices(sdo_geom.sdo_mbr(t.geom))) o
  7*    WHERE t.oid = 100000
gis@XE> /
      MINX       MAXX       MINY       MAXY
---------- ---------- ---------- ----------
503265.593 503361.836 5206993.37 5207088.18

Sensibly, however, most people simplify the SQL to access the lower left and upper right ordinates of the MBR optimized rectangle by using the provided MIN/MAX MBR functions as follows:


gis@XE>SELECT sdo_geom.sdo_min_mbr_ordinate(geom,1) as MINX,
  2           sdo_geom.sdo_max_mbr_ordinate(geom,1) as MAXX,
  3           sdo_geom.sdo_min_mbr_ordinate(geom,2) as MINY,
  4           sdo_geom.sdo_max_mbr_ordinate(geom,2) as MAXY
  5      FROM transport
  6     WHERE oid = 100000
  7  /
      MINX       MAXX       MINY       MAXY
---------- ---------- ---------- ----------
489588.734 489666.972 5442823.66 5442858.68

So how do we avoid the use of these licensed functions in Locator installations?

2.2 SQL.

Firstly, one should note that the SDO_AGGR_MBR aggregate operator is licensed for use in Locator. The MBR functions in SDO_GEOM can be replaced with something that would conform to Oracle licensing in a trivial amount of time.

For example, the above SQL could be replaced by (a slightly different form of the SDO_MBR example above):


gis@XE>SELECT *
  1      FROM TABLE(SELECT sdo_aggr_mbr(geom).sdo_ordinates
  2                   FROM transport
  3                  WHERE oid = 100000)
  4 /
COLUMN_VALUE
------------
   489588.734
   5442823.66
   489666.972
   5442858.68

To return a single row we could do this:


gis@XE>SELECT min(case when rownum = 1 then column_value else NULL end) as minx,
  1           min(case when rownum = 3 then column_value else NULL end) as maxx,
  2           max(case when rownum = 2 then column_value else NULL end) as miny,
  3           max(case when rownum = 4 then column_value else NULL end) as maxy
  4      FROM TABLE(SELECT sdo_aggr_mbr(geom).sdo_ordinates
  5                   FROM transport
  6                  WHERE oid = 100000)
  7 /
      MINX       MAXX       MINY       MAXY
---------- ---------- ---------- ----------
489588.734 489666.972 5442823.66 5442858.68

Or we could do this:


gis@XE>SELECT min(c.x) as minx,
  1           max(c.x) as maxx,
  2           min(c.y) as miny,
  3           max(c.y) as maxy
  4      FROM (SELECT sdo_aggr_mbr(t.geom) as mbr
  5              FROM transport t
  6             WHERE oid = 100000) g,
  7           TABLE(mdsys.sdo_util.getvertices(g.mbr)) c;
  8 /
      MINX       MAXX       MINY       MAXY
---------- ---------- ---------- ----------
489588.734 489666.972 5442823.66 5442858.68

(Note: there are many ways, in SQL, to “skin the cat”. I have deliberately done this in this article.)

2.3 SDO_3GL.

2.3.1 EXTENT_OF_OBJECT.

Locator also includes the SDO_3GL package which is not mentioned in any of the licensing documents. One can conclude from this that the SDO_3GL package is not constrained by Locator license restrictions.

Investigating SDO_3GL we find that the package contains the following MBR procedure.


PROCEDURE EXTENT_OF_OBJECT
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 DIMOBJ                         SDO_DIM_ARRAY           IN
 GEOMOBJ                        SDO_GEOMETRY            IN
 MIN_X                          NUMBER                  OUT
 MAX_X                          NUMBER                  OUT
 MIN_Y                          NUMBER                  OUT
 MAX_Y                          NUMBER                  OUT

Note that this is a procedure not a function: it cannot be used in SQL SELECT statements. The only way we could use this would be via creating a set of functions that encapsulate this procedure and return the relevant elements. I will not do this here as these functions are relatively simple to write and I have already encapsulated them in an MBR object which is included in my free PL/SQL packages: I will demonstrate their use in Section 2.3.3 below.

2.3.2 MBR_GEOMETRY.

The SDO_3GL package also contains the MBR_GEOMETRY function whose signature is:

FUNCTION MBR_GEOMETRY RETURNS SDO_GEOMETRY Argument Name Type In/Out Default? ——————————————— ———————————- ——— ———— GEOM SDO_GEOMETRY IN DIM SDO_DIM_ARRAY IN

This can be used to return the extent of a feature as follows:


gis@XE>SELECT min(c.x) as minx,
  2           max(c.x) as maxx,
  3           min(c.y) as miny,
  4           max(c.y) as maxy
  5      FROM user_sdo_geom_metadata usgm,
  6           transport t,
  7           TABLE(mdsys.sdo_util.getvertices(mdsys.sdo_3gl.mbr_geometry(t.geom,usgm.diminfo))) c
  8     WHERE usgm.table_name = 'TRANSPORT'
  9       AND t.oid = 100000
 10  /
      MINX       MAXX       MINY       MAXY
---------- ---------- ---------- ----------
489588.734 489666.972 5442823.66 5442858.68

2.3.3 MBR package.

The above query using my MBR package would be:


gis@XE>SELECT codesys.mbr(t.geom,usgm.diminfo).minx as minx,
  2           codesys.mbr(t.geom,usgm.diminfo).miny as miny,
  3           codesys.mbr(t.geom,usgm.diminfo).maxx as maxx,
  4           codesys.mbr(t.geom,usgm.diminfo).maxy as maxy
  5      FROM user_sdo_geom_metadata usgm,
  6           transport t
  7     WHERE usgm.table_name = 'TRANSPORT'
  8       AND oid = 100000
  9 /
      MINX       MINX       MINY       MAXY
---------- ---------- ---------- ----------
489588.734 5442823.66 489666.972 5442858.68

The MBR package only uses SDO_3GL.EXTENT_OF_OBJECT procedure and so does not break Standard Edition license restrictions. The MDSYS dependencies of the MBR package can be ascertained as follows:


gis@XE>SELECT referenced_owner, 2 referenced_name 3 FROM dba_dependencies 4 WHERE owner = ‘CODESYS’ 5 AND name = ‘MBR’ 6 AND referenced_owner = ‘MDSYS’ 7 /
REFERENCED_OWNER REFERENCED_NAME
——————————————— ————————
MDSYS SDO_GEOMETRY
MDSYS SDO_GEOMETRY
MDSYS SDO_DIM_ELEMENT
MDSYS SDO_DIM_ARRAY
MDSYS SDO_DIM_ARRAY
MDSYS SDO_3GL

6 rows selected.

In more detail (connected as CODESYS):


codesys@XE>SELECT text
  2          FROM user_source
  3         WHERE name = 'MBR'
  4           AND INSTR(UPPER(text),'SDO_3GL') > 1
  5 /
TEXT
------------------------------------
    MDSYS.SDO_3GL.EXTENT_OF_OBJECT(
    MDSYS.SDO_3GL.EXTENT_OF_OBJECT(

But what about SDO_GEOM? Using:


codesys@XE>SELECT text 2 FROM user_source 3 WHERE name = ‘MBR’ 4 AND INSTR,‘SDO_GEOM’) > 1 5 /
TEXT
———————————————————————————————————————— Constructor Function MBR( p_geometry IN MDSYS.SDO_GEOMETRY, Constructor Function MBR( p_geometry IN MDSYS.SDO_GEOMETRY, Member Procedure SetLargestPart( p_geometry IN MDSYS.SDO_GEOMETRY, Constructor Function MBR( p_geometry IN MDSYS.SDO_GEOMETRY, Constructor Function MBR( p_geometry IN MDSYS.SDO_GEOMETRY, — usage : FUNCTION SetLargestPart ( p_geometry IN MDSYS.SDO_GEOMETRY, p_dimarray IN MDSYS.SDO_DIM_ARRAY ); -- paramtype : p_geomery : MDSYS.SDO_GEOMETRY Member Procedure SetLargestPart( p_geometry IN MDSYS.SDO_GEOMETRY,

8 rows selected.

No SDO_GEOM package functions are being used by my MBR package.

3.0 Centroids.

3.1 SDO_GEOM.SDO_CENTROID.

Now, the SDO_GEOM.SDO_CENTROID function is an Enterprise feature. The SDO_GEOM.SDO_CENTROID function computes a mathematically weighted centroid that does not necessarily fall within a polygon as in the following example:

Possible centroid locations

This function is called as follows:


gis@XE>SELECT mdsys.sdo_geom.sdo_centroid(a.geom,usgm.diminfo)
  2      FROM user_sdo_geom_metadata usgm,
  3           admin a
  4     WHERE usgm.table_name = 'ADMIN'
  5       AND a.oid = 46953
  6 /
MDSYS.SDO_GEOM.SDO_CENTROID(A.GEOM,USGM.DIMINFO)(SDO_GTYPE, SDO_SRID, SDO_POINT(X, Y, Z), SDO_ELEM_INFO, SDO_ORDINATES)
-----------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2001, 82468, SDO_POINT_TYPE(327753.624, 5486215.53, NULL), NULL, NULL)

Elapsed: 00:00:00.01

But what if you don’t have an Enterprise license?

You have two other options for generating a centroid from geometry data using Standard Edition functions.

3.2 GEOM.SDO_CENTROID.

Firstly, you could use my GEOM package’s sdo_centroid function. This is a powerful function that is different from Oracle’s SDO_GEOM.SDO_CENTROID function in that it guarantees that a centroid will fall within a polygon and not outside it (a “para-centroid”). It will also place the centroid in the largest of all parts of a multi-part polygon and will not place a centroid inside any hole in any of the parts.

We call this function as follows:


gis@XE>SELECT codesys.geom.sdo_centroid(a.geom,usgm.diminfo)
  2      FROM user_sdo_geom_metadata usgm,
  3           admin a
  4     WHERE usgm.table_name = 'ADMIN'
  5       AND a.oid = 46953
  6 /
CODESYS.GEOM.SDO_CENTROID(A.GEOM,USGM.DIMINFO)(SDO_GTYPE, SDO_SRID, SDO_POINT(X, Y, Z), SDO_ELEM_INFO, SDO_ORDINATES)
---------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2001, NULL, SDO_POINT_TYPE(327741.04, 5486221.36, NULL), NULL, NULL)

3.3 SDO_3GL.CENTROID.

Secondly, you can use the CENTROID function in the SDO_3GL package. This will return exactly the same result as the SDO_GEOM.SDO_CENTROID function. You use it as follows:


gis@XE>SELECT mdsys.sdo_3gl.centroid(usgm.diminfo,a.geom)
  2      FROM user_sdo_geom_metadata usgm,
  3           admin a
  4     WHERE usgm.table_name = 'ADMIN'
  5       AND a.oid = 46953
  6 /
MDSYS.SDO_3GL.CENTROID(USGM.DIMINFO,A.GEOM)(SDO_GTYPE, SDO_SRID, SDO_POINT(X, Y, Z), SDO_ELEM_INFO, SDO_ORDINATES)
------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2001, 82468, SDO_POINT_TYPE(327753.624, 5486215.53, NULL), NULL, NULL)

4.0 Buffers.

4.1 SDO_GEOM.BUFFER.

The SDO_GEOM.SDO_BUFFER function is also licensed only for use in Enterprise Edition.

We use this function as follows:


gis@XE>SELECT mdsys.sdo_geom.sdo_buffer(a.geom,usgm.diminfo,10)
  2      FROM user_sdo_geom_metadata usgm,
  3           admin a
  4     WHERE usgm.table_name = 'ADMIN'
  5       AND a.oid = 46953
  6 /
-- resulting data not shown -- 

But how can we generate a buffer in Standard Edition?

Again, we can look to the SDO_3GL package.


FUNCTION GENERATE_BUFFER RETURNS SDO_GEOMETRY
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 DIMOBJ                         SDO_DIM_ARRAY           IN
 GEOMOBJ                        SDO_GEOMETRY            IN
 DIST                           NUMBER                  IN

Which we use as follows:


gis@XE>SELECT mdsys.sdo_3gl.generate_buffer(usgm.diminfo,a.geom,10)
  2      FROM user_sdo_geom_metadata usgm,
  3           admin a
  4     WHERE usgm.table_name = 'ADMIN'
  5       AND a.oid = 46953
  6 /
-- Resulting data not shown --

Are the buffers generated by the sdo_geom and sdo_3gl functions the same?


gis@XE>SELECt MDSYS.SDO_GEOM.RELATE(
  2                 MDSYS.SDO_3GL.GENERATE_BUFFER(usgm.diminfo,a.geom,10),
  3                 usgm.diminfo,
  4                 'mask=determine',
  5                 MDSYS.SDO_GEOM.SDO_BUFFER(a.geom,usgm.diminfo,10),
  6                 usgm.diminfo) As Relationship
  7      FROM user_sdo_geom_metadata usgm,
  8           admin a
  9     WHERE usgm.table_name = 'ADMIN'
 10       AND a.oid = 46953
 11 /
RELATIONSHIP
------------
EQUAL

However, we now meet another problem: SDO_GEOM.RELATE is an Enterprise function! How can we check the relationship between two object with Locator?

Can we find a solution in the SDO_3GL RELATE functions?


gis@XE>SELECT MDSYS.SDO_3GL.RELATE(
  2                 usgm.diminfo,
  3                 MDSYS.SDO_3GL.GENERATE_BUFFER(usgm.diminfo,a.geom,10),
  4                 'mask=determine',
  5                 usgm.diminfo,
  6                 MDSYS.SDO_GEOM.SDO_BUFFER(a.geom,usgm.diminfo,10)) as Relationship
  7      FROM user_sdo_geom_metadata usgm,
  8           admin a
  9     WHERE usgm.table_name = 'ADMIN'
 10       AND a.oid = 46953
 11 /
RELATIONSHIP
------------
111111111

What does this mean?

Well, if we do this:


gis@XE>SELECT MDSYS.SDO_3GL.RELATE(
  2                 usgm.diminfo,
  3                 a.geom,
  4                 'mask=determine',
  5                 usgm.diminfo,
  6                 MDSYS.SDO_GEOM.SDO_BUFFER(a.geom,usgm.diminfo,10)) as Relationship
  7      FROM user_sdo_geom_metadata usgm,
  8           admin a
  9     WHERE usgm.table_name = 'ADMIN'
 10       AND a.oid = 46953
 11 /
RELATIONSHIP
------------
111111111

So, a bit mask of all 1s cannot mean EQUAL. I will investigate these masks and functions further to see what else I can discover and report back on them in an edited version of this article.

5.0 Area and Length

5.1 Comment

It has always amazed me that these two functions:

MDSYS.SDO_GEOM.SDO_AREA()
MDSYS.SDO_GEOM.SDO_LENGTH()

…are considered geoprocessing as these are properties of a geometric object and not something that results from the interaction of two objects. Still, it is Oracle’s right to license their technology as they see fit. But, given that these two functions are used an enormous amount in Locator installations we need a way out of the licensing dilemma.

There are two approaches. One is to see what is in the MDSYS.SDO_3GL package; the other is Java Topology Suite. I will only cover the first here and leave the latter for another blog article.

5.2 SDO_3GL functions.

The MDSYS.SDO_3GL package contains two procedures (not functions):


PROCEDURE LENGTH_AREA
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 DIMOBJ                         SDO_DIM_ARRAY           IN
 GEOMOBJ                        SDO_GEOMETRY            IN
 FLAG                           BINARY_INTEGER          IN
 LENGTH                         NUMBER                  OUT
 AREA                           NUMBER                  OUT
PROCEDURE LENGTH_AREA
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 DIMOBJ                         SDO_DIM_ARRAY           IN
 GEOMOBJ                        SDO_GEOMETRY            IN
 FLAG                           BINARY_INTEGER          IN
 UNIT                           VARCHAR2                IN
 LENGTH                         NUMBER                  OUT
 AREA                           NUMBER                  OUT

Note that the two procedures implement both the area and length processing. Both take a flag that indicates which property is required: length or area. The latter includes a UNIT field in case the caller wants the result in different units from the default: to use the units the SDO_SRID property of the SDO_GEOMETRY object must be non-NULL and the value must exist in the MDSYS.SDO_UNITS_OF_MEASURE table.


SELECT uom_id,
       SUBSTR(unit_of_meas_name,1,50) as measure
  FROM SDO_UNITS_OF_MEASURE
 ORDER BY 2;

Experimenting with the FLAG argument shows that:

1 computes the Area of the geometry object
2 computes the lenght/boundary of a geometry object

(Note: This is counter-intuitive as the our parameters in the SDO_3GL.LENGTH_AREA procedures are the revers of this.)

In my GEOM package I have created four “wrapper” functions that provide a drop-in replacement for the SDO_GEOM.SDO_AREA and SDO_GEOM.SDO_LENGTH functions. Here is the definition of the GEOM.AREA implementations.


  Function Length( p_geometry in sdo_geometry,
                   p_diminfo  in sdo_dim_array,
                   p_units    in varchar2 := ‘Meter’ )
    Return number deterministic
  Is
    v_length number;
    v_area   number;
    v_units  varchar2(20) := p_units;
  Begin
    If ( p_geometry.sdo_srid is null ) Then
      v_units := NULL;
    End If;
    mdsys.sdo_3gl.length_area(p_diminfo,p_geometry,2,v_units,v_area,v_length);
    return v_length;
  End Length;

Function Length( p_geometry in sdo_geometry, p_tolerance in number, p_units in varchar2 := ‘Meter’ ) Begin Return &&defaultSchema.geom.Length( p_geometry, MDSYS.SDO_DIM_ARRAY( MDSYS.SDO_DIM_ELEMENT(‘X’, &&defaultSchema..Constants.c_MaxVal, &&defaultSchema..Constants.c_MaxVal, p_tolerance), MDSYS.SDO_DIM_ELEMENT(‘Y’, &&defaultSchema..Constants.c_MaxVal, &&defaultSchema..Constants.c_MaxVal, p_tolerance)), p_units); End Length;

Finally, an example to show that these functions return the correct results.


gis@XE> SELECT substr(PolyType,1,26) as polygon_Name,
  2         mdsys.sdo_geom.sdo_length(a.geom,b.diminfo)
  3            as sdo_length,
  4         codesys.geom.length(a.geom,b.diminfo)
  5            as geom_length,
  6         mdsys.sdo_geom.sdo_area(a.geom,b.diminfo)
  7            as sdo_area,
  8         codesys.geom.area(a.geom,b.diminfo)
  9            as geom_area
 10    FROM ProjPoly2D a,
 11         (select MDSYS.SDO_DIM_ARRAY(
 12                        MDSYS.SDO_DIM_ELEMENT('X',190000, 640000, .005),
 13                        MDSYS.SDO_DIM_ELEMENT('Y',120000, 630000, .005))
 14                    as diminfo
 15            from dual) b;
 16 /
POLYGON_NAME               SDO_LENGTH GEOM_LENGTH   SDO_AREA  GEOM_AREA
-------------------------- ---------- ----------- ---------- ----------
VERTEXWITHHOLE             2450.63204  172538.909 172538.909 2450.63204
VERTEXNOHOLE                10904.004  1878660.14 1878660.14  10904.004
VERTEXNOHOLE               1355.00349  74901.4188 74901.4188 1355.00349
COMPOUNDOUTERSHELL         28.7626555   40.675415  40.675415 28.7626555
VERTEXNOHOLE               1888.23609  189833.345 189833.345 1888.23609
VERTEXWITHARCNOHOLE        28.7626555   40.675415  40.675415 28.7626555
NORMALISEDRECTANGLENOHOLE     1920000  2.2950E+11 2.2950E+11    1920000
CURVEPOLYWITHHOLE          5331.45953  1507964.47 1507964.47 5331.45953
8 rows selected.

6.0 Java Topology Suite – Spatial Companion For Oracle (SC4O)

The Java Topology Suite is a free API for spatial data that is capable of being deployed into the JVM that is shipped with Oracle 10gR2 and 11g. JTS has a set of “geoprocessing” functions that could be used as “drop in” replacements for the Enterprise Edition licensed functions in the SDO_GEOM package or to complement the existing package.

In investigated this capability over the past year or so and have now released a set of Java classes that wrap JTS and Jaspa functions. This package of functionality is called the Spatial Companion for Oracle. The package can be downloaded from here

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

Hello,

In 3.2 GEOM.SDO_CENTROID, you mention your GEOM package’s sdo_centroid function. I need to be able to calculate what you call the “para-centroid”. How can I obtain this package? Can you please give pricing information?

Thanks,

Hugo

— Hugo Tagle · 17 October 2007, 22:27 · #

Hugo,

The PL/SQL packages are free and can be downloaded from here

regards
Simon

Simon · 17 October 2007, 22:37 · #

Simon. First, my thanks and compliments on your blog. I will be a regular visitor. I have some confusion on the PL/SQL packages. On this page you reference vb_library.zip in the link above, but on the downloads page there is a file spatialdbadvisor_oracle_spatial_types_and_packages.zip
Is there some dependence one on the other?
Thanks.


Bill,
I have corrected the link: thanks for pointing it out.

There is no dependence between the vb and pl/sql libraries.
regards
Simon

— Bill · 19 December 2007, 14:15 · #

Hi Simon. I’ve been looking into Locator on 11g and it looks like they are claiming compliance with SQL/MM Spatial except for Relate, Intersection, Union and ST_SYMMETRICDIFFERENCE. This seems like it goes a long way toward un-crippling Locator. I’d love your perspective.

Cheers,

Bill

— Bill · 9 January 2008, 13:32 · #

Bill,

The SQL/MM Spatial type library at 11g remains the same as the one at 10gR2 except that now the ST_* objects can be indexed (not just the internal sdo_geometry object) which means search functions such as ST_Within() now use the spatial index if it is defined eg

SELECT count(*)
  FROM quad q,
       my_points p
 WHERE q.quad_id = 43
   AND p.geometry.ST_Within(q.geometry) = 1;

I will now turn to the Relate/Intersection/Union etc and other disputed functions in the sdo_geom package.

The Appendix B of the Oracle® Spatial Developer's Guide 11g Release 1 (11.1) says that only the following SDO_GEOM package functions and procedures are licensed for use:


* SDO_GEOM.SDO_BUFFER,
* SDO_GEOM.SDO_DISTANCE,
* SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT,
* SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT


Note: SDO_Buffer is included at 11g (it was not in Locator at 10gR2).

However, the PDF ORACLE LOCATOR Location Features in Oracle Database 11g says that Locator includes:

* Spatial functions for distance, area, and length

Yet the actual 11g Appendix B documentation does not include SDO_GEOM.SDO_AREA() or SDO_GEOM.SDO_LENGTH()!

Now the PDF above says that Locator 11g includes all SQL/MM types and operators except four member methods:

* ST_RELATE,
* ST_INTERSECTION,
* ST_UNION, and
* ST_SYMMETRICDIFFERENCE.

Note that SQL/MM for Locator includes ST_AREA and ST_LENGTH but that the licensing does not allow for their equivalent in the SDO_GEOM package. This argument can be extended to other functions like SDO_GEOM.SDO_CENTROID, SDO_GEOM.SDO_CONVEXHULL, SDO_GEOM.SDO_DIFFERENCE etc as the related functions in the SQL/MM type library - ST_CENTROID, ST_CONVEXHULL and ST_DIFFERENCE - are included in Locator.

So, we end up with the crazy situation of this being illegal for Locator 11g:

select mdsys.SDO_Geom.SDO_Centroid(geom,0.5) as geom,
       mdsys.SDO_Geom.SDO_Area(geom,0.5) as area,
       mdsys.SDO_Geom.SDO_Length(geom,0.5) as length,
       mdsys.SDO_Geom.SDO_ConvexHull(geom,0.5) as chull
  from projpoly2d
 where rownum = 1
/

but this is legal

select mdsys.st_polygon(geom).ST_Centroid() as geom,
       mdsys.st_polygon(geom).ST_Area() as area,
       mdsys.st_polygon(geom).ST_ExteriorRing().ST_Length() as length,
       mdsys.st_polygon(geom).ST_ConvexHull() as chull
  from projpoly2d
 where rownum = 1;

So, the licensing is still confused at 11g. All I can recommend is that where you need to use a disputed function in the sdo_geom package, use the related function in the SQL/MM types and operators library.

Finally, the license restriction is arbitrary and restricts (in a fairly fundamental manner) end user manipulation of spatial data in Locator. It also makes Locator less functional that its competitors: namely SQL Server 2008 "Katmai" (all versions including Express) and PostGIS. Perhaps the fact that these functions are available for free in these products will finally force Oracle to make them free for use in Locator.

regards
Simon

Simon Greener · 14 January 2008, 04:47 · #

Good stuff Simon, thank you. I agree that SQL Server 2008 and PostGIS should (hopefully) push Oracle to re-visit.

— Bill · 15 January 2008, 10:34 · #

Simon, First of all thank you for maintaining this great site. I am trying to use codesys sdo_centroid function in Oracle 11g(11.1.0.6). But I am getting ORA-4030 process out of memory errors when I tried the following query. It works fine in 10.2.0.3.

Here is the query.

select codesys.geom.sdo_centroid(SDO_GEOMETRY(2003, 4326, NULL, SDO_ELEM_INFO_ARRAY(1, 1003, 1), SDO_ORDINATE_ARRAY(-98.188095, 31.467118, -98.18846, 31.468043, -98.195101, 31.466029, -98.195631, 31.466992, -98.200194, 31.465637, -98.198701, 31.462233, -98.198678, 31.462179, -98.198454, 31.461669, -98.198437, 31.461631, -98.197313, 31.459068, -98.196229, 31.459431, -98.196131, 31.459465, -98.196118, 31.459469, -98.194407, 31.460043, -98.194698, 31.460734, -98.196271, 31.464479, -98.188095, 31.467118)),0.000001) from dual

Is geom package tested in 11g? Also does codesys package accept tolerance in meters or decimal degrees? I know Oracle spatial accepts in meters.

Thanks for your help.

-Bala

— Bala · 23 January 2008, 02:52 · #

Bala,

This response is for anyone else out there who may follow this thread as Bala and I have resolved the issue via private communication.

Firstly, the answer. It appears that Bala solved the problem as follows:

“Before compiling the GEOM package I have to set the following parameter.”

alter session set plsql_optimize_level=1;

Thanks Bala, I have added this to the compilation script for my packages and uploaded them to my website.

Bala came to this workaround after trying a slightly modified version of the sdo_centroid function. (I inspected my original code and, even though it works on all versions up to 11g, modified it so that the core procedure uses pipelining to cut down on memory use and improve performance).

“Even with modified code it’s still leaking the memory and throwing ORA-04030 errors. Like you said it might be a bug in 11g. I will open a TAR with Oracle.”

Thanks for the great feedback, Bala.

regards
Simon

Simon Greener · 29 January 2008, 06:26 · #

Simon,

In section 4 above you showed how MDSYS.SDO_3GL.RELATE returns a bitmask. It looks like these are defined in MDSYS.MD$RELATE. The inserts for this are in <ORACLE_HOME>/md/admin/relate.sql

So 111111111 would be OVERLAPBDYINTERSECT.

Cheers,
John

— John O'Toole · 16 April 2009, 14:39 · #

Wow! This is awesome information! Does anything similar exist for the differences between locator and spatial in 10g?

— Justin Slootsky · 8 May 2009, 20:07 · #

Justin,

While this article was based on XE, XE is a 10g-based database. The comments made here all apply for 10G, and, sadly, 11g.

My complaint about Area and Geoprocessing functions (SDO_UNION etc) being reserved to Enterprise Edition (ie Spatial) and so cost money, is because these methods are standard methods of a geometry datatype as defined by OGC SFS 1.1 standard. So, now we see Microsoft’s new spatial types in SQL Server 2008 including these functions without charge, while Oracle charges for them.

Perhaps things will change: but I don’t know when. Version 12 perhaps?

regards
Simon

Simon Greener · 9 May 2009, 02:48 · #

Simon,

Nice post !

This ‘111111111’ bitmask is the row-major form of the matrix in the nine-intersection model.
In this model the intersection of two objects’ interior, exterior and boundary are specified (see the Oracle Spatial User Guide for more info)

regards,
—olaf

— Olaf · 14 September 2009, 12:41 · #

Simon,

I do very much appreciate this website, it is a great help in getting out of the confusion in Oracle Spatial Licensing, thanks a lot for that.

Unfortunately the bitmask retrived from the sdo_3gl.relate function seems to be not fully usable. The only two outputs I get are ‘111111111’ and ‘001001111’ which would mean “OVERLAPBDYINTERSECT” and “DISJOINT”. I guess it is not the real relationship between the two geometry objects but rather only that of their bounding box (for use during index retrieval) (at least using “mask=determine”.

There are individual functions for the single relationships, however the arguments are not clear to me.

Probably not seen with grace by Oracle, there is even functionality to modify geometries within sdo_3gl: sdo_3gl.geom_operation.

How would one interpret licensing information for use of those?

— benjamin · 13 November 2009, 14:48 · #

Hi Simon,

Thanks a lot for your article, It has been of great help to me.

Having a look at licensing terms of Locator, I see that making use of “SDO_AGGR_UNION”, is not allowed, can you confirm on this?

I see that this function is being used in method “Filter_Rings”, thus I tend to think It is allowed indeed, but I would like a confirmation on your behalf if possible…

Many thanks again and keep up the great work!

Eduardo.

— Eduardo Molina · 9 March 2010, 12:15 · #

Eduardo,

Yes, SDO_AGGR_UNION is not licensed for use with Locator.

Nor are the following geoprocessing functions:

sdo_geom.sdo_difference;
sdo_geom.sdo_xor;
sdo_geom.sdo_intersection;
sdo_geom.sdo_union.

(Note: Filter_Rings also uses SDO_DIFFERENCE.)

This means that the Filter_Rings function in my GEOM package can only be used, legally, with Spatial (an Enterprise Edition option) and not Locator.

Filter_Rings could be re-written for Locator only. But I will only do so if someone wants it.

regards
Simon

Simon · 10 March 2010, 02:43 · #

Hi Simon,

Many thanks for your quick response.

Oracle has a weird licensing scenario considering that those functions are meant for very basic geometry operations, don’t you agree?

It is not the Filter_Rings function what I am interested in, although I came across it when looking for references to the function I need to use in my project, SDO_AGGR_UNION.

Specifically, I reached your site while looking for a custom function that does the same basic functionality that SDO_AGGR_UNION without infringing the licensing terms for Locator..

Is it possible to build such function without using SDO_UNION or any other function that is part of the Spatial Enterprise option?

I have also noted that the new SDO_AGGR_SET_UNION included in 11.2 is ALLOWED for the Locator license (Its use is not excluded from the Locator license in Appendix B)

This function is the only thing I need to use from Locator, as my only need is to precalculate a few custom maps by grouping zip codes into bigger areas and then save them as shp files to use them at a web app to show sales data by region (maybe I should have started my comment with this point..).

Do you know if this new function is allowed in Locator for 11.2?

Many thanks again for you kind answer,

Eduardo.

— Eduardo Molina · 10 March 2010, 09:38 · #

Eduardo,

I don’t agree with Oracle’s license restrictions for such fundamental geoprocessing functions. (They are also a part of the ST_Geometry OGC/SQL standard though Oracle restricts their use.) Oracle has chosen to implement a typical up-sell approach wrt licensing which does not seem appropriate to something so basic. For SDO_LRS, topology etc, yes, but not basic geoprocessing.

But it is their product. Time and competition will change this (PostGIS and SQL Server both provide aggregates for free).

Yes, it is possible to build an alternate UNION etc aggregates that would work in Locator but it would take me at least a week to do so and I would only be willing to do so if paid for the work.

SDO_AGGR_SET_UNION looks like a candidate but until I get my hands on it I can’t say for sure.

In your case, unless you want to dynamically do your postcode aggregation, why not simply use an external open source GIS package to do the aggregation for you from the source shp files and then save them back. Why not try QGis?

regards
Simon

Simon · 10 March 2010, 10:15 · #

Thanks Simon,

I was going to reply but I think that I should give you some more background so that you could hopefully give me some advice on our designed approach to these mapping implementation and It could be lengthy and slightly off-topic, could I contact you via email?

— Eduardo Molina · 10 March 2010, 17:39 · #

I install software only in standard edition and exclude SPATIAL. If I want to just then add LOCATOR at a later date do I just run

ordinst.sql
iminst.sql

thanks

Alan

— Alan · 5 May 2010, 12:26 · #

hi, i want to create a database design for oracle spatial database having a field shape with data type sdo_geometry.can u plz suggest me in which version of visio and how will i make it possible.

Mhunter · 13 May 2010, 07:38 · #

I’m sorry I do not use Visio for my data modelling. If you want a free tool that works quite well try SQL Power Architect
regards
Simon

Simon · 13 May 2010, 08:31 · #

I want to just then add LOCATOR at a later date do I just run

batterie · 24 June 2010, 10:02 · #

Alan and Batterie,

I really have no experience with upgrading Locator to Spatial. Alan may be right: try it on an empty database and see if it works.

Otherwise, I am sure this issue has been covered on the Oracle Technology Network Spatial Discussion Forum

Simon

Simon · 1 July 2010, 05:35 · #

From a developers point of views, it is also quite a hack to determine if Locator or Spatial is available on the box.

One needs to perform:
SELECT SDO_VERSION() FROM DUAL

Where an error says: No Locator, No Spatial
An empty record says: Locator is installed
A version string returned says: Spatial is installed.

— Patrick · 23 September 2010, 13:52 · #

Too true. Thanks for reminding my readers about this useful function.
Simon

Simon Greener · 25 September 2010, 07:53 · #

Wow. this stuff is really confusing but I think I finally get it thanks to you.

DaftDomain · 26 October 2010, 19:00 · #

I am glad to came here…

labatterie · 14 December 2010, 08:53 · #

just then add LOCATOR at a later date do I just run

forklift courses · 15 December 2010, 15:23 · #

Forklift,

Can you be more specific?

regards
Simon

Simon Greener · 17 December 2010, 10:28 · #

Nice information, many thanks to the author. It is incomprehensible to me now, but in general, the usefulness and significance is overwhelming. Thanks again and good luck!!!

Careprost · 12 March 2011, 06:35 · #

There are may person searching about that now they will find enough resources by your post,

Networking solutions · 12 May 2011, 11:53 · #

Perfect!!

thanks for your work,

Sergi,

— Sergi · 3 June 2011, 11:04 · #

Is anybody using MapInfo Professional with Locator in any edition of Oracle 10g? I’m especially interested to hear from anybody who is using Oracle XE.

Lester @ Adult Trike · 27 June 2011, 07:42 · #

I have found your site on Google and the information written on your post is interesting. I enjoy reading this one, looking forward to reading more of your posts!!

friv · 10 July 2011, 13:20 · #

Using SDO_3GL istead of SDO_GEOM doesn’t work on IBM-AIX and Oracle 10.2.0.4 standard edition

— Karl Mann · 20 July 2011, 13:38 · #

Karl,
Can you explain what “doesn’t work”? Permissions? What?
Simon

Simon Greener · 21 July 2011, 00:31 · #

Your blog is great , thx for the tips

Ben10 · 24 August 2011, 03:12 · #

Thanks you so much for such a great information. I will definetely recommend your website!

y8 · 24 August 2011, 09:08 · #

Hi Simon,
I’m trying to install your free PL/SQL packages on a 10.2.0.5 SE database on SOlaris. I’m getting a lot of errors in the logs. Initially I thought this was to do with the grep command in the install.sh script but I’m not so sure about that now. Can I email you direct with some examples of the errors? I think this web page is fantastically useful for anyone struggling with Oracle Locator and its’ restrictions.

— Karen · 24 August 2011, 16:19 · #

Some geometry functions and the SDO_AGGR_MBR spatial aggregate function

andkon · 15 September 2011, 17:29 · #

Andkon,

What do you mean by some geometry functions? You want access to sdo_geom functions in Locator that are only licensed in Spatial? Which ones?

SDO_AGGR_MBR is available in both Locator and Spatial. Are you referring to SDO_AGGR_UNION etc? What do you want me to do?

regards
Simon

Simon Greener · 15 September 2011, 22:56 · #

Where an error says: No Locator, No Spatial
An empty record says: Locator is installed
A version string returned says: Spatial is installed.

starfall · 3 October 2011, 21:22 · #

Starfall,

This, and your website reference, looks like spam (with a few correct keywords). So, please let me know what is your actual problem or I will delete your comment.

regards
Simon

Simon Greener · 4 October 2011, 03:03 · #

great post

This is a very informative article.I was looking for these things and here I found it. I am doing a project and this information is very useful me.

Y8 · 2 November 2011, 02:18 · #

Oracle Locator is a feature of Oracle Database 10g Standard Edition. Locator provides soul features and services available in Oracle Spatial.

dc credit union · 21 November 2011, 12:18 · #

Can I email you direct with some examples of the errors? I think this web page is fantastically useful for anyone struggling with Oracle Locator and its’ restrictions.

Full face Helmets · 21 December 2011, 10:17 · #

Because, this article concentrates on the SDO_GEOM package functions and procedures, we note that only those functions listed in Table B-1 are licensed. These are:

Vitiligo Symptoms · 6 March 2012, 18:47 · #

I’m trying to install your free PL/SQL packages on a 10.2.0.5 SE database on SOlaris Run

a game · 26 March 2012, 14:17 · #

Both take a flag that indicates which property is required: length or area. The latter includes a UNIT field in case the caller wants the result in different units from the default: to use the units the SDO_SRID property of the SDO_GEOMETRY object must be non-NULL and the value must exist in the MDSYS.SDO_UNITS_OF_MEASURE table.

love facebook statuses · 27 March 2012, 13:38 · #

gran post

Este es un muy informativo article.I estaba buscando estas cosas y aquí lo encontré. Estoy haciendo un proyecto y esta información es muy

— a games · 7 April 2012, 14:13 · #

This document is one of a planned series of documents providing HTML authors with best practices for developing internationalized HTML using XHTML 1.0 or HTML 4.01, supported by CSS1, CSS2 and some aspects of CSS3

<p><a href=“http://dissertationhelp.9f.com/”>dissertation india</a><br /></p>

— Dissertation India · 8 April 2012, 09:33 · #

This is really a great blog .It always share informative and useful article.i really like its fabulous article. its a great learning keep sharing such kind of nice info.
I will keep visiting this blog.

— Tom · 13 April 2012, 10:06 · #

I have really enjoyed reading your blog posts. Any way I’ll be subscribing to your feed and I hope you post again soon.

<p><a href=“http://www.facebook.com/ecommercethesis”> buy dissertation</a><br /></p>

— buy dissertation · 14 April 2012, 09:22 · #

Having something to say or share with students that they will find worth reading, seeing and experiencing. There are lots of resources, so choosing the best wisely is key.

<p><a href=“http://ecommercedissertation.webstarts.com”>
nursing essay</a><br /></p>

— nursing essay · 18 April 2012, 05:52 · #

Working through the Jerusalem consortium was the wise counsel of Rabbi David Rosen. Both the Board of Religious Leaders and the Educational Network were inspirations of one of our board members

<p><a href=“http://financeassignmenthelp.yolasite.com/ “ rel=“nofollow”> Finance Assignment Help </a></p><br />

— finance assignment help · 18 August 2012, 08:11 · #

En France, le lundi de Pâques est férié depuis la loi du 8 mars 1886. Dans les départements français de l’Alsace, de la Guadeloupe, de la Guyane, de la Martinique, de la Moselle, le vendredi saint, qui précède le dimanche de Pâques, est également férié7.

<p><a href=“http://financehomeworkhelp1.brandyourself.com “rel=“nofollow”> Finance Homework Help</a><br /></p>

— Finance Homework Help · 1 September 2012, 11:53 · #

I’m sorry I do not use Visio for my data modelling. If you want a free tool that works quite well try SQL Power Architect
regards
<a href=“http://samsungharddrivedatarecovery.com/category/data-recovery/”>Data Recovery</a>

— Data Recovery · 18 April 2013, 11:46 · #

I have really enjoyed reading your blog posts. Any way I’ll be subscribing to your feed and I hope you post again soon.
<a href=“http://externaldriverecovery.net”>External Drive Recovery Tools</a>

— External Drive Recovery Tools · 27 June 2013, 06:12 · #