diff --git a/layers/landcover/landcover.sql b/layers/landcover/landcover.sql index f157047e..722691c5 100644 --- a/layers/landcover/landcover.sql +++ b/layers/landcover/landcover.sql @@ -9,82 +9,80 @@ --); --CREATE INDEX IF NOT EXISTS landcover_grouped_gen2_geometry_idx ON landcover_grouped_gen2 USING gist(geometry); -CREATE OR REPLACE FUNCTION landcover_class(landuse VARCHAR, "natural" VARCHAR, leisure VARCHAR, wetland VARCHAR) RETURNS TEXT AS $$ +CREATE OR REPLACE FUNCTION landcover_class(subclass VARCHAR) RETURNS TEXT AS $$ SELECT CASE - WHEN landuse IN ('farmland', 'farm', 'orchard', 'vineyard', 'plant_nursery') THEN 'farmland' - WHEN "natural" IN ('glacier', 'ice_shelf') THEN 'ice' - WHEN "natural"='wood' OR landuse IN ('forest') THEN 'wood' - WHEN "natural" IN ('bare_rock', 'scree') THEN 'rock' - WHEN "natural"='grassland' - OR landuse IN ('grass', 'meadow', 'allotments', 'grassland', - 'park', 'village_green', 'recreation_ground') - OR leisure IN ('park', 'garden') - THEN 'grass' - WHEN "natural"='wetland' OR wetland IN ('bog', 'swamp', 'wet_meadow', 'marsh', 'reedbed', 'saltern', 'tidalflat', 'saltmarsh', 'mangrove') THEN 'wetland' - WHEN "natural"IN ('beach', 'sand') THEN 'sand' + WHEN subclass IN ('farmland', 'farm', 'orchard', 'vineyard', 'plant_nursery') THEN 'farmland' + WHEN subclass IN ('glacier', 'ice_shelf') THEN 'ice' + WHEN subclass IN ('wood', 'forest') THEN 'wood' + WHEN subclass IN ('bare_rock', 'scree') THEN 'rock' + WHEN subclass IN ('grassland', 'grass', 'meadow', 'allotments', 'grassland', + 'park', 'village_green', 'recreation_ground', 'park', 'garden') THEN 'grass' + WHEN subclass IN ('wetland', 'bog', 'swamp', 'wet_meadow', 'marsh', 'reedbed', + 'saltern', 'tidalflat', 'saltmarsh', 'mangrove') THEN 'wetland' + WHEN subclass IN ('beach', 'sand') THEN 'sand' ELSE NULL END; $$ LANGUAGE SQL IMMUTABLE; -- etldoc: ne_110m_glaciated_areas -> landcover_z0 CREATE OR REPLACE VIEW landcover_z0 AS ( - SELECT NULL::bigint AS osm_id, geometry, NULL::text AS landuse, 'glacier'::text AS "natural", NULL::text AS leisure, NULL::text AS wetland FROM ne_110m_glaciated_areas + SELECT NULL::bigint AS osm_id, 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, NULL::text AS landuse, 'glacier'::text AS "natural", NULL::text AS leisure, NULL::text AS wetland FROM ne_50m_glaciated_areas + SELECT NULL::bigint AS osm_id, 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, NULL::text AS landuse, 'ice_shelf'::text AS "natural", NULL::text AS leisure, NULL::text AS wetland FROM ne_50m_antarctic_ice_shelves_polys + SELECT NULL::bigint AS osm_id, 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, NULL::text AS landuse, 'glacier'::text AS "natural", NULL::text AS leisure, NULL::text AS wetland FROM ne_10m_glaciated_areas + SELECT NULL::bigint AS osm_id, 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, NULL::text AS landuse, 'ice_shelf'::text AS "natural", NULL::text AS leisure, NULL::text AS wetland FROM ne_10m_antarctic_ice_shelves_polys + SELECT NULL::bigint AS osm_id, 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen7 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen6 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen5 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen4 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen3 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen2 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon_gen1 + 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, landuse, "natural", leisure, wetland FROM osm_landcover_polygon + 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+" ] ; @@ -92,11 +90,8 @@ CREATE OR REPLACE VIEW landcover_z14 AS ( 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, - landcover_class(landuse, "natural", leisure, wetland) AS class, - COALESCE( - NULLIF("natural", ''), NULLIF(landuse, ''), - NULLIF(leisure, ''), NULLIF(wetland, '') - ) AS subclass + landcover_class(subclass) AS class, + subclass FROM ( -- etldoc: landcover_z0 -> layer_landcover:z0_1 SELECT * FROM landcover_z0 diff --git a/layers/landcover/mapping.yaml b/layers/landcover/mapping.yaml index 90e73728..2edb1d38 100644 --- a/layers/landcover/mapping.yaml +++ b/layers/landcover/mapping.yaml @@ -51,22 +51,14 @@ tables: type: id - name: geometry type: validated_geometry - - name: landuse - key: landuse - type: string - - name: leisure - key: leisure - type: string - - name: natural - key: natural - type: string - - name: wetland - key: wetland - type: string - name: area type: area - name: webmerc_area type: webmerc_area + - name: subclass + type: mapping_value + - name: mapping_key + type: mapping_key mapping: landuse: - allotments