diff --git a/layers/building/building.sql b/layers/building/building.sql index 0f550986..fbca048c 100644 --- a/layers/building/building.sql +++ b/layers/building/building.sql @@ -82,7 +82,7 @@ SELECT geometry, CASE WHEN hide_3d THEN TRUE END AS hide_3d FROM ( SELECT - -- etldoc: osm_building_block_gen1 -> layer_building:z13 + -- etldoc: osm_building_block_gen_z13 -> layer_building:z13 osm_id, geometry, NULL::int AS render_height, @@ -90,7 +90,7 @@ FROM ( NULL::text AS material, NULL::text AS colour, FALSE AS hide_3d - FROM osm_building_block_gen1 + FROM osm_building_block_gen_z13 WHERE zoom_level = 13 AND geometry && bbox UNION ALL diff --git a/layers/building/etl_diagram.png b/layers/building/etl_diagram.png index c77cd48f..6e16c11e 100644 Binary files a/layers/building/etl_diagram.png and b/layers/building/etl_diagram.png differ diff --git a/layers/building/update_building.sql b/layers/building/update_building.sql index 97d9eb3e..d363eaca 100644 --- a/layers/building/update_building.sql +++ b/layers/building/update_building.sql @@ -1,13 +1,13 @@ DROP TRIGGER IF EXISTS trigger_refresh ON buildings.updates; DROP TRIGGER IF EXISTS trigger_flag ON osm_building_polygon; ---creating aggregated building blocks with removed small polygons and small ---holes. Aggregated polygons are simplified. +-- Creating aggregated building blocks with removed small polygons and small +-- holes. Aggregated polygons are simplified by Visvalingam-Whyatt algorithm. +-- Aggregating is made block by block using country_osm_grid polygon table. ---function returning recordset for matview ---returning recordset of buildings aggregates by zres 14, with removed small ---holes and with removed small buildings/blocks --- +-- Function returning recordset for matview. +-- Returning recordset of buildings aggregates by zres 14, with removed small +-- holes and with removed small buildings/blocks. CREATE OR REPLACE FUNCTION osm_building_block_gen1() RETURNS table @@ -20,50 +20,68 @@ $$ DECLARE zres14 float := Zres(14); zres12 float := Zres(12); + zres14vw float := Zres(14) * Zres(14); + polyg_world record; + BEGIN - FOR osm_id, geometry IN - WITH dta AS ( -- CTE is used because of optimization - SELECT o.osm_id, o.geometry, ST_ClusterDBSCAN(o.geometry, eps := zres14, minpoints := 1) OVER () cid - FROM osm_building_polygon o - ) - SELECT (array_agg(dta.osm_id))[1] osm_id, - ST_Buffer(ST_MemUnion(ST_Buffer(dta.geometry, zres14, 'join=mitre')), -zres14, 'join=mitre') geometry - FROM dta - GROUP BY cid - + FOR polyg_world IN + SELECT ST_Transform(country.geometry, 3857) AS geometry + FROM country_osm_grid country + LOOP - -- removing holes smaller than - IF ST_NumInteriorRings(geometry) > 0 THEN -- only from geometries wih holes - geometry := ( - -- there are some multi-geometries in this layer - SELECT ST_Collect(gn) - FROM ( - -- in some cases are "holes" NULL, because all holes are smaller than - SELECT COALESCE( - -- exterior ring - ST_MakePolygon(ST_ExteriorRing(dmp.geom), holes), - ST_MakePolygon(ST_ExteriorRing(dmp.geom)) - ) gn + FOR osm_id, geometry IN + WITH dta AS ( -- CTE is used because of optimization + SELECT o.osm_id, + o.geometry, + ST_ClusterDBSCAN(o.geometry, eps := zres14, minpoints := 1) OVER () cid + FROM osm_building_polygon o + WHERE ST_Intersects(o.geometry, polyg_world.geometry) + ) + SELECT (array_agg(dta.osm_id))[1] AS osm_id, + ST_Buffer( + ST_Union( + ST_Buffer( + ST_SnapToGrid(dta.geometry, 0.000001) + , zres14, 'join=mitre') + ) + , -zres14, 'join=mitre') AS geometry + FROM dta + GROUP BY cid - FROM ST_Dump(geometry) dmp, -- 1 dump polygons - LATERAL ( - SELECT array_agg(ST_Boundary(rg.geom)) holes -- 2 create array - FROM ST_DumpRings(dmp.geom) rg -- 3 from rings - WHERE rg.path[1] > 0 -- 5 except inner ring - AND ST_Area(rg.geom) >= power(zres12, 2) -- 4 bigger than - ) holes - ) new_geom - ); - END IF; + LOOP + -- removing holes smaller than + IF ST_NumInteriorRings(geometry) > 0 THEN -- only from geometries wih holes + geometry := ( + -- there are some multi-geometries in this layer + SELECT ST_Collect(gn) + FROM ( + -- in some cases are "holes" NULL, because all holes are smaller than + SELECT COALESCE( + -- exterior ring + ST_MakePolygon(ST_ExteriorRing(dmp.geom), holes), + ST_MakePolygon(ST_ExteriorRing(dmp.geom)) + ) gn - IF ST_Area(geometry) < power(zres12, 2) THEN - CONTINUE; - END IF; + FROM ST_Dump(geometry) dmp, -- 1 dump polygons + LATERAL ( + SELECT array_agg(ST_Boundary(rg.geom)) holes -- 2 create array + FROM ST_DumpRings(dmp.geom) rg -- 3 from rings + WHERE rg.path[1] > 0 -- 5 except inner ring + AND ST_Area(rg.geom) >= power(zres12, 2) -- 4 bigger than + ) holes + ) new_geom + ); + END IF; - -- simplify - geometry := ST_SimplifyPreserveTopology(geometry, zres14::float); + IF ST_Area(geometry) < power(zres12, 2) THEN + CONTINUE; + END IF; - RETURN NEXT; + -- simplify + geometry := ST_SimplifyVW(geometry, zres14vw); + + RETURN NEXT; + END LOOP; END LOOP; END; $$ LANGUAGE plpgsql STABLE @@ -71,15 +89,52 @@ $$ LANGUAGE plpgsql STABLE PARALLEL SAFE; -DROP MATERIALIZED VIEW IF EXISTS osm_building_block_gen1; +DROP MATERIALIZED VIEW IF EXISTS osm_building_block_gen1_dup CASCADE; -CREATE MATERIALIZED VIEW osm_building_block_gen1 AS +CREATE MATERIALIZED VIEW osm_building_block_gen1_dup AS SELECT * FROM osm_building_block_gen1(); -CREATE INDEX ON osm_building_block_gen1 USING gist (geometry); -CREATE UNIQUE INDEX ON osm_building_block_gen1 USING btree (osm_id); +CREATE INDEX ON osm_building_block_gen1_dup USING gist (geometry); +-- etldoc: osm_building_polygon -> osm_building_block_gen_z13 +DROP MATERIALIZED VIEW IF EXISTS osm_building_block_gen_z13; +CREATE MATERIALIZED VIEW osm_building_block_gen_z13 AS +( +WITH + counts AS ( + SELECT count(osm_id) AS counts, + osm_id + FROM osm_building_block_gen1_dup + GROUP BY osm_id + ), + + duplicates AS ( + SELECT counts.osm_id + FROM counts + WHERE counts.counts > 1 + ) + +SELECT osm.osm_id, + ST_Union( + ST_MakeValid(osm.geometry)) AS geometry + FROM osm_building_block_gen1_dup osm, + duplicates + WHERE osm.osm_id = duplicates.osm_id + GROUP BY osm.osm_id + + UNION ALL + + SELECT osm.osm_id, + osm.geometry + FROM osm_building_block_gen1_dup osm, + counts + WHERE counts.counts = 1 + AND osm.osm_id = counts.osm_id +); + +CREATE INDEX ON osm_building_block_gen_z13 USING gist (geometry); +CREATE UNIQUE INDEX ON osm_building_block_gen_z13 USING btree (osm_id); -- Handle updates @@ -106,7 +161,8 @@ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN RAISE LOG 'Refresh buildings block'; - REFRESH MATERIALIZED VIEW osm_building_block_gen1; + REFRESH MATERIALIZED VIEW osm_building_block_gen1_dup; + REFRESH MATERIALIZED VIEW osm_building_block_gen_z13; -- noinspection SqlWithoutWhere DELETE FROM buildings.updates;