diff --git a/layers/transportation/update_transportation_merge.sql b/layers/transportation/update_transportation_merge.sql index b1c465e..7bacd55 100644 --- a/layers/transportation/update_transportation_merge.sql +++ b/layers/transportation/update_transportation_merge.sql @@ -1,11 +1,12 @@ -DROP TRIGGER IF EXISTS trigger_osm_transportation_merge_linestring_gen_z8 ON osm_transportation_merge_linestring_gen_z8; +DROP TRIGGER IF EXISTS trigger_store_osm_transportation_merge_linestring_gen_z8 ON osm_transportation_merge_linestring_gen_z8; DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring_gen_z9 ON osm_transportation_merge_linestring_gen_z9; DROP TRIGGER IF EXISTS trigger_flag_transportation_z9 ON osm_transportation_merge_linestring_gen_z9; DROP TRIGGER IF EXISTS trigger_refresh_z8 ON transportation.updates_z9; -DROP TRIGGER IF EXISTS trigger_osm_transportation_merge_linestring_gen_z11 ON osm_transportation_merge_linestring_gen_z11; DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring_gen_z11 ON osm_highway_linestring_gen_z11; +DROP TRIGGER IF EXISTS trigger_store_osm_transportation_merge_linestring_gen_z11 ON osm_transportation_merge_linestring_gen_z11; DROP TRIGGER IF EXISTS trigger_flag_transportation_z11 ON osm_highway_linestring_gen_z11; DROP TRIGGER IF EXISTS trigger_refresh_z11 ON transportation.updates_z11; +DROP TRIGGER IF EXISTS trigger_store_transportation_name_network ON osm_transportation_name_network; -- Determine whether a segment is long enough to have bridge/tunnel attributes -- Dropping small brunnel sections allow for generalization as distinct segments get too small @@ -101,21 +102,30 @@ FROM ( WHERE (hl.name <> '' OR hl.ref <> '' OR rm1.ref <> '' OR rm1.network <> '') AND hl.highway <> '' ) AS t; -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id); -CREATE INDEX IF NOT EXISTS osm_transportation_name_network_name_ref_idx ON osm_transportation_name_network (coalesce(tags->'name', ''), coalesce(ref, '')); -CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist (geometry); --- 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'); +-- Create Primary-Key for osm_transportation_name_network table +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_network' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_network ADD PRIMARY KEY (osm_id); + END IF; +END; +$$ LANGUAGE plpgsql; +-- Geometry Index +CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx + ON osm_transportation_name_network USING gist (geometry); -- etldoc: osm_highway_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z11 CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11( - geometry geometry, - id SERIAL PRIMARY KEY, + geometry geometry('LineString'), + id SERIAL, osm_id bigint, + source_ids bigint[], highway character varying, network character varying, construction character varying, @@ -134,9 +144,52 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11( layer integer ); -INSERT INTO osm_transportation_merge_linestring_gen_z11(geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer) -SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry, - NULL::bigint AS osm_id, +-- Create osm_transportation_merge_linestring_gen_z10 as a copy of osm_transportation_merge_linestring_gen_z11 but +-- drop the "source_ids" column. This can be done because z10 and z9 tables are only simplified and not merged, +-- therefore relations to sources are direct via the id column. +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z10 + (LIKE osm_transportation_merge_linestring_gen_z11); +ALTER TABLE osm_transportation_merge_linestring_gen_z10 DROP COLUMN IF EXISTS source_ids; + +-- Create osm_transportation_merge_linestring_gen_z9 as a copy of osm_transportation_merge_linestring_gen_z10 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z9 + (LIKE osm_transportation_merge_linestring_gen_z10); + +-- Create OneToMany-Relation-Table storing relations of a Merged-LineString in table +-- osm_transportation_merge_linestring_gen_z11 to Source-LineStrings from table osm_highway_linestring_gen_z11 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_source_ids( + id int, + source_id bigint, + PRIMARY KEY (id, source_id) +); + +-- Index for storing OSM-IDs of Source-LineStrings +CREATE UNIQUE INDEX IF NOT EXISTS osm_highway_linestring_gen_z11_osm_id_idx ON osm_highway_linestring_gen_z11 ("osm_id"); + +-- Analyze created indexes +ANALYZE osm_highway_linestring_gen_z11; + +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_merge_linestring_gen_z11; +TRUNCATE osm_transportation_merge_linestring_gen_z11_source_ids; + +-- Merge LineStrings from osm_highway_linestring_gen_z11 by grouping them and creating intersecting clusters of +-- 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) +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 + -- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if + -- more than two LineStrings form an intersection or no intersection could be found. + -- https://postgis.net/docs/ST_LineMerge.html + -- In order to not end up with a mixture of LineStrings and MultiLineStrings we dump eventual + -- MultiLineStrings via ST_Dump. https://postgis.net/docs/ST_Dump.html + array_agg(osm_id) as source_ids, + -- Temporary Merged-LineString to Source-LineStrings-ID column to store relations before they have been + -- intersected highway, network, construction, @@ -156,46 +209,133 @@ SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry, toll, layer FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - NULL::bigint AS osm_id, - highway, - network, - construction, - 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, - z_order, - bicycle, - foot, - horse, - mtb_scale, - sac_scale, - access, - toll, - visible_layer(geometry, layer, 11) AS layer - FROM osm_highway_linestring_gen_z11 -) osm_highway_linestring_normalized_brunnel_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, expressway, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer -; + SELECT osm_highway_linestring_normalized_brunnel_z11.*, + -- Get intersecting clusters by setting minimum distance to 0 and minimum intersecting points to 1 + -- 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 + ) 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 + ) as cluster_group + FROM ( + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + SELECT geometry, + osm_id, + highway, + network, + construction, + 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, + z_order, + bicycle, + foot, + horse, + mtb_scale, + sac_scale, + access, + toll, + visible_layer(geometry, layer, 11) AS layer + FROM osm_highway_linestring_gen_z11 + ) 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; + +-- Geometry Index CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_geometry_idx ON osm_transportation_merge_linestring_gen_z11 USING gist (geometry); - -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z10 - (LIKE osm_transportation_merge_linestring_gen_z11); - -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z9 - (LIKE osm_transportation_merge_linestring_gen_z10); - - -CREATE OR REPLACE FUNCTION insert_transportation_merge_linestring_gen_z10(update_id bigint) RETURNS void AS -$$ +-- Create Primary-Keys for osm_transportation_merge_linestring_gen_z11/z10/z9 tables +DO $$ BEGIN + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z11' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z10' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z10 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z9' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z9 ADD PRIMARY KEY (id); + END IF; +END; +$$ LANGUAGE plpgsql; + +-- Indexes which can be utilized during full-update for queries originating from +-- insert_transportation_merge_linestring_gen_z10() function +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_update_partial_idx + ON osm_transportation_merge_linestring_gen_z11 (id) + WHERE highway NOT IN ('tertiary', 'tertiary_link', 'busway') AND + construction NOT IN ('tertiary', 'tertiary_link', 'busway'); + +-- Analyze populated table with new indexes +ANALYZE osm_transportation_merge_linestring_gen_z11; + +-- Store OSM-IDs of Source-LineStrings by intersecting Merged-LineStrings with their sources. This required because +-- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if +-- more than two LineStrings form an intersection or no intersection could be found. +-- Execute after indexes have been created on osm_highway_linestring_gen_z11 to improve performance +INSERT INTO osm_transportation_merge_linestring_gen_z11_source_ids (id, source_id) +SELECT m.id, m.source_id +FROM ( + SELECT id, unnest(source_ids) AS source_id, geometry + FROM osm_transportation_merge_linestring_gen_z11 +) m +JOIN osm_highway_linestring_gen_z11 s ON (m.source_id = s.osm_id) +WHERE ST_Intersects(s.geometry, m.geometry) +ON CONFLICT (id, source_id) DO NOTHING; + +-- Drop temporary Merged-LineString to Source-LineStrings-ID column +ALTER TABLE osm_transportation_merge_linestring_gen_z11 DROP COLUMN IF EXISTS source_ids; + +CREATE SCHEMA IF NOT EXISTS transportation; + +CREATE TABLE IF NOT EXISTS transportation.changes_z9_z10 +( + is_old boolean, + id int, + PRIMARY KEY (is_old, id) +); + +CREATE OR REPLACE FUNCTION insert_transportation_merge_linestring_gen_z10(full_update bool) RETURNS void AS +$$ +DECLARE + t TIMESTAMP WITH TIME ZONE := clock_timestamp(); +BEGIN + RAISE LOG 'Refresh transportation z9 10'; + + -- Analyze tracking and source tables before performing update + ANALYZE transportation.changes_z9_z10; + ANALYZE osm_transportation_merge_linestring_gen_z11; + + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z10 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z9_z10 + WHERE full_update IS TRUE OR ( + transportation.changes_z9_z10.is_old IS TRUE AND + transportation.changes_z9_z10.id = osm_transportation_merge_linestring_gen_z10.id + ); -- etldoc: osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z10 INSERT INTO osm_transportation_merge_linestring_gen_z10 @@ -205,9 +345,10 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + 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, z_order, bicycle, @@ -217,37 +358,35 @@ BEGIN sac_scale, access, toll, - layer - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - NULL::bigint AS osm_id, - highway, - network, - construction, - 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, - z_order, - bicycle, - foot, - horse, - mtb_scale, - sac_scale, - access, - toll, - visible_layer(geometry, layer, 11) AS layer - FROM osm_transportation_merge_linestring_gen_z11 - ) osm_highway_linestring_normalized_brunnel_z11 - WHERE (update_id IS NULL OR id = update_id) - AND highway NOT IN ('tertiary', 'tertiary_link', 'busway', 'bus_guideway') - AND construction NOT IN ('tertiary', 'tertiary_link', 'busway', 'bus_guideway') - ; + visible_layer(geometry, layer, 11) AS layer + FROM osm_transportation_merge_linestring_gen_z11 + WHERE (full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z9_z10 + WHERE transportation.changes_z9_z10.is_old IS FALSE AND + transportation.changes_z9_z10.id = osm_transportation_merge_linestring_gen_z11.id + )) + AND ( + highway NOT IN ('tertiary', 'tertiary_link', 'busway', 'bus_guideway') + AND construction NOT IN ('tertiary', 'tertiary_link', 'busway', 'bus_guideway') + ) + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + 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, + access = excluded.access, toll = excluded.toll, layer = excluded.layer; + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z9 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z9_z10 + WHERE full_update IS TRUE OR ( + transportation.changes_z9_z10.is_old IS TRUE AND + transportation.changes_z9_z10.id = osm_transportation_merge_linestring_gen_z9.id + ); + + -- Analyze source table + ANALYZE osm_transportation_merge_linestring_gen_z10; -- etldoc: osm_transportation_merge_linestring_gen_z10 -> osm_transportation_merge_linestring_gen_z9 INSERT INTO osm_transportation_merge_linestring_gen_z9 @@ -257,9 +396,10 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + visible_brunnel(geometry, is_bridge, 10) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 10) AS is_tunnel, + visible_brunnel(geometry, is_ford, 10) AS is_ford, expressway, z_order, bicycle, @@ -269,53 +409,46 @@ BEGIN sac_scale, access, toll, - layer - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - NULL::bigint AS osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 10) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 10) AS is_tunnel, - visible_brunnel(geometry, is_ford, 10) AS is_ford, - expressway, - z_order, - bicycle, - foot, - horse, - mtb_scale, - sac_scale, - access, - toll, - visible_layer(geometry, layer, 10) AS layer - FROM osm_transportation_merge_linestring_gen_z10 - ) osm_highway_linestring_normalized_brunnel_z10 - WHERE (update_id IS NULL OR id = update_id) - ; + visible_layer(geometry, layer, 10) AS layer + FROM osm_transportation_merge_linestring_gen_z10 + WHERE full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z9_z10 + WHERE transportation.changes_z9_z10.is_old IS FALSE AND + transportation.changes_z9_z10.id = osm_transportation_merge_linestring_gen_z10.id + ) + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + 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, + access = excluded.access, toll = excluded.toll, layer = excluded.layer; + + -- noinspection SqlWithoutWhere + DELETE FROM transportation.changes_z9_z10; + + RAISE LOG 'Refresh transportation z9 10 done in %', age(clock_timestamp(), t); END; $$ LANGUAGE plpgsql; -SELECT insert_transportation_merge_linestring_gen_z10(NULL); +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_merge_linestring_gen_z10; +TRUNCATE osm_transportation_merge_linestring_gen_z9; +SELECT insert_transportation_merge_linestring_gen_z10(TRUE); + +-- Geometry Indexes CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z10_geometry_idx ON osm_transportation_merge_linestring_gen_z10 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z10_id_idx - ON osm_transportation_merge_linestring_gen_z10(id); - CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z9_geometry_idx ON osm_transportation_merge_linestring_gen_z9 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z9_id_idx - ON osm_transportation_merge_linestring_gen_z9(id); - -- etldoc: osm_transportation_merge_linestring_gen_z9 -> osm_transportation_merge_linestring_gen_z8 CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z8( - geometry geometry, - id SERIAL PRIMARY KEY, + geometry geometry('LineString'), + id SERIAL, osm_id bigint, + source_ids int[], highway character varying, network character varying, construction character varying, @@ -326,9 +459,64 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z8( z_order integer ); -INSERT INTO osm_transportation_merge_linestring_gen_z8(geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order) -SELECT ST_Simplify(ST_LineMerge(ST_Collect(geometry)), ZRes(10)) AS geometry, - NULL::bigint AS osm_id, +-- Create osm_transportation_merge_linestring_gen_z7 as a copy of osm_transportation_merge_linestring_gen_z8 but +-- drop the "source_ids" column. This can be done because z7 to z5 tables are only simplified and not merged, +-- therefore relations to sources are direct via the id column. +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z7 + (LIKE osm_transportation_merge_linestring_gen_z8); +ALTER TABLE osm_transportation_merge_linestring_gen_z7 DROP COLUMN IF EXISTS source_ids; + +-- Create osm_transportation_merge_linestring_gen_z6 as a copy of osm_transportation_merge_linestring_gen_z7 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z6 + (LIKE osm_transportation_merge_linestring_gen_z7); + +-- Create osm_transportation_merge_linestring_gen_z5 as a copy of osm_transportation_merge_linestring_gen_z6 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z5 + (LIKE osm_transportation_merge_linestring_gen_z6); + +-- Create osm_transportation_merge_linestring_gen_z4 as a copy of osm_transportation_merge_linestring_gen_z5 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z4 + (LIKE osm_transportation_merge_linestring_gen_z5); + +-- Create OneToMany-Relation-Table storing relations of a Merged-LineString in table +-- osm_transportation_merge_linestring_gen_z8 to Source-LineStrings from table +-- osm_transportation_merge_linestring_gen_z9 +CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_source_ids( + id int, + source_id bigint, + PRIMARY KEY (id, source_id) +); + +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_merge_linestring_gen_z8; +TRUNCATE osm_transportation_merge_linestring_gen_z8_source_ids; + +-- Indexes for filling and updating osm_transportation_merge_linestring_gen_z8 table +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z9_update_partial_idx + ON osm_transportation_merge_linestring_gen_z9 (id) + WHERE ( + highway IN ('motorway', 'trunk', 'primary') OR + construction IN ('motorway', 'trunk', 'primary') + ) AND ST_IsValid(geometry) AND access IS NULL; + +-- Analyze populated table with indexes +ANALYZE osm_transportation_merge_linestring_gen_z9; + +-- Merge LineStrings from osm_transportation_merge_linestring_gen_z9 by grouping them and creating intersecting +-- clusters of each group via ST_ClusterDBSCAN +INSERT INTO osm_transportation_merge_linestring_gen_z8(geometry, source_ids, highway, network, construction, is_bridge, + is_tunnel, is_ford, expressway, z_order) +SELECT (ST_Dump(ST_Simplify(ST_LineMerge(ST_Union(geometry)), ZRes(10)))).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 + -- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if + -- more than two LineStrings form an intersection or no intersection could be found. + -- https://postgis.net/docs/ST_LineMerge.html + -- In order to not end up with a mixture of LineStrings and MultiLineStrings we dump eventual + -- MultiLineStrings via ST_Dump. https://postgis.net/docs/ST_Dump.html + array_agg(id) AS source_ids, + -- Temporary Merged-LineString to Source-LineStrings-ID column to store relations before they have been + -- intersected highway, network, construction, @@ -338,46 +526,139 @@ SELECT ST_Simplify(ST_LineMerge(ST_Collect(geometry)), ZRes(10)) AS geometry, expressway, min(z_order) as z_order FROM ( + SELECT osm_highway_linestring_normalized_brunnel_z9.*, + -- Get intersecting clusters by setting minimum distance to 0 and minimum intersecting points to 1 + -- 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 + ) 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 + ) as cluster_group + FROM ( -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 9) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 9) AS is_tunnel, - visible_brunnel(geometry, is_ford, 9) AS is_ford, - expressway, - z_order + SELECT id, + geometry, + highway, + network, + construction, + visible_brunnel(geometry, is_bridge, 9) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 9) AS is_tunnel, + visible_brunnel(geometry, is_ford, 9) AS is_ford, + expressway, + 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) - AND access IS NULL + WHERE ( + highway IN ('motorway', 'trunk', 'primary') OR + construction IN ('motorway', 'trunk', 'primary') + ) AND ST_IsValid(geometry) AND access IS NULL ) osm_highway_linestring_normalized_brunnel_z9 -GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway -; +) q +GROUP BY cluster_group, cluster, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway; + +-- Geometry Index CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_geometry_idx ON osm_transportation_merge_linestring_gen_z8 USING gist (geometry); -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z7 - (LIKE osm_transportation_merge_linestring_gen_z8); - -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z6 - (LIKE osm_transportation_merge_linestring_gen_z7); - -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z5 - (LIKE osm_transportation_merge_linestring_gen_z6); - -CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z4 - (LIKE osm_transportation_merge_linestring_gen_z5); - - -CREATE OR REPLACE FUNCTION insert_transportation_merge_linestring_gen_z7(update_id bigint) RETURNS void AS -$$ +-- Create Primary-Keys for osm_transportation_merge_linestring_gen_z8/z7/z6/z5/z4 tables +DO $$ BEGIN + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z8' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z7' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z7 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z6' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z6 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z5' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z5 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_merge_linestring_gen_z4' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_merge_linestring_gen_z4 ADD PRIMARY KEY (id); + END IF; +END; +$$ LANGUAGE plpgsql; + +-- Indexes which can be utilized during full-update for queries originating from +-- insert_transportation_merge_linestring_gen_z7() function +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_update_partial_idx + ON osm_transportation_merge_linestring_gen_z8 (id) + WHERE ST_Length(geometry) > 50; + +-- Analyze populated table with indexes +ANALYZE osm_transportation_merge_linestring_gen_z8; + +-- Store OSM-IDs of Source-LineStrings by intersecting Merged-LineStrings with their sources. This required because +-- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if +-- more than two LineStrings form an intersection or no intersection could be found. +-- Execute after indexes have been created on osm_transportation_merge_linestring_gen_z11 to improve performance +INSERT INTO osm_transportation_merge_linestring_gen_z8_source_ids (id, source_id) +SELECT m.id, m.source_id +FROM ( + SELECT id, unnest(source_ids) AS source_id, geometry + FROM osm_transportation_merge_linestring_gen_z8 +) m +JOIN osm_transportation_merge_linestring_gen_z9 s ON (m.source_id = s.id) +WHERE ST_Intersects(s.geometry, m.geometry) +ON CONFLICT (id, source_id) DO NOTHING; + +-- Drop temporary Merged-LineString to Source-LineStrings-ID column +ALTER TABLE osm_transportation_merge_linestring_gen_z8 DROP COLUMN IF EXISTS source_ids; + +CREATE TABLE IF NOT EXISTS transportation.changes_z4_z5_z6_z7 +( + is_old boolean, + id int, + PRIMARY KEY (is_old, id) +); + +CREATE OR REPLACE FUNCTION insert_transportation_merge_linestring_gen_z7(full_update boolean) RETURNS void AS +$$ +DECLARE + t TIMESTAMP WITH TIME ZONE := clock_timestamp(); +BEGIN + RAISE LOG 'Refresh transportation z4 z5 z6 z7'; + + -- Analyze tracking and source tables before performing update + ANALYZE transportation.changes_z4_z5_z6_z7; + ANALYZE osm_transportation_merge_linestring_gen_z8; + + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z7 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z4_z5_z6_z7 + WHERE full_update IS TRUE OR ( + transportation.changes_z4_z5_z6_z7.is_old IS TRUE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z7.id + ); -- etldoc: osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z7 INSERT INTO osm_transportation_merge_linestring_gen_z7 @@ -387,33 +668,36 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + visible_brunnel(geometry, is_bridge, 8) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 8) AS is_tunnel, + visible_brunnel(geometry, is_ford, 8) AS is_ford, expressway, z_order - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 8) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 8) AS is_tunnel, - visible_brunnel(geometry, is_ford, 8) AS is_ford, - expressway, - z_order - FROM osm_transportation_merge_linestring_gen_z8 - ) osm_highway_linestring_normalized_brunnel_z8 + FROM osm_transportation_merge_linestring_gen_z8 -- Current view: motorway/trunk/primary WHERE - (update_id IS NULL OR id = update_id) AND - ST_Length(geometry) > 50; + (full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z4_z5_z6_z7 + WHERE transportation.changes_z4_z5_z6_z7.is_old IS FALSE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z8.id + )) AND + (ST_Length(geometry) > 50) + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + expressway = excluded.expressway, z_order = excluded.z_order; + -- Analyze source table + ANALYZE osm_transportation_merge_linestring_gen_z7; + + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z6 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z4_z5_z6_z7 + WHERE full_update IS TRUE OR ( + transportation.changes_z4_z5_z6_z7.is_old IS TRUE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z6.id + ); -- etldoc: osm_transportation_merge_linestring_gen_z7 -> osm_transportation_merge_linestring_gen_z6 INSERT INTO osm_transportation_merge_linestring_gen_z6 @@ -423,35 +707,37 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + visible_brunnel(geometry, is_bridge, 7) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 7) AS is_tunnel, + visible_brunnel(geometry, is_ford, 7) AS is_ford, expressway, z_order - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 7) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 7) AS is_tunnel, - visible_brunnel(geometry, is_ford, 7) AS is_ford, - expressway, - z_order - FROM osm_transportation_merge_linestring_gen_z7 - WHERE - (highway IN ('motorway', 'trunk') OR construction IN ('motorway', 'trunk')) - ) osm_highway_linestring_normalized_brunnel_z7 - -- Current view: motorway/trunk/primary + FROM osm_transportation_merge_linestring_gen_z7 + -- Current view: motorway/trunk/primary WHERE - (update_id IS NULL OR id = update_id) AND - ST_Length(geometry) > 100; + (full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z4_z5_z6_z7 + WHERE transportation.changes_z4_z5_z6_z7.is_old IS FALSE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z7.id + )) AND + (highway IN ('motorway', 'trunk') OR construction IN ('motorway', 'trunk')) AND + ST_Length(geometry) > 100 + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + expressway = excluded.expressway, z_order = excluded.z_order; + -- Analyze source table + ANALYZE osm_transportation_merge_linestring_gen_z6; + + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z5 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z4_z5_z6_z7 + WHERE full_update IS TRUE OR ( + transportation.changes_z4_z5_z6_z7.is_old IS TRUE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z5.id + ); -- etldoc: osm_transportation_merge_linestring_gen_z6 -> osm_transportation_merge_linestring_gen_z5 INSERT INTO osm_transportation_merge_linestring_gen_z5 @@ -461,39 +747,41 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged + visible_brunnel(geometry, is_bridge, 6) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 6) AS is_tunnel, + visible_brunnel(geometry, is_ford, 6) AS is_ford, expressway, z_order - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 6) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 6) AS is_tunnel, - visible_brunnel(geometry, is_ford, 6) AS is_ford, - expressway, - z_order - FROM osm_transportation_merge_linestring_gen_z6 - WHERE - (highway = 'motorway' - OR construction = 'motorway' - -- Allow trunk roads that are part of a nation's most important route network to show at z4 - OR (highway = 'trunk' AND osm_national_network(network)) - ) - ) osm_highway_linestring_normalized_brunnel_z6 + FROM osm_transportation_merge_linestring_gen_z6 WHERE - (update_id IS NULL OR id = update_id) AND + (full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z4_z5_z6_z7 + WHERE transportation.changes_z4_z5_z6_z7.is_old IS FALSE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z6.id + )) AND -- Current view: all motorways and trunks of national-importance - ST_Length(geometry) > 500; + (highway = 'motorway' + OR construction = 'motorway' + -- Allow trunk roads that are part of a nation's most important route network to show at z5 + OR (highway = 'trunk' AND osm_national_network(network)) + ) AND + ST_Length(geometry) > 500 + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + expressway = excluded.expressway, z_order = excluded.z_order; + -- Analyze source table + ANALYZE osm_transportation_merge_linestring_gen_z5; + + -- Remove entries which have been deleted from source table DELETE FROM osm_transportation_merge_linestring_gen_z4 - WHERE update_id IS NULL OR id = update_id; + USING transportation.changes_z4_z5_z6_z7 + WHERE full_update IS TRUE OR ( + transportation.changes_z4_z5_z6_z7.is_old IS TRUE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z4.id + ); -- etldoc: osm_transportation_merge_linestring_gen_z5 -> osm_transportation_merge_linestring_gen_z4 INSERT INTO osm_transportation_merge_linestring_gen_z4 @@ -503,104 +791,110 @@ BEGIN highway, network, construction, - is_bridge, - is_tunnel, - is_ford, + visible_brunnel(geometry, is_bridge, 5) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 5) AS is_tunnel, + visible_brunnel(geometry, is_ford, 5) AS is_ford, expressway, z_order - FROM ( - -- Remove bridge/tunnel/ford attributes from short sections of road so they can be merged - SELECT geometry, - id, - osm_id, - highway, - network, - construction, - visible_brunnel(geometry, is_bridge, 5) AS is_bridge, - visible_brunnel(geometry, is_tunnel, 5) AS is_tunnel, - visible_brunnel(geometry, is_ford, 5) AS is_ford, - expressway, - z_order - FROM osm_transportation_merge_linestring_gen_z5 - WHERE osm_national_network(network) - ) osm_highway_linestring_normalized_brunnel_z5 + FROM osm_transportation_merge_linestring_gen_z5 WHERE - (update_id IS NULL OR id = update_id) AND + (full_update IS TRUE OR EXISTS( + SELECT NULL FROM transportation.changes_z4_z5_z6_z7 + WHERE transportation.changes_z4_z5_z6_z7.is_old IS FALSE AND + transportation.changes_z4_z5_z6_z7.id = osm_transportation_merge_linestring_gen_z5.id + )) AND + osm_national_network(network) AND -- Current view: national-importance motorways and trunks - ST_Length(geometry) > 1000; + ST_Length(geometry) > 1000 + ON CONFLICT (id) DO UPDATE SET osm_id = excluded.osm_id, highway = excluded.highway, network = excluded.network, + construction = excluded.construction, is_bridge = excluded.is_bridge, + is_tunnel = excluded.is_tunnel, is_ford = excluded.is_ford, + expressway = excluded.expressway, z_order = excluded.z_order; + + -- noinspection SqlWithoutWhere + DELETE FROM transportation.changes_z4_z5_z6_z7; + + RAISE LOG 'Refresh transportation z4 z5 z6 z7 done in %', age(clock_timestamp(), t); END; $$ LANGUAGE plpgsql; -SELECT insert_transportation_merge_linestring_gen_z7(NULL); +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_merge_linestring_gen_z7; +TRUNCATE osm_transportation_merge_linestring_gen_z6; +TRUNCATE osm_transportation_merge_linestring_gen_z5; +TRUNCATE osm_transportation_merge_linestring_gen_z4; +SELECT insert_transportation_merge_linestring_gen_z7(TRUE); + +-- Indexes for queries originating from insert_transportation_merge_linestring_gen_z7() function +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_update_partial_idx + ON osm_transportation_merge_linestring_gen_z7 (id) + WHERE (highway IN ('motorway', 'trunk') OR construction IN ('motorway', 'trunk')) AND + ST_Length(geometry) > 100; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z6_update_partial_idx + ON osm_transportation_merge_linestring_gen_z6 (id) + WHERE (highway = 'motorway' + OR construction = 'motorway' + OR (highway = 'trunk' AND osm_national_network(network)) + ) AND + ST_Length(geometry) > 500; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_update_partial_idx + ON osm_transportation_merge_linestring_gen_z5 (id) + WHERE osm_national_network(network) AND ST_Length(geometry) > 1000; + +-- Geometry Indexes CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_geometry_idx ON osm_transportation_merge_linestring_gen_z7 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_id_idx - ON osm_transportation_merge_linestring_gen_z7(id); - CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z6_geometry_idx ON osm_transportation_merge_linestring_gen_z6 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z6_id_idx - ON osm_transportation_merge_linestring_gen_z6(id); - CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_geometry_idx ON osm_transportation_merge_linestring_gen_z5 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_id_idx - ON osm_transportation_merge_linestring_gen_z5(id); - CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z4_geometry_idx ON osm_transportation_merge_linestring_gen_z4 USING gist (geometry); -CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z4_id_idx - ON osm_transportation_merge_linestring_gen_z4(id); -- Handle updates on -- osm_highway_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z11 - -CREATE SCHEMA IF NOT EXISTS transportation; - +-- osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z10 +-- osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z9 CREATE TABLE IF NOT EXISTS transportation.changes_z11 ( - id serial PRIMARY KEY, - is_old boolean, - geometry geometry, + is_old boolean NULL, osm_id bigint, - highway character varying, - network character varying, - construction character varying, - is_bridge boolean, - is_tunnel boolean, - is_ford boolean, - expressway boolean, - z_order integer, - bicycle character varying, - foot character varying, - horse character varying, - mtb_scale character varying, - sac_scale character varying, - access character varying, - toll boolean, - layer integer + PRIMARY KEY (is_old, osm_id) ); -CREATE OR REPLACE FUNCTION transportation.store_z11() RETURNS trigger AS +-- Store IDs of changed elements from osm_highway_linestring_gen_z11 table. +CREATE OR REPLACE FUNCTION transportation.store_gen_z11() RETURNS trigger AS $$ BEGIN - IF (tg_op = 'DELETE' OR tg_op = 'UPDATE') THEN - INSERT INTO transportation.changes_z11(is_old, geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer) - VALUES (true, old.geometry, old.osm_id, old.highway, old.network, old.construction, old.is_bridge, old.is_tunnel, old.is_ford, old.expressway, old.z_order, old.bicycle, old.foot, old.horse, old.mtb_scale, old.sac_scale, - CASE - WHEN old.access IN ('private', 'no') THEN 'no' - ELSE NULL::text END, - old.toll, old.layer); + IF (tg_op = 'INSERT' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z11(is_old, osm_id) + VALUES (FALSE, new.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; END IF; - IF (tg_op = 'UPDATE' OR tg_op = 'INSERT') THEN - INSERT INTO transportation.changes_z11(is_old, geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer) - VALUES (false, new.geometry, new.osm_id, new.highway, new.network, new.construction, new.is_bridge, new.is_tunnel, new.is_ford, new.expressway, new.z_order, new.bicycle, new.foot, new.horse, new.mtb_scale, new.sac_scale, - CASE - WHEN new.access IN ('private', 'no') THEN 'no' - ELSE NULL::text END, - new.toll, new.layer); + IF (tg_op = 'DELETE' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z11(is_old, osm_id) + VALUES (TRUE, old.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Store IDs of changed elements from osm_highway_linestring_gen_z9 table. +CREATE OR REPLACE FUNCTION transportation.store_merge_z11() RETURNS trigger AS +$$ +BEGIN + IF (tg_op = 'INSERT' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z9_z10(is_old, id) + VALUES (FALSE, new.id) + ON CONFLICT (is_old, id) DO NOTHING; + END IF; + IF tg_op = 'DELETE' THEN + INSERT INTO transportation.changes_z9_z10(is_old, id) + VALUES (TRUE, old.id) + ON CONFLICT (is_old, id) DO NOTHING; END IF; RETURN NULL; END; @@ -627,166 +921,208 @@ DECLARE BEGIN RAISE LOG 'Refresh transportation z11'; - -- Compact the change history to keep only the first and last version - CREATE TEMP TABLE changes_compact AS - SELECT - * - FROM (( - SELECT DISTINCT ON (osm_id) * - FROM transportation.changes_z11 - WHERE is_old - ORDER BY osm_id, - id ASC - ) UNION ALL ( - SELECT DISTINCT ON (osm_id) * - FROM transportation.changes_z11 - WHERE NOT is_old - ORDER BY osm_id, - id DESC - )) AS t; + -- Analyze tracking and source tables before performing update + ANALYZE transportation.changes_z11; + ANALYZE osm_highway_linestring_gen_z11; - -- Collect all original existing ways from impacted mmerge - CREATE TEMP TABLE osm_highway_linestring_original AS - SELECT DISTINCT ON (h.osm_id) - NULL::integer AS id, - NULL::boolean AS is_old, - h.geometry, - h.osm_id, - h.highway, - h.network, - h.construction, - h.is_bridge, - h.is_tunnel, - h.is_ford, - h.expressway, - h.z_order, - h.bicycle, - h.foot, - h.horse, - h.mtb_scale, - h.sac_scale, - h.access, - h.toll, - h.layer - FROM - changes_compact AS c - JOIN osm_transportation_merge_linestring_gen_z11 AS m ON - m.geometry && c.geometry - AND m.highway IS NOT DISTINCT FROM c.highway - AND m.network IS NOT DISTINCT FROM c.network - AND m.construction IS NOT DISTINCT FROM c.construction - AND m.is_bridge IS NOT DISTINCT FROM c.is_bridge - AND m.is_tunnel IS NOT DISTINCT FROM c.is_tunnel - AND m.is_ford IS NOT DISTINCT FROM c.is_ford - AND m.expressway IS NOT DISTINCT FROM c.expressway - AND m.bicycle IS NOT DISTINCT FROM c.bicycle - AND m.foot IS NOT DISTINCT FROM c.foot - AND m.horse IS NOT DISTINCT FROM c.horse - AND m.mtb_scale IS NOT DISTINCT FROM c.mtb_scale - AND m.sac_scale IS NOT DISTINCT FROM c.sac_scale - AND m.access IS NOT DISTINCT FROM c.access - AND m.toll IS NOT DISTINCT FROM c.toll - AND m.layer IS NOT DISTINCT FROM c.layer - JOIN osm_highway_linestring_gen_z11 AS h ON - h.geometry && c.geometry - AND h.osm_id NOT IN (SELECT osm_id FROM changes_compact) - AND ST_Contains(m.geometry, h.geometry) - AND h.highway IS NOT DISTINCT FROM m.highway - AND h.network IS NOT DISTINCT FROM m.network - AND h.construction IS NOT DISTINCT FROM m.construction - AND h.is_bridge IS NOT DISTINCT FROM m.is_bridge - AND h.is_tunnel IS NOT DISTINCT FROM m.is_tunnel - AND h.is_ford IS NOT DISTINCT FROM m.is_ford - AND h.expressway IS NOT DISTINCT FROM m.expressway - AND h.bicycle IS NOT DISTINCT FROM m.bicycle - AND h.foot IS NOT DISTINCT FROM m.foot - AND h.horse IS NOT DISTINCT FROM m.horse - AND h.mtb_scale IS NOT DISTINCT FROM m.mtb_scale - AND h.sac_scale IS NOT DISTINCT FROM m.sac_scale - AND CASE - WHEN h.access IN ('private', 'no') THEN 'no' - ELSE NULL::text END IS NOT DISTINCT FROM m.access - AND h.toll IS NOT DISTINCT FROM m.toll - AND h.layer IS NOT DISTINCT FROM m.layer - ORDER BY - h.osm_id - ; + -- Fetch updated and deleted Merged-LineString from relation-table filtering for each Merged-LineString which + -- contains an updated Source-LineString. + -- Additionally attach a list of Source-LineString-IDs to each Merged-LineString in order to unnest them later. + CREATE TEMPORARY TABLE affected_merged_linestrings AS + SELECT m.id, array_agg(source_id) AS source_ids + FROM osm_transportation_merge_linestring_gen_z11_source_ids m + WHERE EXISTS( + SELECT NULL + FROM transportation.changes_z11 c + WHERE c.is_old IS TRUE AND c.osm_id = m.source_id + ) + GROUP BY id; + -- Analyze the created table to speed up subsequent queries + ANALYZE affected_merged_linestrings; + + -- Delete all Merged-LineStrings which contained an updated or deleted Source-LineString DELETE - FROM osm_transportation_merge_linestring_gen_z11 AS m - USING changes_compact AS c - WHERE - m.geometry && c.geometry - AND m.highway IS NOT DISTINCT FROM c.highway - AND m.network IS NOT DISTINCT FROM c.network - AND m.construction IS NOT DISTINCT FROM c.construction - AND m.is_bridge IS NOT DISTINCT FROM c.is_bridge - AND m.is_tunnel IS NOT DISTINCT FROM c.is_tunnel - AND m.is_ford IS NOT DISTINCT FROM c.is_ford - AND m.expressway IS NOT DISTINCT FROM c.expressway - AND m.bicycle IS NOT DISTINCT FROM c.bicycle - AND m.foot IS NOT DISTINCT FROM c.foot - AND m.horse IS NOT DISTINCT FROM c.horse - AND m.mtb_scale IS NOT DISTINCT FROM c.mtb_scale - AND m.sac_scale IS NOT DISTINCT FROM c.sac_scale - AND m.access IS NOT DISTINCT FROM c.access - AND m.toll IS NOT DISTINCT FROM c.toll - AND m.layer IS NOT DISTINCT FROM c.layer - ; + FROM osm_transportation_merge_linestring_gen_z11 m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + DELETE + FROM osm_transportation_merge_linestring_gen_z11_source_ids m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; - INSERT INTO osm_transportation_merge_linestring_gen_z11(geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer) - SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry, - NULL::bigint AS osm_id, - highway, - network, - construction, - is_bridge, - is_tunnel, - is_ford, - expressway, - min(z_order) as z_order, - bicycle, - foot, - horse, - mtb_scale, - sac_scale, - CASE - WHEN access IN ('private', 'no') THEN 'no' - ELSE NULL::text END AS access, - toll, - layer - FROM (( - SELECT * FROM osm_highway_linestring_original - ) UNION ALL ( - -- New or updated ways - SELECT - * - FROM - changes_compact - WHERE - NOT is_old - )) AS t - GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, layer - ; + -- Analyze the tables affected by the delete-query in order to speed up subsequent queries + ANALYZE osm_transportation_merge_linestring_gen_z11; + ANALYZE osm_transportation_merge_linestring_gen_z11_source_ids; + + -- Create a table containing all LineStrings which should be merged + CREATE TEMPORARY TABLE linestrings_to_merge AS + -- Add all Source-LineStrings affected by this update + SELECT osm_highway_linestring_gen_z11.osm_id, NULL::INTEGER AS id, geometry, highway, network, construction, + 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, + 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 + FROM ( + -- Get Source-LineString-IDs of deleted or updated elements + SELECT unnest(affected_merged_linestrings.source_ids)::bigint AS source_id FROM affected_merged_linestrings + UNION + -- Get Source-LineString-IDs of inserted or updated elements + SELECT osm_id AS source_id FROM transportation.changes_z11 WHERE is_old IS FALSE + ORDER BY source_id + ) affected_source_linestrings + JOIN osm_highway_linestring_gen_z11 ON ( + affected_source_linestrings.source_id = osm_highway_linestring_gen_z11.osm_id + ); + + -- Drop temporary tables early to save resources + DROP TABLE affected_merged_linestrings; + + -- Create index on geometry column and analyze the created table to speed up subsequent queries + CREATE INDEX ON linestrings_to_merge USING GIST (geometry); + ANALYZE linestrings_to_merge; + + -- Add all Merged-LineStrings intersecting with Source-LineStrings affected by this update + INSERT INTO linestrings_to_merge + SELECT s.source_id AS osm_id, m.id, + geometry, highway, network, construction, + 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, access, toll, + visible_layer(geometry, layer, 11) AS layer, z_order + FROM osm_transportation_merge_linestring_gen_z11 m + JOIN osm_transportation_merge_linestring_gen_z11_source_ids s ON (m.id = s.id) + WHERE EXISTS(SELECT NULL FROM linestrings_to_merge WHERE ST_Intersects(linestrings_to_merge.geometry, m.geometry)); + + -- Analyze the created table to speed up subsequent queries + ANALYZE linestrings_to_merge; + + -- Delete all Merged-LineStrings intersecting with Source-LineStrings affected by this update. + -- We can use the linestrings_to_merge table since Source-LineStrings affected by this update and present in the + -- table will have their ID-Column set to NULL by the previous query. + DELETE + FROM osm_transportation_merge_linestring_gen_z11 m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + DELETE + FROM osm_transportation_merge_linestring_gen_z11_source_ids m + USING linestrings_to_merge + WHERE linestrings_to_merge.id = m.id; + + -- Create table containing all LineStrings to and create clusters of intersecting LineStrings partitioned by their + -- groups + CREATE TEMPORARY TABLE clustered_linestrings_to_merge AS + SELECT *, + -- Get intersecting clusters by setting minimum distance to 0 and minimum intersecting points to 1 + -- 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 + ) 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 + ) as cluster_group + FROM linestrings_to_merge; + + -- Drop temporary tables early to save resources + DROP TABLE linestrings_to_merge; + + -- Create index on cluster columns and analyze the created table to speed up subsequent queries + CREATE INDEX ON clustered_linestrings_to_merge (cluster_group, cluster); + ANALYZE clustered_linestrings_to_merge; + + -- Create temporary Merged-LineString to Source-LineStrings-ID column to store relations before they have been + -- intersected + ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS source_ids bigint[]; + + WITH inserted_linestrings AS ( + -- Merge LineStrings of each cluster and insert them + 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) + 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 + -- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if + -- more than two LineStrings form an intersection or no intersection could be found. + -- https://postgis.net/docs/ST_LineMerge.html + -- In order to not end up with a mixture of LineStrings and MultiLineStrings we dump eventual + -- MultiLineStrings via ST_Dump. https://postgis.net/docs/ST_Dump.html + array_agg(osm_id) AS source_ids, + highway, + network, + construction, + is_bridge, + is_tunnel, + is_ford, + expressway, + min(z_order) as z_order, + bicycle, + foot, + horse, + mtb_scale, + sac_scale, + 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 + RETURNING id, source_ids, geometry + ) + -- Store OSM-IDs of Source-LineStrings by intersecting Merged-LineStrings with their sources. + -- This is required because ST_LineMerge only merges across singular intersections and groups its output into a + -- MultiLineString if more than two LineStrings form an intersection or no intersection could be found. + INSERT INTO osm_transportation_merge_linestring_gen_z11_source_ids (id, source_id) + SELECT m.id, source_id + FROM ( + SELECT id, unnest(source_ids) AS source_id, geometry + FROM inserted_linestrings + ) m + JOIN osm_highway_linestring_gen_z11 s ON (m.source_id = s.osm_id) + WHERE ST_Intersects(s.geometry, m.geometry) + ON CONFLICT (id, source_id) DO NOTHING; + + -- Cleanup remaining table + DROP TABLE clustered_linestrings_to_merge; + + -- Drop temporary Merged-LineString to Source-LineStrings-ID column + ALTER TABLE osm_transportation_merge_linestring_gen_z11 DROP COLUMN IF EXISTS source_ids; - DROP TABLE osm_highway_linestring_original; - DROP TABLE changes_compact; -- noinspection SqlWithoutWhere DELETE FROM transportation.changes_z11; -- noinspection SqlWithoutWhere DELETE FROM transportation.updates_z11; RAISE LOG 'Refresh transportation z11 done in %', age(clock_timestamp(), t); + + -- Update z10 and z9 tables + PERFORM insert_transportation_merge_linestring_gen_z10(FALSE); + RETURN NULL; END; $$ LANGUAGE plpgsql; - CREATE TRIGGER trigger_store_transportation_highway_linestring_gen_z11 AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring_gen_z11 FOR EACH ROW -EXECUTE PROCEDURE transportation.store_z11(); +EXECUTE PROCEDURE transportation.store_gen_z11(); + +CREATE TRIGGER trigger_store_osm_transportation_merge_linestring_gen_z11 + AFTER INSERT OR UPDATE OR DELETE + ON osm_transportation_merge_linestring_gen_z11 + FOR EACH ROW +EXECUTE PROCEDURE transportation.store_merge_z11(); CREATE TRIGGER trigger_flag_transportation_z11 AFTER INSERT OR UPDATE OR DELETE @@ -802,64 +1138,51 @@ CREATE CONSTRAINT TRIGGER trigger_refresh_z11 EXECUTE PROCEDURE transportation.refresh_z11(); --- Handle updates on --- osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z10 --- osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z9 - - -CREATE OR REPLACE FUNCTION transportation.merge_linestring_gen_refresh_z10() RETURNS trigger AS -$$ -BEGIN - IF (tg_op = 'DELETE') THEN - DELETE FROM osm_transportation_merge_linestring_gen_z10 WHERE id = old.id; - DELETE FROM osm_transportation_merge_linestring_gen_z9 WHERE id = old.id; - END IF; - - IF (tg_op = 'UPDATE' OR tg_op = 'INSERT') THEN - PERFORM insert_transportation_merge_linestring_gen_z10(new.id); - END IF; - - RETURN NULL; -END; -$$ LANGUAGE plpgsql; - - -CREATE TRIGGER trigger_osm_transportation_merge_linestring_gen_z11 - AFTER INSERT OR UPDATE OR DELETE - ON osm_transportation_merge_linestring_gen_z11 - FOR EACH ROW -EXECUTE PROCEDURE transportation.merge_linestring_gen_refresh_z10(); - - -- Handle updates on -- osm_transportation_merge_linestring_gen_z9 -> osm_transportation_merge_linestring_gen_z8 - +-- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z7 +-- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z6 +-- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z5 +-- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z4 CREATE TABLE IF NOT EXISTS transportation.changes_z9 ( is_old boolean, - geometry geometry, id bigint, - highway character varying, - network character varying, - construction character varying, - is_bridge boolean, - is_tunnel boolean, - is_ford boolean, - expressway boolean, - z_order integer + PRIMARY KEY (is_old, id) ); +-- Store IDs of changed elements from osm_highway_linestring_gen_z9 table. CREATE OR REPLACE FUNCTION transportation.store_z9() RETURNS trigger AS $$ BEGIN - IF (tg_op = 'DELETE' OR tg_op = 'UPDATE') THEN - INSERT INTO transportation.changes_z9(is_old, geometry, id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order) - VALUES (true, old.geometry, old.id, old.highway, old.network, old.construction, old.is_bridge, old.is_tunnel, old.is_ford, old.expressway, old.z_order); + IF (tg_op = 'INSERT' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z9(is_old, id) + VALUES (FALSE, new.id) + ON CONFLICT (is_old, id) DO NOTHING; END IF; - IF (tg_op = 'UPDATE' OR tg_op = 'INSERT') THEN - INSERT INTO transportation.changes_z9(is_old, geometry, id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order) - VALUES (false, new.geometry, new.id, new.highway, new.network, new.construction, new.is_bridge, new.is_tunnel, new.is_ford, new.expressway, new.z_order); + IF (tg_op = 'DELETE' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z9(is_old, id) + VALUES (TRUE, old.id) + ON CONFLICT (is_old, id) DO NOTHING; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Store IDs of changed elements from osm_highway_linestring_gen_z8 table. +CREATE OR REPLACE FUNCTION transportation.store_z8() RETURNS trigger AS +$$ +BEGIN + IF (tg_op = 'INSERT' OR tg_op = 'UPDATE') THEN + INSERT INTO transportation.changes_z4_z5_z6_z7(is_old, id) + VALUES (FALSE, new.id) + ON CONFLICT (is_old, id) DO NOTHING; + END IF; + IF tg_op = 'DELETE' THEN + INSERT INTO transportation.changes_z4_z5_z6_z7(is_old, id) + VALUES (TRUE, old.id) + ON CONFLICT (is_old, id) DO NOTHING; END IF; RETURN NULL; END; @@ -884,124 +1207,198 @@ $$ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN - RAISE LOG 'Refresh transportation z9'; + RAISE LOG 'Refresh transportation z8'; - -- Compact the change history to keep only the first and last version - CREATE TEMP TABLE changes_compact AS - SELECT - * - FROM (( - SELECT DISTINCT ON (id) * - FROM transportation.changes_z9 - WHERE is_old - ORDER BY id, - id ASC - ) UNION ALL ( - SELECT DISTINCT ON (id) * - FROM transportation.changes_z9 - WHERE NOT is_old - ORDER BY id, - id DESC - )) AS t; + -- Analyze tracking and source tables before performing update + ANALYZE transportation.changes_z9; + ANALYZE osm_transportation_merge_linestring_gen_z9; - -- Collect all original existing ways from impacted mmerge - CREATE TEMP TABLE osm_highway_linestring_original AS - SELECT DISTINCT ON (h.id) - NULL::boolean AS is_old, - h.geometry, - h.id, - h.highway, - h.network, - h.construction, - h.is_bridge, - h.is_tunnel, - h.is_ford, - h.expressway, - h.z_order - FROM - changes_compact AS c - JOIN osm_transportation_merge_linestring_gen_z8 AS m ON - m.geometry && c.geometry - AND m.highway IS NOT DISTINCT FROM c.highway - AND m.network IS NOT DISTINCT FROM c.network - AND m.construction IS NOT DISTINCT FROM c.construction - AND m.is_bridge IS NOT DISTINCT FROM c.is_bridge - AND m.is_tunnel IS NOT DISTINCT FROM c.is_tunnel - AND m.is_ford IS NOT DISTINCT FROM c.is_ford - AND m.expressway IS NOT DISTINCT FROM c.expressway - JOIN osm_transportation_merge_linestring_gen_z9 AS h ON - h.geometry && c.geometry - AND h.id NOT IN (SELECT id FROM changes_compact) - AND ST_Contains(m.geometry, h.geometry) - AND h.highway IS NOT DISTINCT FROM m.highway - AND h.network IS NOT DISTINCT FROM m.network - AND h.construction IS NOT DISTINCT FROM m.construction - AND h.is_bridge IS NOT DISTINCT FROM m.is_bridge - AND h.is_tunnel IS NOT DISTINCT FROM m.is_tunnel - AND h.is_ford IS NOT DISTINCT FROM m.is_ford - AND h.expressway IS NOT DISTINCT FROM m.expressway - ORDER BY - h.id - ; + -- Fetch updated and deleted Merged-LineString from relation-table filtering for each Merged-LineString which + -- contains an updated Source-LineString. + -- Additionally attach a list of Source-LineString-IDs to each Merged-LineString in order to unnest them later. + CREATE TEMPORARY TABLE affected_merged_linestrings AS + SELECT m.id, array_agg(source_id) AS source_ids + FROM osm_transportation_merge_linestring_gen_z8_source_ids m + WHERE EXISTS( + SELECT NULL + FROM transportation.changes_z9 c + WHERE c.is_old IS TRUE AND c.id = m.source_id + ) + GROUP BY id; + -- Analyze the created table to speed up subsequent queries + ANALYZE affected_merged_linestrings; + + -- Delete all Merged-LineStrings which contained an updated or deleted Source-LineString DELETE - FROM osm_transportation_merge_linestring_gen_z8 AS m - USING changes_compact AS c - WHERE - m.geometry && c.geometry - AND m.highway IS NOT DISTINCT FROM c.highway - AND m.network IS NOT DISTINCT FROM c.network - AND m.construction IS NOT DISTINCT FROM c.construction - AND m.is_bridge IS NOT DISTINCT FROM c.is_bridge - AND m.is_tunnel IS NOT DISTINCT FROM c.is_tunnel - AND m.is_ford IS NOT DISTINCT FROM c.is_ford - AND m.expressway IS NOT DISTINCT FROM c.expressway - ; + FROM osm_transportation_merge_linestring_gen_z8 m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + DELETE + FROM osm_transportation_merge_linestring_gen_z8_source_ids m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; - INSERT INTO osm_transportation_merge_linestring_gen_z8(geometry, osm_id, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway, z_order) - SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry, - NULL::bigint AS osm_id, - highway, - network, - construction, - is_bridge, - is_tunnel, - is_ford, - expressway, - min(z_order) as z_order - FROM (( - SELECT * FROM osm_highway_linestring_original - ) UNION ALL ( - -- New or updated ways - SELECT - * - FROM - changes_compact - WHERE - NOT is_old - )) AS t - GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway - ; + -- Analyze the tables affected by the delete-query in order to speed up subsequent queries + ANALYZE osm_transportation_merge_linestring_gen_z8; + ANALYZE osm_transportation_merge_linestring_gen_z8_source_ids; + + -- Create a table containing all LineStrings which should be merged + CREATE TEMPORARY TABLE linestrings_to_merge AS + -- Add all Source-LineStrings affected by this update + SELECT id AS source_id, NULL::int AS id, geometry, highway, network, construction, + visible_brunnel(geometry, is_bridge, 9) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 9) AS is_tunnel, + visible_brunnel(geometry, is_ford, 9) AS is_ford, expressway, z_order + -- Create a table containing the IDs of all Source-LineStrings affected by this update + FROM ( + -- Get Source-LineString-IDs of deleted or updated elements + SELECT unnest(affected_merged_linestrings.source_ids)::bigint AS source_id FROM affected_merged_linestrings + UNION + -- Get Source-LineString-IDs of inserted or updated elements + SELECT id AS source_id FROM transportation.changes_z9 WHERE transportation.changes_z9.is_old IS FALSE + ORDER BY source_id + ) affected_source_linestrings + JOIN osm_transportation_merge_linestring_gen_z9 ON ( + affected_source_linestrings.source_id = osm_transportation_merge_linestring_gen_z9.id AND + ( + highway IN ('motorway', 'trunk', 'primary') OR + construction IN ('motorway', 'trunk', 'primary') + ) AND + ST_IsValid(geometry) AND + access IS NULL + ); + + -- Drop temporary tables early to save resources + DROP TABLE affected_merged_linestrings; + + -- Create index on geometry column and analyze the created table to speed up subsequent queries + CREATE INDEX ON linestrings_to_merge USING GIST (geometry); + ANALYZE linestrings_to_merge; + + -- Add all Merged-LineStrings intersecting with Source-LineStrings affected by this update + INSERT INTO linestrings_to_merge + SELECT s.source_id, m.id, geometry, highway, network, construction, + visible_brunnel(geometry, is_bridge, 9) AS is_bridge, + visible_brunnel(geometry, is_tunnel, 9) AS is_tunnel, + visible_brunnel(geometry, is_ford, 9) AS is_ford, expressway, z_order + FROM osm_transportation_merge_linestring_gen_z8 m + JOIN osm_transportation_merge_linestring_gen_z8_source_ids s ON (m.id = s.id) + WHERE EXISTS(SELECT NULL FROM linestrings_to_merge WHERE ST_Intersects(linestrings_to_merge.geometry, m.geometry)); + + -- Analyze the created table to speed up subsequent queries + ANALYZE linestrings_to_merge; + + -- Delete all Merged-LineStrings intersecting with Source-LineStrings affected by this update. + -- We can use the linestrings_to_merge table since Source-LineStrings affected by this update and present in the + -- table will have their ID-Column set to NULL by the previous query. + DELETE + FROM osm_transportation_merge_linestring_gen_z8 m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + DELETE + FROM osm_transportation_merge_linestring_gen_z8_source_ids m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + + -- Create table containing all LineStrings to and create clusters of intersecting LineStrings partitioned by their + -- groups + CREATE TEMPORARY TABLE clustered_linestrings_to_merge AS + SELECT *, + -- Get intersecting clusters by setting minimum distance to 0 and minimum intersecting points to 1 + -- 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 + ) 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 + ) as cluster_group + FROM linestrings_to_merge; + + -- Drop temporary tables early to save resources + DROP TABLE linestrings_to_merge; + + -- Create index on cluster columns and analyze the created table to speed up subsequent queries + CREATE INDEX ON clustered_linestrings_to_merge (cluster_group, cluster); + ANALYZE clustered_linestrings_to_merge; + + -- Create temporary Merged-LineString to Source-LineStrings-ID column to store relations before they have been + -- intersected + ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS source_ids bigint[]; + + WITH inserted_linestrings AS ( + -- Merge LineStrings of each cluster and insert them + INSERT INTO osm_transportation_merge_linestring_gen_z8(geometry, source_ids, highway, network, construction, + is_bridge, is_tunnel, is_ford, expressway, z_order) + SELECT (ST_Dump(ST_Simplify(ST_LineMerge(ST_Union(geometry)), ZRes(10)))).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 + -- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if + -- more than two LineStrings form an intersection or no intersection could be found. + -- https://postgis.net/docs/ST_LineMerge.html + -- In order to not end up with a mixture of LineStrings and MultiLineStrings we dump eventual + -- MultiLineStrings via ST_Dump. https://postgis.net/docs/ST_Dump.html + array_agg(source_id) as source_ids, + highway, + network, + construction, + is_bridge, + is_tunnel, + is_ford, + expressway, + min(z_order) as z_order + FROM clustered_linestrings_to_merge + GROUP BY cluster_group, cluster, highway, network, construction, is_bridge, is_tunnel, is_ford, expressway + RETURNING id, source_ids, geometry + ) + -- Store OSM-IDs of Source-LineStrings by intersecting Merged-LineStrings with their sources. This required because + -- ST_LineMerge only merges across singular intersections and groups its output into a MultiLineString if + -- more than two LineStrings form an intersection or no intersection could be found. + INSERT INTO osm_transportation_merge_linestring_gen_z8_source_ids (id, source_id) + SELECT m.id, m.source_id + FROM ( + SELECT id, unnest(source_ids) AS source_id, geometry + FROM inserted_linestrings + ) m + JOIN osm_transportation_merge_linestring_gen_z9 s ON (m.source_id = s.id) + WHERE ST_Intersects(s.geometry, m.geometry) + ON CONFLICT (id, source_id) DO NOTHING; + + -- Cleanup + DROP TABLE clustered_linestrings_to_merge; + + -- Drop temporary Merged-LineString to Source-LineStrings-ID column + ALTER TABLE osm_transportation_merge_linestring_gen_z8 DROP COLUMN IF EXISTS source_ids; - DROP TABLE osm_highway_linestring_original; - DROP TABLE changes_compact; -- noinspection SqlWithoutWhere DELETE FROM transportation.changes_z9; -- noinspection SqlWithoutWhere DELETE FROM transportation.updates_z9; - RAISE LOG 'Refresh transportation z9 done in %', age(clock_timestamp(), t); + RAISE LOG 'Refresh transportation z8 done in %', age(clock_timestamp(), t); + + -- Update z7, z6, z5 and z4 tables + PERFORM insert_transportation_merge_linestring_gen_z7(FALSE); + RETURN NULL; END; $$ LANGUAGE plpgsql; - CREATE TRIGGER trigger_store_transportation_highway_linestring_gen_z9 AFTER INSERT OR UPDATE OR DELETE ON osm_transportation_merge_linestring_gen_z9 FOR EACH ROW EXECUTE PROCEDURE transportation.store_z9(); +CREATE TRIGGER trigger_store_osm_transportation_merge_linestring_gen_z8 + AFTER INSERT OR UPDATE OR DELETE + ON osm_transportation_merge_linestring_gen_z8 + FOR EACH ROW +EXECUTE PROCEDURE transportation.store_z8(); + CREATE TRIGGER trigger_flag_transportation_z9 AFTER INSERT OR UPDATE OR DELETE ON osm_transportation_merge_linestring_gen_z9 @@ -1014,35 +1411,3 @@ CREATE CONSTRAINT TRIGGER trigger_refresh_z8 INITIALLY DEFERRED FOR EACH ROW EXECUTE PROCEDURE transportation.refresh_z8(); - - --- Handle updates on --- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z7 --- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z6 --- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z5 --- osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z4 - - -CREATE OR REPLACE FUNCTION transportation.merge_linestring_gen_refresh_z7() RETURNS trigger AS -$$ -BEGIN - IF (tg_op = 'DELETE') THEN - DELETE FROM osm_transportation_merge_linestring_gen_z7 WHERE id = old.id; - DELETE FROM osm_transportation_merge_linestring_gen_z6 WHERE id = old.id; - DELETE FROM osm_transportation_merge_linestring_gen_z5 WHERE id = old.id; - DELETE FROM osm_transportation_merge_linestring_gen_z4 WHERE id = old.id; - END IF; - - IF (tg_op = 'UPDATE' OR tg_op = 'INSERT') THEN - PERFORM insert_transportation_merge_linestring_gen_z7(new.id); - END IF; - - RETURN NULL; -END; -$$ LANGUAGE plpgsql; - -CREATE TRIGGER trigger_osm_transportation_merge_linestring_gen_z8 - AFTER INSERT OR UPDATE OR DELETE - ON osm_transportation_merge_linestring_gen_z8 - FOR EACH ROW -EXECUTE PROCEDURE transportation.merge_linestring_gen_refresh_z7();