-
Notifications
You must be signed in to change notification settings - Fork 0
/
pgr_aStarFromAtoB.sql
177 lines (151 loc) · 6.04 KB
/
pgr_aStarFromAtoB.sql
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
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
CREATE OR REPLACE FUNCTION pgr_aStarFromAtoB(
IN tbl varchar,
IN st_x double precision,
IN st_y double precision,
IN end_x double precision,
IN end_y double precision,
OUT seq integer,
OUT gid integer,
OUT name text,
OUT heading double precision,
OUT cost double precision,
OUT geom geometry,
OUT x1 double precision,
OUT y1 double precision,
OUT x2 double precision,
OUT y2 double precision
)
RETURNS SETOF record AS
$BODY$
DECLARE
sql text;
rec record;
source integer;
target integer;
--point integer;
BEGIN
-- Find nearest node
EXECUTE 'SELECT id::integer FROM ways_vertices_pgr
ORDER BY the_geom <-> ST_GeometryFromText(''POINT('
|| st_x || ' ' || st_y || ')'',4326) LIMIT 1' INTO rec;
source := rec.id;
EXECUTE 'SELECT id::integer FROM ways_vertices_pgr
ORDER BY the_geom <-> ST_GeometryFromText(''POINT('
|| end_x || ' ' || end_y || ')'',4326) LIMIT 1' INTO rec;
target := rec.id;
-- Shortest path query (TODO: limit extent by BBOX)
seq := 0;
sql := 'SELECT gid, the_geom, name, cost, source, target, x1, y1, x2, y2,
ST_Reverse(the_geom) AS flip_geom FROM ' ||
'pgr_astar(''SELECT gid as id, source::integer, target::integer, '
|| 'length::double precision AS cost, '
|| 'x1::double precision, y1::double precision,'
|| 'x2::double precision, y2::double precision,'
|| 'reverse_cost::double precision FROM '
|| quote_ident(tbl) || ''', '
|| source || ', ' || target
|| ' , true, true), '
|| quote_ident(tbl) || ' WHERE id2 = gid ORDER BY seq';
-- Remember start point
--point := source;
FOR rec IN EXECUTE sql
LOOP
-- Return record
seq := seq + 1;
gid := rec.gid;
name := rec.name;
cost := rec.cost;
geom := rec.the_geom;
x1 := rec.x1;
y1 := rec.y1;
x2 := rec.x2;
y2 := rec.y2;
RETURN NEXT;
END LOOP;
RETURN;
END;
$BODY$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--In order to use this function
--SELECT geom FROM pgr_aStarFromAtoB('ways', 28.231233, 41.324324, 29.432432, 42.423542)
--SELECT cost FROM pgr_aStarFromAtoB('ways', 28.231233, 41.324324, 29.432432, 42.423542)
--etc etc
--In GeoServer, we make an SQL View like the following
--SELECT geom FROM pgr_aStarFromAtoB('ways', %x1%, %y1%, %x2%, %y2%) ORDER BY seq
---------------------------------------------------------------------------------------
---------------------------------------------------------------------------------------
OR
CREATE OR REPLACE FUNCTION pgr_aStarFromAtoB(
IN tbl varchar,
IN st_x double precision,
IN st_y double precision,
IN end_x double precision,
IN end_y double precision,
OUT seq integer,
OUT gid integer,
OUT name text,
OUT heading double precision,
OUT cost double precision,
OUT geom geometry,
OUT x1 double precision,
OUT y1 double precision,
OUT x2 double precision,
OUT y2 double precision
)
RETURNS SETOF record AS
$BODY$
DECLARE
sql text;
rec record;
source integer;
target integer;
--point integer;
BEGIN
-- Find nearest node
EXECUTE 'SELECT id::integer FROM ways_vertices_pgr
ORDER BY the_geom <-> ST_GeometryFromText(''POINT('
|| st_x || ' ' || st_y || ')'',4326) LIMIT 1' INTO rec;
source := rec.id;
EXECUTE 'SELECT id::integer FROM ways_vertices_pgr
ORDER BY the_geom <-> ST_GeometryFromText(''POINT('
|| end_x || ' ' || end_y || ')'',4326) LIMIT 1' INTO rec;
target := rec.id;
-- Shortest path query (TODO: limit extent by BBOX)
seq := 0;
sql := 'SELECT gid, the_geom, name, pgr.cost as cost, source, target, x1, y1, x2, y2,
ST_Reverse(the_geom) AS flip_geom FROM ' ||
'pgr_astar(''SELECT gid as id, source::integer, target::integer, '
|| 'length::double precision AS cost, '
|| 'x1::double precision, y1::double precision,'
|| 'x2::double precision, y2::double precision,'
|| 'reverse_cost::double precision FROM '
|| quote_ident(tbl) || ''', '
|| source || ', ' || target
|| ' , true, true) as pgr, '
|| quote_ident(tbl) || ' WHERE id2 = gid ORDER BY seq';
-- Remember start point
--point := source;
FOR rec IN EXECUTE sql
LOOP
-- Return record
seq := seq + 1;
gid := rec.gid;
name := rec.name;
cost := rec.cost;
geom := rec.the_geom;
x1 := rec.x1;
y1 := rec.y1;
x2 := rec.x2;
y2 := rec.y2;
RETURN NEXT;
END LOOP;
RETURN;
END;
$BODY$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--In order to use this function
--SELECT geom FROM pgr_aStarFromAtoB('ways', 28.231233, 41.324324, 29.432432, 42.423542)
--SELECT cost FROM pgr_aStarFromAtoB('ways', 28.231233, 41.324324, 29.432432, 42.423542)
--etc etc
--In GeoServer, we make an SQL View like the following
--SELECT geom FROM pgr_aStarFromAtoB('ways', %x1%, %y1%, %x2%, %y2%) ORDER BY seq