Oracle Spatial and Graph offers the industry’s most comprehensive, advanced database for enterprise spatial applications and high performance, secure graph databases. With Oracle Database 19c, in the cloud and on premises, Spatial and Graph powers applications from GIS and location services to fraud detection, social networks, linked data and knowledge management.
The spatial features of Spatial and Graph include both basic spatial data management and analysis and additional high-end functionality including: spatial aggregates, 3D, LiDAR, geospatial imagery, geocoding, routing, and linear referencing.
Oracle Spatial and Graph is included at no extra cost with all Oracle Database cloud services and on-prem editions. Not all Spatial features are enabled on Autonomous Database as described here under the section Restrictions for Database Features.
Each time you log into LiveSQL you are provided a fresh schema, and all objects are dropped when you log out. This tutorial assumes you are in a fresh LiveSQL session with no existing objects.. If you need to start over just log out of LiveSQL and log back in and you'll have a clean slate.
MyCompany has several major warehouses. It needs to locate its customers who are near a given warehouse, to inform them of new advertising promotions. To locate its customers and perform location-based analysis, MyCompany must store location data for both its customers and warehouses.
This tutorial uses CUSTOMERS and WAREHOUSES tables. WAREHOUSES are created from scratch. CUSTOMERS are copied from the OE schema that is available in LiveSQL.
Each table stores location using Oracle's native spatial data type, SDO_GEOMETRY. A location can be stored as a point in an SDO_GEOMETRY column of a table. The customer's location is associated with longitude and latitude values on the Earth's surface—for example, -63.13631, 52.485426.
We will now create tables and spatial metadata for CUSTOMERS and WAREHOUSES.
We first create the CUSTOMERS and WAREHOUSES tables. Notice that each has a column of type SDO_GEOMETRY to store location.
CREATE TABLE CUSTOMERS
(
CUSTOMER_ID NUMBER(6, 0)
, CUST_FIRST_NAME VARCHAR2(20 CHAR)
, CUST_LAST_NAME VARCHAR2(20 CHAR)
, GENDER VARCHAR2(1 CHAR)
, CUST_GEO_LOCATION SDO_GEOMETRY
, ACCOUNT_MGR_ID NUMBER(6, 0)
);
CREATE TABLE WAREHOUSES
(
WAREHOUSE_ID NUMBER(3,0)
, WAREHOUSE_NAME VARCHAR2(35 CHAR)
, LOCATION_ID NUMBER(4,0)
, WH_GEO_LOCATION SDO_GEOMETRY
);
Next we add Spatial metadata for the CUSTOMERS and WAREHOUSES tables to the USER_SDO_GEOM_METADATA view. Each SDO_GEOMETRY column is registered with a row in USER_SDO_GEOM_METADATA. This is normally a simple INSERT statement, and a GUI in SQL Developer. However due to the proxy user configuration of LiveSQL we must use a procedure that gets the actual database username:
EXECUTE SDO_UTIL.INSERT_SDO_GEOM_METADATA (sys_context('userenv','current_user'), -
'CUSTOMERS', 'CUST_GEO_LOCATION', -
SDO_DIM_ARRAY(SDO_DIM_ELEMENT('X',-180, 180, 0.05), -
SDO_DIM_ELEMENT('Y', -90, 90, 0.05)),-
4326);
EXECUTE SDO_UTIL.INSERT_SDO_GEOM_METADATA (sys_context('userenv','current_user'), -
'WAREHOUSES', 'WH_GEO_LOCATION', -
SDO_DIM_ARRAY(SDO_DIM_ELEMENT('X',-180, 180, 0.05), -
SDO_DIM_ELEMENT('Y', -90, 90, 0.05)),-
4326);
Here is a description of the items that were entered:
First we load CUSTOMERS by copying from the table OE.CUSTOMERS. Note that we are using two spatial functions in this step: 1) we use sdo_cs.transform() to convert to our desired coordinate system SRID of 4326, and 2) we use sdo_geom.validate_geometry() to insert only valid geometries.
INSERT INTO CUSTOMERS
SELECT CUSTOMER_ID, CUST_FIRST_NAME, CUST_LAST_NAME , GENDER, sdo_cs.transform(CUST_GEO_LOCATION,4326), ACCOUNT_MGR_ID
FROM oe.customers
WHERE sdo_geom.validate_geometry(CUST_GEO_LOCATION,0.05)='TRUE';
commit;
Next WAREHOUSES manually load warehouses using teh SDO_GEOMETRY constructor.
INSERT INTO WAREHOUSES values (1,'Southlake, TX',1400,
SDO_GEOMETRY(2001, 4326, MDSYS.SDO_POINT_TYPE(-103.00195, 36.500374, NULL), NULL, NULL));
INSERT INTO WAREHOUSES values (2,'San Francisco, CA',1500,
SDO_GEOMETRY(2001, 4326, MDSYS.SDO_POINT_TYPE(-124.21014, 41.998016, NULL), NULL, NULL));
INSERT INTO WAREHOUSES values (3,'Sussex, NJ',1600,
SDO_GEOMETRY(2001, 4326, MDSYS.SDO_POINT_TYPE(-74.695305, 41.35733, NULL), NULL, NULL));
INSERT INTO WAREHOUSES values (4,'Seattle, WA',1700,
SDO_GEOMETRY(2001, 4326, MDSYS.SDO_POINT_TYPE(-123.61526, 46.257458, NULL), NULL, NULL));
COMMIT;
The elements of the constructor are:
Query 1: Find the five customers closest to the warehouse whose warehouse ID is 3.
SELECT
c.customer_id,
c.cust_last_name,
c.GENDER
FROM warehouses w,
customers c
WHERE w.warehouse_id = 3
AND sdo_nn (c.cust_geo_location, w.wh_geo_location, 'sdo_num_res=5') = 'TRUE';
Notes on Query 1:
Query 2: Find the five customers closest to warehouse 3 and put the results in order of distance
SELECT
c.customer_id,
c.cust_last_name,
c.GENDER,
round( sdo_nn_distance (1), 2) distance_in_miles
FROM warehouses w,
customers c
WHERE w.warehouse_id = 3
AND sdo_nn
(c.cust_geo_location, w.wh_geo_location, 'sdo_num_res=5 unit=mile', 1) = 'TRUE'
ORDER BY distance_in_miles;
Notes on Query 2:
Query 3: Find the five female customers closest to warehouse 3, put the results in order of distance, and give the distance in miles
SELECT
c.customer_id,
c.cust_last_name,
c.GENDER,
round( sdo_nn_distance(1), 2) distance_in_miles
FROM warehouses w,
customers c
WHERE w.warehouse_id = 3
AND sdo_nn (c.cust_geo_location, w.wh_geo_location,
'sdo_batch_size =5 unit=mile', 1) = 'TRUE'
AND c.GENDER = 'F'
AND rownum < 6
ORDER BY distance_in_miles;
Notes on Query 3:
Query 4: Find all the customers within 100 miles of warehouse 3
SELECT
c.customer_id,
c.cust_last_name,
c.GENDER
FROM warehouses w,
customers c
WHERE w.warehouse_id = 3
AND sdo_within_distance (c.cust_geo_location,
w.wh_geo_location,
'distance = 100 unit=MILE') = 'TRUE';
Notes on Query 4:
Query 5: Find all the customers within 100 miles of warehouse 3, put the results in order of distance, and give the distance in miles
SELECT
c.customer_id,
c.cust_last_name,
c.GENDER,
round(
sdo_geom.sdo_distance (c.cust_geo_location,
w.wh_geo_location,
.005, 'unit=MILE'), 2) distance_in_miles
FROM warehouses w,
customers c
WHERE w.warehouse_id = 3
AND sdo_within_distance (c.cust_geo_location,
w.wh_geo_location,
'distance = 100 unit=MILE') = 'TRUE'
ORDER BY distance_in_miles;
Notes on Query 5:
In this tutorial, you learned how to:
For more information, please see the Spatial Developer's Guide at https://docs.oracle.com/en/database/oracle/oracle-database/19/spatl/index.html