root/tags/release-1.0-beta/routing.sql.in

Revision 39, 8.4 KB (checked in by anton, 3 years ago)

1.0.0b tag added

Line 
1--
2-- Shortest path algorithm for PostgreSQL
3--
4-- Copyright (c) 2005 Sylvain Pasche,
5--               2006-2007 Anton A. Patrushev, Orkney, Inc.
6--
7-- This program is free software; you can redistribute it and/or modify
8-- it under the terms of the GNU General Public License as published by
9-- the Free Software Foundation; either version 2 of the License, or
10-- (at your option) any later version.
11--
12-- This program is distributed in the hope that it will be useful,
13-- but WITHOUT ANY WARRANTY; without even the implied warranty of
14-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
15-- GNU General Public License for more details.
16--
17-- You should have received a copy of the GNU General Public License
18-- along with this program; if not, write to the Free Software
19-- Foundation, Inc., 59 Temple Place - Suite 330, Boston, MA 02111-1307, USA.
20--
21
22
23CREATE TYPE path_result AS (vertex_id integer, edge_id integer, cost float8);
24CREATE TYPE vertex_result AS (x float8, y float8);
25
26-----------------------------------------------------------------------
27-- Core function for shortest_path computation
28-- See README for description
29-----------------------------------------------------------------------
30CREATE OR REPLACE FUNCTION shortest_path(sql text, source_id integer,
31        target_id integer, directed boolean, has_reverse_cost boolean)
32        RETURNS SETOF path_result
33        AS '$libdir/routing'
34        LANGUAGE 'C' IMMUTABLE STRICT;
35
36-----------------------------------------------------------------------
37-- Core function for shortest_path_astar computation
38-- Simillar to shortest_path in usage but uses the A* algorithm
39-- instead of Dijkstra's.
40-----------------------------------------------------------------------
41CREATE OR REPLACE FUNCTION shortest_path_astar(sql text, source_id integer,
42        target_id integer,directed boolean, has_reverse_cost boolean)
43         RETURNS SETOF path_result
44         AS '$libdir/routing'
45         LANGUAGE 'C' IMMUTABLE STRICT;
46
47-----------------------------------------------------------------------
48-- Core function for shortest_path_astar computation
49-- Simillar to shortest_path in usage but uses the Shooting* algorithm
50-----------------------------------------------------------------------
51CREATE OR REPLACE FUNCTION shortest_path_shooting_star(sql text, source_id integer,
52        target_id integer,directed boolean, has_reverse_cost boolean)
53         RETURNS SETOF path_result
54         AS '$libdir/routing'
55         LANGUAGE 'C' IMMUTABLE STRICT;
56
57-----------------------------------------------------------------------
58-- Core function for shortest_path_astar computation
59-- See README for description
60-----------------------------------------------------------------------
61CREATE OR REPLACE FUNCTION tsp(sql text, ids varchar, source integer)
62        RETURNS SETOF path_result
63        AS '$libdir/routing'
64        LANGUAGE 'C' IMMUTABLE STRICT;
65                       
66-----------------------------------------------------------------------
67-- Core function for shortest_path computation
68-- See README for description
69-----------------------------------------------------------------------
70CREATE OR REPLACE FUNCTION driving_distance(sql text, source_id integer,
71        distance float8,directed boolean, has_reverse_cost boolean)
72        RETURNS SETOF path_result
73        AS '$libdir/routing'
74        LANGUAGE 'C' IMMUTABLE STRICT;
75                       
76-----------------------------------------------------------------------
77-- Core function for alpha shape computation.
78-- The sql should return vertex ids and x,y values. Return ordered
79-- vertex ids. Used in points_as_polygon function found in
80-- routing_postgis.sql
81-----------------------------------------------------------------------
82CREATE OR REPLACE FUNCTION alphashape(sql text)
83        RETURNS SETOF vertex_result
84        AS '$libdir/routing'
85        LANGUAGE 'C' IMMUTABLE STRICT;
86
87-----------------------------------------------------------------------
88-- Drops the vertices and edges tables related to the given geom_table
89-----------------------------------------------------------------------
90CREATE OR REPLACE FUNCTION drop_graph_tables(geom_table varchar)
91        RETURNS void AS
92$$
93DECLARE
94        vertices_table varchar := quote_ident(geom_table) || '_vertices';
95        edges_table varchar := quote_ident(geom_table) || '_edges';
96BEGIN
97
98        BEGIN
99                EXECUTE 'DROP TABLE ' || vertices_table;
100        EXCEPTION
101                WHEN UNDEFINED_TABLE THEN
102        END;
103        BEGIN
104                EXECUTE 'DROP TABLE ' || edges_table;
105        EXCEPTION
106                WHEN UNDEFINED_TABLE THEN
107        END;
108        RETURN;
109END;
110$$
111LANGUAGE 'plpgsql' VOLATILE STRICT;
112
113-----------------------------------------------------------------------
114-- This function should not be used directly. Use create_graph_tables instead
115--
116-- Insert a vertex into the vertices table if not already there, and
117--  return the id of the newly inserted or already existing element
118-----------------------------------------------------------------------
119CREATE OR REPLACE FUNCTION insert_vertex(vertices_table varchar,
120       geom_id anyelement)
121       RETURNS int AS
122$$
123DECLARE
124        vertex_id int;
125        myrec record;
126BEGIN
127        LOOP
128          FOR myrec IN EXECUTE 'SELECT id FROM ' ||
129                     quote_ident(vertices_table) ||
130                     ' WHERE geom_id = ' || quote_literal(geom_id)  LOOP
131
132                        IF myrec.id IS NOT NULL THEN
133                                RETURN myrec.id;
134                        END IF;
135          END LOOP;
136          EXECUTE 'INSERT INTO ' || quote_ident(vertices_table) ||
137                  ' (geom_id) VALUES (' || quote_literal(geom_id) || ')';
138        END LOOP;
139END;
140$$
141LANGUAGE 'plpgsql' VOLATILE STRICT;
142
143-----------------------------------------------------------------------
144-- Create the vertices and edges tables from a table matching the
145--  geometry schema described above.
146-----------------------------------------------------------------------
147CREATE OR REPLACE FUNCTION create_graph_tables(geom_table varchar,
148       column_type varchar)
149       RETURNS void AS
150$$
151DECLARE
152        geom record;
153        edge_id int;
154        myrec record;
155        source_id int;
156        target_id int;
157        vertices_table varchar := quote_ident(geom_table) || '_vertices';
158        edges_table varchar := quote_ident(geom_table) || '_edges';
159BEGIN
160
161        EXECUTE 'CREATE TABLE ' || vertices_table ||
162                ' (id serial, geom_id ' || quote_ident(column_type) ||
163                '  NOT NULL UNIQUE)';
164
165        EXECUTE 'CREATE INDEX ' || vertices_table || '_id_idx on ' ||
166                vertices_table || ' (id)';
167
168        EXECUTE 'CREATE TABLE ' || edges_table ||
169                ' (id serial, source int, target int, ' ||
170                'cost float8, reverse_cost float8, UNIQUE (source, target))';
171
172        EXECUTE 'CREATE INDEX ' || edges_table ||
173                '_source_target_idx on ' || edges_table ||
174                ' (source, target)';
175
176        FOR geom IN EXECUTE 'SELECT gid as id, ' ||
177             ' source_id AS source, ' ||
178             ' target_id AS target FROM ' || quote_ident(geom_table) LOOP
179
180                SELECT INTO source_id insert_vertex(vertices_table,
181                                                    geom.source);
182
183                SELECT INTO target_id insert_vertex(vertices_table,
184                                                    geom.target);
185
186                BEGIN
187                    EXECUTE 'INSERT INTO ' || edges_table ||
188                            ' (source, target) VALUES ('  ||
189                            quote_literal(source_id) || ', ' ||
190                            quote_literal(target_id) || ')';
191
192                EXCEPTION
193                        WHEN UNIQUE_VIOLATION THEN
194                END;
195
196                FOR myrec IN EXECUTE 'SELECT id FROM ' || edges_table ||
197                    ' e WHERE ' || ' e.source = ' ||
198                    quote_literal(source_id) ||
199                    ' and e.target = ' ||
200                    quote_literal(target_id) LOOP
201                END LOOP;
202
203                edge_id := myrec.id;
204
205                IF edge_id IS NULL OR edge_id < 0 THEN
206                        RAISE EXCEPTION 'Bad edge id';
207                END IF;
208
209                EXECUTE 'UPDATE ' || quote_ident(geom_table) ||
210                        ' SET edge_id = ' || edge_id ||
211                        ' WHERE gid =  ' || geom.id;
212        END LOOP;
213        RETURN;
214END;
215$$
216LANGUAGE 'plpgsql' VOLATILE STRICT;
Note: See TracBrowser for help on using the browser.