pgRouting functions provide low level interface. When developing for a higher level application, the requirements need to be represented in the SQL queries. As these SQL queries get more complex, it is desirable to store them in postgreSQL stored procedures. Stored procedures are an effective way to wrap application logic, in this case, related to routing logic.
Chapter Contents
The stored procedure that is going to be developed has the following requirements:
Name of the road on the path.
The vehicle can not circulate on non pedestrian roads
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | -- DROP VIEW vehicle_net CASCADE;
CREATE VIEW vehicle_net AS
SELECT gid,
source,
target,
-- converting to minutes
cost_s / 60 AS cost,
reverse_cost_s / 60 AS reverse_cost,
the_geom
FROM ways JOIN osm_way_classes AS c
USING (class_id)
WHERE c.name NOT IN ('pedestrian','steps','footway','path');
-- Verification
SELECT count(*) FROM ways;
SELECT count(*) FROM vehicle_net;
|
The vehicle can only circulate inside this Boundig Box:
(-71.05 42.34, -71.03 42.35)
(-71.05 42.34, -71.03 42.35)
vehicle_net
VIEW.1 2 3 4 5 6 7 8 9 | -- DROP VIEW little_net;
CREATE VIEW little_net AS
SELECT *
FROM vehicle_net
WHERE vehicle_net.the_geom && ST_MakeEnvelope(-71.05, 42.34,-71.03, 42.36);
-- Verification
SELECT count(*) FROM little_net;
|
From the Venue to the Brewry using the osm_id.
61350413
to vertex 61479912
.osm_id
.seq
for ordering and unique row identifiername
of the road segments1 2 3 4 5 6 7 | SELECT *
FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
-- source
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
-- target
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912));
|
From the Venue to the Brewry, additionally get the name of the roads.
61350413
to vertex 61479912
.name
of the road segments1 2 3 4 5 6 7 8 | SELECT dijkstra.*, ways.name
FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912)
) AS dijkstra
LEFT JOIN ways
ON (edge = gid) ORDER BY seq;
|
From the Venue to the Brewry, additionally get the geometry in human readable form.
61350413
to vertex 61479912
.1 2 3 4 5 6 7 8 | SELECT dijkstra.*, ways.name, ST_AsText(ways.the_geom)
FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912)
) AS dijkstra
LEFT JOIN ways
ON (edge = gid) ORDER BY seq;
|
Solution to Chapter 7 Exercise 5
Note
The last record of the result, does not contain a geometry value since the
shortest path function returns -1
for the last record to indicate the end
of the route.
From the Venue, going to the Brewry by car, also get the binary format geometry that can be used by a front end app.
Note
Not using ST_AsText
gives the binary format.
Tip
WITH
provides a way to write auxiliary statements in larger queries.
It can be thought of as defining temporary tables that exist just for one query.
61350413
to vertex 61479912
.1 2 3 4 5 6 7 8 9 10 | WITH
dijkstra AS (
SELECT * FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912))
)
SELECT dijkstra.*, ways.name, ways.the_geom AS route_geom
FROM dijkstra LEFT JOIN ways ON (edge = gid)
ORDER BY seq;
|
From the Venue to the Brewry, calculate the azimuth in degrees.
61350413
to vertex 61479912
.seq
, name
, cost
, azimuth
in degrees and the geomtery
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | WITH
dijkstra AS (
SELECT * FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912))
),
get_geom AS (
SELECT dijkstra.*, ways.name, ways.the_geom AS route_geom
FROM dijkstra JOIN ways ON (edge = gid)
ORDER BY seq)
SELECT seq, name, cost,
-- calculating the azimuth
degrees(ST_azimuth(ST_StartPoint(route_geom), ST_EndPoint(route_geom))) AS azimuth,
ST_AsText(route_geom),
route_geom
FROM get_geom
ORDER BY seq;
|
From the Venue, going to the Brewry by car, get the geometry with correct arrow directionality.
When we generate a route the segements are returned as the geometry in the database. that means the segments can be reverserd relative to the direction of the route path. Goal is to have all segments oriented correctly along the route path.
61350413
to vertex 61479912
.seq
, name
, cost
, azimuth
and the geomtery
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 | WITH
dijkstra AS (
SELECT * FROM pgr_dijkstra(
'SELECT gid AS id, * FROM vehicle_net',
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61350413),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = 61479912))
),
get_geom AS (
SELECT dijkstra.*, ways.name,
-- adjusting directionality
CASE
WHEN dijkstra.node = ways.source THEN the_geom
ELSE ST_Reverse(the_geom)
END AS route_geom
FROM dijkstra JOIN ways ON (edge = gid)
ORDER BY seq)
SELECT seq, name, cost,
degrees(ST_azimuth(ST_StartPoint(route_geom), ST_EndPoint(route_geom))) AS azimuth,
ST_AsText(route_geom),
route_geom
FROM get_geom
ORDER BY seq;
|
Solution to Chapter 7 Exercise 8
Note
Comparing row 1 & 2 from Solution to Chapter 7 Exercise 5
-- from Exercise 5
LINESTRING(-71.0414012 42.3502602,-71.040802 42.351054)
LINESTRING(-71.0415194 42.3501037,-71.0414012 42.3502602)
-- from Excercise 7
LINESTRING(-71.040802 42.351054,-71.0414012 42.3502602)
LINESTRING(-71.0414012 42.3502602,-71.0415194 42.3501037)
The following function simplifies (and sets default values) when it calls the shortest path Dijkstra function.
Tip
pgRouting uses heavely function overloading:
Putting all together in a SQL function
osm_id
.seq
, name
, cost
, azimuth
and the geomtery
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 |
--DROP FUNCTION wrk_dijkstra(regclass, bigint, bigint);
CREATE OR REPLACE FUNCTION wrk_dijkstra(
IN edges_subset regclass,
IN source BIGINT,
IN target BIGINT,
OUT seq INTEGER,
OUT gid BIGINT,
OUT name TEXT,
OUT cost FLOAT,
OUT azimuth FLOAT,
OUT route_readable TEXT,
OUT route_geom geometry
)
RETURNS SETOF record AS
$BODY$
WITH
dijkstra AS (
SELECT * FROM pgr_dijkstra(
-- using parameters instead of specific values
'SELECT gid AS id, * FROM ' || $1,
(SELECT id FROM ways_vertices_pgr WHERE osm_id = $2),
(SELECT id FROM ways_vertices_pgr WHERE osm_id = $3))
),
get_geom AS (
SELECT dijkstra.*, ways.name,
CASE
WHEN dijkstra.node = ways.source THEN the_geom
ELSE ST_Reverse(the_geom)
END AS route_geom
FROM dijkstra JOIN ways ON (edge = gid)
ORDER BY seq)
SELECT
seq,
edge, -- will get the name "gid"
name,
cost,
degrees(ST_azimuth(ST_StartPoint(route_geom), ST_EndPoint(route_geom))) AS azimuth,
ST_AsText(route_geom),
route_geom
FROM get_geom
ORDER BY seq;
$BODY$
LANGUAGE 'sql';
|
osm_id
must exist on the ways_vertices_pgr
table.osm_id
falls outside the view, No path will be returned.1 2 | SELECT *
FROM wrk_dijkstra('vehicle_net', 61350413, 61479912);
|
Solution to Chapter 7 Exercise 10
Note
Try the function with little_net
and a combination of the interesting places:
61350413
is the Seaport Hotel & World Trade Center.61441749
is the Central Parking at the Airport.61479912
is the Harpoon Brewery.61493634
is the Market Place.1718017636
is the Westin Boston Waterfront.2481136250
is the New England AquariumSave the function code above into a file ~/Desktop/workshop/dijkstraHeading.sql
.
Saving functions in a file can be used to install the functionin another database. Install the function into the database with:
psql -U user -d city_routing -f ~/Desktop/workshop/wrk_dijkstra.sql