Compare commits
3 Commits
check-trav
...
CDB_UNION_
| Author | SHA1 | Date | |
|---|---|---|---|
|
|
9e2f2b7c2d | ||
|
|
69b6aa6aca | ||
|
|
e84b467cbc |
25
pg/doc/05_cdb_union_adjacent.md
Normal file
25
pg/doc/05_cdb_union_adjacent.md
Normal file
@@ -0,0 +1,25 @@
|
||||
### Union Adjacent
|
||||
|
||||
This is an aggregate function that will take a set of polygons and return a geometry array
|
||||
of regions where the polygons are continuous. Basically it combines polygons
|
||||
which are touching in to single polygons.
|
||||
|
||||
It takes a single value:
|
||||
|
||||
* `geometry` a list of geometries to be clustered and joined
|
||||
|
||||
and returns
|
||||
|
||||
* `geometry[]` an array of the joined geometries.
|
||||
|
||||
An example usage would be something like:
|
||||
|
||||
```postgresql
|
||||
with joined_polygons as (
|
||||
select cdb_union_adjacent(the_geom) regions from some_table
|
||||
)
|
||||
select unnest(region) the_geom from joined_polygons
|
||||
```
|
||||
|
||||
which will produce a table with regions of continuous polygons from the original
|
||||
table.
|
||||
43
pg/sql/0.0.1/05_cdb_union_adjacent.sql
Normal file
43
pg/sql/0.0.1/05_cdb_union_adjacent.sql
Normal file
@@ -0,0 +1,43 @@
|
||||
CREATE OR REPLACE FUNCTION _cdb_final_union_adjacent( joined_geoms geometry[] )
|
||||
RETURNS geometry[] AS $$
|
||||
BEGIN
|
||||
RETURN joined_geoms;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION _cdb_state_update_union_adjacent(clusters geometry[], new_geom geometry)
|
||||
RETURNS geometry[] AS $$
|
||||
DECLARE
|
||||
joins geometry[] :='{}';
|
||||
unjoined geometry[] :='{}';
|
||||
i integer;
|
||||
combined geometry;
|
||||
BEGIN
|
||||
joins := (select array_agg(g)
|
||||
from unnest(clusters) a(g)
|
||||
where ST_TOUCHES(g, new_geom));
|
||||
|
||||
unjoined := (select array_agg(g)
|
||||
from unnest(clusters) a(g)
|
||||
where ST_TOUCHES(g, new_geom) = false);
|
||||
|
||||
IF array_length(joins, 1) > 0 THEN
|
||||
joins := array_append(joins, new_geom);
|
||||
combined := ST_UNION(joins);
|
||||
ELSE
|
||||
combined := new_geom;
|
||||
END IF;
|
||||
|
||||
unjoined := array_append(unjoined, combined);
|
||||
RETURN unjoined;
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE AGGREGATE cdb_union_adjacent(geometry)(
|
||||
SFUNC=_cdb_state_update_union_adjacent,
|
||||
STYPE=geometry[],
|
||||
FINALFUNC=_cdb_final_union_adjacent,
|
||||
INITCOND='{}'
|
||||
);
|
||||
22
pg/test/0.0.1/expected/05_cdb_union_adjacent_test.out
Normal file
22
pg/test/0.0.1/expected/05_cdb_union_adjacent_test.out
Normal file
@@ -0,0 +1,22 @@
|
||||
\i test/fixtures/touching_polygons.sql
|
||||
-- test table (polygons, some of which touch and some which dont)
|
||||
CREATE TABLE touching_polygons(cartodb_id integer, the_geom geometry);
|
||||
INSERT INTO touching_polygons VALUES
|
||||
(1, ST_GeomFromText('POLYGON ((0 0, 1 0,1 1, 0 1, 0 0 ))')),
|
||||
(2, ST_GeomFromText('POLYGON ((1 0, 2 0, 2 1, 1 1, 1 0))')),
|
||||
(1, ST_GeomFromText('POLYGON ((0 1, 1 1,1 2, 0 2, 0 1 ))')),
|
||||
(4, ST_GeomFromText('POLYGON ((3 0, 4 0, 4 1, 3 1, 3 0))')),
|
||||
(5, ST_GeomFromText('POLYGON ((3 1, 4 1, 4 2, 3 2, 3 1))'));
|
||||
WITH joined_polygons AS (
|
||||
SELECT cdb_crankshaft.cdb_union_adjacent(the_geom) the_geom FROM touching_polygons
|
||||
),
|
||||
unnested_polygons as (
|
||||
select unnest(joined_polygons.the_geom) the_geom from joined_polygons
|
||||
)
|
||||
select ST_ASTEXT(unnested_polygons.the_geom) from unnested_polygons;
|
||||
st_astext
|
||||
------------------------------------------------
|
||||
POLYGON((1 0,0 0,0 1,0 2,1 2,1 1,2 1,2 0,1 0))
|
||||
POLYGON((4 1,4 0,3 0,3 1,3 2,4 2,4 1))
|
||||
(2 rows)
|
||||
|
||||
9
pg/test/0.0.1/sql/05_cdb_union_adjacent_test.sql
Normal file
9
pg/test/0.0.1/sql/05_cdb_union_adjacent_test.sql
Normal file
@@ -0,0 +1,9 @@
|
||||
\i test/fixtures/touching_polygons.sql
|
||||
|
||||
WITH joined_polygons AS (
|
||||
SELECT cdb_crankshaft.cdb_union_adjacent(the_geom) the_geom FROM touching_polygons
|
||||
),
|
||||
unnested_polygons as (
|
||||
select unnest(joined_polygons.the_geom) the_geom from joined_polygons
|
||||
)
|
||||
select ST_ASTEXT(unnested_polygons.the_geom) from unnested_polygons;
|
||||
8
pg/test/fixtures/touching_polygons.sql
vendored
Normal file
8
pg/test/fixtures/touching_polygons.sql
vendored
Normal file
@@ -0,0 +1,8 @@
|
||||
-- test table (polygons, some of which touch and some which dont)
|
||||
CREATE TABLE touching_polygons(cartodb_id integer, the_geom geometry);
|
||||
INSERT INTO touching_polygons VALUES
|
||||
(1, ST_GeomFromText('POLYGON ((0 0, 1 0,1 1, 0 1, 0 0 ))')),
|
||||
(2, ST_GeomFromText('POLYGON ((1 0, 2 0, 2 1, 1 1, 1 0))')),
|
||||
(1, ST_GeomFromText('POLYGON ((0 1, 1 1,1 2, 0 2, 0 1 ))')),
|
||||
(4, ST_GeomFromText('POLYGON ((3 0, 4 0, 4 1, 3 1, 3 0))')),
|
||||
(5, ST_GeomFromText('POLYGON ((3 1, 4 1, 4 2, 3 2, 3 1))'));
|
||||
Reference in New Issue
Block a user