-/**********************************************************************
+/**********************************************************************
* $Id$
*
* PostGIS - Spatial Types for PostgreSQL
* in Mass State Plane feet and load Boston, MA tiger data
* with tolerance of 1 foot
* SELECT topology.DropTopology('topo_boston');
- * SELECT topology.CreateTopology('topo_boston', 2249,1);
+ * SELECT topology.CreateTopology('topo_boston', 2249,0.25);
* SELECT tiger.topology_load_tiger('topo_boston', 'place', '2507000');
* SELECT topology.TopologySummary('topo_boston');
* SELECT topology.ValidateTopology('topo_boston');
)
SELECT DISTINCT ON (t.tlid) t.tlid As edge_id,t.geom
, t.tnidf As start_node, t.tnidt As end_node, COALESCE(t.tfidl,0) As left_face
- , COALESCE(t.tfidr,0) As right_face, tl.tlid AS next_left_edge, tr.tlid As next_right_edge, t.orig_geom
+ , COALESCE(t.tfidr,0) As right_face, COALESCE(tl.tlid, t.tlid) AS next_left_edge, COALESCE(tr.tlid, t.tlid) As next_right_edge, t.orig_geom
FROM
te AS t LEFT JOIN te As tl ON (t.tnidf = tl.tnidt AND t.tfidl = tl.tfidl)
LEFT JOIN te As tr ON (t.tnidt = tr.tnidf AND t.tfidr = tr.tfidr)
-- start load in faces
var_sql := 'INSERT INTO ' || quote_ident(toponame) || '.face(face_id, mbr)
- SELECT f.tfid, ST_Envelope(ST_Transform(f.the_geom,$2)) As mbr
+ SELECT f.tfid, ST_Envelope(ST_Transform(f.the_geom,$3)) As mbr
FROM tiger.faces AS f
WHERE statefp = $1 AND
( tfid IN(SELECT left_face FROM tmp_edge)
- OR tfid IN(SELECT right_face FROM tmp_edge) )
+ OR tfid IN(SELECT right_face FROM tmp_edge) OR ST_Covers($2, the_geom) )
AND tfid NOT IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face) ';
- EXECUTE var_sql USING var_statefp, var_srid;
+ EXECUTE var_sql USING var_statefp, var_rgeom, var_srid;
GET DIAGNOSTICS var_rcnt = ROW_COUNT;
var_result := var_result || var_rcnt::text || ' faces added. ';
-- end load in faces
(SELECT tlid, ST_GeometryN(ST_SnapToGrid(ST_Transform(ST_LineMerge(the_geom),$2),$3),1) As geom, tnidf, tnidt, tfidl, tfidr, the_geom As orig_geom
FROM tiger.edges
WHERE statefp = $1 AND
- tfidl IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face)
- AND tfidr IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face)
+ (tfidl IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face)
+ OR tfidr IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face) )
AND tlid NOT IN(SELECT edge_id FROM tmp_edge)
)
FROM tiger.faces WHERE statefp = $1
AND tfid IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face)
) As f
- WHERE ST_Contains(f.the_geom, ST_Transform(n.geom,4269)) ';
+ WHERE ST_ContainsProperly(f.the_geom, ST_Transform(n.geom,4269)) ';
EXECUTE var_sql USING var_statefp, var_rgeom;
GET DIAGNOSTICS var_rcnt = ROW_COUNT;
var_result := var_result || ' ' || var_rcnt::text || ' nodes contained in a face. ';
-- end Mark nodes contained in faces
- -- Set orphan left right to itself
+ -- Set orphan left right to itself and set edges with missing faces to world face
var_sql := 'UPDATE tmp_edge SET next_left_edge = -1*edge_id WHERE next_left_edge IS NULL OR next_left_edge NOT IN(SELECT edge_id FROM tmp_edge);
- UPDATE tmp_edge SET next_right_edge = -1*edge_id WHERE next_right_edge IS NULL OR next_right_edge NOT IN(SELECT edge_id FROM tmp_edge);';
+ UPDATE tmp_edge SET next_right_edge = -1*edge_id WHERE next_right_edge IS NULL OR next_right_edge NOT IN(SELECT edge_id FROM tmp_edge);
+ UPDATE tmp_edge SET left_face = 0 WHERE left_face NOT IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face);
+ UPDATE tmp_edge SET right_face = 0 WHERE right_face NOT IN(SELECT face_id FROM ' || quote_ident(toponame) || '.face);';
EXECUTE var_sql;
+
+ -- force edges start and end points to match the start and end nodes --
+ var_sql := 'UPDATE tmp_edge SET geom = ST_SetPoint(ST_SetPoint(tmp_edge.geom, 0, s.geom), ST_NPoints(tmp_edge.geom) - 1,e.geom)
+ FROM ' || quote_ident(toponame) || '.node AS s, ' || quote_ident(toponame) || '.node As e
+ WHERE s.node_id = tmp_edge.start_node AND e.node_id = tmp_edge.end_node AND
+ ( NOT ST_Equals(s.geom, ST_StartPoint(tmp_edge.geom) ) OR NOT ST_Equals(e.geom, ST_EndPoint(tmp_edge.geom) ) ) ' ;
+ EXECUTE var_sql;
+ GET DIAGNOSTICS var_rcnt = ROW_COUNT;
+ var_result := var_result || ' ' || var_rcnt::text || ' edge start end corrected. ';
-- TODO: Load in edges --
var_sql := '
INSERT INTO ' || quote_ident(toponame) || '.edge(edge_id, geom, start_node, end_node, left_face, right_face, next_left_edge, next_right_edge)