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 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305
|
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- PostGIS - Spatial Types for PostgreSQL
-- http://postgis.net
--
-- Copyright (C) 2013 Sandro Santilli <strk@kbt.io>
--
-- This is free software; you can redistribute and/or modify it under
-- the terms of the GNU General Public Licence. See the COPYING file.
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- Functions used for TopoJSON export
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
/* #define POSTGIS_TOPOLOGY_DEBUG 1 */
--{
--
-- API FUNCTION
--
-- text AsTopoJSON(TopoGeometry, edgeMapTable)
--
-- Format specification here:
-- http://github.com/mbostock/topojson-specification/blob/master/README.md
--
-- }{
CREATE OR REPLACE FUNCTION topology.AsTopoJSON(tg topology.TopoGeometry, edgeMapTable regclass)
RETURNS text AS
$$
DECLARE
toponame text;
json text;
sql text;
bounds GEOMETRY;
rec RECORD;
rec2 RECORD;
side int;
arcid int;
arcs int[];
ringtxt TEXT[];
comptxt TEXT[];
edges_found BOOLEAN;
old_search_path TEXT;
all_faces int[];
faces int[];
bounding_edges int[];
visited_face int;
shell_faces int[];
visited_edges int[];
looking_for_holes BOOLEAN;
BEGIN
IF tg IS NULL THEN
RETURN NULL;
END IF;
-- Get topology name (for subsequent queries)
SELECT name FROM topology.topology into toponame
WHERE id = tg.topology_id;
-- TODO: implement scale ?
-- Puntal TopoGeometry, simply delegate to AsGeoJSON
IF tg.type = 1 THEN
json := ST_AsGeoJSON(topology.Geometry(tg));
return json;
ELSIF tg.type = 2 THEN -- lineal
FOR rec IN SELECT (ST_Dump(topology.Geometry(tg))).geom
LOOP -- {
sql := 'SELECT e.*, ST_LineLocatePoint($1'
|| ', ST_LineInterpolatePoint(e.geom, 0.2)) as pos'
|| ', ST_LineLocatePoint($1'
|| ', ST_LineInterpolatePoint(e.geom, 0.8)) as pos2 FROM '
|| quote_ident(toponame)
|| '.edge e WHERE ST_Covers($1'
|| ', e.geom) ORDER BY pos';
-- TODO: add relation to the conditional, to reduce load ?
FOR rec2 IN EXECUTE sql USING rec.geom
LOOP -- {
IF edgeMapTable IS NOT NULL THEN
sql := 'SELECT arc_id-1 FROM ' || edgeMapTable::text || ' WHERE edge_id = $1';
EXECUTE sql INTO arcid USING rec2.edge_id;
IF arcid IS NULL THEN
EXECUTE 'INSERT INTO ' || edgeMapTable::text
|| '(edge_id) VALUES ($1) RETURNING arc_id-1'
INTO arcid USING rec2.edge_id;
END IF;
ELSE
arcid := rec2.edge_id;
END IF;
-- edge goes in opposite direction
IF rec2.pos2 < rec2.pos THEN
arcid := -(arcid+1);
END IF;
arcs := arcs || arcid;
END LOOP; -- }
comptxt := comptxt || ( '[' || array_to_string(arcs, ',') || ']' );
arcs := NULL;
END LOOP; -- }
json := '{ "type": "MultiLineString", "arcs": [' || array_to_string(comptxt,',') || ']}';
return json;
ELSIF tg.type = 3 THEN -- areal
json := '{ "type": "MultiPolygon", "arcs": [';
EXECUTE 'SHOW search_path' INTO old_search_path;
EXECUTE 'SET search_path TO ' || quote_ident(toponame) || ',' || old_search_path;
SELECT array_agg(id) as f
FROM ( SELECT (topology.GetTopoGeomElements(tg))[1] as id ) as f
INTO all_faces;
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG 'Faces: %', all_faces;
#endif
visited_edges := ARRAY[]::int[];
faces := all_faces;
looking_for_holes := false;
shell_faces := ARRAY[]::int[];
SELECT array_agg(edge_id)
FROM edge_data e
WHERE
( e.left_face = ANY ( faces ) OR
e.right_face = ANY ( faces ) )
INTO bounding_edges;
LOOP -- {
arcs := NULL;
edges_found := false;
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG 'LOOP START - looking for next % binding faces %',
CASE WHEN looking_for_holes THEN 'hole' ELSE 'shell' END, faces;
#endif
FOR rec in -- {
WITH RECURSIVE
_edges AS (
SELECT e.*,
e.left_face = ANY ( faces ) as lf,
e.right_face = ANY ( faces ) as rf
FROM edge e
WHERE edge_id = ANY (bounding_edges)
AND NOT e.edge_id = ANY ( visited_edges )
),
_leftmost_non_dangling_edge AS (
SELECT e.* FROM _edges e WHERE e.lf != e.rf
ORDER BY ST_XMin(geom), ST_YMin(geom) LIMIT 1
),
_edgepath AS (
SELECT
CASE
WHEN e.lf THEN lme.edge_id
ELSE -lme.edge_id
END as signed_edge_id,
false as back,
e.lf = e.rf as dangling,
e.left_face, e.right_face,
e.lf, e.rf,
e.next_right_edge, e.next_left_edge
FROM _edges e, _leftmost_non_dangling_edge lme
WHERE e.edge_id = abs(lme.edge_id)
UNION
SELECT
CASE
WHEN p.dangling AND NOT p.back THEN -p.signed_edge_id
WHEN p.signed_edge_id < 0 THEN p.next_right_edge
ELSE p.next_left_edge
END, -- signed_edge_id
CASE
WHEN p.dangling AND NOT p.back THEN true
ELSE false
END, -- back
e.lf = e.rf, -- dangling
e.left_face, e.right_face,
e.lf, e.rf,
e.next_right_edge, e.next_left_edge
FROM _edges e, _edgepath p
WHERE
e.edge_id = CASE
WHEN p.dangling AND NOT p.back THEN abs(p.signed_edge_id)
WHEN p.signed_edge_id < 0 THEN abs(p.next_right_edge)
ELSE abs(p.next_left_edge)
END
)
SELECT abs(signed_edge_id) as edge_id, signed_edge_id, dangling,
lf, rf, left_face, right_face
FROM _edgepath
LOOP -- }{
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG ' edge % lf:%(%) rf:%(%)' , rec.signed_edge_id, rec.lf, rec.left_face, rec.rf, rec.right_face;
#endif
IF rec.left_face = ANY (all_faces) AND NOT rec.left_face = ANY (shell_faces) THEN
shell_faces := shell_faces || rec.left_face;
END IF;
IF rec.right_face = ANY (all_faces) AND NOT rec.right_face = ANY (shell_faces) THEN
shell_faces := shell_faces || rec.right_face;
END IF;
visited_edges := visited_edges || rec.edge_id;
edges_found := true;
-- TODO: drop ?
IF rec.dangling THEN
CONTINUE;
END IF;
IF rec.left_face = ANY (all_faces) AND rec.right_face = ANY (all_faces) THEN
CONTINUE;
END IF;
IF edgeMapTable IS NOT NULL THEN
sql := 'SELECT arc_id-1 FROM ' || edgeMapTable::text || ' WHERE edge_id = $1';
EXECUTE sql INTO arcid USING rec.edge_id;
IF arcid IS NULL THEN
EXECUTE 'INSERT INTO ' || edgeMapTable::text
|| '(edge_id) VALUES ($1) RETURNING arc_id-1'
INTO arcid USING rec.edge_id;
END IF;
ELSE
arcid := rec.edge_id-1;
END IF;
-- Swap sign, use two's complement for negative edges
IF rec.signed_edge_id >= 0 THEN
arcid := - ( arcid + 1 );
END IF;
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG 'ARC id: %' , arcid;
#endif
arcs := arcid || arcs;
END LOOP; -- }
#ifdef POSTGIS_TOPOLOGY_DEBUG
--RAISE DEBUG 'Edges found:%, visited faces: %, ARCS: %' , edges_found, shell_faces, arcs;
#endif
IF NOT edges_found THEN
IF looking_for_holes THEN
looking_for_holes := false;
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG 'NO MORE holes, rings:%', ringtxt;
#endif
comptxt := comptxt || ( '[' || array_to_string(ringtxt, ',') || ']' );
ringtxt := NULL;
faces := all_faces;
shell_faces := ARRAY[]::int[];
ELSE
EXIT; -- end of loop
END IF;
ELSE
faces := shell_faces;
IF arcs IS NOT NULL THEN
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG ' % arcs: %', CASE WHEN looking_for_holes THEN 'hole' ELSE 'shell' END, arcs;
#endif
ringtxt := ringtxt || ( '[' || array_to_string(arcs,',') || ']' );
END IF;
looking_for_holes := true;
END IF;
END LOOP; -- }
json := json || array_to_string(comptxt, ',') || ']}';
EXECUTE 'SET search_path TO ' || old_search_path;
ELSIF tg.type = 4 THEN -- collection
RAISE EXCEPTION 'Collection TopoGeometries are not supported by AsTopoJSON';
END IF;
RETURN json;
END
$$ LANGUAGE 'plpgsql' VOLATILE; -- writes into visited table
-- } AsTopoJSON(TopoGeometry, visited_table)
|