| 1 | pgRouting - Routing Functionalities on PostgreSQL |
|---|
| 2 | |
|---|
| 3 | |
|---|
| 4 | INTRODUCTION |
|---|
| 5 | |
|---|
| 6 | This library contains following features: |
|---|
| 7 | |
|---|
| 8 | * Dijkstra algorithm - Shortest path algorithm, which named in honor |
|---|
| 9 | of Prof. Dr. Edsger Wybe Dijkstra who has invented it |
|---|
| 10 | * A-star (A*) algorithm - Shortest path algorithm using heuristical |
|---|
| 11 | function |
|---|
| 12 | * Driving distance - area person can cover in certain time from start |
|---|
| 13 | point using road network |
|---|
| 14 | * TSP - Travelling Salesman Problem solution with default mazimum of |
|---|
| 15 | 40 points |
|---|
| 16 | * Shooting star (Shooting*) algorithm - Shortest path algorithm for |
|---|
| 17 | real road networks with turn restrictions, traffic lights and one |
|---|
| 18 | way streets. |
|---|
| 19 | |
|---|
| 20 | REQUIREMENT |
|---|
| 21 | |
|---|
| 22 | * C and C++ compilers |
|---|
| 23 | * CMake >= 2.3 |
|---|
| 24 | * Postgresql 8.x |
|---|
| 25 | * PostGIS 1.x |
|---|
| 26 | * Proj 4.x |
|---|
| 27 | * GEOS (Geometry Engine - Open Source) library 2.x |
|---|
| 28 | See http://geos.refractions.net/ |
|---|
| 29 | * The Boost Graph Library (BGL). |
|---|
| 30 | Version >= 1.33 or previous having astar.hpp |
|---|
| 31 | See http://www.boost.org/libs/graph/doc/index.html |
|---|
| 32 | * The Genetic Algorithm Utility Library (GAUL). |
|---|
| 33 | See http://gaul.sourceforge.net |
|---|
| 34 | * Computational Geometry Algorithms Library (CGAL) version >= 3.2. |
|---|
| 35 | See http://www.cgal.org/ |
|---|
| 36 | |
|---|
| 37 | INSTALLATION |
|---|
| 38 | |
|---|
| 39 | * Edit Makefile, and set the BOOST_PATH with the location of your |
|---|
| 40 | boost library (if you are on Debian, just type |
|---|
| 41 | "apt-get install libboost-graph-dev" and you don't need to modify anything) |
|---|
| 42 | |
|---|
| 43 | * Enter pgrouting directory |
|---|
| 44 | |
|---|
| 45 | * Type "cmake .", then "make" |
|---|
| 46 | To include extra packages use "cmake -DWITH_TSP=ON -DWITH_DD=ON ." |
|---|
| 47 | |
|---|
| 48 | * If you have BGL installed but the version is less than 1.33.0, |
|---|
| 49 | just download the astar.hpp file from |
|---|
| 50 | http://www.boost.org/boost/graph/astar_search.hpp and copy it to |
|---|
| 51 | BOOST_PATH/graph directory. |
|---|
| 52 | |
|---|
| 53 | * If you have PostGIS installed, you can launch routing_wrapper.sql |
|---|
| 54 | which will create PostGIS import and manipulation functions. |
|---|
| 55 | |
|---|
| 56 | * GAUL library should be compilled with --no-slang option. |
|---|
| 57 | Otherwise make sure you have slang.h installed in /usr/include. |
|---|
| 58 | For more details please refer to corresponding README or INSTALL file. |
|---|
| 59 | |
|---|
| 60 | * Use interactive mode to install CGAL library. To avoid conflicts you should |
|---|
| 61 | exclude BOOST support from the installation (follow on-screen instructions). |
|---|
| 62 | |
|---|
| 63 | * Execute the sql file dijkstra.sql to install the functions in your database |
|---|
| 64 | (you need the plpgsql language enabled on your database. |
|---|
| 65 | Type "createlang plpgsql YOUR_DATABASE" if not) |
|---|
| 66 | |
|---|
| 67 | |
|---|
| 68 | |
|---|
| 69 | USAGE |
|---|
| 70 | |
|---|
| 71 | The core module is a function which computes a shortest path from a |
|---|
| 72 | set of edges and vertices. The function expects data in a specific |
|---|
| 73 | format in input. |
|---|
| 74 | |
|---|
| 75 | Some functions are provided for importing data from geometric tables, |
|---|
| 76 | and for generating results as geometries. |
|---|
| 77 | |
|---|
| 78 | |
|---|
| 79 | The shortest_path functions have the following signature: |
|---|
| 80 | ======================================================== |
|---|
| 81 | |
|---|
| 82 | CREATE OR REPLACE FUNCTION shortest_path(sql text, source_id integer, target_id integer, |
|---|
| 83 | directed boolean, has_reverse_cost boolean) |
|---|
| 84 | RETURNS SETOF path_result |
|---|
| 85 | |
|---|
| 86 | Where path_result is: |
|---|
| 87 | |
|---|
| 88 | CREATE TYPE path_result AS (vertex_id integer, edge_id integer, cost float8); |
|---|
| 89 | |
|---|
| 90 | arguments are: |
|---|
| 91 | |
|---|
| 92 | * sql: a SQL query, which should return a set of rows with the |
|---|
| 93 | following columns: |
|---|
| 94 | |
|---|
| 95 | - id: an int4 identifier of the edge |
|---|
| 96 | - source: an int4 identifier of the source vertex |
|---|
| 97 | - target: an int4 identifier of the target vertex |
|---|
| 98 | - cost: double precision value of the edge traversal cost. (a negative cost |
|---|
| 99 | will prevent the edge from being inserted in the graph). |
|---|
| 100 | - reverse_cost (optional): the cost for the reverse traversal of the |
|---|
| 101 | edge. This is only used when the directed and has_reverse_cost |
|---|
| 102 | parameters are true (see the above remark about negative costs). |
|---|
| 103 | - directed: true if the graph is directed |
|---|
| 104 | - has_reverse_cost: if true, the reverse_cost column of the SQL |
|---|
| 105 | generated set of rows will be used for the cost of the traversal of |
|---|
| 106 | the edge in the opposite direction. |
|---|
| 107 | |
|---|
| 108 | A* and Shooting* functions also need: |
|---|
| 109 | - x1: double precision value of x coordinate for edge's start vertex |
|---|
| 110 | - y1: double precision value of y coordinate for edge's start vertex |
|---|
| 111 | - x2: double precision value of x coordinate for edge's end vertex |
|---|
| 112 | - y2: double precision value of y coordinate for edge's end vertex |
|---|
| 113 | |
|---|
| 114 | Shooting* function also needs: |
|---|
| 115 | - rule: a string with a comma separated list of edge ids which describes |
|---|
| 116 | a rule for turning restriction (if you came along these edges, you can |
|---|
| 117 | pass through the current one only with the cost stated in to_cost column) |
|---|
| 118 | - to_cost: a cost of restricted passage (can be very high in a case of |
|---|
| 119 | turn restriction or comparable with an edge cost in a case of traffic light) |
|---|
| 120 | |
|---|
| 121 | For example, |
|---|
| 122 | |
|---|
| 123 | gid | source | target | cost | x1 | y1 | x2 | y2 | to_cost | rule |
|---|
| 124 | -----+--------+--------+------+----+----+----+----+---------+------ |
|---|
| 125 | 12 | 3 | 10 | 2 | 4 | 3 | 4 | 5 | 1000 | 14 |
|---|
| 126 | |
|---|
| 127 | means that the cost of going from edge 14 to edge 12 is 1000, |
|---|
| 128 | |
|---|
| 129 | and |
|---|
| 130 | |
|---|
| 131 | gid | source | target | cost | x1 | y1 | x2 | y2 | to_cost | rule |
|---|
| 132 | -----+--------+--------+------+----+----+----+----+---------+------ |
|---|
| 133 | 12 | 3 | 10 | 2 | 4 | 3 | 4 | 5 | 1000 | 14, 4 |
|---|
| 134 | |
|---|
| 135 | means that the cost of going from edge 14 to edge 12 through edge 4 is 1000. |
|---|
| 136 | |
|---|
| 137 | |
|---|
| 138 | The function returns a set of rows. There is one row for each crossed |
|---|
| 139 | edge, and an additional one containing the terminal vertex. |
|---|
| 140 | The columns of each row are: |
|---|
| 141 | |
|---|
| 142 | - vertex_id: the identifier of source vertex of each edge. There is one |
|---|
| 143 | more row after the last edge, which contains the vertex identifier of |
|---|
| 144 | the target path. |
|---|
| 145 | - edge_id: the identifier of the edge crossed |
|---|
| 146 | - cost: The cost associated to the current edge. It is 0 for the row |
|---|
| 147 | after the last edge. Thus, the path total cost can be computated using |
|---|
| 148 | a sum of all rows in the cost column. |
|---|
| 149 | |
|---|
| 150 | examples: |
|---|
| 151 | |
|---|
| 152 | SELECT * from shortest_path('SELECT source, id, target, cost FROM edges', |
|---|
| 153 | 3, 7, false, false); |
|---|
| 154 | |
|---|
| 155 | vertex_id | edge_id | cost |
|---|
| 156 | -----------+---------+------ |
|---|
| 157 | 3 | 2 | 0 |
|---|
| 158 | 4 | 21 | 0 |
|---|
| 159 | 6 | 5 | 0 |
|---|
| 160 | 7 | -1 | 0 |
|---|
| 161 | (4 rows) |
|---|
| 162 | |
|---|
| 163 | |
|---|
| 164 | To search a path using the A* algorithm: |
|---|
| 165 | |
|---|
| 166 | SELECT * from shortest_path_astar('SELECT id, source, target, cost, |
|---|
| 167 | x1, y1, x2, y2 FROM edges',3, 7, false, false); |
|---|
| 168 | |
|---|
| 169 | vertex_id | edge_id | cost |
|---|
| 170 | -----------+---------+------------------------ |
|---|
| 171 | 3 | 2 | 0.000763954363701041 |
|---|
| 172 | 4 | 21 | 0.00150254971056274 |
|---|
| 173 | 6 | 5 | 0.000417442425988342 |
|---|
| 174 | 7 | -1 | 0 |
|---|
| 175 | (4 rows) |
|---|
| 176 | |
|---|
| 177 | |
|---|
| 178 | Shooting* algorithm calculates a path from edge to edge (not from vertex to |
|---|
| 179 | vertex). Column vertex_id contains start vertex of an edge from column edge_id. |
|---|
| 180 | |
|---|
| 181 | To search a path using the Shooting* algorithm: |
|---|
| 182 | |
|---|
| 183 | SELECT * from shortest_path_shooting_star('SELECT id, source, target, cost, |
|---|
| 184 | x1, y1, x2, y2, rule, to_cost FROM edges', 17, 9, true, false); |
|---|
| 185 | |
|---|
| 186 | vertex_id | edge_id | cost |
|---|
| 187 | -----------+---------+------ |
|---|
| 188 | 16 | 17 | 1 |
|---|
| 189 | 15 | 16 | 1 |
|---|
| 190 | 2 | 5 | 1 |
|---|
| 191 | 3 | 4 | 1 |
|---|
| 192 | 20 | 12 | 2 |
|---|
| 193 | 10 | 9 | 2 |
|---|
| 194 | (6 rows) |
|---|
| 195 | |
|---|
| 196 | |
|---|
| 197 | The tsp function has the following signature: |
|---|
| 198 | ============================================ |
|---|
| 199 | |
|---|
| 200 | CREATE OR REPLACE FUNCTION tsp(sql text, ids varchar, source_id integer) |
|---|
| 201 | RETURNS SETOF path_result |
|---|
| 202 | |
|---|
| 203 | arguments are: |
|---|
| 204 | |
|---|
| 205 | * sql: a SQL query, which should return a set of rows with the |
|---|
| 206 | following columns: |
|---|
| 207 | |
|---|
| 208 | - source_id: an int4 identifier of the vertex |
|---|
| 209 | - x: x coordinate of the vertex |
|---|
| 210 | - y: y coordinate of the vertex |
|---|
| 211 | |
|---|
| 212 | * ids: text string containig int4 ids of vertices separated by commas |
|---|
| 213 | * source_id: int 4 id of the start point |
|---|
| 214 | |
|---|
| 215 | The function returns a set of rows. There is one row for each crossed |
|---|
| 216 | edge, and an additional one containing the terminal vertex. |
|---|
| 217 | The columns of each row are: |
|---|
| 218 | |
|---|
| 219 | - vertex_id: the identifier of source vertex of each edge. There is one |
|---|
| 220 | more row after the last edge, which contains the vertex identifier of |
|---|
| 221 | the target path. |
|---|
| 222 | - edge_id: unused, always 0 |
|---|
| 223 | - cost: unused, always 0 |
|---|
| 224 | |
|---|
| 225 | examples: |
|---|
| 226 | |
|---|
| 227 | SELECT * from tsp('select distinct source as source_id, x1::double precision as x, |
|---|
| 228 | y1::double precision as y from dourol where source in (83593,66059,10549,18842,13)', |
|---|
| 229 | '83593,66059,10549,18842,13', 10549); |
|---|
| 230 | |
|---|
| 231 | vertex_id | edge_id | cost |
|---|
| 232 | -----------+---------+------ |
|---|
| 233 | 10549 | 0 | 0 |
|---|
| 234 | 83593 | 0 | 0 |
|---|
| 235 | 66059 | 0 | 0 |
|---|
| 236 | 18842 | 0 | 0 |
|---|
| 237 | 13 | 0 | 0 |
|---|
| 238 | (5 rows) |
|---|
| 239 | |
|---|
| 240 | Afterwards vertex_id column can be used for shortest path calculation. |
|---|
| 241 | |
|---|
| 242 | |
|---|
| 243 | The driving_distance function has the following signature: |
|---|
| 244 | ========================================================= |
|---|
| 245 | |
|---|
| 246 | CREATE OR REPLACE FUNCTION driving_distance(sql text, source_id integer, distance float8) |
|---|
| 247 | |
|---|
| 248 | RETURNS SETOF path_result |
|---|
| 249 | |
|---|
| 250 | arguments are: |
|---|
| 251 | |
|---|
| 252 | * sql: a SQL query, which should return a set of rows with the |
|---|
| 253 | following columns: |
|---|
| 254 | |
|---|
| 255 | - id: an int4 identifier of the edge |
|---|
| 256 | - source: an int4 identifier of the source vertex |
|---|
| 257 | - target: an int4 identifier of the target vertex |
|---|
| 258 | - cost: an float8 value, of the edge traversal cost. (a negative cost |
|---|
| 259 | will prevent the edge from being inserted in the graph). |
|---|
| 260 | |
|---|
| 261 | * source_id: int4 id of the start point |
|---|
| 262 | * distance: float8 value of distance in degrees |
|---|
| 263 | |
|---|
| 264 | The function returns a set of rows. There is one row for each crossed |
|---|
| 265 | edge, and an additional one containing the terminal vertex. |
|---|
| 266 | The columns of each row are: |
|---|
| 267 | |
|---|
| 268 | - vertex_id: the identifier of source vertex of each edge. There is one |
|---|
| 269 | more row after the last edge, which contains the vertex identifier of |
|---|
| 270 | the target path. |
|---|
| 271 | - edge_id: the identifier of the edge crossed |
|---|
| 272 | - cost: The cost associated to the current edge. It is 0 for the row |
|---|
| 273 | after the last edge. Thus, the path total cost can be computated using |
|---|
| 274 | a sum of all rows in the cost column. |
|---|
| 275 | |
|---|
| 276 | examples: |
|---|
| 277 | |
|---|
| 278 | SELECT * from driving_distance('select gid as id,source,target, |
|---|
| 279 | length::double precision as cost from dourol',10549,0.01); |
|---|
| 280 | |
|---|
| 281 | vertex_id | edge_id | cost |
|---|
| 282 | -----------+---------+--------------- |
|---|
| 283 | 6190 | 120220 | 0.00967666852 |
|---|
| 284 | 6205 | 118671 | 0.00961557335 |
|---|
| 285 | 6225 | 119384 | 0.00965668162 |
|---|
| 286 | 6320 | 119378 | 0.00959826176 |
|---|
| 287 | . |
|---|
| 288 | . |
|---|
| 289 | . |
|---|
| 290 | 15144 | 122612 | 0.00973386526 |
|---|
| 291 | 15285 | 120471 | 0.00912965866 |
|---|
| 292 | 15349 | 122085 | 0.00944814966 |
|---|
| 293 | 15417 | 120471 | 0.00942316736 |
|---|
| 294 | 15483 | 121629 | 0.00972957546 |
|---|
| 295 | (293 rows) |
|---|
| 296 | |
|---|
| 297 | |
|---|
| 298 | |
|---|
| 299 | |
|---|
| 300 | The power of SQL can be used for more complex cost computation: |
|---|
| 301 | |
|---|
| 302 | SELECT shortest_path('SELECT gid as id, node1_id as source, node2_id |
|---|
| 303 | as target, coalesce(CASE WHEN gid IN |
|---|
| 304 | (1956, 123) THEN 12 ELSE weights1.weight END, 99999) as cost |
|---|
| 305 | FROM lines2 LEFT JOIN weights1 USING (gid)', 12, 78, false, false); |
|---|
| 306 | |
|---|
| 307 | |
|---|
| 308 | |
|---|
| 309 | |
|---|
| 310 | GRAPH IMPORTATION |
|---|
| 311 | |
|---|
| 312 | The shortest_path function expects edges id and vertices id to be |
|---|
| 313 | integer ranging from zero to the maximum number of edges or vertices |
|---|
| 314 | (holes are allowed, but it will be less efficient). |
|---|
| 315 | However, you may want to compute shortest path on a table which has |
|---|
| 316 | vertex identifier stored as strings, like in the following example: |
|---|
| 317 | |
|---|
| 318 | SELECT * FROM graph1; |
|---|
| 319 | |
|---|
| 320 | gid | source_id | target_id | edge_id |
|---|
| 321 | -----+-----------+-----------+--------- |
|---|
| 322 | 0 | A | B | |
|---|
| 323 | 1 | A | C | |
|---|
| 324 | 2 | D | A | |
|---|
| 325 | 3 | B | C | |
|---|
| 326 | (4 rows) |
|---|
| 327 | |
|---|
| 328 | A function called "create_graph_tables" is available which will create |
|---|
| 329 | two tables for edges and vertices. Example: |
|---|
| 330 | |
|---|
| 331 | SELECT create_graph_tables('graph1', 'varchar'); |
|---|
| 332 | |
|---|
| 333 | The first argument is the name of the table containing the graph, and |
|---|
| 334 | the second is the type of the source and target vertex identifiers. |
|---|
| 335 | |
|---|
| 336 | It will create the following tables: |
|---|
| 337 | |
|---|
| 338 | SELECT * FROM graph1_edges; |
|---|
| 339 | |
|---|
| 340 | id | source | target | cost | reverse_cost |
|---|
| 341 | ----+--------+--------+------+-------------- |
|---|
| 342 | 1 | 1 | 2 | | |
|---|
| 343 | 2 | 1 | 3 | | |
|---|
| 344 | 3 | 4 | 1 | | |
|---|
| 345 | 4 | 2 | 3 | | |
|---|
| 346 | (4 rows) |
|---|
| 347 | |
|---|
| 348 | And |
|---|
| 349 | |
|---|
| 350 | SELECT * FROM graph1_vertices; |
|---|
| 351 | |
|---|
| 352 | id | geom_id |
|---|
| 353 | ----+--------- |
|---|
| 354 | 1 | A |
|---|
| 355 | 2 | B |
|---|
| 356 | 3 | C |
|---|
| 357 | 4 | D |
|---|
| 358 | (4 rows) |
|---|
| 359 | |
|---|
| 360 | |
|---|
| 361 | Notice the function will also update the edge_id column of graph1: |
|---|
| 362 | |
|---|
| 363 | gid | source_id | target_id | edge_id |
|---|
| 364 | -----+-----------+-----------+--------- |
|---|
| 365 | 0 | A | B | 1 |
|---|
| 366 | 1 | A | C | 2 |
|---|
| 367 | 2 | D | A | 3 |
|---|
| 368 | 3 | B | C | 4 |
|---|
| 369 | (4 rows) |
|---|
| 370 | |
|---|
| 371 | |
|---|
| 372 | Then, you can use the shortest_path function, as below: |
|---|
| 373 | |
|---|
| 374 | SELECT * FROM shortest_path('SELECT id, source, target, 1::float8 AS |
|---|
| 375 | cost FROM graph1_edges', |
|---|
| 376 | (SELECT id FROM graph1_vertices WHERE geom_id = 'A'), |
|---|
| 377 | (SELECT id FROM graph1_vertices WHERE geom_id = 'C'), |
|---|
| 378 | false, false); |
|---|
| 379 | |
|---|
| 380 | The initial table has to contain the following columns: |
|---|
| 381 | |
|---|
| 382 | - gid anyelement: a unique identifier for each edge in you graph |
|---|
| 383 | - source_id anyelement: an identifier for the starting vertex of the line |
|---|
| 384 | - target_id anyelement: an identifier for the target vertex of the line |
|---|
| 385 | (if the graph is not directed, source or target has the same |
|---|
| 386 | meaning) |
|---|
| 387 | - edge_id integer: this column will be filled by the allocated edge |
|---|
| 388 | identifier. All data there will be overwritten, and you need to create |
|---|
| 389 | this column if it does not exists before. |
|---|
| 390 | |
|---|
| 391 | The function "drop_graph_tables" will simply delete the edges and |
|---|
| 392 | vertices associated tables. Example: |
|---|
| 393 | |
|---|
| 394 | SELECT drop_graph_tables('graph1'); |
|---|
| 395 | |
|---|
| 396 | |
|---|
| 397 | POSTGIS GEOMETRIES IMPORTATION |
|---|
| 398 | |
|---|
| 399 | Some pl/pgsql functions are available for working with geographical |
|---|
| 400 | data from PostGis tables. |
|---|
| 401 | |
|---|
| 402 | The table containing the graph has to contain the columns described in |
|---|
| 403 | the previous section, and an additional geometric column called |
|---|
| 404 | "the_geom" of type MULTILINESTRING. Only the first line in the |
|---|
| 405 | multiline geomety will be handled. This restriction is because the |
|---|
| 406 | shp2pgsql tool provided with postgis creates MULTILINESTRING geometric |
|---|
| 407 | tables for shapefiles containing a set of lines. The importation |
|---|
| 408 | should however handle more that only the first line in the multi line |
|---|
| 409 | geometry (see TODO). |
|---|
| 410 | |
|---|
| 411 | Here's an example of such a table: |
|---|
| 412 | |
|---|
| 413 | SELECT gid, source_id, target_id, astext(the_geom) FROM graph2 LIMIT 4; |
|---|
| 414 | |
|---|
| 415 | gid | source_id | target_id | astext |
|---|
| 416 | -----+-----------+-----------+-------------------------------------------------------------------------------------------- |
|---|
| 417 | 0 | | | MULTILINESTRING((-0.357902298850575 51.2777105057471,-0.364822129560221 51.455488954023)) |
|---|
| 418 | 1 | | | MULTILINESTRING((-0.415775862068966 51.6386587816092,-0.478232130809596 51.5784636541729)) |
|---|
| 419 | 2 | | | MULTILINESTRING((-0.478232130809596 51.5784636541729,-0.382585141804099 51.5791468469515)) |
|---|
| 420 | 3 | | | MULTILINESTRING((-0.364822129560221 51.455488954023,-0.433824600199901 51.5244914246627)) |
|---|
| 421 | (4 rows) |
|---|
| 422 | |
|---|
| 423 | |
|---|
| 424 | If the graph table does not contain identifier values in the source_id |
|---|
| 425 | and target_id columns, a function is able to generate such ids, by |
|---|
| 426 | extracting the starting and ending points of the line, and generating |
|---|
| 427 | an unique id, for all points that are in a given distance. Example: |
|---|
| 428 | |
|---|
| 429 | SELECT assign_vertex_id('graph2', 0.1); |
|---|
| 430 | |
|---|
| 431 | SELECT gid, source_id, target_id, astext(the_geom) FROM graph2 LIMIT 4; |
|---|
| 432 | |
|---|
| 433 | gid | source_id | target_id | astext |
|---|
| 434 | -----+-----------+-----------+-------------------------------------------------------------------------------------------- |
|---|
| 435 | 0 | 1 | 2 | MULTILINESTRING((-0.357902298850575 51.2777105057471,-0.364822129560221 51.455488954023)) |
|---|
| 436 | 1 | 3 | 3 | MULTILINESTRING((-0.415775862068966 51.6386587816092,-0.478232130809596 51.5784636541729)) |
|---|
| 437 | 2 | 3 | 3 | MULTILINESTRING((-0.478232130809596 51.5784636541729,-0.382585141804099 51.5791468469515)) |
|---|
| 438 | 3 | 2 | 2 | MULTILINESTRING((-0.364822129560221 51.455488954023,-0.433824600199901 51.5244914246627)) |
|---|
| 439 | |
|---|
| 440 | |
|---|
| 441 | Now that the source_id and target_id are filled, the function |
|---|
| 442 | create_graph_tables() can be used to create the edges |
|---|
| 443 | and vertices tables (see above for the detailed description of |
|---|
| 444 | create_graph_tables): |
|---|
| 445 | |
|---|
| 446 | SELECT create_graph_tables('graph2', 'int4'); |
|---|
| 447 | |
|---|
| 448 | Here's the content of the edges table: |
|---|
| 449 | |
|---|
| 450 | SELECT * FROM graph2_edges LIMIT 3; |
|---|
| 451 | |
|---|
| 452 | id | source | target | cost | reverse_cost |
|---|
| 453 | ----+--------+--------+------+-------------- |
|---|
| 454 | 1 | 1 | 2 | | |
|---|
| 455 | 2 | 3 | 3 | | |
|---|
| 456 | 4 | 2 | 2 | | |
|---|
| 457 | (3 rows) |
|---|
| 458 | |
|---|
| 459 | We can see that it contains NULL values for the cost column. |
|---|
| 460 | |
|---|
| 461 | The function update_cost_from_distance can update the cost column with |
|---|
| 462 | the distance of the lines contained in the geometry table, attached to |
|---|
| 463 | each edge: |
|---|
| 464 | |
|---|
| 465 | SELECT update_cost_from_distance('graph2'); |
|---|
| 466 | |
|---|
| 467 | The costs are now: |
|---|
| 468 | |
|---|
| 469 | SELECT * FROM graph2_edges LIMIT 3; |
|---|
| 470 | |
|---|
| 471 | id | source | target | cost | reverse_cost |
|---|
| 472 | ----+--------+--------+-------------------+-------------- |
|---|
| 473 | 1 | 1 | 2 | 0.230081516048264 | |
|---|
| 474 | 2 | 3 | 3 | 0.446760794328524 | |
|---|
| 475 | 4 | 2 | 2 | 0.174348470878483 | |
|---|
| 476 | |
|---|
| 477 | |
|---|
| 478 | Now, all is set up correctly for using the shortest_path() on these |
|---|
| 479 | data: |
|---|
| 480 | |
|---|
| 481 | SELECT * FROM shortest_path('SELECT id, source, target, cost FROM graph2_edges', |
|---|
| 482 | 1, 2, false, false); |
|---|
| 483 | |
|---|
| 484 | vertex_id | edge_id | cost |
|---|
| 485 | -----------+---------+------ |
|---|
| 486 | 1 | 1 | 0 |
|---|
| 487 | 2 | -1 | 0 |
|---|
| 488 | |
|---|
| 489 | An additional function shortest_path_as_geometry() can be used to |
|---|
| 490 | retrieve the result as a set of rows containing the geometry |
|---|
| 491 | identifier and the geometry itself: |
|---|
| 492 | |
|---|
| 493 | SELECT gid, astext(the_geom) FROM shortest_path_as_geometry('graph2', 1, 2); |
|---|
| 494 | |
|---|
| 495 | gid | astext |
|---|
| 496 | -----+-------------------------------------------------------------------------------------------- |
|---|
| 497 | 0 | MULTILINESTRING((-0.357902298850575 51.2777105057471,-0.364822129560221 51.455488954023)) |
|---|
| 498 | 22 | MULTILINESTRING((-0.417298850574714 51.3371070574713,-0.408546467391305 51.3885360617191)) |
|---|
| 499 | (2 rows) |
|---|
| 500 | |
|---|
| 501 | |
|---|
| 502 | MAPSERVER INTEGRATION |
|---|
| 503 | |
|---|
| 504 | The function shortest_path_as_geometry() can be used inside mapserver |
|---|
| 505 | to draw shortest path directly, as in the following example: |
|---|
| 506 | |
|---|
| 507 | |
|---|
| 508 | LAYER |
|---|
| 509 | NAME "europe2" |
|---|
| 510 | TYPE LINE |
|---|
| 511 | |
|---|
| 512 | STATUS DEFAULT |
|---|
| 513 | CONNECTIONTYPE postgis |
|---|
| 514 | CONNECTION "user=postgres host=localhost dbname=geo" |
|---|
| 515 | DATA "the_geom from (SELECT the_geom, gid from |
|---|
| 516 | shortest_path_as_geometry('bahnlinien_europa_polyline', 2629, 10171)) as |
|---|
| 517 | foo using unique gid using srid=-1" |
|---|
| 518 | |
|---|
| 519 | TEMPLATE "t" |
|---|
| 520 | CLASS |
|---|
| 521 | NAME "0" |
|---|
| 522 | STYLE |
|---|
| 523 | SYMBOL "circle" |
|---|
| 524 | SIZE 10 |
|---|
| 525 | COLOR 50 50 100 |
|---|
| 526 | END |
|---|
| 527 | END |
|---|
| 528 | END |
|---|
| 529 | |
|---|
| 530 | Notice however, that this function will be called at each map |
|---|
| 531 | display, computing the shortest path every time. |
|---|
| 532 | |
|---|
| 533 | A better approach would be to generate the shortest path in a |
|---|
| 534 | temporary table. |
|---|
| 535 | |
|---|
| 536 | |
|---|
| 537 | LIMITATION / TODO |
|---|
| 538 | |
|---|
| 539 | Usage of the Boost graph library can certainly be optimised. Help from |
|---|
| 540 | Boost/STL experts is welcomed. |
|---|
| 541 | |
|---|
| 542 | Might not work on very large datasets due to memory |
|---|
| 543 | requirements. (Tested with sucess on a 8 million edges table). |
|---|
| 544 | |
|---|
| 545 | LICENCE |
|---|
| 546 | |
|---|
| 547 | Most features are available under GPL. |
|---|
| 548 | Some Boost extesions are available under Boost license (see LICENSE_1_0.txt) |
|---|
| 549 | |
|---|
| 550 | AUTHORS |
|---|
| 551 | |
|---|
| 552 | Anton A. Patrushev <anton@orkney.co.jp> |
|---|
| 553 | Mario H. Basa <mbasa@orkney.co.jp> |
|---|
| 554 | |
|---|
| 555 | Dijkstra part was made by |
|---|
| 556 | Sylvain Pasche <sylvain.pasche@camptocamp.com> |
|---|