diff --git a/layers/landcover/etl_diagram.png b/layers/landcover/etl_diagram.png index 8fb941a7..ee164fd0 100644 Binary files a/layers/landcover/etl_diagram.png and b/layers/landcover/etl_diagram.png differ diff --git a/layers/landcover/generalized.sql b/layers/landcover/generalized.sql new file mode 100644 index 00000000..373da467 --- /dev/null +++ b/layers/landcover/generalized.sql @@ -0,0 +1,277 @@ +DROP TABLE IF EXISTS osm_landcover_gen_z7; +DROP TABLE IF EXISTS osm_landcover_gen_z8; +DROP TABLE IF EXISTS osm_landcover_gen_z9; +DROP TABLE IF EXISTS osm_landcover_gen_z10; +DROP TABLE IF EXISTS osm_landcover_gen_z11; +DROP TABLE IF EXISTS osm_landcover_gen_z12; +DROP TABLE IF EXISTS osm_landcover_gen_z13; + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z7 +CREATE TABLE osm_landcover_gen_z7 AS +( + WITH simplify_vw_z7 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(7)*zres(7))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(5),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_Dump( + ST_Union(geometry))).geom) AS geometry + FROM + ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) OVER () AS cid, + geometry + FROM simplify_vw_z7 + ) union_geom +GROUP BY subclass, + cid + ); + +CREATE INDEX ON osm_landcover_gen_z7 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z8 +CREATE TABLE osm_landcover_gen_z8 AS +( + WITH simplify_vw_z8 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(8)*zres(8))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(6),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_Dump( + ST_Union(geometry))).geom) AS geometry + FROM + ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) OVER () AS cid, + geometry + FROM simplify_vw_z8 + ) union_geom +GROUP BY subclass, + cid + ); + +CREATE INDEX ON osm_landcover_gen_z8 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z9 +CREATE TABLE osm_landcover_gen_z9 AS +( + WITH simplify_vw_z9 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(9)*zres(9))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(7),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z9 + WHERE ST_NPoints(geometry) < 50) union_geom50 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, st_makevalid((ST_dump(ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z9 + WHERE ST_NPoints(geometry) >= 50 AND ST_NPoints(geometry) < 300) union_geom300 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, + ST_MakeValid( + (ST_Dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z9 + WHERE ST_NPoints(geometry) >= 300) union_geom_rest + GROUP BY subclass, + cid + ); + +CREATE INDEX ON osm_landcover_gen_z9 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z10 +CREATE TABLE osm_landcover_gen_z10 AS +( + WITH simplify_vw_z10 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(10)*zres(10))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(8),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z10 + WHERE ST_NPoints(geometry) < 50) union_geom50 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, st_makevalid((ST_dump(ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z10 + WHERE ST_NPoints(geometry) >= 50 AND ST_NPoints(geometry) < 300) union_geom300 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, + geometry + FROM simplify_vw_z10 + WHERE ST_NPoints(geometry) >= 300 + ); + +CREATE INDEX ON osm_landcover_gen_z10 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z11 +CREATE TABLE osm_landcover_gen_z11 AS +( + WITH simplify_vw_z11 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(11)*zres(11))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(8),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z11 + WHERE ST_NPoints(geometry) < 50) union_geom50 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, st_makevalid((ST_dump(ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z11 + WHERE ST_NPoints(geometry) >= 50 AND ST_NPoints(geometry) < 300) union_geom300 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, + geometry + FROM simplify_vw_z11 + WHERE ST_NPoints(geometry) >= 300 + ); + +CREATE INDEX ON osm_landcover_gen_z11 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z12 +CREATE TABLE osm_landcover_gen_z12 AS +( + WITH simplify_vw_z12 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(12)*zres(12))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(9),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z12 + WHERE ST_NPoints(geometry) < 50) union_geom50 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, st_makevalid((ST_dump(ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z12 + WHERE ST_NPoints(geometry) >= 50 AND ST_NPoints(geometry) < 300) union_geom300 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, + geometry + FROM simplify_vw_z12 + WHERE ST_NPoints(geometry) >= 300 + ); + +CREATE INDEX ON osm_landcover_gen_z12 USING GIST (geometry); + +-- etldoc: osm_landcover_polygon -> osm_landcover_gen_z13 +CREATE TABLE osm_landcover_gen_z13 AS +( + WITH simplify_vw_z13 AS + ( + SELECT subclass, + ST_MakeValid( + ST_SimplifyVW(geometry, zres(13)*zres(13))) AS geometry + FROM osm_landcover_polygon + WHERE ST_Area(geometry) > power(zres(10),2) + ) + +SELECT subclass, + ST_MakeValid( + (ST_dump( + ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z13 + WHERE ST_NPoints(geometry) < 50) union_geom50 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, st_makevalid((ST_dump(ST_Union(geometry))).geom) AS geometry + FROM ( + SELECT subclass, + ST_ClusterDBSCAN(geometry, eps := 0, minpoints := 1) over () AS cid, geometry + FROM simplify_vw_z13 + WHERE ST_NPoints(geometry) >= 50 AND ST_NPoints(geometry) < 300) union_geom300 + GROUP BY subclass, + cid + UNION ALL + SELECT subclass, + geometry + FROM simplify_vw_z13 + WHERE ST_NPoints(geometry) >= 300 + ); + +CREATE INDEX ON osm_landcover_gen_z13 USING GIST (geometry); \ No newline at end of file diff --git a/layers/landcover/landcover.sql b/layers/landcover/landcover.sql index 35e4d59b..75e5d2aa 100644 --- a/layers/landcover/landcover.sql +++ b/layers/landcover/landcover.sql @@ -21,168 +21,121 @@ $$ LANGUAGE SQL IMMUTABLE -- etldoc: ne_110m_glaciated_areas -> landcover_z0 CREATE OR REPLACE VIEW landcover_z0 AS ( -SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass +SELECT geometry, 'glacier'::text AS subclass FROM ne_110m_glaciated_areas ); CREATE OR REPLACE VIEW landcover_z2 AS ( -- etldoc: ne_50m_glaciated_areas -> landcover_z2 -SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass +SELECT geometry, 'glacier'::text AS subclass FROM ne_50m_glaciated_areas UNION ALL -- etldoc: ne_50m_antarctic_ice_shelves_polys -> landcover_z2 -SELECT NULL::bigint AS osm_id, geometry, 'ice_shelf'::text AS subclass +SELECT geometry, 'ice_shelf'::text AS subclass FROM ne_50m_antarctic_ice_shelves_polys ); CREATE OR REPLACE VIEW landcover_z5 AS ( -- etldoc: ne_10m_glaciated_areas -> landcover_z5 -SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass +SELECT geometry, 'glacier'::text AS subclass FROM ne_10m_glaciated_areas UNION ALL -- etldoc: ne_10m_antarctic_ice_shelves_polys -> landcover_z5 -SELECT NULL::bigint AS osm_id, geometry, 'ice_shelf'::text AS subclass +SELECT geometry, 'ice_shelf'::text AS subclass FROM ne_10m_antarctic_ice_shelves_polys ); -CREATE OR REPLACE VIEW landcover_z7 AS -( --- etldoc: osm_landcover_polygon_gen7 -> landcover_z7 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen7 - ); - -CREATE OR REPLACE VIEW landcover_z8 AS -( --- etldoc: osm_landcover_polygon_gen6 -> landcover_z8 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen6 - ); - -CREATE OR REPLACE VIEW landcover_z9 AS -( --- etldoc: osm_landcover_polygon_gen5 -> landcover_z9 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen5 - ); - -CREATE OR REPLACE VIEW landcover_z10 AS -( --- etldoc: osm_landcover_polygon_gen4 -> landcover_z10 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen4 - ); - -CREATE OR REPLACE VIEW landcover_z11 AS -( --- etldoc: osm_landcover_polygon_gen3 -> landcover_z11 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen3 - ); - -CREATE OR REPLACE VIEW landcover_z12 AS -( --- etldoc: osm_landcover_polygon_gen2 -> landcover_z12 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen2 - ); - -CREATE OR REPLACE VIEW landcover_z13 AS -( --- etldoc: osm_landcover_polygon_gen1 -> landcover_z13 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon_gen1 - ); - -CREATE OR REPLACE VIEW landcover_z14 AS -( --- etldoc: osm_landcover_polygon -> landcover_z14 -SELECT osm_id, geometry, subclass -FROM osm_landcover_polygon - ); - -- etldoc: layer_landcover[shape=record fillcolor=lightpink, style="rounded, filled", label="layer_landcover | z0-z1 | z2-z4 | z5-z6 | z7 | z8 | z9 | z10 | z11 | z12| z13| z14+" ] ; CREATE OR REPLACE FUNCTION layer_landcover(bbox geometry, zoom_level int) RETURNS TABLE ( - osm_id bigint, geometry geometry, class text, subclass text ) AS $$ -SELECT osm_id, - geometry, +SELECT geometry, landcover_class(subclass) AS class, subclass FROM ( -- etldoc: landcover_z0 -> layer_landcover:z0_1 - SELECT * + SELECT geometry, + subclass FROM landcover_z0 WHERE zoom_level BETWEEN 0 AND 1 AND geometry && bbox UNION ALL -- etldoc: landcover_z2 -> layer_landcover:z2_4 - SELECT * + SELECT geometry, + subclass FROM landcover_z2 WHERE zoom_level BETWEEN 2 AND 4 AND geometry && bbox UNION ALL -- etldoc: landcover_z5 -> layer_landcover:z5_6 - SELECT * + SELECT geometry, + subclass FROM landcover_z5 WHERE zoom_level BETWEEN 5 AND 6 AND geometry && bbox UNION ALL - -- etldoc: landcover_z7 -> layer_landcover:z7 - SELECT * - FROM landcover_z7 + -- etldoc: osm_landcover_gen_z7 -> layer_landcover:z7 + SELECT geometry, + subclass + FROM osm_landcover_gen_z7 WHERE zoom_level = 7 AND geometry && bbox UNION ALL - -- etldoc: landcover_z8 -> layer_landcover:z8 - SELECT * - FROM landcover_z8 + -- etldoc: osm_landcover_gen_z8 -> layer_landcover:z8 + SELECT geometry, + subclass + FROM osm_landcover_gen_z8 WHERE zoom_level = 8 AND geometry && bbox UNION ALL - -- etldoc: landcover_z9 -> layer_landcover:z9 - SELECT * - FROM landcover_z9 + -- etldoc: osm_landcover_gen_z9 -> layer_landcover:z9 + SELECT geometry, + subclass + FROM osm_landcover_gen_z9 WHERE zoom_level = 9 AND geometry && bbox UNION ALL - -- etldoc: landcover_z10 -> layer_landcover:z10 - SELECT * - FROM landcover_z10 + -- etldoc: osm_landcover_gen_z10 -> layer_landcover:z10 + SELECT geometry, + subclass + FROM osm_landcover_gen_z10 WHERE zoom_level = 10 AND geometry && bbox UNION ALL - -- etldoc: landcover_z11 -> layer_landcover:z11 - SELECT * - FROM landcover_z11 + -- etldoc: osm_landcover_gen_z11 -> layer_landcover:z11 + SELECT geometry, + subclass + FROM osm_landcover_gen_z11 WHERE zoom_level = 11 AND geometry && bbox UNION ALL - -- etldoc: landcover_z12 -> layer_landcover:z12 - SELECT * - FROM landcover_z12 + -- etldoc: osm_landcover_gen_z12 -> layer_landcover:z12 + SELECT geometry, + subclass + FROM osm_landcover_gen_z12 WHERE zoom_level = 12 AND geometry && bbox UNION ALL - -- etldoc: landcover_z13 -> layer_landcover:z13 - SELECT * - FROM landcover_z13 + -- etldoc: osm_landcover_gen_z13 -> layer_landcover:z13 + SELECT geometry, + subclass + FROM osm_landcover_gen_z13 WHERE zoom_level = 13 AND geometry && bbox UNION ALL - -- etldoc: landcover_z14 -> layer_landcover:z14_ - SELECT * - FROM landcover_z14 + -- etldoc: osm_landcover_polygon -> layer_landcover:z14_ + SELECT geometry, + subclass + FROM osm_landcover_polygon WHERE zoom_level >= 14 AND geometry && bbox ) AS zoom_levels; diff --git a/layers/landcover/landcover.yaml b/layers/landcover/landcover.yaml index 6d51fe4f..56536d05 100644 --- a/layers/landcover/landcover.yaml +++ b/layers/landcover/landcover.yaml @@ -73,6 +73,7 @@ layer: geometry_field: geometry query: (SELECT geometry, class, subclass FROM layer_landcover(!bbox!, z(!scale_denominator!))) AS t schema: + - ./generalized.sql - ./landcover.sql datasources: - type: imposm3 diff --git a/layers/landcover/mapping.yaml b/layers/landcover/mapping.yaml index 142f3dd5..c0f06679 100644 --- a/layers/landcover/mapping.yaml +++ b/layers/landcover/mapping.yaml @@ -1,54 +1,7 @@ - -generalized_tables: - - # etldoc: imposm3 -> osm_landcover_polygon_gen7 - landcover_polygon_gen7: - source: landcover_polygon_gen6 - sql_filter: area>power(ZRES5,2) - tolerance: ZRES7 - - # etldoc: imposm3 -> osm_landcover_polygon_gen6 - landcover_polygon_gen6: - source: landcover_polygon_gen5 - sql_filter: area>power(ZRES6,2) - tolerance: ZRES8 - - # etldoc: imposm3 -> osm_landcover_polygon_gen5 - landcover_polygon_gen5: - source: landcover_polygon_gen4 - sql_filter: area>power(ZRES7,2) - tolerance: ZRES9 - - # etldoc: imposm3 -> osm_landcover_polygon_gen4 - landcover_polygon_gen4: - source: landcover_polygon_gen3 - sql_filter: area>power(ZRES8,2) - tolerance: ZRES10 - - # etldoc: imposm3 -> osm_landcover_polygon_gen3 - landcover_polygon_gen3: - source: landcover_polygon_gen2 - sql_filter: area>power(ZRES8,2) - tolerance: ZRES11 - - # etldoc: imposm3 -> osm_landcover_polygon_gen2 - landcover_polygon_gen2: - source: landcover_polygon_gen1 - sql_filter: area>power(ZRES9,2) - tolerance: ZRES12 - - # etldoc: imposm3 -> osm_landcover_polygon_gen1 - landcover_polygon_gen1: - source: landcover_polygon - sql_filter: area>power(ZRES10,2) AND ST_IsValid(geometry) - tolerance: ZRES13 - tables: # etldoc: imposm3 -> osm_landcover_polygon landcover_polygon: columns: - - name: osm_id - type: id - name: geometry type: validated_geometry - name: area