Showing posts with label geometry. Show all posts
Showing posts with label geometry. Show all posts

Monday, July 8, 2019

MySQL Workbench and OpenStreetMap Data Visualization

I have a presentation next month on MySQL and GIS.  MySQL 8.0 has benefited greatly from the three dimensional libraries from Boost.Geometry. There are many facets to the Geographic Data world that it is damn near impossible not to lurch down one rabbit hole into another in an unending spiral of acronyms, standards, projections, and functions.  But thankfully I have MySQL Workbench to aid me.

Texas


I wanted some test data to use for some GIS exercises and was very happy to find many useful sets curated by the OpenStreetMaps folks. Shapefiles are used to hold the various data points of an item of interest.  I had assumed that the data would have some sort of longitude/latitude pairs but was wondering what I would need to do to work with that data and what ever came bundled with it.  I download the Texas data and then loaded it into the database.

You will need a copy of the ogr2org utility This wonderful program reads the raw shapefile and converts it into SQL. You may want to get the source but hopefully a version may be available for you Linux distribution.  There is a copy of the ogr2ogr program that comes with MySQL Workbench but I have not been able to get it to convert the data and load that data into a MySQL instance, with either Windows, Fedora, or Ubuntu.

$ogr2ogr -overwrite -progress -f "MySQL" mysql:texas,user=dave,password=****** gis_osm_natural_a_free_1.shp
0...10...20...30...40...50...60...70...80...90...100 - done.
$ ogr2ogr -overwrite -progress -f "MySQL" mysql:texas,user=dave,password=***** gis_osm_natural_free_1.shp
0...10...20...30...40...50...60...70...80...90...100 - done.


The Data


The ogr2org utility reads the shape files and puts all the attributes into a a table. 

mysql> DESC gis_osm_natural_free_1;
+---------+--------------+------+-----+---------+----------------+
| Field   | Type         | Null | Key | Default | Extra          |
+---------+--------------+------+-----+---------+----------------+
| OGR_FID | int(11)      | NO   | PRI | NULL    | auto_increment |
| SHAPE   | geometry     | NO   | MUL | NULL    |                |
| osm_id  | varchar(10)  | YES  |     | NULL    |                |
| code    | decimal(4,0) | YES  |     | NULL    |                |
| fclass  | varchar(28)  | YES  |     | NULL    |                |
| name    | varchar(100) | YES  |     | NULL    |                |
+---------+--------------+------+-----+---------+----------------+
6 rows in set (0.01 sec)

And a sample line from that table.

mysql> select OGR_FID,ST_ASTEXT(SHAPE) as Shape, osm_id, code, fclass, name FROM gis_osm_natural_free_1 limit 1;
+---------+-------------------------------+----------+------+--------+--------------------+
| OGR_FID | Shape                         | osm_id   | code | fclass | name               |
+---------+-------------------------------+----------+------+--------+--------------------+
|       1 | POINT(29.3060929 -94.7679897) | 80029566 | 4141 | beach  | Stewart Beach Park |
+---------+-------------------------------+----------+------+--------+--------------------+
1 row in set (0.00 sec)

The SHAPE column has the desired longitude and latitude. So now we have this data but I had zero clue to where Stewart Beach Park was located.

MySQL Workbench to the Rescue


Workbench makes it easy to 'see' where the data was.  You can see in the below example that Stewart Beach Park is the first row returned.

MySQL Workbench has an amazing number of features including the ability to help display GIS data.

If you right click on the 'BLOB' graphic under the shape column you will see an option to Show Point In Browser.  

The location of Stewart Beach Park on the Galveston Sea Wall

So Stewart Beach Park is right on the Galveston Sea Wall and around the corner from the cruise ship terminals. 

Mid-Atlantic Developer's Conference


I will be speaking on MySQL & GIS at the Mid-Atlantic Developer's Conference and you can still attend but tickets are going quickly. 








Wednesday, April 3, 2019

MySQL Workbench Spatial Viewer or How to See your GEOMETRY Data

The past couple of blog entries have been on Geographic Information Systems and Geometric Data.  Visualizing that data with MySQL Workbench makes it easier for me to see what the results really mean.
Example drawn by MySQL Workbench 8.0.15
Workbench 8.0.15 will draw the polygon with the Spatial View Option

So how do you get there?

Start Workbench, create a new SQL Tab in your favorite scratch schema, and crate the table below. 

CREATE TABLE `test` (
  `id` INT NOT NULL AUTO_INCREMENT,
  `geom` GEOMETRY NULL,
  PRIMARY KEY (`id`));

Next add some data.

INSERT INTO `test`
  (`geom`)
VALUES
  (st_geomfromtext
  ('polygon((0 0,0 3,3 0, 2 2,0 0),(1 1,1 2,2 1,2 2, 1 1))')
   );

The run the query.

select geom from test;

However the result will default to the Result Grid. Look off to the right hand side of the results window to see a series of stacked icons and the default is the Result Grid.  And that 'BLOB' is the result of the query.  But that result is not exactly visually stunning.

Output from the query in the results grid view
The 'BLOB' is the result of the query.

Click on the Form Editor icon. It is directly below the Result Grid Icon

Select the Form Editor Icon
And you should see the image from the top of this blog entry.

Bonus!


Now scroll down below the Form Editor icon and select Spatial View.

Spatial View of the Query




Tuesday, April 2, 2019

MySQL 8.0 GIS -- Inserting Data & Fun Functions

The last blog entry was very popular and there were lots of requests for some introductory information on the spatial data types. 

Well Known Text Or Binary


I am going to use the GEOMETRY data type over POINT, LINESTRING, or POLYGON as it can store any of those three while the other three can only contain data matching their name (so POINT can holds only point data, etc.). The values are stored in an internal geometry format but it takes wither WKT or WKB formatted data.

Those are Well-Known Text (WKT) or Well-Known Binary (WKB) formats repectively. I am hoping most of your are better with text than binary so the following examples demonstrate how to insert geometry values into a table by converting WKT values to internal geometry format.

So let us start with a simple table.

mysql> create table geom (type text, g geometry);
Query OK, 0 rows affected (0.04 sec)

We can use the ST_GeomFromText function to take some strings and convert into the internal format.

mysql> insert into geom values 
       ('point', st_geomfromtext('point(1 1)'));
Query OK, 1 row affected (0.01 sec)

mysql> insert into geom values 
       ('linestring', st_geomfromtext('linestring(0 0,1 1, 2 2)'));
Query OK, 1 row affected (0.01 sec)

There are type specific functions for POINT, LINESTRING, and POLYGON that we can also take advantage of for this work.

mysql> SET @g = 
     'POLYGON((0 0,10 0,10 10,0 10,0 0),(5 5,7 5,7 7,5 7, 5 5))';
Query OK, 0 rows affected (0.00 sec)

mysql> INSERT INTO geom 
       VALUES ('polygon',ST_PolygonFromText(@g));
Query OK, 1 row affected (0.00 sec)

If you do a SELECT * FROM geom; you will get the g column output in binary.  Thankfully we can use ST_AsText() to provide us with something more readable.


mysql> select type, st_astext(g) from geom;
+------------+----------------------------------------------------------+
| type       | st_astext(g)                                             |
+------------+----------------------------------------------------------+
| point      | POINT(1 1)                                               |
| linestring | LINESTRING(0 0,1 1,2 2)                                  |
| polygon    | POLYGON((0 0,10 0,10 10,0 10,0 0),(5 5,7 5,7 7,5 7,5 5)) |
+------------+----------------------------------------------------------+
3 rows in set (0.00 sec)

mysql>


Put the 'fun' in Function

There are functions that can be use with each of these type to provide information., For instance there are the x & Y coordinates for a point.

mysql> select type, st_x(g), st_y(g) from geom where type='point';
+-------+---------+---------+
| type  | st_x(g) | st_y(g) |
+-------+---------+---------+
| point |       1 |       1 |
+-------+---------+---------+
1 row in set (0.00 sec)

We can even use our linestring data to get the minimal bounding rectangle for the given coordinates (basically if we had to put an envelope around the points the results are the coordinates points to enclose those x,y coordinates)

mysql> select st_astext(st_envelope(g)) 
       from geom where type='linestring';
+--------------------------------+
| st_astext(st_envelope(g))      |
+--------------------------------+
| POLYGON((0 0,2 0,2 2,0 2,0 0)) |
+--------------------------------+
1 row in set (0.00 sec)


And we can get the area of a polygon too.

mysql> select type, st_area((g)) from geom where type='polygon';
+---------+--------------+
| type    | st_area((g)) |
+---------+--------------+
| polygon |           96 |
+---------+--------------+
1 row in set (0.00 sec)

And find the mathematical center of that polygon.

mysql> select type, 
       st_astext(st_centroid(g)) 
       from geom where type='polygon';
+---------+--------------------------------------------+
| type    | st_astext(st_centroid(g))                  |
+---------+--------------------------------------------+
| polygon | POINT(4.958333333333333 4.958333333333333) |
+---------+--------------------------------------------+
1 row in set (0.00 sec)

Plus we can get the linestring data if we wanted to draw out polygon.

mysql> select type, 
       st_astext(st_exteriorring(g)) 
       from geom where type='polygon';
+---------+-------------------------------------+
| type    | st_astext(st_exteriorring(g))       |
+---------+-------------------------------------+
| polygon | LINESTRING(0 0,10 0,10 10,0 10,0 0) |
+---------+-------------------------------------+
1 row in set (0.00 sec)