Oracle8i Spatial User's Guide and Reference
Release 8.1.5

A67295-01

Library

Product

Contents

Index

Prev Next

3
Loading and Indexing Spatial Object Types

This chapter describes how to load spatial data into a database, including storing the data in a table with a column of type SDO_GEOMETRY and creating a spatial index for it.

The following steps will enable you to efficiently query spatial data:

  1. Load data into column of type SDO_GEOMETRY

  2. Create spatial indexes on columns of type SDO_GEOMETRY

3.1 Load Process

The process of loading data can be classified into two categories:

3.1.1 Bulk Loading

Bulk loading can import large amounts of ASCII data into an Oracle database. Bulk loading is accomplished with the SQL*Loader utility.

3.1.1.1 Bulk Loading the SDO_GEOMETRY Object

The following example assumes a table called POLY_4PT was created as follows:

CREATE TABLE POLY_4PT (GID     VARCHAR2(32)
                       GEOMETRY  MDSYS.SDO_GEOMETRY);

Assume that the ASCII data consists of a file with delimited columns and separate rows fixed by the limits of the table with the following format:

geometry rows:    GID, GEOMETRY

The coordinates in the geometry column represent roads for a region. Example 3-1 shows the control file for loading the roads and attributes.

Example 3-1 Control File for a Bulk Load

LOAD DATA INFILE *
INTO TABLE POLY_4PT
REPLACE
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'
TRAILING NULLCOLS
(
gid    char(6),
geometry COLUMN OBJECT
( sdo_gtype INTEGER EXTERNAL,
  sdo_srid INTEGER EXTERNAL,
   isnull FILLER CHAR,
  SDO_POINT COLUMN OBJECT  NULLIF geometry.isnull="pt"
  ( X INTEGER EXTERNAL,
    Y INTEGER EXTERNAL,
    Z INTEGER EXTERNAL),
 SDO_ELEM_INFO VARRAY terminated by ';'
        (SDO_ORDINATES char(38)),
 SDO_ORDINATES VARRAY terminated by ':'
    (SDO_ORDINATES char(38))))
begindata
1,3,,pt,,,,1,3,1; -122.4215,37.7862, -122.422,37.7869, -122.421,37.789,
-122.42,37.7866, -122.4215,37.7862:
2,3,,pt,,,,1,3,1; -122.4019,37.8052, -122.4027,37.8055, -122.4031,37.806,
-122.4012,37.8052, -122.4019,37.8052:
3,3,,pt,,,,1,3,1; -122.426,37.803, -122.4242,37.8053, -122.42355,37.8044,
-122.4235,37.8025, -122.426,37.803:

3.1.1.2 Bulk Loading Point-Only Data in the SDO_GEOMETRY Object

Example 3-2 shows a control file for loading a table with point data.

Example 3-2 Control File for a Bulk Load of Point-Only Data

LOAD DATA INFILE *
INTO TABLE POINT
REPLACE
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'
TRAILING NULLCOLS
(
gid    char(6),
geometry COLUMN OBJECT
( sdo_gtype INTEGER EXTERNAL,
  sdo_srid INTEGER EXTERNAL,
  SDO_POINT COLUMN OBJECT 
  ( X INTEGER EXTERNAL,
    Y INTEGER EXTERNAL,
    Z INTEGER EXTERNAL),
    is_null1 FILLER CHAR, 
 SDO_ELEM_INFO VARRAY terminated by ';' NULLIF geometry.is_null1="v1"
        (SDO_ORDINATES char(38)),
    is_null2 FILLER CHAR, 
 SDO_ORDINATES VARRAY terminated by ':'
 NULLIF geometry.is_null2="v2"
    (SDO_ORDINATES char(38))))
begindata
1,1,,-122.4215,37.7862,,v1,;v2,:
2,1,,-122.4019,37.8052,,v1,;v2,:
3,1,,-122.426,37.803,,v1,;v2,:
4,1,,-122.4171,37.8034,,v1,;v2,:
5,1,,-122.416151,37.8027228,,v1,;v2,:

3.1.2 Transactional Insert Using SQL

Oracle8i Spatial uses standard Oracle8i tables that can be accessed or loaded with standard SQL syntax. This section contains examples of transactional inserts into columns of type SDO_GEOMETRY. Note that SQL statements in Oracle8i have a limit of 999 arguments. Therefore, you cannot create variable-length arrays of more than 999 elements using transactional INSERT statements.

3.1.2.1 Polygon with Hole

The geometry to be stored is a polygon with a hole, as shown in Figure 3-1. The coordinate values for elements 1 and 2 are:

Element 1= [P1(6,15), P2(10,10), P3(20,10), P4(25,15), P5(25,35), P6(19,40),
P7(11,40), P8(6,25), P1(6,15)] Element 2= [H1(12,15), H2(15,24)]

Figure 3-1 Example Geometry OBJ_1

This example assumes that table PARKS was created as follows:

CREATE TABLE PARKS (NAME VARCHAR2(32),
                    SHAPE MDSYS.SDO_GEOMETRY);

The SQL statement for inserting the data for geometry OBJ_1 is:

INSERT INTO PARKS 
  VALUES ('OBJ_1', MDSYS.SDO_GEOMETRY(3, NULL,NULL,
MDSYS.SDO_ELEM_INFO_ARRAY(1,3,1, 19,3,3),
MDSYS.SDO_ORDINATE_ARRAY(6,15, 10,10, 20,10, 25,15, 25,35,
19,40, 11,40, 6,25, 6,15, 12,15, 15,24)));

The SDO_GEOMETRY( ) object type takes values and constructors for its attributes SDO_GTYPE, SDO_ELEM_INFO, and SDO_ORDINATES. The SDO_GTYPE is 3, and the SDO_ELEM_INFO has 2 triplet values because there are 2 elements. Element 1 starts at offset 1, is of ETYPE 3, and its interpretation value is 1 because the points are connected by straight line segments. Element 2 starts at offset 19, is of ETYPE 3, and has an interpretation value of 3 (a rectangle). The SDO_ORDINATES varying length array has 22 values with SDO_ORDINATES(1...18) describing element 1 and SDO_ORDINATES(19...22) describing element 2.

Assume that two dimensions are named X and Y, their bounds are 0 to 100, and the tolerance for both dimensions is 0.005. The SQL statement for loading the
SDO_GEOM_METADATA table is:

INSERT INTO SDO_GEOM_METADATA 
  VALUES ('PARKS', 'SHAPE', 
MDSYS.SDO_DIM_ARRAY(MDSYS.SDO_DIM_ELEMENT('X', 0, 100, 0.005),
MDSYS.SDO_DIM_ELEMENT('Y', 0, 100, 0.005)));

3.1.2.2 Compound Line String

A compound line string is a connected sequence of straight line segments and circular arcs. Figure 3-2 is an example of a compound line string. The coordinate values for points P1..P7 that describe the line string OBJ_2 are:

OBJ_2 = [P1(15,10), P2(25,10), P3(30,5), P4(38,5), P5(38,10), 
P6(35,15), P7(25,20)]

The SQL statement for inserting this compound line string in a feature table ROADS(GID Varchar2, Shape MDSYS.SDO_GEOMETRY) is:

INSERT INTO ROADS VALUES ('OBJ_2', MDSYS.SDO_GEOMETRY(2, NULL,
MDSYS.SDO_ELEM_INFO_ARRAY(1,4,2, 1,2,1, 9, 2, 2),
MDSYS.SDO_ORDINATE_ARRAY(15,10, 25,10, 30,5, 38,5, 38,10, 35,15, 25,20)));

The SDO_GEOMETRY( ) object type takes values and constructors for its attributes GTYPE, SDO_ELEM_INFO, and SDO_ORDINATES. The GTYPE is 2, the SDO_ELEM_INFO has nine values because there are two subelements for the compound line string. The first subelement starts at offset 1, is of ETYPE 2, and its interpretation value is 1 because the points are connected by straight line segments. Similarly, subelement 2 has a starting offset of 9. That is, the first ordinate value is SDO_ORDINATES(9), is of ETYPE 2, and has an interpretation value of 2 because the points describe a circular arc. The SDO_ORDINATES varying length array has 14 values, with SDO_ORDINATES(1..10) describing subelement 1, and SDO_ORDINATES(9..14) describing subelement 2.

Figure 3-2 Line String Consisting of Arcs and Straight Line Segments

Assume that two dimensions are named X and Y, their bounds are 0 to 100, and tolerance for both dimensions is 0.005. The SQL statement to insert the metadata into the SDO_GEOM_METADATA table is:

INSERT INTO SDO_GEOM_METADATA VALUES ('ROADS', 'SHAPE', 
MDSYS.SDO_DIM_ARRAY(MDSYS.SDO_DIM_ELEMENT('X', 0, 100, 0.005), MDSYS.SDO_DIM_ELEMENT('Y', 0, 100, 0.005)));

3.1.2.3 Compound Polygon

A compound polygon's boundary is a connected sequence of straight line segments and circular arcs, whose first point is equal to its last point. Figure 3-3 is an example of a compound polygon. The coordinate values for points P1 to P8 that describe the polygon OBJ_3 are:

OBJ_3 = [P1(20,30), P2(11,30), P3(7,22), P4(7,15), P5(11,10), P6(21,10), 
P7(27,30), P8(25,27), P1(20,30)]

This example assumes the PARKS table was created as follows:

CREATE TABLE PARKS (GID VARCHAR2(32), SHAPE MSSYS.SDO_GEOMETRY);

The SQL statement for inserting this compound polygon is:

INSERT INTO PARKS VALUES ('OBJ_3', MDSYS.SDO_GEOMETRY(3, NULL,NULL
MDSYS.SDO_ELEM_INFO_ARRAY(1,5,2, 1,2,1, 13,2,2),
MDSYS.SDO_ORDINATE_ARRAY(20,30, 11,30, 7,22, 7,15, 11,10, 21,10, 27,30,
25,27, 20,30)));

The SDO_GEOMETRY() object type takes values and constructors for its attributes SDO_GTYPE, SDO_ELEM_INFO, and SDO_ORDINATES. The SDO_GTYPE is 3, the SDO_ELEM_INFO has 3 triplet values. The first triplet (1,5,2) identifies the element as a compound polygon (ETYPE 5) with two subelements. The first subelement starts at offset 1, is of ETYPE 2, and its interpretation value is 1 because the points are connected by straight line segments. Subelement 2 has a starting offset of 13, is of ETYPE 2, and has an interpretation value of 2 because the points describe a circular arc. The SDO_ORDINATES varying length array has 18 values, with SDO_ORDINATES(1...14) describing subelement 1, and SDO_ORDINATES(13...18) describing subelement 2.

Figure 3-3 Compound Polygon

This example assumes the PARKS table was created as follows:

CREATE TABLE PARKS (GID VARCHAR2(32), SHAPE MSSYS.SDO_GEOMETRY);

Assume that two dimensions are named X and Y, their bounds are 0 to 100, and tolerance for both dimensions is 0.005. The SQL statement to insert the metadata into the SDO_GEOM_METADATA table is:

INSERT INTO SDO_GEOM_METADATA VALUES ('PARKS', 'SHAPE', 
MDSYS.SDO_DIM_ARRAY(MDSYS.SDO_DIM_ELEMENT('X', 0, 100, 0.005), MDSYS.SDO_DIM_ELEMENT('Y', 0, 100, 0.005)));

3.1.2.4 Compound Polygon with Holes

A compound polygon's boundary is a connected sequence of straight line segments and circular arcs. Figure 3-4 is an example of a geometry that contains a compound polygon with a hole (or void.) The coordinate values for points P1 to P8 (Element 1) and C1 to C3 (Element 2) that describe the geometry OBJ_4 are:

Element 1 = [P1(20,30), P2(11,30), P3(7,22), P4(7,15), P5(11,10), P6(21,10),
             P7(27,30), P8(25,27), P1(20,30)]
Element 2 = [C1(10,17), C2(15,22), C3(20,17)]

This example assumes the table PARKS has been created as follows:

CREATE TABLE PARKS (GID VARCHAR2(32), SHAPE MSSYS.SDO_GEOMETRY);

The SQL statement for inserting this compound polygon with holes is:

INSERT INTO Parks VALUES ('OBJ_4', MDSYS.SDO_GEOMETRY(3, NULL,NULL
MDSYS.SDO_ELEM_INFO_ARRAY(1,5,2, 1,2,1, 13,2,2, 19,3,4),
MDSYS.SDO_ORDINATE_ARRAY(20,30, 11,30, 7,22, 7,15, 11,10, 21,10, 27,30, 25,27, 20,30, 10,17, 15,22, 20,17)));

The SDO_GEOMETRY( ) object type takes values and constructors for its attributes SDO_GTYPE, SDO_ELEM_INFO, and SDO_ORDINATES. The GTYPE is 3, the SDO_ELEM_INFO has four triplet values. The first 3 triplet values represent element 1. The first triplet (1,5,2) identifies this element as a compound element with two subelements. The values in SDO_ELEM_INFO(1...9) pertain to element 1, while SDO_ELEM_INFO(10...12) are for element 2.

The first subelement starts at offset 1, is of ETYPE 2, and its interpretation is 1 because the points are connected by straight line segments. Subelement 2 has a starting offset of 13, is of ETYPE 2, and has an interpretation value of 2 because the points describe a circular arc. The fourth triplet (19,3,4) represents element 2. Element 2 starts at offset 19, is of ETYPE 3, and its interpretation value is 4, indicating that it is a circle. The SDO_ORDINATES varying length array has 24 values, with SDO_ORDINATES(1...14) describing subelement 1, SDO_ORDINATES(13...18) describing subelement 2, and SDO_ORDINATES(19...24) describing element 2.

Figure 3-4 Compound Polygon with a Hole

Assume that two dimensions are named X and Y, their bounds are 0 to 100, and tolerance for both dimensions is 0.005. The SQL statement to insert the metadata into the SDO_GEOM_METADATA table is:

INSERT INTO sdo_geom_METADATA VALUES ('PARKS', 'SHAPE', 
MDSYS.SDO_DIM_ARRAY(MDSYS.SDO_DIM_ELEMENT('X', 0, 100, 0.005), MDSYS.SDO_DIM_ELEMENT('Y', 0, 100, 0.005)));

3.1.2.5 Transactional Insert of Point-Only Data

A point-only geometry can be inserted with the following statement:

INSERT INTO PARKS VALUES ('OBJ_PT',
                          MDSYS.SDO_GEOMETRY(1,NULL,
                                             MDSYS.SDO_POINT(20,30,NULL),
                                             NULL, NULL)
                          );

3.2 Index Creation

Once data has been loaded into the spatial tables through either bulk or transactional loading, a spatial index must be created on the tables for efficient access to the data. This is done by approximating geometries with tiles. For each geometry, you will have a set of tiles that fully cover the geometry.

3.2.1 Determining Index Creation Behavior

Spatial provides two methods for spatial indexing, fixed and hybrid. Hybrid indexing is recommended for the Spatial object-relational model. If specified correctly, it will provide better selectivity and spatial join performance for most data sets and application scenarios.

The tessellation algorithm used by the CREATE INDEX and index maintenance routines on INSERT, or UPDATE, is determined by the SDO_LEVEL and SDO_NUMTILES values supplied by the user in the PARAMETERS clause of the CREATE INDEX statement.They are interpreted as follows:

SDO_LEVEL   SDO_NUMTILES   Action  

Not specified.  

Not specified.  

Error.  

>= 1  

Not specified.  

Fixed indexing, (indexing with fixed-size tiles).  

>= 1  

>= 1  

Hybrid indexing with fixed-size and variable-sized tiles. The SDO_LEVEL column defines the fixed tile size. The SDO_NUMTILES column defines the number of variable tiles to generate per geometry.  

Not specified.  

>= 1  

Not supported.  

The CREATE INDEX routine for spatial indexing has the same semantics as a standard SQL CREATE INDEX statement. An explicit commit is executed after the tessellation of all the geometries in a geometry column.

Because spatial index creation operates as a single transaction, it may require a sizable amount of rollback space. To reduce the amount of rollback space required you can supply the SDO_COMMIT_INTERVAL parameter in the CREATE INDEX statement. This will perform a database commit after every N geometries are indexed, where N is a user-defined value.

If the index creation does not complete for any reason, the index is invalid and must be dropped with the DROP INDEX <index_name> [FORCE] statement.

3.2.2 Spatial Indexing with Fixed-Size Tiles

Oracle recommends using hybrid indexing when indexing a geometry using the object-relational model. Because fixed indexing is an integral part of hybrid indexing, it is important to understand the information in this section. Hybrid indexing is discussed in Section 3.2.3.

While not the preferred method, you can use fixed-size tiles to index the object-relational model. The fixed-size tile algorithm is expressed as a level referring to the number of tessellations performed. To use fixed-size tile indexing, omit the SDO_NUMTILES parameter and set the SDO_LEVEL value to the desired tiling level. The relationship between the tiling level and the resulting size of the tiles depends on the domain of the layer.

The domain used for indexing is defined by the upper and lower boundaries of each dimension stored in the DIMINFO column of the SDO_GEOM_METADATA table, which contains an entry for the table and geometry column to spatially index. A typical domain could be -180 to 180 degrees for longitude2, and -90 to 90 degrees for latitude, as represented in Figure 3-5.

Figure 3-5 Sample Domain

If the SDO_LEVEL column is set to 1, then the tiles created by the indexing mechanism are the same size as tiles at the first level of tessellation. Each tile would be 180 degrees by 90 degrees as shown in Figure 3-6.

Figure 3-6 Fixed-Size Tiling at Level 1

The formula for the number of fixed-size tiles in a domain is 4n where n is the number of tessellations, stored in the SDO_LEVEL column. In reality, tiles are only generated where geometries exist, and not necessarily for the whole domain. Figure 3-7 shows fixed-size tiling at level 2. In this figure, each tile is 90 degrees by 45 degrees.

Figure 3-7 Fixed-Size Tiling at Level 2

The size of a tile can be determined by applying the following formula to each dimension:

length = (upper_bound - lower_bound) / 2 ^ sdo_level

The length refers to the length of the tile along the specified dimension. Applying this formula to the tiling shown in Figure 3-7 yields the following sizes:

length for dimension X = (180 - (-180) ) / 2^2
                       = (360)  / 4
                       = 90
length for dimension Y = (90 - (-90) ) / 2^2
                       = (180) / 4
                       = 45

At level 2 the tiles are 90x45 degrees in size. As the number of levels increases, the tiles become smaller and smaller. Smaller tiles provide a more precise fit of the tiles over the geometry being indexed. However, because the number of tiles generated is unbounded, you must take into account the performance implications of using higher levels. The SDO_TUNE.ESTIMATE_TILING_LEVEL() function can be used to determine an appropriate level for indexing with fixed-size tiles. See Chapter 14 for a description of this function.

Besides the performance aspects related to selecting a fixed-size tile, tessellating the geometry into fixed-size tiles might have benefits related to the type of data being stored, such as using tiles sized to represent 1-acre farm plots, city blocks, or individual pixels on a display. Data modeling is an important part any database design, and is essential in a spatial database where the data often represents actual physical locations.

In Example 3-3, assume that data has been loaded into a table called ROADS, and the SDO_GEOM_METADATA has an entry for ROADS. GEOMETRY. Use the following SQL statement to create a fixed index named ROADS_FIXED on ROADS_GEOMETRY.

Example 3-3 Create a Fixed Index

CREATE INDEX ROADS_FIXED ON ROADS(GEOMETRY) INDEXTYPE IS MDSYS.SPATIAL_INDEX
PARAMETERS('SDO_LEVEL = 8');

The value in SDO_LEVEL is used while tessellating objects. Increasing the level results in smaller tiles and better geometry approximations. See the description of the ESTIMATE_TILING_LEVEL()function in Chapter 14 for information on estimating the tiling level in several different ways.

3.2.3 Hybrid Spatial Indexing with Fixed-Size and Variable-Sized Tiles

This section describes hybrid indexing, which uses both fixed-size and variable-sized tiles as a spatial indexing mechanism. For each geometry, you will have a set of fixed-size tiles that fully cover the geometry, and a set of variable-sized tiles that fully cover the geometry.The terms hybrid indexing, hybrid tiling, and hybrid tessellation are used interchangeably in this section.

To use hybrid tiling, the SDO_LEVEL and SDO_NUMTILES keywords in the PARAMETERS clause must contain valid values. Both SDO_LEVEL and SDO_NUMTILES must be greater than 1.

The SDO_NUMTILES value determines the number of variable tiles that will be used to fully cover a geometry being indexed. Typically this value is small. For points, SDO_NUMTILES is always one. For other element types, you might set SDO_NUMTILES to a value around 8. The larger the SDO_NUMTILES parameter, the better the tiles will approximate the geometry being covered. This improves the selectivity of the primary filter, but also increases the number of index entries per geometry (see Section 4.2.1 and Section 4.2.2 for a discussion of primary and secondary filters). The SDO_NUMTILES value should be larger for long, linear spatial entities, such as major highways or rivers, than it would be for area-related spatial entities such as county or state boundaries.

The SDO_LEVEL value determines the size of the fixed tiles used to fully cover the geometry being indexed. Setting the proper SDO_LEVEL value may appear more like art than science. Performing some simple data analysis and testing puts the process back in the realm of science. One approach would be use the SDO_TUNE.ESTIMATE_TILING_LEVEL() function to determine an appropriate starting SDO_LEVEL value, and then compare the performance with slightly higher or lower values. This, and other techniques, are described in Appendix A, "Tuning Tips and Sample SQL Scripts".

As in Example 3-3, assume that the ROADS table has been loaded. Use the following statement to create the spatial index on ROADS.GEOMETRY:

CREATE INDEX ROADS_FIXED ON ROADS(GEOMETRY) 
INDEXTYPE IS MDSYS.SPATIAL_INDEX PARAMETERS('SDO_LEVEL = 6, SDO_NUMTILES=12');


1 See Oracle8i Utilities for information on SQL*Loader.
2 The transference of the domain onto a sphere or Mercator projection is left up to an application. Spatial treats the domain as a flat Cartesian grid.



Prev

Next
Oracle
Copyright © 1999 Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index