Update of "VirtualRouting"
Not logged in

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview

Artifact ID: 259ab1c98822d2449eec7db509d2ad1f83fa317f
Page Name:VirtualRouting
Date: 2018-04-01 19:53:48
Original User: sandro
Parent: eb4769d3b31190e5253b0df56d0661ff076d744a (diff)
Next 977ae572d10fbb11743df9410e4f4dad5599aeb6
Content

back



Table of Contents

1 - Introduction
2 - The sample/test DB
3 - Creating VirtualRouting Tables


1 -Introduction

Previous versions of SpatiaLite traditionally supported a pure SQL routing module that was named VirtualNetwork.

Since version 5.0.0 a brand new routing module (more advanced and sophisticated) is available, that is called VirtualRouting.
The now obsolete VirtualNetwork is still supported by version 5.0.0 so as to not cause an abrupt break to already existing applications, but will presumably be discontinued in future versions.
Using VirtualRouting instead of VirtualNetwirk is warmly recommended for any new development.

Theoretical foundations - an ultra-quick recall

All Routing algorithms (aka Shortest Path algorithms) are based on the mathematics of the Graph theory or to be more precise: on Weighted Graphs.
network
A topologically valid Network is a dataset that fulfills the following requirements:

Logical conclusions

Any topologically valid Network (irrespective of whether it is a Spatial or Logical type) is a valid Graph.
A Network allowing the support (direct or indirect) of some appropriate cost value is a valid Weighted Graph, and can consequently support Routing algorithms.
All Routing algorithms are intended to identify the Shortest Path solution connecting two Nodes in a weighted graph (aka Network).

Note: the term Shortest Path can be easily misunderstood.
Due to historical reasons the most common application field for Routing algorithms is related to Road Networks, but also many other kinds of Networks exist:
In all the above cases we certainly have valid Networks supporting Routing algorithns, but not all of them can imply something like a spatial distance (geometric length) or a travel time.
In the most general acception costs can be represented by any reasonable physical quantity.
So a more generalized definition is assuming that Routing algorithms are intended to identify lesser cost solutions on a weighted graph.
The exact interpretation of the involved costs (aka weights) strictly depends on the very specific nature of each Network.

The Dijkstra's algorithm

This well known algorithm isn't necessarily the fastest one, but it always ensures full correctness:

The A* algorithm

Many alternative Routing algorithms have been invented during the years.
All them are based on heuristic assumptions and are intended to be faster than Dijkstra's, but none of them can ensure full correctness as Dijkstra's does.
The A* algorithm applies a mild heuristic optimization, and can be a realistic alternative to Dijkstra's in many cases.


2 - The sample/test DB

You are expected to follow the current tutorial about VirtualRouting by directly testing all SQL queries discussed below on behalf of the sample/test DB that you can download from here

The sample DB contains the full road network of Tuscany Region (Italy) (Iter.Net dataset) kindly released under the CC-BY-SA 4.0 licence terms.
The contents stored into the sample database were opportunely rearranged, and are still subject to the initial CC-BY-SA 4.0 clauses (derived work).



3 - Creating VirtualRouting Tables

All VirtualRouting queries are based on some VirtualRouting Table, and in turn any VirtualRouting Table is based on some appropriate Binary Data Table supporting an efficient representation of the underlying Network.
So we'll start first by creating such tables.

The old and now superseded VirtualNetwork required using a separate CLI tool (spatialite_network) in order to properly initialize a VirtualNetwork Table and its companion Binary Data Table; alternatively spatialite_gui supported a GUI wizard for the same task. Since version 5.0.0 now SpatiaLite directly supports a specific CreateRouting() SQL function.
SELECT CreateRouting('byfoot_data', 'byfoot', 'roads_vw', 'node_from', 'nodeto', 'geom', NULL);

SELECT CreateRouting_GetLastError();
------------------------------------
ToNode Column "nodeto" is not defined in the Input Table
Note: this first query contains an intended error causing CreateRouting() to fail raising an exception.
CreateRouting() can fail for multiple reasons, and by calling CreateRouting_GetLastError() you can easily identify the exact reason why the most recent call to CreateRouting() failed.
SELECT CreateRouting('byfoot_data', 'byfoot', 'roads_vw', 'node_from', 'node_to', 'geom', NULL);
-------------
1

SELECT CreateRouting_GetLastError();
------------------------------------
NULL
This second attempt if finally successful, and now CreateRouting() returns 1 (aka TRUE), and as you can easily check now the Database contains two new Tables: byfoot and byfoot_data.
Note: after a successful call to CreateRouting() CreateRouting_GetLastError() will always return NULL.

You've just used the reduced form of CreateRouting(); let's see in more depth all the arguments and their meaning:
  1. byfoot_data: the name of the Network Binary Data Table to be created.
  2. byfoot: the name of the VirtualRouting Table to be created.
  3. roads_vw: the name of the Spatial Table or Spatial View representing the underlying Network.
    Note: in this case we actually used a Spatial View.
  4. node_from: name of the column (in the above Table or View) expected to contain node-from values.
  5. node_to: name of the column (in the above Table or View) expected to contain node-to values.
  6. geom: name of the column (in the above Table or View) expected to contain Linestrings.
    We could have legitimately passed a NULL value for this argument in the case of a Logical Network.
  7. NULL: name of the column (in the above Table or View) expected to contain cost values.
    In this case we have passed a NULL value, and consequently the cost of each Link will be assumed to be represented by the geometric length of the corresponding Linestring.
    Note #1: in the case of Networks based on longitudes and latitudes (aka geographic Reference Systems) the geometry length of all Linestrings will be precisely measured on the ellipsoid by applying the most accurate geodesic formulae and will be consequently expressed in meters. In any other case (projected Reference Systems) lengths will be expressed in the measure unit defined by the Reference System (e.g. meters for UTM projections and feet for NAD-ft projections).
    Note #2: the geom-column and cost-column arguments are never allowed to be NULL at the same time.

Technical note

The internal encoding adopted by the Binary Data Table is unchanged and is the same for both VirtualNetwok and VirtualRouting.
You can safely base a VirtualRouting Table on any existing Binary Data Table created by the spatialite-network CLI tool, exactly as you can base a VirtualNetwork Table on any Binary Data Table created by the CreateRouting() SQL function.
CREATE VIRTUAL TABLE test_network USING VirtualNetwork('some_data_table');

CREATE VIRTUAL TABLE test_routing USING VirtualRouting('some_data_table');
In order to manually create your Virtual Tables you just have to execute an appropriate CREATE VIRTUAL TABLE ... USING Virtual... (...) statement.

Warning

In the case of Spatial Networks based on any geographic Reference System (using longitudes and latitudes) there is an important difference between Binary Data Tables created by the spatialite_network GUI tool and Binary Data Tables created by the CreateRouting() SQL function when costs are implicitly based on the geometric length of the Link's Linestring:
  • the spatialite_network CLI tool (and the GUI wizard implemented by previous versions of spatialite_gui) compute the Linestring's length as an angular distance expressed in degrees.
  • the CreateRouting() SQL function computes the Linestring's length as a linear distance expressed in metres by applying the most accurate geodesic formulae on the ellipsoid.


SELECT CreateRouting('bycar_data', 'bycar', 'roads_vw', 'node_from', 'node_to', 'geom', 'cost', 'toponym', 1, 1, 'oneway_fromto', 'oneway_tofrom', 0);
--------------------
1
After calling yet another time CreateRouting() now the Database contains two further Tables: bycar and bycar_data.
This time you've used the complete form of CreateRouting(); let's see in more depth all the arguments and their meaning:
  1. bycar_data: same as above.
  2. bycar: same as above.
  3. roads_vw: same as above.
  4. node_from: same as above.
  5. node_to: same as above.
  6. geom: same as above.
  7. cost: same as above. In this case we have referenced a column preloaded with values corresponding to the time measured in seconds required to traverse each Link.
  8. toponym: name of the column (in the above Table or View) expected to contain road-name values.
    It could be legitimately set to NULL if all Links are anonymous.
  9. 1: a boolean flag intended to specify if the Network must support the A* algorithm or not (set to TRUE by default).
  10. 1: a boolean flag intended to specify if all Network's Links are assumed to be bidirectional or not (assumed to be TRUE by default).
  11. oneway_fromto: name of the column (in the above Table or View) expected to contain boolean flags specifying if each Link can be traversed in the from-to direction or not.
  12. oneway_tofrom: name of the column (in the above Table or View) expected to contain boolean flags specifying if each Link can be traversed in the to-from direction or not.
    Note #1: both from-to and to-from column names can be legitimately set as NULL if no one-way restrictions apply to the current Network.
    Note #2: Networks of the unidirectional type are never enabled to reference one-way columns (they should always be set to NULL).
  13. 0: a boolean flag intending an overwrite authorization.
    • If set to FALSE an exception will be raised if the Binary Data Table and/or the VirtualRouting Table do already exist.
    • If set to TRUE eventually existing Tables will be preventively dropped immediately before starting the execution of CreateRouting().

Automatically setting NodeFrom and NodeTo IDs

Sometimes it could eventually happen to encounter some Spatial Network representation being fully topologically consistent but completely lacking any definition about NodeFrom and NodeTo identifiers.
In this specific case you can successfully recover a perfectly valid Network by calling the CreateRoutingNodes() SQL function.
SELECT CreateRoutingNodes(NULL, 'table_name', 'geom', 'node_from', 'node_to');
_________________________
1
Let's examine all arguments and their meaning:
  1. NULL: name of the Attached-DB containing the Spatial Table.
    It can be legitimately set to NULL, and in this case the MAIN DB is assumed.
  2. table_name: name of the Spatial Table.
  3. geom
  4. : name of the column ((in the above Table) containing Linestrings.
  5. node_from: name of the column to be added to the above Table and populated with appropriate NodeFrom IDs.
  6. node_to: name of the column to be added to the above Table and populated with appropriate NodeTo IDs.
    Note: both NodeFrom and NodeTo columns should not be already defined in the above Table.
CreateRoutingNodes() will return 1 (aka TRUE) on success; an exception will be raised on failure.
Note: you can call CreateRouting_GetLastError() so to precisely identify the cause accounting for failure.

back