| 1 | ----------------------------------------------------------------------- |
|---|
| 2 | -- This function should not be used directly. Use assign_vertex_id instead |
|---|
| 3 | -- |
|---|
| 4 | -- Inserts a point into a temporary vertices table, and return an id |
|---|
| 5 | -- of a new point or an existing point. Tolerance is the minimal distance |
|---|
| 6 | -- between existing points and the new point to create a new point. |
|---|
| 7 | -- |
|---|
| 8 | -- Last changes: 16.04.2008 |
|---|
| 9 | -- Author: Christian Gonzalez |
|---|
| 10 | ----------------------------------------------------------------------- |
|---|
| 11 | CREATE OR REPLACE FUNCTION point_to_id(p geometry, tolerance double precision) |
|---|
| 12 | RETURNS BIGINT |
|---|
| 13 | AS |
|---|
| 14 | $$ |
|---|
| 15 | |
|---|
| 16 | DECLARE |
|---|
| 17 | _r record; |
|---|
| 18 | _id bigint; |
|---|
| 19 | _srid integer; |
|---|
| 20 | |
|---|
| 21 | BEGIN |
|---|
| 22 | |
|---|
| 23 | _srid := Find_SRID('public','vertices_tmp','the_geom'); |
|---|
| 24 | |
|---|
| 25 | SELECT |
|---|
| 26 | |
|---|
| 27 | Distance(the_geom,GeometryFromText( AsText(p), _srid)) AS d, id, the_geom |
|---|
| 28 | |
|---|
| 29 | INTO _r FROM vertices_tmp WHERE |
|---|
| 30 | |
|---|
| 31 | the_geom && Expand(GeometryFromText(AsText(p), _srid), tolerance ) AND Distance(the_geom, GeometryFromText(AsText(p), _srid)) < tolerance |
|---|
| 32 | |
|---|
| 33 | ORDER BY d LIMIT 1; IF FOUND THEN |
|---|
| 34 | |
|---|
| 35 | _id:= _r.id; |
|---|
| 36 | |
|---|
| 37 | ELSE |
|---|
| 38 | |
|---|
| 39 | INSERT INTO vertices_tmp(the_geom) VALUES (SetSRID(p,_srid)); _id:=lastval(); |
|---|
| 40 | |
|---|
| 41 | END IF; |
|---|
| 42 | |
|---|
| 43 | RETURN _id; |
|---|
| 44 | |
|---|
| 45 | END; $$ LANGUAGE 'plpgsql' VOLATILE STRICT; |
|---|
| 46 | |
|---|
| 47 | |
|---|
| 48 | ----------------------------------------------------------------------- |
|---|
| 49 | -- Fill the source and target_id column for all lines. All line ends |
|---|
| 50 | -- with a distance less than tolerance, are assigned the same id |
|---|
| 51 | -- |
|---|
| 52 | -- Last changes: 16.04.2008 |
|---|
| 53 | -- Author: Christian Gonzalez |
|---|
| 54 | ----------------------------------------------------------------------- |
|---|
| 55 | |
|---|
| 56 | CREATE OR REPLACE FUNCTION assign_vertex_id(geom_table varchar, tolerance double precision, geo_cname varchar, gid_cname varchar) |
|---|
| 57 | RETURNS VARCHAR AS |
|---|
| 58 | $$ |
|---|
| 59 | DECLARE |
|---|
| 60 | _r record; |
|---|
| 61 | source_id int; |
|---|
| 62 | target_id int; |
|---|
| 63 | srid integer; |
|---|
| 64 | BEGIN |
|---|
| 65 | |
|---|
| 66 | BEGIN |
|---|
| 67 | DROP TABLE vertices_tmp; |
|---|
| 68 | EXCEPTION |
|---|
| 69 | WHEN UNDEFINED_TABLE THEN |
|---|
| 70 | END; |
|---|
| 71 | |
|---|
| 72 | EXECUTE 'CREATE TABLE vertices_tmp (id serial)'; |
|---|
| 73 | |
|---|
| 74 | -- FOR _r IN EXECUTE 'SELECT srid FROM geometry_columns WHERE f_table_name='''|| quote_ident(geom_table)||''';' LOOP |
|---|
| 75 | -- srid := _r.srid; |
|---|
| 76 | -- END LOOP; |
|---|
| 77 | |
|---|
| 78 | srid := Find_SRID('public',quote_ident(geom_table),quote_ident(geo_cname)); |
|---|
| 79 | |
|---|
| 80 | |
|---|
| 81 | EXECUTE 'SELECT addGeometryColumn(''vertices_tmp'', ''the_geom'', '||srid||', ''POINT'', 2)'; |
|---|
| 82 | CREATE INDEX vertices_tmp_idx ON vertices_tmp USING GIST (the_geom); |
|---|
| 83 | |
|---|
| 84 | FOR _r IN EXECUTE 'SELECT ' || quote_ident(gid_cname) || ' AS id,' |
|---|
| 85 | || ' StartPoint('|| quote_ident(geo_cname) ||') AS source,' |
|---|
| 86 | || ' EndPoint('|| quote_ident(geo_cname) ||') as target' |
|---|
| 87 | || ' FROM ' || quote_ident(geom_table) |
|---|
| 88 | LOOP |
|---|
| 89 | |
|---|
| 90 | source_id := point_to_id(setsrid(_r.source, srid), tolerance); |
|---|
| 91 | target_id := point_to_id(setsrid(_r.target, srid), tolerance); |
|---|
| 92 | |
|---|
| 93 | EXECUTE 'update ' || quote_ident(geom_table) || |
|---|
| 94 | ' SET source = ' || source_id || |
|---|
| 95 | ', target = ' || target_id || |
|---|
| 96 | ' WHERE ' || quote_ident(gid_cname) || ' = ' || _r.id; |
|---|
| 97 | END LOOP; |
|---|
| 98 | |
|---|
| 99 | RETURN 'OK'; |
|---|
| 100 | |
|---|
| 101 | END; |
|---|
| 102 | $$ |
|---|
| 103 | LANGUAGE 'plpgsql' VOLATILE STRICT; |
|---|
| 104 | |
|---|