diff --git a/layers/transportation/mapping.yaml b/layers/transportation/mapping.yaml index a2513bd4..f6f5a322 100644 --- a/layers/transportation/mapping.yaml +++ b/layers/transportation/mapping.yaml @@ -193,6 +193,14 @@ sac_scale_field: &sac_scale key: sac_scale name: sac_scale type: string +operator_field: &operator + key: operator + name: operator + type: string +informal_field: &informal + key: informal + name: informal + type: string surface_field: &surface key: surface name: surface @@ -249,6 +257,8 @@ tables: - *horse - *mtb_scale - *sac_scale + - *operator + - *informal - *surface - *expressway mapping: diff --git a/layers/transportation/transportation.sql b/layers/transportation/transportation.sql index 3c060888..e68c3774 100644 --- a/layers/transportation/transportation.sql +++ b/layers/transportation/transportation.sql @@ -30,6 +30,7 @@ CREATE OR REPLACE FUNCTION layer_transportation(bbox geometry, zoom_level int) foot text, horse text, mtb_scale text, + official int, surface text ) AS @@ -70,6 +71,14 @@ SELECT osm_id, NULLIF(foot, '') AS foot, NULLIF(horse, '') AS horse, NULLIF(mtb_scale, '') AS mtb_scale, + CASE WHEN highway IN ('path', 'footway', 'cycleway', 'bridleway') + THEN + CASE WHEN informal = 'yes' THEN 0 + WHEN informal = 'no' OR operator != '' THEN 1 + ELSE NULL + END + ELSE NULL + END AS official, NULLIF(surface, '') AS surface FROM ( -- etldoc: osm_transportation_merge_linestring_gen_z4 -> layer_transportation:z4 @@ -99,6 +108,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z4 @@ -132,6 +143,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z5 @@ -165,6 +178,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z6 @@ -198,6 +213,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z7 @@ -231,6 +248,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z8 @@ -264,6 +283,8 @@ FROM ( foot, horse, mtb_scale, + operator, + informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z9 @@ -297,6 +318,8 @@ FROM ( foot, horse, mtb_scale, + operator, + informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z10 @@ -330,6 +353,8 @@ FROM ( foot, horse, mtb_scale, + operator, + informal, NULL AS surface, z_order FROM osm_transportation_merge_linestring_gen_z11 @@ -368,6 +393,8 @@ FROM ( foot, horse, mtb_scale, + hl.operator, + hl.informal, surface_value(COALESCE(NULLIF(surface, ''), tracktype)) AS "surface", hl.z_order FROM osm_highway_linestring hl @@ -420,6 +447,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring_gen_z8 @@ -456,6 +485,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring_gen_z9 @@ -492,6 +523,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring_gen_z10 @@ -527,6 +560,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring_gen_z11 @@ -562,6 +597,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring_gen_z12 @@ -598,6 +635,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_railway_linestring @@ -634,6 +673,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_aerialway_linestring_gen_z12 @@ -668,6 +709,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_aerialway_linestring @@ -701,6 +744,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z4 @@ -734,6 +779,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z5 @@ -767,6 +814,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z6 @@ -800,6 +849,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z7 @@ -833,6 +884,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z8 @@ -866,6 +919,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z9 @@ -899,6 +954,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z10 @@ -932,6 +989,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z11 @@ -965,6 +1024,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring_gen_z12 @@ -999,6 +1060,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_shipway_linestring @@ -1040,6 +1103,8 @@ FROM ( NULL AS foot, NULL AS horse, NULL AS mtb_scale, + NULL AS operator, + NULL AS informal, NULL AS surface, z_order FROM osm_highway_polygon diff --git a/layers/transportation/transportation.yaml b/layers/transportation/transportation.yaml index 4e0caf8e..656f6c3f 100644 --- a/layers/transportation/transportation.yaml +++ b/layers/transportation/transportation.yaml @@ -198,6 +198,10 @@ layer: mtb_scale: description: | Original value of the [`mtb:scale`](http://wiki.openstreetmap.org/wiki/Key:mtb:scale) tag (highways only). + official: + description: | + Whether or not a path or trail is official according to the land manager. + values: [0, 1] surface: description: | Values of [`surface`](https://wiki.openstreetmap.org/wiki/Key:surface) tag devided into 2 groups `paved` (paved, asphalt, cobblestone, concrete, concrete:lanes, concrete:plates, metal, paving_stones, sett, unhewn_cobblestone, wood) and `unpaved` (unpaved, compacted, dirt, earth, fine_gravel, grass, grass_paver, gravel, gravel_turf, ground, ice, mud, pebblestone, salt, sand, snow, woodchips). @@ -207,7 +211,7 @@ layer: datasource: geometry_field: geometry srid: 900913 - query: (SELECT geometry, class, subclass, network, oneway, ramp, brunnel, service, access, toll, expressway, layer, level, indoor, bicycle, foot, horse, mtb_scale, surface FROM layer_transportation(!bbox!, z(!scale_denominator!))) AS t + query: (SELECT geometry, class, subclass, network, oneway, ramp, brunnel, service, access, toll, expressway, layer, level, indoor, bicycle, foot, horse, mtb_scale, official, surface FROM layer_transportation(!bbox!, z(!scale_denominator!))) AS t schema: - ./network_type.sql - ./class.sql diff --git a/layers/transportation/update_transportation_merge.sql b/layers/transportation/update_transportation_merge.sql index 88c4e18f..218935f3 100644 --- a/layers/transportation/update_transportation_merge.sql +++ b/layers/transportation/update_transportation_merge.sql @@ -159,6 +159,8 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11( horse character varying, mtb_scale character varying, sac_scale character varying, + operator character varying, + informal character varying, access text, toll boolean, layer integer @@ -208,8 +210,8 @@ TRUNCATE osm_transportation_merge_linestring_gen_z11_source_ids; -- each group via ST_ClusterDBSCAN INSERT INTO osm_transportation_merge_linestring_gen_z11 (geometry, source_ids, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, - bicycle, foot, horse, mtb_scale, sac_scale, access, toll, - layer) + bicycle, foot, horse, mtb_scale, sac_scale, operator, + informal, access, toll, layer) SELECT (ST_Dump(ST_LineMerge(ST_Union(geometry)))).geom AS geometry, -- We use St_Union instead of St_Collect to ensure no overlapping points exist within the geometries to -- merge. https://postgis.net/docs/ST_Union.html @@ -234,6 +236,8 @@ SELECT (ST_Dump(ST_LineMerge(ST_Union(geometry)))).geom AS geometry, horse, mtb_scale, sac_scale, + operator, + informal, CASE WHEN access IN ('private', 'no') THEN 'no' ELSE NULL::text END AS access, @@ -245,14 +249,14 @@ FROM ( -- https://postgis.net/docs/ST_ClusterDBSCAN.html ST_ClusterDBSCAN(geometry, 0, 1) OVER ( PARTITION BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, bicycle, - foot, horse, mtb_scale, sac_scale, access, toll, layer + foot, horse, mtb_scale, sac_scale, operator, informal, access, toll, layer ) AS cluster, -- ST_ClusterDBSCAN returns an increasing integer as the cluster-ids within each partition starting at 0. -- This leads to clusters having the same ID across multiple partitions therefore we generate a -- Cluster-Group-ID by utilizing the DENSE_RANK function sorted over the partition columns. DENSE_RANK() OVER ( ORDER BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, bicycle, - foot, horse, mtb_scale, sac_scale, access, toll, layer + foot, horse, mtb_scale, sac_scale, operator, informal, access, toll, layer ) as cluster_group FROM ( -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged @@ -271,6 +275,8 @@ FROM ( horse, mtb_scale, sac_scale, + operator, + informal, access, toll, visible_layer(geometry, layer, 11) AS layer @@ -278,7 +284,7 @@ FROM ( ) osm_highway_linestring_normalized_brunnel_z11 ) q GROUP BY cluster_group, cluster, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, - bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer; + bicycle, foot, horse, mtb_scale, sac_scale, operator, informal, access, toll, layer; -- Geometry Index CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_geometry_idx @@ -387,6 +393,8 @@ BEGIN horse, mtb_scale, sac_scale, + operator, + informal, access, toll, visible_layer(geometry, layer, 11) AS layer @@ -406,6 +414,7 @@ BEGIN expressway = excluded.expressway, z_order = excluded.z_order, bicycle = excluded.bicycle, foot = excluded.foot, horse = excluded.horse, mtb_scale = excluded.mtb_scale, sac_scale = excluded.sac_scale, + operator = excluded.operator, informal = excluded.informal, access = excluded.access, toll = excluded.toll, layer = excluded.layer; -- Remove entries which have been deleted from source table @@ -438,6 +447,8 @@ BEGIN horse, mtb_scale, sac_scale, + operator, + informal, access, toll, visible_layer(geometry, layer, 10) AS layer @@ -453,6 +464,7 @@ BEGIN expressway = excluded.expressway, z_order = excluded.z_order, bicycle = excluded.bicycle, foot = excluded.foot, horse = excluded.horse, mtb_scale = excluded.mtb_scale, sac_scale = excluded.sac_scale, + operator = excluded.operator, informal = excluded.informal, access = excluded.access, toll = excluded.toll, layer = excluded.layer; -- noinspection SqlWithoutWhere @@ -1061,7 +1073,7 @@ BEGIN visible_brunnel(geometry, is_bridge, 11) AS is_bridge, visible_brunnel(geometry, is_tunnel, 11) AS is_tunnel, visible_brunnel(geometry, is_ford, 11) AS is_ford, - expressway, bicycle, foot, horse, mtb_scale, sac_scale, + expressway, bicycle, foot, horse, mtb_scale, sac_scale, operator, informal, CASE WHEN access IN ('private', 'no') THEN 'no' ELSE NULL::text END AS access, toll, visible_layer(geometry, layer, 11) AS layer, z_order -- Table containing the IDs of all Source-LineStrings affected by this update @@ -1092,7 +1104,8 @@ BEGIN visible_brunnel(m.geometry, m.is_bridge, 11) AS is_bridge, visible_brunnel(m.geometry, m.is_tunnel, 11) AS is_tunnel, visible_brunnel(m.geometry, m.is_ford, 11) AS is_ford, - m.expressway, m.bicycle, m.foot, m.horse, m.mtb_scale, m.sac_scale, m.access, m.toll, + m.expressway, m.bicycle, m.foot, m.horse, m.mtb_scale, m.sac_scale, + m.operator, m.informal, m.access, m.toll, visible_layer(m.geometry, m.layer, 11) AS layer, m.z_order FROM linestrings_to_merge JOIN osm_transportation_merge_linestring_gen_z11 m ON (ST_Intersects(linestrings_to_merge.geometry, m.geometry)); @@ -1120,14 +1133,14 @@ BEGIN -- https://postgis.net/docs/ST_ClusterDBSCAN.html ST_ClusterDBSCAN(geometry, 0, 1) OVER ( PARTITION BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, bicycle, foot, - horse, mtb_scale, sac_scale, access, toll, layer + horse, mtb_scale, sac_scale, operator, informal, access, toll, layer ) AS cluster, -- ST_ClusterDBSCAN returns an increasing integer as the cluster-ids within each partition starting at 0. -- This leads to clusters having the same ID across multiple partitions therefore we generate a -- Cluster-Group-ID by utilizing the DENSE_RANK function sorted over the partition columns. DENSE_RANK() OVER ( ORDER BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, bicycle, foot, horse, - mtb_scale, sac_scale, access, toll, layer + mtb_scale, sac_scale, operator, informal, access, toll, layer ) as cluster_group FROM linestrings_to_merge; @@ -1143,7 +1156,7 @@ BEGIN INSERT INTO osm_transportation_merge_linestring_gen_z11(geometry, new_source_ids, old_source_ids, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, bicycle, foot, horse, mtb_scale, - sac_scale, access, toll, layer) + sac_scale, operator, informal, access, toll, layer) SELECT (ST_Dump(ST_LineMerge(ST_Union(geometry)))).geom AS geometry, -- We use St_Union instead of St_Collect to ensure no overlapping points exist within the geometries to -- merge. https://postgis.net/docs/ST_Union.html @@ -1167,12 +1180,14 @@ BEGIN horse, mtb_scale, sac_scale, + operator, + informal, access, toll, layer FROM clustered_linestrings_to_merge GROUP BY cluster_group, cluster, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, - bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer + bicycle, foot, horse, mtb_scale, sac_scale, operator, informal, access, toll, layer RETURNING id, new_source_ids, old_source_ids, geometry ) -- Store OSM-IDs of Source-LineStrings by intersecting Merged-LineStrings with their sources.