diff --git a/layers/water/etl_diagram.png b/layers/water/etl_diagram.png index ffcc395..1ba8125 100644 Binary files a/layers/water/etl_diagram.png and b/layers/water/etl_diagram.png differ diff --git a/layers/water/update_water.sql b/layers/water/update_water.sql index 9094fc5..1f3f387 100644 --- a/layers/water/update_water.sql +++ b/layers/water/update_water.sql @@ -1,3 +1,27 @@ +-- Recreate ocean layer by union regular squares into larger polygons +-- etldoc: osm_ocean_polygon -> osm_ocean_polygon_union +CREATE TABLE IF NOT EXISTS osm_ocean_polygon_union AS + ( + SELECT (ST_Dump(ST_Union(ST_MakeValid(geometry)))).geom::geometry(Polygon, 3857) AS geometry + FROM osm_ocean_polygon + --for union select just full square (not big triangles) + WHERE ST_Area(geometry) > 100000000 AND + ST_NPoints(geometry) = 5 + UNION ALL + SELECT geometry + FROM osm_ocean_polygon + -- as 321 records have less then 5 coordinates (triangle) + -- bigger then 5 coordinates have squares with holes from island and coastline + WHERE ST_NPoints(geometry) <> 5 + ); + +CREATE INDEX IF NOT EXISTS osm_ocean_polygon_union_geom_idx + ON osm_ocean_polygon_union + USING GIST (geometry); + +--Drop data from original table but keep table as `CREATE TABLE IF NOT EXISTS` still test if query is valid +TRUNCATE TABLE osm_ocean_polygon; + -- This statement can be deleted after the water importer image stops creating this object as a table DO $$ @@ -8,12 +32,12 @@ $$ END; $$ LANGUAGE plpgsql; --- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen1 +-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen1 DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen1 CASCADE; CREATE MATERIALIZED VIEW osm_ocean_polygon_gen1 AS ( SELECT ST_Simplify(geometry, 20) AS geometry -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen1_idx ON osm_ocean_polygon_gen1 USING gist (geometry); @@ -28,12 +52,12 @@ $$ END; $$ LANGUAGE plpgsql; --- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen2 +-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen2 DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen2 CASCADE; CREATE MATERIALIZED VIEW osm_ocean_polygon_gen2 AS ( SELECT ST_Simplify(geometry, 40) AS geometry -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen2_idx ON osm_ocean_polygon_gen2 USING gist (geometry); @@ -48,12 +72,12 @@ $$ END; $$ LANGUAGE plpgsql; --- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen3 +-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen3 DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen3 CASCADE; CREATE MATERIALIZED VIEW osm_ocean_polygon_gen3 AS ( SELECT ST_Simplify(geometry, 80) AS geometry -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen3_idx ON osm_ocean_polygon_gen3 USING gist (geometry); @@ -68,11 +92,11 @@ $$ END; $$ LANGUAGE plpgsql; --- etldoc: osm_ocean_polygon -> osm_ocean_polygon_gen4 +-- etldoc: osm_ocean_polygon_union -> osm_ocean_polygon_gen4 DROP MATERIALIZED VIEW IF EXISTS osm_ocean_polygon_gen4 CASCADE; CREATE MATERIALIZED VIEW osm_ocean_polygon_gen4 AS ( SELECT ST_Simplify(geometry, 160) AS geometry -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union ) /* DELAY_MATERIALIZED_VIEW_CREATION */ ; CREATE INDEX IF NOT EXISTS osm_ocean_polygon_gen4_idx ON osm_ocean_polygon_gen4 USING gist (geometry); diff --git a/layers/water/water.sql b/layers/water/water.sql index b5f9166..da2d51f 100644 --- a/layers/water/water.sql +++ b/layers/water/water.sql @@ -237,13 +237,13 @@ WHERE "natural" != 'bay' CREATE OR REPLACE VIEW water_z12 AS ( --- etldoc: osm_ocean_polygon_gen1 -> water_z12 +-- etldoc: osm_ocean_polygon_union -> water_z12 SELECT geometry, 'ocean'::text AS class, NULL::boolean AS is_intermittent, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union UNION ALL -- etldoc: osm_water_polygon -> water_z12 SELECT geometry, @@ -257,13 +257,13 @@ WHERE "natural" != 'bay' CREATE OR REPLACE VIEW water_z13 AS ( --- etldoc: osm_ocean_polygon -> water_z13 +-- etldoc: osm_ocean_polygon_union -> water_z13 SELECT geometry, 'ocean'::text AS class, NULL::boolean AS is_intermittent, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union UNION ALL -- etldoc: osm_water_polygon -> water_z13 SELECT geometry, @@ -277,13 +277,13 @@ WHERE "natural" != 'bay' CREATE OR REPLACE VIEW water_z14 AS ( --- etldoc: osm_ocean_polygon -> water_z14 +-- etldoc: osm_ocean_polygon_union -> water_z14 SELECT geometry, 'ocean'::text AS class, NULL::boolean AS is_intermittent, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel -FROM osm_ocean_polygon +FROM osm_ocean_polygon_union UNION ALL -- etldoc: osm_water_polygon -> water_z14 SELECT geometry,