Using geospatial analytics gives you the ability to ask and answer the “where” questions about your business.
When was the last time you searched for the nearest coffee shop, tracked the distance traveled during a car trip, or looked up the new address of a store that moved its location? In order to answer these questions, you used geospatial data. Geospatial data is data that represents an object that exists or an event that happens on the surface of the earth. An example of geospatial data is the longitude and latitude location of all coffee shops in a town. This geospatial data on its own, however, does not answer my first question: “Where is the nearest coffee shop?” Instead, I need to compare my current location to the location of all the coffee shops in my town and calculate and compare the distance between myself and each shop. From this calculation, I can find that the nearest coffee shop to my current location is less than half a mile. This combination of traditional data with the comparison and calculation of geospatial data makes up geospatial analytics.
Businesses and other agencies have many different uses for geospatial analytics. For example, they may ask questions like these:
- Where are their stores located, where are their customers located, and what are the relationships between the two?
- What are the historical weather patterns and trends within a 30-mile radius of a potential site of a new warehouse location?
- What are the current locations of their key assets, such as trucks, ships, and containers? Where are these assets traveling to?
The answers to these questions can be found through the use of geospatial data and geospatial analytics. Geospatial Analytics in Db2 for i provides the tools to generate and store geospatial data in the database using user-defined geospatial distinct types combined with the ability to analyze and compare geospatial data using geospatial scalar and table functions. These new functions use integrated IBM Watson technology to perform the geospatial calculations. The IBM Watson geospatial solution uses an ellipsoidal representation of the earth that describes a round, continuous, closed surface with no edges or seams. This allows for projection-free computations, leading to more accurate and precise results.
In order to store geospatial data in a table, new user-defined geospatial distinct types exist in QSYS2. These distinct types represent the following geometries:
- Point (QSYS2.ST_POINT)
- Linestring (QSYS2.ST_LINESTRING)
- Polygon (QSYS2.ST_POLYGON)
- Geometry collection (QSYS2.ST_GEOMCOLLECTION)
- Polygon collection (QSYS2.ST_MULTIPOLYGON)
- Linestring collection (QSYS2.ST_MULITLINESTRING)
- A point collection (QSYS2.ST_MULTIPOINT)
A generic geometry type (QSYS2.ST_GEOMETRY) exists that any type of geometry can be stored in.
Let’s look at an example. We’ll use the example from the very beginning of this tip and find out which coffee shop is closest to me.
First, we will create a table that can store information, including the location of coffee shops. A coffee shop is a single point, so a ST_POINT column will be used to store the geospatial data that represents the location of the coffee shop.
CREATE TABLE COFFEE_SHOPS(shop_id CHAR(5),
shop_name CHAR(50),
address CHAR(50),
city CHAR(20),
state CHAR(2),
zip_code CHAR(5),
coffee_shop_location QSYS2.ST_POINT);
In order to generate the geospatial data that will be inserted into the geospatial column, scalar functions called “constructor functions” can be used. For example, to insert data into a ST_POINT column, we will use the QSYS2.ST_POINT constructor function. This function takes a Well Known Text (WKT) representation of the longitude and latitude and converts it into binary data that can be inserted into the ST_POINT column. WKT is a text format used to represent a geometry as defined by the Open Geospatial Consortium (OGC).
INSERT INTO COFFEE_SHOPS VALUES
('00001', 'Cafe Steam', '315 S. Broadway', 'Rochester', 'MN', '55904', QSYS2.ST_POINT('point( -92.4632 44.01989)')),
('00002', 'Caribou Coffee', '3900 Marketplace Drive NW', 'Rochester', 'MN', '55901', QSYS2.ST_POINT('point(-92.50088 44.06375)')),
('00003', 'Dunn Brothers', '120 Elton Hills Drive NW', 'Rochester', 'MN', '55901', QSYS2.ST_POINT('point(-92.46361 44.04162)'));
Now that we have generated geospatial data, we can use the new geospatial scalar functions to find an answer to our question. There are 50 new geospatial functions, including both scalar functions and table functions. They can be used to answer all kinds of questions, such as whether two geometries overlap, whether two geometries intersect, what the union of two is, and much more. All of these new functions exist in QSYS2.
For our example, the question that we are answering is about distance. Therefore, we will use the ST_DISTANCE function to determine the distance between my current location and the coffee shops in the COFFEE_SHOPS table.
First, we will create a variable and store our current location in the variable. The variable is a point and therefore uses the ST_POINT datatype. Just like with the table, we will use the ST_POINT constructor function to set the variable. Then we will query our COFFEE_SHOPS table. The query uses the QSYS2.ST_DISTANCE scalar function, passing in the geospatial representation of my current location stored in the MY_LOCATION variable and the geospatial representation of the coffee shop location stored in the coffee_shop_location ST_POINT column. The ST_DISTANCE scalar function returns the distance between the two points in meters. To convert to miles, we can divide by 1609.34 to get an approximate value. In order to find the closest coffee shop, we will order the results by distance in ascending order.
CREATE VARIABLE MY_LOCATION QSYS2.ST_POINT;
SET MY_LOCATION = QSYS2.ST_POINT('point(-92.50365 44.05841)');
SELECT
SHOP_NAME,
ADDRESS,
ROUND((QSYS2.ST_DISTANCE(MY_LOCATION, coffee_shop_location)/1609.34),4)
AS DISTANCE_MILES,
QSYS2.ST_ASTEXT(coffee_shop_location) AS LOCATION
FROM COFFEE_SHOPS
ORDER BY DISTANCE_MILES ASC;
These are the query results:
SHOP_NAME |
ADDRESS |
DISTANCE_MILES |
LOCATION |
Caribou Coffee |
3900 Marketplace Drive NW |
0.3942 |
POINT (-92.50088 44.06375) |
Dunn Brothers |
120 Elton Hills Drive NW |
2.3046 |
POINT (-92.46361 44.041619999999995) |
Cafe Steam |
315 S. Broadway |
3.3384 |
POINT (-92.4632 44.01989) |
We can see that the closest coffee shop, at .3942 miles, is Caribou Coffee on Marketplace Drive. One thing to note is the use of the QSYS2.ST_ASTEXT function when returning the location column. This converts the binary geospatial data stored in the ST_POINT column back into a readable format.
Geospatial data represents the world around us. It can be used to represent the homes, business, events, mobile devices, roads, parks, states, districts, and vehicles around us. Using Geospatial Analytics gives you the ability to ask and answer the “where” questions about your business.
A new book, Geospatial Analytics, provides additional information about the new geospatial support. This new support will be provided in both IBM i 7.4 and IBM i 7.5 as of December 2022.
LATEST COMMENTS
MC Press Online