diff --git a/layers/transportation/etl_diagram.png b/layers/transportation/etl_diagram.png index a8069b3..0e497b3 100644 Binary files a/layers/transportation/etl_diagram.png and b/layers/transportation/etl_diagram.png differ diff --git a/layers/transportation/update_route_member.sql b/layers/transportation/update_route_member.sql index 2e0e619..5f453ae 100644 --- a/layers/transportation/update_route_member.sql +++ b/layers/transportation/update_route_member.sql @@ -77,6 +77,9 @@ CREATE INDEX IF NOT EXISTS osm_route_member_ref_idx ON osm_route_member ("ref"); CREATE INDEX IF NOT EXISTS osm_route_member_network_type_idx ON osm_route_member ("network_type"); +CREATE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id"); +CREATE INDEX IF NOT EXISTS osm_highway_linestring_gen_z11_osm_id_idx ON osm_highway_linestring_gen_z11 ("osm_id"); + ALTER TABLE osm_route_member ADD COLUMN IF NOT EXISTS concurrency_index int; INSERT INTO osm_route_member (id, concurrency_index) diff --git a/layers/transportation/update_transportation_merge.sql b/layers/transportation/update_transportation_merge.sql index e92be0e..8e92b4e 100644 --- a/layers/transportation/update_transportation_merge.sql +++ b/layers/transportation/update_transportation_merge.sql @@ -7,16 +7,16 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation.updates; -- Because this works well for roads that do not have relations as well --- Improve performance of the sql in transportation_name/network_type.sql +-- Improve performance of the sql in transportation/update_route_member.sql CREATE INDEX IF NOT EXISTS osm_highway_linestring_highway_partial_idx ON osm_highway_linestring (highway) - WHERE highway IN ('motorway', 'trunk', 'primary', 'construction'); + WHERE highway IN ('motorway', 'trunk'); -- etldoc: osm_highway_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z11 DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z11 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z11 AS ( -SELECT (ST_Dump(geometry)).geom AS geometry, +SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry, NULL::bigint AS osm_id, highway, network, @@ -24,36 +24,20 @@ SELECT (ST_Dump(geometry)).geom AS geometry, is_bridge, is_tunnel, is_ford, - z_order, + min(z_order) as z_order, bicycle, foot, horse, mtb_scale, layer -FROM ( - SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry, - highway, - network, - construction, - is_bridge, - is_tunnel, - is_ford, - min(z_order) AS z_order, - bicycle, - foot, - horse, - mtb_scale, - layer - FROM osm_highway_linestring_gen_z11 - WHERE ST_IsValid(geometry) - GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, bicycle, foot, horse, mtb_scale, layer - ) AS highway_union +FROM osm_highway_linestring_gen_z11 +-- mapping.yaml pre-filter: motorway/trunk/primary/secondary/tertiary, with _link variants, construction, ST_IsValid() +GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, bicycle, foot, horse, mtb_scale, layer ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_geometry_idx ON osm_transportation_merge_linestring_gen_z11 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z10 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z10 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z10 AS ( SELECT ST_Simplify(geometry, ZRes(12)) AS geometry, @@ -72,13 +56,12 @@ SELECT ST_Simplify(geometry, ZRes(12)) AS geometry, layer FROM osm_transportation_merge_linestring_gen_z11 WHERE highway NOT IN ('tertiary', 'tertiary_link') - OR highway = 'construction' AND construction NOT IN ('tertiary', 'tertiary_link') + OR construction NOT IN ('tertiary', 'tertiary_link') ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z10_geometry_idx ON osm_transportation_merge_linestring_gen_z10 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z10 -> osm_transportation_merge_linestring_gen_z9 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z9 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z9 AS ( SELECT ST_Simplify(geometry, ZRes(11)) AS geometry, @@ -96,17 +79,15 @@ SELECT ST_Simplify(geometry, ZRes(11)) AS geometry, mtb_scale, layer FROM osm_transportation_merge_linestring_gen_z10 -WHERE highway NOT IN ('tertiary', 'tertiary_link') - OR highway = 'construction' AND construction NOT IN ('tertiary', 'tertiary_link') + -- Current view: motorway/primary/secondary, with _link variants and construction ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z9_geometry_idx ON osm_transportation_merge_linestring_gen_z9 USING gist (geometry); --- etldoc: osm_highway_linestring -> osm_transportation_merge_linestring_gen_z8 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z8 CASCADE; +-- etldoc: osm_transportation_merge_linestring_gen_z9 -> osm_transportation_merge_linestring_gen_z8 CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z8 AS ( -SELECT ST_Simplify((ST_Dump(geometry)).geom, ZRes(10)) AS geometry, +SELECT ST_Simplify(ST_LineMerge(ST_Collect(geometry)), ZRes(10)) AS geometry, NULL::bigint AS osm_id, highway, network, @@ -114,28 +95,17 @@ SELECT ST_Simplify((ST_Dump(geometry)).geom, ZRes(10)) AS geometry, is_bridge, is_tunnel, is_ford, - z_order -FROM ( - SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry, - highway, - network, - construction, - is_bridge, - is_tunnel, - is_ford, - min(z_order) AS z_order - FROM osm_highway_linestring - WHERE (highway IN ('motorway', 'trunk', 'primary') OR - highway = 'construction' AND construction IN ('motorway', 'trunk', 'primary')) - AND ST_IsValid(geometry) - GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford - ) AS highway_union + min(z_order) as z_order +FROM osm_transportation_merge_linestring_gen_z9 +WHERE (highway IN ('motorway', 'trunk', 'primary') OR + construction IN ('motorway', 'trunk', 'primary')) + AND ST_IsValid(geometry) +GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_geometry_idx ON osm_transportation_merge_linestring_gen_z8 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z7 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z7 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z7 AS ( SELECT ST_Simplify(geometry, ZRes(9)) AS geometry, @@ -155,7 +125,6 @@ CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_geometry_i ON osm_transportation_merge_linestring_gen_z7 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z7 -> osm_transportation_merge_linestring_gen_z6 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z6 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z6 AS ( SELECT ST_Simplify(geometry, ZRes(8)) AS geometry, @@ -168,14 +137,13 @@ SELECT ST_Simplify(geometry, ZRes(8)) AS geometry, is_ford, z_order FROM osm_transportation_merge_linestring_gen_z7 -WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk')) +WHERE (highway IN ('motorway', 'trunk') OR construction IN ('motorway', 'trunk')) AND ST_Length(geometry) > 100 ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z6_geometry_idx ON osm_transportation_merge_linestring_gen_z6 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z6 -> osm_transportation_merge_linestring_gen_z5 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z5 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z5 AS ( SELECT ST_Simplify(geometry, ZRes(7)) AS geometry, @@ -195,7 +163,6 @@ CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_geometry_i ON osm_transportation_merge_linestring_gen_z5 USING gist (geometry); -- etldoc: osm_transportation_merge_linestring_gen_z5 -> osm_transportation_merge_linestring_gen_z4 -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z4 CASCADE; CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z4 AS ( SELECT ST_Simplify(geometry, ZRes(6)) AS geometry, @@ -208,7 +175,7 @@ SELECT ST_Simplify(geometry, ZRes(6)) AS geometry, is_ford, z_order FROM osm_transportation_merge_linestring_gen_z5 -WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway') +WHERE (highway = 'motorway' OR construction = 'motorway') AND ST_Length(geometry) > 1000 ) /* DELAY_MATERIALIZED_VIEW_CREATION */; CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z4_geometry_idx @@ -239,6 +206,9 @@ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN RAISE LOG 'Refresh transportation'; + REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z11; + REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z10; + REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z9; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z8; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z7; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z6;