diff --git a/layers/transportation/etl_diagram.png b/layers/transportation/etl_diagram.png index f960a37..b21fb86 100644 Binary files a/layers/transportation/etl_diagram.png and b/layers/transportation/etl_diagram.png differ diff --git a/layers/transportation/network_type.sql b/layers/transportation/network_type.sql index 3c621de..f1fa864 100644 --- a/layers/transportation/network_type.sql +++ b/layers/transportation/network_type.sql @@ -32,15 +32,3 @@ $$ 'us-interstate'); $$ LANGUAGE sql IMMUTABLE PARALLEL SAFE; - -DO -$$ - BEGIN - BEGIN - ALTER TABLE osm_route_member - ADD COLUMN network_type route_network_type; - EXCEPTION - WHEN duplicate_column THEN RAISE NOTICE 'column network_type already exists in network_type.'; - END; - END; -$$; diff --git a/layers/transportation/update_route_member.sql b/layers/transportation/update_route_member.sql index 584b520..77d7773 100644 --- a/layers/transportation/update_route_member.sql +++ b/layers/transportation/update_route_member.sql @@ -1,3 +1,5 @@ +DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring ON osm_highway_linestring; + -- Create bounding windows for country-specific processing -- etldoc: ne_10m_admin_0_countries -> ne_10m_admin_0_gb_buffer @@ -16,12 +18,11 @@ WHERE iso_a2 = 'IE'; -- etldoc: osm_highway_linestring -> gbr_route_members_view -- etldoc: ne_10m_admin_0_gb_buffer -> gbr_route_members_view CREATE OR REPLACE VIEW gbr_route_members_view AS -SELECT 0, - osm_id, - substring(ref FROM E'^[ABM][0-9ABM()]+'), +SELECT osm_id AS member, + substring(ref FROM E'^[ABM][0-9ABM()]+') AS ref, -- See https://wiki.openstreetmap.org/wiki/Roads_in_the_United_Kingdom CASE WHEN highway = 'motorway' THEN 'omt-gb-motorway' - WHEN highway = 'trunk' THEN 'omt-gb-trunk' + WHEN highway = 'trunk' THEN 'omt-gb-trunk' WHEN highway IN ('primary','secondary') THEN 'omt-gb-primary' END AS network FROM osm_highway_linestring WHERE length(ref) > 1 @@ -32,12 +33,11 @@ WHERE length(ref) > 1 -- etldoc: osm_highway_linestring -> ire_route_members_view -- etldoc: ne_10m_admin_0_ie_buffer -> ire_route_members_view CREATE OR REPLACE VIEW ire_route_members_view AS -SELECT 0, - osm_id, - substring(ref FROM E'^[MNRL][0-9]+'), +SELECT osm_id AS member, + substring(ref FROM E'^[MNRL][0-9]+') AS ref, -- See https://wiki.openstreetmap.org/wiki/Ireland/Roads CASE WHEN highway = 'motorway' THEN 'omt-ie-motorway' - WHEN highway IN ('trunk','primary') THEN 'omt-ie-national' + WHEN highway IN ('trunk','primary') THEN 'omt-ie-national' ELSE 'omt-ie-regional' END AS network FROM osm_highway_linestring WHERE length(ref) > 1 @@ -45,23 +45,6 @@ WHERE length(ref) > 1 AND highway IN ('motorway', 'trunk', 'primary', 'secondary', 'unclassified') ; --- Create GBR/IRE relations (so we can use it in the same way as other relations) --- etldoc: osm_route_member -> osm_route_member -DELETE -FROM osm_route_member -WHERE network IN ('omt-gb-motorway', 'omt-gb-trunk', 'omt-gb-primary', - 'omt-ie-motorway', 'omt-ie-national', 'omt-ie-national'); - --- etldoc: gbr_route_members_view -> osm_route_member -INSERT INTO osm_route_member (osm_id, member, ref, network) -SELECT * -FROM gbr_route_members_view; - --- etldoc: ire_route_members_view -> osm_route_member -INSERT INTO osm_route_member (osm_id, member, ref, network) -SELECT * -FROM ire_route_members_view; - CREATE OR REPLACE FUNCTION osm_route_member_network_type(network text, ref text) RETURNS route_network_type AS $$ SELECT CASE @@ -91,79 +74,132 @@ SELECT CASE $$ LANGUAGE sql IMMUTABLE PARALLEL SAFE; --- etldoc: osm_route_member -> osm_route_member --- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes -UPDATE osm_route_member -SET network_type = osm_route_member_network_type(network, ref) -WHERE network != '' - AND network_type IS DISTINCT FROM osm_route_member_network_type(network, ref) -; +CREATE TABLE IF NOT EXISTS transportation_route_member_coalesced +( + member bigint, + network varchar, + ref varchar, + osm_id bigint not null, + role varchar, + type smallint, + name varchar, + osmc_symbol varchar, + colour varchar, + network_type route_network_type, + concurrency_index integer, + rank integer, + PRIMARY KEY (member, network, ref) +); -CREATE OR REPLACE FUNCTION update_osm_route_member() RETURNS void AS +CREATE OR REPLACE FUNCTION update_osm_route_member(full_update bool) RETURNS void AS $$ BEGIN + -- Analyze tracking and source tables before performing update + ANALYZE transportation_name.network_changes; + ANALYZE osm_highway_linestring; + ANALYZE osm_route_member; + DELETE - FROM osm_route_member AS r - USING - transportation_name.network_changes AS c - WHERE network IN ('omt-gb-motorway', 'omt-gb-trunk', 'omt-gb-primary', - 'omt-ie-motorway', 'omt-ie-national', 'omt-ie-regional') - AND r.osm_id = c.osm_id; + FROM transportation_route_member_coalesced + USING transportation_name.network_changes c + WHERE c.is_old IS TRUE AND transportation_route_member_coalesced.member = c.osm_id; - INSERT INTO osm_route_member (osm_id, member, ref, network) - SELECT r.* - FROM gbr_route_members_view AS r - JOIN transportation_name.network_changes AS c ON - r.osm_id = c.osm_id; + -- Create GBR/IRE relations (so we can use it in the same way as other relations) + -- etldoc: gbr_route_members_view -> transportation_route_member_coalesced + INSERT INTO transportation_route_member_coalesced (member, network, ref, network_type, concurrency_index, osm_id) + SELECT member, network, ref, osm_route_member_network_type(network, ref) AS network_type, + 1 AS concurrency_index, 0 AS osm_id + FROM gbr_route_members_view + WHERE full_update OR EXISTS( + SELECT NULL + FROM transportation_name.network_changes c + WHERE c.is_old IS FALSE AND c.osm_id = gbr_route_members_view.member + ) + GROUP BY member, network, ref + ON CONFLICT (member, network, ref) DO NOTHING; - INSERT INTO osm_route_member (osm_id, member, ref, network) - SELECT r.* - FROM ire_route_members_view AS r - JOIN transportation_name.network_changes AS c ON - r.osm_id = c.osm_id; + -- etldoc: ire_route_members_view -> transportation_route_member_coalesced + INSERT INTO transportation_route_member_coalesced (member, network, ref, network_type, concurrency_index, osm_id) + SELECT member, network, ref, osm_route_member_network_type(network, ref) AS network_type, + 1 AS concurrency_index, 0 AS osm_id + FROM ire_route_members_view + WHERE full_update OR EXISTS( + SELECT NULL + FROM transportation_name.network_changes c + WHERE c.is_old IS FALSE AND c.osm_id = ire_route_members_view.member + ) + GROUP BY member, network, ref + ON CONFLICT (member, network, ref) DO NOTHING; - INSERT INTO osm_route_member (id, osm_id, network_type) + -- etldoc: osm_route_member -> transportation_route_member_coalesced + INSERT INTO transportation_route_member_coalesced SELECT - id, - osm_id, - osm_route_member_network_type(network, ref) AS network_type - FROM osm_route_member rm - WHERE rm.member IN - (SELECT DISTINCT osm_id FROM transportation_name.network_changes) - ON CONFLICT (id, osm_id) DO UPDATE SET network_type = EXCLUDED.network_type; - REFRESH MATERIALIZED VIEW transportation_route_member_coalesced; + osm_route_member_filtered.*, + osm_route_member_network_type(network, ref) AS network_type, + DENSE_RANK() OVER ( + PARTITION BY member + ORDER BY osm_route_member_network_type(network, ref), network, LENGTH(ref), ref + ) AS concurrency_index, + CASE + WHEN network IN ('iwn', 'nwn', 'rwn') THEN 1 + WHEN network = 'lwn' THEN 2 + WHEN osmc_symbol || colour <> '' THEN 2 + END AS rank + FROM ( + -- etldoc: osm_route_member -> osm_route_member + -- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes + SELECT DISTINCT ON (member, network, ref) + member, + network, + ref, + osm_id, + role, + type, + name, + osmc_symbol, + colour + FROM osm_route_member + WHERE full_update OR EXISTS( + SELECT NULL + FROM transportation_name.network_changes c + WHERE c.is_old IS FALSE AND c.osm_id = osm_route_member.member + ) + ) osm_route_member_filtered + ON CONFLICT (member, network, ref) DO UPDATE SET osm_id = EXCLUDED.osm_id, role = EXCLUDED.role, + type = EXCLUDED.type, name = EXCLUDED.name, + osmc_symbol = EXCLUDED.osmc_symbol, colour = EXCLUDED.colour, + rank = EXCLUDED.rank; END; $$ LANGUAGE plpgsql; -CREATE INDEX IF NOT EXISTS osm_route_member_osm_id_idx ON osm_route_member ("osm_id"); +-- Indexes which can be utilized during full-update for queries originating from update_osm_route_member() function +CREATE INDEX IF NOT EXISTS osm_route_member_member_network_ref_idx ON osm_route_member (member, network, ref); --- etldoc: osm_route_member -> transportation_route_member_coalesced -DROP MATERIALIZED VIEW IF EXISTS transportation_route_member_coalesced CASCADE; -CREATE MATERIALIZED VIEW transportation_route_member_coalesced AS -SELECT - member, - network_type, - network, - ref, - DENSE_RANK() over (PARTITION BY member ORDER BY network_type, network, LENGTH(ref), ref) AS concurrency_index, - rank -FROM ( - SELECT DISTINCT - member, - network_type, - network, - ref, - CASE - WHEN network IN ('iwn', 'nwn', 'rwn') THEN 1 - WHEN network = 'lwn' THEN 2 - WHEN osmc_symbol || colour <> '' THEN 2 - END AS rank - FROM osm_route_member -) osm_route_member_filtered -GROUP BY member, network_type, network, ref, rank; +-- Analyze created index +ANALYZE osm_route_member; -CREATE INDEX IF NOT EXISTS transportation_route_member_member_idx ON transportation_route_member_coalesced ("member"); -CREATE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id"); +-- Ensure transportation_name.network_changes table exists since it is required by update_osm_route_member +CREATE SCHEMA IF NOT EXISTS transportation_name; +CREATE TABLE IF NOT EXISTS transportation_name.network_changes +( + is_old bool, + osm_id bigint, + PRIMARY KEY (is_old, osm_id) +); + +-- Fill transportation_route_member_coalesced table +TRUNCATE transportation_route_member_coalesced; +SELECT update_osm_route_member(TRUE); + +-- Index for queries against transportation_route_member_coalesced during transportation-name-network updates +CREATE INDEX IF NOT EXISTS transportation_route_member_member_idx ON + transportation_route_member_coalesced ("member", "concurrency_index"); + +-- Analyze populated table with indexes +ANALYZE transportation_route_member_coalesced; + +-- Ensure OSM-ID index exists on osm_highway_linestring +CREATE UNIQUE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id"); -- etldoc: osm_route_member -> osm_highway_linestring UPDATE osm_highway_linestring hl diff --git a/layers/transportation_name/transportation_name.sql b/layers/transportation_name/transportation_name.sql index 60d0fd8..9db6d01 100644 --- a/layers/transportation_name/transportation_name.sql +++ b/layers/transportation_name/transportation_name.sql @@ -54,7 +54,20 @@ SELECT geometry, FROM ( -- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6 - SELECT *, + SELECT geometry, + tags, + ref, + highway, + subclass, + brunnel, + network, + route_1, + route_2, + route_3, + route_4, + route_5, + route_6, + z_order, NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor @@ -63,7 +76,20 @@ FROM ( UNION ALL -- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7 - SELECT *, + SELECT geometry, + tags, + ref, + highway, + subclass, + brunnel, + network, + route_1, + route_2, + route_3, + route_4, + route_5, + route_6, + z_order, NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor @@ -72,7 +98,20 @@ FROM ( UNION ALL -- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z8 - SELECT *, + SELECT geometry, + tags, + ref, + highway, + subclass, + brunnel, + network, + route_1, + route_2, + route_3, + route_4, + route_5, + route_6, + z_order, NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor @@ -83,7 +122,20 @@ FROM ( -- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z9 -- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z10 -- etldoc: osm_transportation_name_linestring_gen1 -> layer_transportation_name:z11 - SELECT *, + SELECT geometry, + tags, + ref, + highway, + subclass, + brunnel, + network, + route_1, + route_2, + route_3, + route_4, + route_5, + route_6, + z_order, NULL::int AS layer, NULL::int AS level, NULL::boolean AS indoor diff --git a/layers/transportation_name/update_transportation_name.sql b/layers/transportation_name/update_transportation_name.sql index 68bdf40..ffe7bba 100644 --- a/layers/transportation_name/update_transportation_name.sql +++ b/layers/transportation_name/update_transportation_name.sql @@ -1,13 +1,86 @@ +DROP TRIGGER IF EXISTS trigger_store_transportation_route_member ON osm_route_member; +DROP TRIGGER IF EXISTS trigger_store_transportation_superroute_member ON osm_superroute_member; +DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring ON osm_highway_linestring; +DROP TRIGGER IF EXISTS trigger_flag_transportation_name ON transportation_name.network_changes; +DROP TRIGGER IF EXISTS trigger_refresh_network ON transportation_name.updates_network; +DROP TRIGGER IF EXISTS trigger_store_transportation_name_network ON osm_transportation_name_network; +DROP TRIGGER IF EXISTS trigger_store_transportation_name_shipway ON osm_shipway_linestring; +DROP TRIGGER IF EXISTS trigger_store_transportation_name_aerialway ON osm_aerialway_linestring; +DROP TRIGGER IF EXISTS trigger_store_transportation_name_linestring ON osm_transportation_name_linestring; +DROP TRIGGER IF EXISTS trigger_flag_name ON transportation_name.name_changes; +DROP TRIGGER IF EXISTS trigger_flag_shipway ON transportation_name.shipway_changes; +DROP TRIGGER IF EXISTS trigger_flag_aerialway ON transportation_name.aerialway_changes; +DROP TRIGGER IF EXISTS trigger_refresh_name ON transportation_name.updates_name; +DROP TRIGGER IF EXISTS trigger_refresh_shipway ON transportation_name.updates_shipway; +DROP TRIGGER IF EXISTS trigger_refresh_aerialway ON transportation_name.updates_aerialway; + -- Instead of using relations to find out the road names we -- stitch together the touching ways with the same name -- to allow for nice label rendering -- Because this works well for roads that do not have relations as well +-- Indexes for filling and updating osm_transportation_name_linestring table +CREATE UNIQUE INDEX IF NOT EXISTS osm_shipway_linestring_update_partial_idx ON osm_shipway_linestring (osm_id) + WHERE name <> ''; +CREATE UNIQUE INDEX IF NOT EXISTS osm_aerialway_linestring_update_partial_idx ON osm_aerialway_linestring (osm_id) + WHERE name <> ''; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_network_update_partial_idx + ON osm_transportation_name_network (osm_id) + WHERE coalesce(tags->'name', '') <> '' OR + coalesce(ref, '') <> ''; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id); + +-- Analyze tables with indexes created on them +ANALYZE osm_aerialway_linestring, osm_shipway_linestring, osm_transportation_name_network; + -- etldoc: osm_transportation_name_network -> osm_transportation_name_linestring -- etldoc: osm_shipway_linestring -> osm_transportation_name_linestring -- etldoc: osm_aerialway_linestring -> osm_transportation_name_linestring -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS -SELECT (ST_Dump(geometry)).geom AS geometry, +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring( + id SERIAL, + source integer, + geometry geometry('LineString'), + source_ids bigint[], + tags hstore, + ref text, + highway varchar, + subclass text, + brunnel text, + sac_scale varchar, + "level" integer, + layer integer, + indoor boolean, + network route_network_type, + route_1 text, + route_2 text, + route_3 text, + route_4 text, + route_5 text, + route_6 text, + z_order integer, + route_rank integer +); + +-- Create OneToMany-Relation-Table storing relations of a Merged-LineString in table +-- osm_transportation_name_linestring to Source-LineStrings from tables osm_transportation_name_network, +-- osm_shipway_linestring and osm_aerialway_linestring +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_source_ids( + source int, + id int, + source_id bigint, + PRIMARY KEY (source, id, source_id) +); + +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_name_linestring; +TRUNCATE osm_transportation_name_linestring_source_ids; + +INSERT INTO osm_transportation_name_linestring(source, geometry, source_ids, tags, ref, highway, subclass, brunnel, + sac_scale, "level", layer, indoor, network, route_1, route_2, + route_3, route_4, route_5, route_6,z_order, route_rank) +SELECT source, + geometry, + source_ids, tags || get_basic_names(tags, geometry) AS tags, ref, highway, @@ -22,30 +95,70 @@ SELECT (ST_Dump(geometry)).geom AS geometry, z_order, route_rank FROM ( - SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry, + -- Merge LineStrings from osm_transportation_name_network by grouping them and creating intersecting + -- clusters of each group via ST_ClusterDBSCAN + 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, + 0 AS source, tags, ref, highway, subclass, - CASE WHEN COUNT(*) = COUNT(brunnel) AND MAX(brunnel) = MIN(brunnel) - THEN MAX(brunnel) - ELSE NULL::text END AS brunnel, + brunnel, sac_scale, - "level", + level, layer, indoor, network_type, route_1, route_2, route_3, route_4, route_5, route_6, min(z_order) AS z_order, min(route_rank) AS route_rank - FROM osm_transportation_name_network - WHERE tags->'name' <> '' OR ref <> '' - GROUP BY tags, ref, highway, subclass, "level", layer, sac_scale, indoor, network_type, - route_1, route_2, route_3, route_4, route_5, route_6 + FROM ( + 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 tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, + network_type, route_1, route_2, route_3, route_4, route_5, route_6 + ) 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 tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, + network_type, route_1, route_2, route_3, route_4, route_5, route_6 + ) as cluster_group + FROM osm_transportation_name_network + WHERE coalesce(tags->'name', '') <> '' OR + coalesce(ref, '') <> '' + ) q + GROUP BY cluster_group, cluster, tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, + network_type, route_1, route_2, route_3, route_4, route_5, route_6 UNION ALL - SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry, - transportation_name_tags(NULL::geometry, tags, name, name_en, name_de) AS tags, + -- Merge LineStrings from osm_shipway_linestring by grouping them and creating intersecting + -- clusters of each group via ST_ClusterDBSCAN + 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, + 1 AS source, + transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ) AS tags, NULL AS ref, 'shipway' AS highway, shipway AS subclass, @@ -63,13 +176,47 @@ FROM ( NULL AS route_6, min(z_order) AS z_order, NULL::int AS route_rank - FROM osm_shipway_linestring - WHERE name <> '' - GROUP BY name, name_en, name_de, tags, subclass, "level", layer + FROM ( + 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 transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), shipway, 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 transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), shipway, layer + ) as cluster_group + FROM osm_shipway_linestring + WHERE name <> '' + ) q + GROUP BY cluster_group, cluster, transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), shipway, layer UNION ALL - SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry, - transportation_name_tags(NULL::geometry, tags, name, name_en, name_de) AS tags, + -- Merge LineStrings from osm_aerialway_linestring by grouping them and creating intersecting + -- clusters of each group via ST_ClusterDBSCAN + 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, + 2 AS source, + transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ) AS tags, NULL AS ref, 'aerialway' AS highway, aerialway AS subclass, @@ -87,144 +234,401 @@ FROM ( NULL AS route_6, min(z_order) AS z_order, NULL::int AS route_rank - FROM osm_aerialway_linestring - WHERE name <> '' - GROUP BY name, name_en, name_de, tags, subclass, "level", layer - ) AS highway_union -; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_name_ref_idx ON osm_transportation_name_linestring (coalesce(tags->'name', ''), coalesce(ref, '')); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist (geometry); + FROM ( + 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 transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), aerialway, 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 transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), aerialway, layer + ) as cluster_group + FROM osm_aerialway_linestring + WHERE name <> '' + ) q + GROUP BY cluster_group, cluster, transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ), aerialway, layer + ) AS highway_union; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_highway_partial_idx - ON osm_transportation_name_linestring (highway, subclass) - WHERE highway IN ('motorway', 'trunk', 'construction'); +-- Geometry Index +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx + ON osm_transportation_name_linestring USING gist (geometry); --- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1 -CREATE OR REPLACE VIEW osm_transportation_name_linestring_gen1_view AS -SELECT ST_Simplify(geometry, 50) AS geometry, - tags, - ref, - highway, - subclass, - brunnel, - network, - route_1, route_2, route_3, route_4, route_5, route_6, - z_order -FROM osm_transportation_name_linestring -WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) - AND ST_Length(geometry) > 8000 -; -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS -SELECT * -FROM osm_transportation_name_linestring_gen1_view; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_name_ref_idx ON osm_transportation_name_linestring_gen1((coalesce(tags->'name', ref))); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist (geometry); +-- Create table for simplified LineStrings +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 ( + id integer, + geometry geometry('LineString'), + tags hstore, + ref text, + highway varchar, + subclass text, + brunnel text, + network route_network_type, + route_1 text, + route_2 text, + route_3 text, + route_4 text, + route_5 text, + route_6 text, + z_order integer +); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_highway_partial_idx - ON osm_transportation_name_linestring_gen1 (highway, subclass) - WHERE highway IN ('motorway', 'trunk', 'construction'); +-- Create osm_transportation_name_linestring_gen2 as a copy of osm_transportation_name_linestring_gen1 +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 +(LIKE osm_transportation_name_linestring_gen1); --- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2 -CREATE OR REPLACE VIEW osm_transportation_name_linestring_gen2_view AS -SELECT ST_Simplify(geometry, 120) AS geometry, - tags, - ref, - highway, - subclass, - brunnel, - network, - route_1, route_2, route_3, route_4, route_5, route_6, - z_order -FROM osm_transportation_name_linestring_gen1 -WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) - AND ST_Length(geometry) > 14000 -; -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS -SELECT * -FROM osm_transportation_name_linestring_gen2_view; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_name_ref_idx ON osm_transportation_name_linestring_gen2((coalesce(tags->'name', ref))); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist (geometry); +-- Create osm_transportation_name_linestring_gen3 as a copy of osm_transportation_name_linestring_gen2 +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen3 +(LIKE osm_transportation_name_linestring_gen2); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_highway_partial_idx - ON osm_transportation_name_linestring_gen2 (highway, subclass) - WHERE highway IN ('motorway', 'trunk', 'construction'); +-- Create osm_transportation_name_linestring_gen4 as a copy of osm_transportation_name_linestring_gen3 +CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen4 +(LIKE osm_transportation_name_linestring_gen3); --- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3 -CREATE OR REPLACE VIEW osm_transportation_name_linestring_gen3_view AS -SELECT ST_Simplify(geometry, 200) AS geometry, - tags, - ref, - highway, - subclass, - brunnel, - network, - route_1, route_2, route_3, route_4, route_5, route_6, - z_order -FROM osm_transportation_name_linestring_gen2 -WHERE (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') - AND ST_Length(geometry) > 20000 -; -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen3 AS -SELECT * -FROM osm_transportation_name_linestring_gen3_view; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_name_ref_idx ON osm_transportation_name_linestring_gen3((coalesce(tags->'name', ref))); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist (geometry); +-- Create Primary-Keys for osm_transportation_name_linestring and +-- osm_transportation_name_linestring_gen1/gen2/gen3/gen4 tables +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_linestring' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_linestring ADD PRIMARY KEY (id); + END IF; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_highway_partial_idx - ON osm_transportation_name_linestring_gen3 (highway, subclass) - WHERE highway IN ('motorway', 'construction'); + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_linestring_gen1' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_linestring_gen1 ADD PRIMARY KEY (id); + END IF; --- etldoc: osm_transportation_name_linestring_gen3 -> osm_transportation_name_linestring_gen4 -CREATE OR REPLACE VIEW osm_transportation_name_linestring_gen4_view AS -SELECT ST_Simplify(geometry, 500) AS geometry, - tags, - ref, - highway, - subclass, - brunnel, - network, - route_1, route_2, route_3, route_4, route_5, route_6, - z_order -FROM osm_transportation_name_linestring_gen3 -WHERE (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') - AND ST_Length(geometry) > 20000 -; -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen4 AS -SELECT * -FROM osm_transportation_name_linestring_gen4_view; -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_name_ref_idx ON osm_transportation_name_linestring_gen4((coalesce(tags->'name', ref))); -CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx ON osm_transportation_name_linestring_gen4 USING gist (geometry); + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_linestring_gen2' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_linestring_gen2 ADD PRIMARY KEY (id); + END IF; --- Handle updates + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_linestring_gen3' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_linestring_gen3 ADD PRIMARY KEY (id); + END IF; + + IF NOT EXISTS ( + SELECT constraint_name + FROM information_schema.table_constraints + WHERE table_name = 'osm_transportation_name_linestring_gen4' AND constraint_type = 'PRIMARY KEY' + ) THEN + ALTER TABLE osm_transportation_name_linestring_gen4 ADD PRIMARY KEY (id); + END IF; +END; +$$ LANGUAGE plpgsql; + +-- Indexes which can be utilized during full-update for queries originating from +-- update_transportation_name_linestring_gen() function +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_linestring_update_partial_idx + ON osm_transportation_name_linestring (id) + WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) + AND ST_Length(geometry) > 8000; + +-- Temporary index for filling source tables +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_source_idx ON osm_transportation_name_linestring (source); + +-- Analyze populated table with indexes +ANALYZE osm_transportation_name_linestring; + +-- 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_name_linestring_source_ids(source, id, source_id) +SELECT m.source, m.id, source_id +FROM ( + SELECT id, source, unnest(source_ids) AS source_id, geometry + FROM osm_transportation_name_linestring + WHERE osm_transportation_name_linestring.source = 0 +) m +JOIN osm_transportation_name_network s ON (m.source_id = s.osm_id) +WHERE ST_Intersects(s.geometry, m.geometry) +ON CONFLICT (source, id, source_id) DO NOTHING; +INSERT INTO osm_transportation_name_linestring_source_ids(source, id, source_id) +SELECT m.source, m.id, source_id +FROM ( + SELECT id, source, unnest(source_ids) AS source_id, geometry + FROM osm_transportation_name_linestring + WHERE osm_transportation_name_linestring.source = 1 +) m +JOIN osm_shipway_linestring s ON (m.source_id = s.osm_id) +WHERE ST_Intersects(s.geometry, m.geometry) +ON CONFLICT (source, id, source_id) DO NOTHING; +INSERT INTO osm_transportation_name_linestring_source_ids(source, id, source_id) +SELECT m.source, m.id, source_id +FROM ( + SELECT id, source, unnest(source_ids) AS source_id, geometry + FROM osm_transportation_name_linestring + WHERE osm_transportation_name_linestring.source = 2 +) m +JOIN osm_aerialway_linestring s ON (m.source_id = s.osm_id) +WHERE ST_Intersects(s.geometry, m.geometry) +ON CONFLICT (source, id, source_id) DO NOTHING; + +-- Drop temporary Merged-LineString to Source-LineStrings-ID column +ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS source_ids; + +-- Drop temporary index +DROP INDEX IF EXISTS osm_transportation_name_linestring_source_idx; CREATE SCHEMA IF NOT EXISTS transportation_name; +CREATE TABLE IF NOT EXISTS transportation_name.name_changes_gen +( + is_old boolean, + id int, + PRIMARY KEY (is_old, id) +); + +CREATE OR REPLACE FUNCTION update_transportation_name_linestring_gen (full_update bool) RETURNS VOID AS $$ +DECLARE + t TIMESTAMP WITH TIME ZONE := clock_timestamp(); +BEGIN + RAISE LOG 'Refresh transportation_name merged'; + + -- Analyze tracking and source tables before performing update + ANALYZE transportation_name.name_changes_gen; + ANALYZE osm_transportation_name_linestring; + + -- Remove entries which have been deleted from source table + DELETE FROM osm_transportation_name_linestring_gen1 + USING transportation_name.name_changes_gen + WHERE full_update IS TRUE OR ( + transportation_name.name_changes_gen.is_old IS TRUE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen1.id + ); + + -- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1 + INSERT INTO osm_transportation_name_linestring_gen1 (id, geometry, tags, ref, highway, subclass, brunnel, network, + route_1, route_2, route_3, route_4, route_5, route_6, z_order) + SELECT id, ST_Simplify(geometry, 50) AS geometry, tags, ref, highway, subclass, brunnel, network, route_1, route_2, + route_3, route_4, route_5, route_6, z_order + FROM osm_transportation_name_linestring + WHERE ( + full_update IS TRUE OR EXISTS ( + SELECT NULL + FROM transportation_name.name_changes_gen + WHERE transportation_name.name_changes_gen.is_old IS FALSE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring.id + ) + ) AND ( + (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) AND + ST_Length(geometry) > 8000 + ) ON CONFLICT (id) DO UPDATE SET geometry = excluded.geometry, tags = excluded.tags, ref = excluded.ref, + highway = excluded.highway, subclass = excluded.subclass, + brunnel = excluded.brunnel, network = excluded.network, route_1 = excluded.route_1, + route_2 = excluded.route_2, route_3 = excluded.route_3, route_4 = excluded.route_4, + route_5 = excluded.route_5, route_6 = excluded.route_6, z_order = excluded.z_order; + + -- Analyze source table + ANALYZE osm_transportation_name_linestring_gen1; + + -- Remove entries which have been deleted from source table + DELETE FROM osm_transportation_name_linestring_gen2 + USING transportation_name.name_changes_gen + WHERE full_update IS TRUE OR ( + transportation_name.name_changes_gen.is_old IS TRUE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen2.id + ); + + -- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2 + INSERT INTO osm_transportation_name_linestring_gen2 (id, geometry, tags, ref, highway, subclass, brunnel, network, + route_1, route_2, route_3, route_4, route_5, route_6, z_order) + SELECT id, ST_Simplify(geometry, 120) AS geometry, tags, ref, highway, subclass, brunnel, network, route_1, route_2, + route_3, route_4, route_5, route_6, z_order + FROM osm_transportation_name_linestring_gen1 + WHERE ( + full_update IS TRUE OR EXISTS ( + SELECT NULL + FROM transportation_name.name_changes_gen + WHERE transportation_name.name_changes_gen.is_old IS FALSE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen1.id + ) + ) AND ( + (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) AND + ST_Length(geometry) > 14000 + ) ON CONFLICT (id) DO UPDATE SET geometry = excluded.geometry, tags = excluded.tags, ref = excluded.ref, + highway = excluded.highway, subclass = excluded.subclass, + brunnel = excluded.brunnel, network = excluded.network, route_1 = excluded.route_1, + route_2 = excluded.route_2, route_3 = excluded.route_3, route_4 = excluded.route_4, + route_5 = excluded.route_5, route_6 = excluded.route_6, z_order = excluded.z_order; + + -- Analyze source table + ANALYZE osm_transportation_name_linestring_gen2; + + -- Remove entries which have been deleted from source table + DELETE FROM osm_transportation_name_linestring_gen3 + USING transportation_name.name_changes_gen + WHERE full_update IS TRUE OR ( + transportation_name.name_changes_gen.is_old IS TRUE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen3.id + ); + + -- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3 + INSERT INTO osm_transportation_name_linestring_gen3 (id, geometry, tags, ref, highway, subclass, brunnel, network, + route_1, route_2, route_3, route_4, route_5, route_6, z_order) + SELECT id, ST_Simplify(geometry, 200) AS geometry, tags, ref, highway, subclass, brunnel, network, route_1, route_2, + route_3, route_4, route_5, route_6, z_order + FROM osm_transportation_name_linestring_gen2 + WHERE ( + full_update IS TRUE OR EXISTS ( + SELECT NULL + FROM transportation_name.name_changes_gen + WHERE transportation_name.name_changes_gen.is_old IS FALSE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen2.id + ) + ) AND ( + (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') AND + ST_Length(geometry) > 20000 + ) ON CONFLICT (id) DO UPDATE SET geometry = excluded.geometry, tags = excluded.tags, ref = excluded.ref, + highway = excluded.highway, subclass = excluded.subclass, + brunnel = excluded.brunnel, network = excluded.network, route_1 = excluded.route_1, + route_2 = excluded.route_2, route_3 = excluded.route_3, route_4 = excluded.route_4, + route_5 = excluded.route_5, route_6 = excluded.route_6, z_order = excluded.z_order; + + -- Analyze source table + ANALYZE osm_transportation_name_linestring_gen3; + + -- Remove entries which have been deleted from source table + DELETE FROM osm_transportation_name_linestring_gen4 + USING transportation_name.name_changes_gen + WHERE full_update IS TRUE OR ( + transportation_name.name_changes_gen.is_old IS TRUE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen4.id + ); + + -- etldoc: osm_transportation_name_linestring_gen3 -> osm_transportation_name_linestring_gen4 + INSERT INTO osm_transportation_name_linestring_gen4 (id, geometry, tags, ref, highway, subclass, brunnel, network, + route_1, route_2, route_3, route_4, route_5, route_6, z_order) + SELECT id, ST_Simplify(geometry, 500) AS geometry, tags, ref, highway, subclass, brunnel, network, route_1, route_2, + route_3, route_4, route_5, route_6, z_order + FROM osm_transportation_name_linestring_gen3 + WHERE ( + full_update IS TRUE OR EXISTS ( + SELECT NULL + FROM transportation_name.name_changes_gen + WHERE transportation_name.name_changes_gen.is_old IS FALSE AND + transportation_name.name_changes_gen.id = osm_transportation_name_linestring_gen3.id + ) + ) AND ( + (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') AND + ST_Length(geometry) > 20000 + ) ON CONFLICT (id) DO UPDATE SET geometry = excluded.geometry, tags = excluded.tags, ref = excluded.ref, + highway = excluded.highway, subclass = excluded.subclass, + brunnel = excluded.brunnel, network = excluded.network, route_1 = excluded.route_1, + route_2 = excluded.route_2, route_3 = excluded.route_3, route_4 = excluded.route_4, + route_5 = excluded.route_5, route_6 = excluded.route_6, z_order = excluded.z_order; + + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.name_changes_gen; + + RAISE LOG 'Refresh transportation_name merged done in %', age(clock_timestamp(), t); +END; +$$ LANGUAGE plpgsql; + +-- Ensure tables are emtpy if they haven't been created +TRUNCATE osm_transportation_name_linestring_gen1; +TRUNCATE osm_transportation_name_linestring_gen2; +TRUNCATE osm_transportation_name_linestring_gen3; +TRUNCATE osm_transportation_name_linestring_gen4; + +SELECT update_transportation_name_linestring_gen(TRUE); + +-- Indexes for queries originating from update_transportation_name_linestring_gen() function +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_update_partial_idx + ON osm_transportation_name_linestring_gen1 (id) + WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND subclass IN ('motorway', 'trunk')) + AND ST_Length(geometry) > 14000; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_update_partial_idx + ON osm_transportation_name_linestring_gen2 (id) + WHERE (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') + AND ST_Length(geometry) > 20000; +CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_update_partial_idx + ON osm_transportation_name_linestring_gen3 (id) + WHERE (highway = 'motorway' OR highway = 'construction' AND subclass = 'motorway') + AND ST_Length(geometry) > 20000; + +-- Geometry Indexes +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx + ON osm_transportation_name_linestring_gen1 USING gist (geometry); +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx + ON osm_transportation_name_linestring_gen2 USING gist (geometry); +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx + ON osm_transportation_name_linestring_gen3 USING gist (geometry); +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx + ON osm_transportation_name_linestring_gen4 USING gist (geometry); + +-- Handle updates + -- Trigger to update "osm_transportation_name_network" from "osm_route_member" and "osm_highway_linestring" CREATE TABLE IF NOT EXISTS transportation_name.network_changes ( + is_old bool, osm_id bigint, - UNIQUE (osm_id) + PRIMARY KEY (is_old, osm_id) ); +-- Store IDs of changed elements from osm_route_member table. CREATE OR REPLACE FUNCTION transportation_name.route_member_store() RETURNS trigger AS $$ BEGIN - INSERT INTO transportation_name.network_changes(osm_id) - VALUES (CASE WHEN tg_op IN ('DELETE', 'UPDATE') THEN old.member ELSE new.member END) - ON CONFLICT(osm_id) DO NOTHING; - + IF tg_op = 'DELETE' OR (tg_op = 'UPDATE' AND (old.member IS DISTINCT FROM new.member)) + THEN + INSERT INTO transportation_name.network_changes(is_old, osm_id) + VALUES (TRUE, old.member) + ON CONFLICT(is_old, osm_id) DO NOTHING; + END IF; + IF (tg_op IN ('UPDATE', 'INSERT')) + THEN + INSERT INTO transportation_name.network_changes(is_old, osm_id) + VALUES (FALSE, new.member) + ON CONFLICT(is_old, osm_id) DO NOTHING; + END IF; RETURN NULL; END; $$ LANGUAGE plpgsql; +-- Store IDs of changed elements from osm_highway_linestring table. CREATE OR REPLACE FUNCTION transportation_name.highway_linestring_store() RETURNS trigger AS $$ BEGIN - INSERT INTO transportation_name.network_changes(osm_id) - VALUES (CASE WHEN tg_op IN ('DELETE', 'UPDATE') THEN old.osm_id ELSE new.osm_id END) - ON CONFLICT(osm_id) DO NOTHING; - + IF tg_op = 'DELETE' OR (tg_op = 'UPDATE' AND (old.osm_id IS DISTINCT FROM new.osm_id)) + THEN + INSERT INTO transportation_name.network_changes(is_old, osm_id) + VALUES (TRUE, old.osm_id) + ON CONFLICT(is_old, osm_id) DO NOTHING; + END IF; + IF (tg_op IN ('UPDATE', 'INSERT')) + THEN + INSERT INTO transportation_name.network_changes(is_old, osm_id) + VALUES (FALSE, new.osm_id) + ON CONFLICT(is_old, osm_id) DO NOTHING; + END IF; RETURN NULL; END; $$ LANGUAGE plpgsql; @@ -249,30 +653,38 @@ DECLARE t TIMESTAMP WITH TIME ZONE := clock_timestamp(); BEGIN RAISE LOG 'Refresh transportation_name_network'; - PERFORM update_osm_route_member(); + + -- Update Way-Relations and analyze table afterwards + PERFORM update_osm_route_member(FALSE); + ANALYZE transportation_route_member_coalesced; -- REFRESH osm_transportation_name_network DELETE - FROM osm_transportation_name_network AS n - USING - transportation_name.network_changes AS c - WHERE n.osm_id = c.osm_id; + FROM osm_transportation_name_network + USING transportation_name.network_changes c + WHERE c.is_old IS TRUE AND osm_transportation_name_network.osm_id = c.osm_id; - UPDATE osm_highway_linestring hl - SET network = rm.network_type - FROM transportation_name.network_changes c, - transportation_route_member_coalesced rm - WHERE hl.osm_id=c.osm_id - AND hl.osm_id=rm.member - AND rm.concurrency_index=1; + UPDATE osm_highway_linestring + SET network = NULL + FROM transportation_name.network_changes c + WHERE c.is_old IS TRUE AND osm_highway_linestring.osm_id = c.osm_id; - UPDATE osm_highway_linestring_gen_z11 hl + UPDATE osm_highway_linestring_gen_z11 + SET network = NULL + FROM transportation_name.network_changes c + WHERE c.is_old IS TRUE AND osm_highway_linestring_gen_z11.osm_id = c.osm_id; + + UPDATE osm_highway_linestring SET network = rm.network_type - FROM transportation_name.network_changes c, - transportation_route_member_coalesced rm - WHERE hl.osm_id=c.osm_id - AND hl.osm_id=rm.member - AND rm.concurrency_index=1; + FROM transportation_name.network_changes c + JOIN transportation_route_member_coalesced rm ON (c.osm_id = rm.member AND rm.concurrency_index=1) + WHERE c.is_old IS FALSE AND osm_highway_linestring.osm_id=c.osm_id; + + UPDATE osm_highway_linestring_gen_z11 + SET network = rm.network_type + FROM transportation_name.network_changes c + JOIN transportation_route_member_coalesced rm ON (c.osm_id = rm.member AND rm.concurrency_index=1) + WHERE c.is_old IS FALSE AND osm_highway_linestring_gen_z11.osm_id=c.osm_id; INSERT INTO osm_transportation_name_network SELECT @@ -318,7 +730,7 @@ BEGIN LEAST(rm1.rank, rm2.rank, rm3.rank, rm4.rank, rm5.rank, rm6.rank) AS route_rank FROM osm_highway_linestring hl JOIN transportation_name.network_changes AS c ON - hl.osm_id = c.osm_id + c.is_old IS FALSE AND hl.osm_id = c.osm_id LEFT OUTER JOIN transportation_route_member_coalesced rm1 ON rm1.member = hl.osm_id AND rm1.concurrency_index=1 LEFT OUTER JOIN transportation_route_member_coalesced rm2 ON rm2.member = hl.osm_id AND rm2.concurrency_index=2 LEFT OUTER JOIN transportation_route_member_coalesced rm3 ON rm3.member = hl.osm_id AND rm3.concurrency_index=3 @@ -366,51 +778,109 @@ CREATE CONSTRAINT TRIGGER trigger_refresh_network FOR EACH ROW EXECUTE PROCEDURE transportation_name.refresh_network(); --- Trigger to update "osm_transportation_name_linestring" from "osm_transportation_name_network" +-- Handle updates on +-- osm_transportation_name_network -> osm_transportation_name_linestring +-- osm_shipway_linestring -> osm_transportation_name_linestring +-- osm_aerialway_linestring -> osm_transportation_name_linestring +-- osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1 +-- osm_transportation_name_linestring -> osm_transportation_name_linestring_gen2 +-- osm_transportation_name_linestring -> osm_transportation_name_linestring_gen3 +-- osm_transportation_name_linestring -> osm_transportation_name_linestring_gen4 CREATE TABLE IF NOT EXISTS transportation_name.name_changes ( - id serial PRIMARY KEY, is_old boolean, osm_id bigint, - tags hstore, - ref character varying, - highway character varying, - subclass character varying, - brunnel character varying, - sac_scale character varying, - level integer, - layer integer, - indoor boolean, - network_type route_network_type, - route_1 character varying, - route_2 character varying, - route_3 character varying, - route_4 character varying, - route_5 character varying, - route_6 character varying + PRIMARY KEY (is_old, osm_id) +); +CREATE TABLE IF NOT EXISTS transportation_name.shipway_changes +( + is_old boolean, + osm_id bigint, + PRIMARY KEY (is_old, osm_id) +); +CREATE TABLE IF NOT EXISTS transportation_name.aerialway_changes +( + is_old boolean, + osm_id bigint, + PRIMARY KEY (is_old, osm_id) ); +-- Store IDs of changed elements from osm_transportation_name_network table. CREATE OR REPLACE FUNCTION transportation_name.name_network_store() RETURNS trigger AS $$ BEGIN IF (tg_op IN ('DELETE', 'UPDATE')) THEN - INSERT INTO transportation_name.name_changes(is_old, osm_id, tags, ref, highway, subclass, - brunnel, sac_scale, level, layer, indoor, network_type, - route_1, route_2, route_3, route_4, route_5, route_6) - VALUES (TRUE, old.osm_id, old.tags, old.ref, old.highway, old.subclass, - old.brunnel, old.sac_scale, old.level, old.layer, old.indoor, old.network_type, - old.route_1, old.route_2, old.route_3, old.route_4, old.route_5, old.route_6); + INSERT INTO transportation_name.name_changes(is_old, osm_id) + VALUES (TRUE, old.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; END IF; IF (tg_op IN ('UPDATE', 'INSERT')) THEN - INSERT INTO transportation_name.name_changes(is_old, osm_id, tags, ref, highway, subclass, - brunnel, sac_scale, level, layer, indoor, network_type, - route_1, route_2, route_3, route_4, route_5, route_6) - VALUES (FALSE, new.osm_id, new.tags, new.ref, new.highway, new.subclass, - new.brunnel, new.sac_scale, new.level, new.layer, new.indoor, new.network_type, - new.route_1, new.route_2, new.route_3, new.route_4, new.route_5, new.route_6); + INSERT INTO transportation_name.name_changes(is_old, osm_id) + VALUES (FALSE, new.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Store IDs of changed elements from osm_shipway_linestring table. +CREATE OR REPLACE FUNCTION transportation_name.name_shipway_store() RETURNS trigger AS +$$ +BEGIN + IF (tg_op IN ('DELETE', 'UPDATE')) + THEN + INSERT INTO transportation_name.shipway_changes(is_old, osm_id) + VALUES (TRUE, old.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + IF (tg_op IN ('UPDATE', 'INSERT')) + THEN + INSERT INTO transportation_name.shipway_changes(is_old, osm_id) + VALUES (FALSE, new.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Store IDs of changed elements from osm_aerialway_linestring table. +CREATE OR REPLACE FUNCTION transportation_name.name_aerialway_store() RETURNS trigger AS +$$ +BEGIN + IF (tg_op IN ('DELETE', 'UPDATE')) + THEN + INSERT INTO transportation_name.aerialway_changes(is_old, osm_id) + VALUES (TRUE, old.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + IF (tg_op IN ('UPDATE', 'INSERT')) + THEN + INSERT INTO transportation_name.aerialway_changes(is_old, osm_id) + VALUES (FALSE, new.osm_id) + ON CONFLICT (is_old, osm_id) DO NOTHING; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Store IDs of changed elements from osm_transportation_name_linestring table. +CREATE OR REPLACE FUNCTION transportation_name.name_linestring_store() RETURNS trigger AS +$$ +BEGIN + IF (tg_op = 'DELETE') + THEN + INSERT INTO transportation_name.name_changes_gen(is_old, id) + VALUES (TRUE, old.id) + ON CONFLICT (is_old, id) DO NOTHING; + END IF; + IF (tg_op = 'UPDATE' OR tg_op = 'INSERT') + THEN + INSERT INTO transportation_name.name_changes_gen(is_old, id) + VALUES (FALSE, new.id) + ON CONFLICT (is_old, id) DO NOTHING; END IF; RETURN NULL; END; @@ -422,6 +892,18 @@ CREATE TABLE IF NOT EXISTS transportation_name.updates_name t text, UNIQUE (t) ); +CREATE TABLE IF NOT EXISTS transportation_name.updates_shipway +( + id serial PRIMARY KEY, + t text, + UNIQUE (t) +); +CREATE TABLE IF NOT EXISTS transportation_name.updates_aerialway +( + id serial PRIMARY KEY, + t text, + UNIQUE (t) +); CREATE OR REPLACE FUNCTION transportation_name.flag_name() RETURNS trigger AS $$ BEGIN @@ -430,6 +912,22 @@ BEGIN END; $$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION transportation_name.flag_shipway() RETURNS trigger AS +$$ +BEGIN + INSERT INTO transportation_name.updates_shipway(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION transportation_name.flag_aerialway() RETURNS trigger AS +$$ +BEGIN + INSERT INTO transportation_name.updates_aerialway(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION transportation_name.refresh_name() RETURNS trigger AS $BODY$ DECLARE @@ -437,264 +935,517 @@ DECLARE BEGIN RAISE LOG 'Refresh transportation_name'; - -- REFRESH osm_transportation_name_linestring + -- REFRESH osm_transportation_name_linestring from osm_transportation_name_network - -- Compact the change history to keep only the first and last version, and then uniq version of row - CREATE TEMP TABLE name_changes_compact AS - SELECT DISTINCT ON (tags, ref, highway, subclass, brunnel, sac_scale, level, layer, indoor, network_type, - route_1, route_2, route_3, route_4, route_5, route_6) - tags, - ref, - highway, - subclass, - brunnel, - sac_scale, - level, - layer, - indoor, - network_type, - route_1, route_2, route_3, route_4, route_5, route_6, - coalesce(tags->'name', ref) AS name_ref - FROM (( - SELECT DISTINCT ON (osm_id) * - FROM transportation_name.name_changes - WHERE is_old - ORDER BY osm_id, - id ASC - ) - UNION ALL - ( - SELECT DISTINCT ON (osm_id) * - FROM transportation_name.name_changes - WHERE NOT is_old - ORDER BY osm_id, - id DESC - )) AS t; + -- Analyze tracking and source tables before performing update + ANALYZE transportation_name.name_changes; + ANALYZE osm_transportation_name_network; + -- 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_name_linestring_source_ids m + WHERE m.source = 0 AND EXISTS( + SELECT NULL + FROM transportation_name.name_changes 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_name_linestring AS n - USING name_changes_compact AS c - WHERE coalesce(n.ref, '') = coalesce(c.ref, '') - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.sac_scale IS NOT DISTINCT FROM c.sac_scale - AND n.level IS NOT DISTINCT FROM c.level - AND n.layer IS NOT DISTINCT FROM c.layer - AND n.indoor IS NOT DISTINCT FROM c.indoor - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + FROM osm_transportation_name_linestring m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + DELETE + FROM osm_transportation_name_linestring_source_ids m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; - INSERT INTO osm_transportation_name_linestring - SELECT (ST_Dump(geometry)).geom AS geometry, - tags|| get_basic_names(tags, geometry) AS tags, - ref, - highway, - subclass, - brunnel, - sac_scale, - level, - layer, - indoor, - network_type AS network, - route_1, route_2, route_3, route_4, route_5, route_6, - z_order + -- Analyze the tables affected by the delete-query in order to speed up subsequent queries + ANALYZE osm_transportation_name_linestring; + ANALYZE osm_transportation_name_linestring_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_id, NULL::INTEGER AS id, geometry, tags, ref, highway, subclass, brunnel, sac_scale, level, layer, + indoor, network_type, route_1, route_2, route_3, route_4, route_5, route_6, + z_order, route_rank FROM ( - SELECT ST_LineMerge(ST_Collect(n.geometry)) AS geometry, - n.tags, - n.ref, - n.highway, - n.subclass, - n.brunnel, - n.sac_scale, - n.level, - n.layer, - n.indoor, - n.network_type, - n.route_1, n.route_2, n.route_3, n.route_4, n.route_5, n.route_6, - min(n.z_order) AS z_order - FROM osm_transportation_name_network AS n - JOIN name_changes_compact AS c ON - coalesce(n.ref, '') = coalesce(c.ref, '') - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.sac_scale IS NOT DISTINCT FROM c.sac_scale - AND n.level IS NOT DISTINCT FROM c.level - AND n.layer IS NOT DISTINCT FROM c.layer - AND n.indoor IS NOT DISTINCT FROM c.indoor - AND n.network_type IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6 - GROUP BY n.tags, n.ref, n.highway, n.subclass, n.brunnel, n.sac_scale, n.level, n.layer, n.indoor, n.network_type, - n.route_1, n.route_2, n.route_3, n.route_4, n.route_5, n.route_6 - ) AS highway_union; + -- 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_name.name_changes WHERE is_old IS FALSE + ORDER BY source_id + ) affected_source_linestrings + JOIN osm_transportation_name_network ON ( + affected_source_linestrings.source_id = osm_transportation_name_network.osm_id AND + coalesce(tags->'name', '') <> '' OR coalesce(ref, '') <> '' + ); - -- REFRESH osm_transportation_name_linestring_gen1 - DELETE FROM osm_transportation_name_linestring_gen1 AS n - USING name_changes_compact AS c - WHERE - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- Drop temporary tables early to save resources + DROP TABLE affected_merged_linestrings; - INSERT INTO osm_transportation_name_linestring_gen1 - SELECT n.* - FROM osm_transportation_name_linestring_gen1_view AS n - JOIN name_changes_compact AS c ON - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- 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; - -- REFRESH osm_transportation_name_linestring_gen2 - DELETE FROM osm_transportation_name_linestring_gen2 AS n - USING name_changes_compact AS c - WHERE - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- 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, tags, ref, highway, subclass, brunnel, sac_scale, level, + layer, indoor, network AS network_type, route_1, route_2, route_3, route_4, route_5, route_6, z_order, + route_rank + FROM osm_transportation_name_linestring m + JOIN osm_transportation_name_linestring_source_ids s ON (s.source = 0 AND m.id = s.id) + WHERE EXISTS( + SELECT NULL FROM linestrings_to_merge WHERE ST_Intersects(linestrings_to_merge.geometry, m.geometry) + ); - INSERT INTO osm_transportation_name_linestring_gen2 - SELECT n.* - FROM osm_transportation_name_linestring_gen2_view AS n - JOIN name_changes_compact AS c ON - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- Analyze the created table to speed up subsequent queries + ANALYZE linestrings_to_merge; - -- REFRESH osm_transportation_name_linestring_gen3 - DELETE FROM osm_transportation_name_linestring_gen3 AS n - USING name_changes_compact AS c - WHERE - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- 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_name_linestring m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + DELETE + FROM osm_transportation_name_linestring_source_ids m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; - INSERT INTO osm_transportation_name_linestring_gen3 - SELECT n.* - FROM osm_transportation_name_linestring_gen3_view AS n - JOIN name_changes_compact AS c ON - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- 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 tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, network_type, + route_1, route_2, route_3, route_4, route_5, route_6 + ) 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 tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, network_type, route_1, + route_2, route_3, route_4, route_5, route_6 + ) as cluster_group + FROM linestrings_to_merge; - -- REFRESH osm_transportation_name_linestring_gen4 - DELETE FROM osm_transportation_name_linestring_gen4 AS n - USING name_changes_compact AS c - WHERE - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- Drop temporary tables early to save resources + DROP TABLE linestrings_to_merge; - INSERT INTO osm_transportation_name_linestring_gen4 - SELECT n.* - FROM osm_transportation_name_linestring_gen4_view AS n - JOIN name_changes_compact AS c ON - coalesce(n.tags->'name', n.ref) = c.name_ref - AND coalesce(n.tags, '') = coalesce(c.tags, '') - AND n.ref IS NOT DISTINCT FROM c.ref - AND n.highway IS NOT DISTINCT FROM c.highway - AND n.subclass IS NOT DISTINCT FROM c.subclass - AND n.brunnel IS NOT DISTINCT FROM c.brunnel - AND n.network IS NOT DISTINCT FROM c.network_type - AND n.route_1 IS NOT DISTINCT FROM c.route_1 - AND n.route_2 IS NOT DISTINCT FROM c.route_2 - AND n.route_3 IS NOT DISTINCT FROM c.route_3 - AND n.route_4 IS NOT DISTINCT FROM c.route_4 - AND n.route_5 IS NOT DISTINCT FROM c.route_5 - AND n.route_6 IS NOT DISTINCT FROM c.route_6; + -- 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; - DROP TABLE name_changes_compact; + -- Create temporary Merged-LineString to Source-LineStrings-ID column to store relations before they have been + -- intersected + ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS source_ids bigint[]; + + + WITH inserted_linestrings AS ( + -- Merge LineStrings of each cluster and insert them + INSERT INTO osm_transportation_name_linestring(source, geometry, source_ids, tags, ref, highway, subclass, + brunnel, sac_scale, "level", layer, indoor, network, route_1, + route_2, route_3, route_4, route_5, route_6,z_order, route_rank) + SELECT 0 AS source, (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, tags, ref, highway, subclass, brunnel, sac_scale, level, layer, + indoor, network_type, route_1, route_2, route_3, route_4, route_5, route_6, min(z_order) AS z_order, + min(route_rank) AS route_rank + FROM clustered_linestrings_to_merge + GROUP BY cluster_group, cluster, tags, ref, highway, subclass, brunnel, level, layer, sac_scale, indoor, + network_type, route_1, route_2, route_3, route_4, route_5, route_6 + RETURNING source, 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_name_linestring_source_ids (source, id, source_id) + SELECT m.source, m.id, source_id + FROM ( + SELECT source, id, unnest(source_ids) AS source_id, geometry + FROM inserted_linestrings + ) m + JOIN osm_transportation_name_network s ON (m.source_id = s.osm_id) + WHERE ST_Intersects(s.geometry, m.geometry) + ON CONFLICT (source, 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_name_linestring DROP COLUMN IF EXISTS source_ids; + + -- noinspection SqlWithoutWhere DELETE FROM transportation_name.name_changes; + -- noinspection SqlWithoutWhere DELETE FROM transportation_name.updates_name; RAISE LOG 'Refresh transportation_name done in %', age(clock_timestamp(), t); + + -- Update gen1, gen2, gen3 and gen4 tables + PERFORM update_transportation_name_linestring_gen(FALSE); + RETURN NULL; END; -$BODY$ - LANGUAGE plpgsql; +$BODY$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION transportation_name.refresh_shipway_linestring() RETURNS trigger AS +$BODY$ +DECLARE + t TIMESTAMP WITH TIME ZONE := clock_timestamp(); +BEGIN + RAISE LOG 'Refresh transportation_name shiwpway'; + + -- REFRESH osm_transportation_name_linestring from osm_shipway_linestring + + -- Analyze tracking and source tables before performing update + ANALYZE transportation_name.name_changes; + ANALYZE osm_shipway_linestring; + + -- 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_name_linestring_source_ids m + WHERE m.source = 1 AND EXISTS( + SELECT NULL + FROM transportation_name.shipway_changes 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_name_linestring m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + DELETE + FROM osm_transportation_name_linestring_source_ids m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + + -- Analyze the tables affected by the delete-query in order to speed up subsequent queries + ANALYZE osm_transportation_name_linestring; + ANALYZE osm_transportation_name_linestring_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_id, NULL::INTEGER AS id, geometry, + transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ) AS tags, shipway AS subclass, layer, z_order + 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_name.shipway_changes WHERE is_old IS FALSE + ORDER BY source_id + ) affected_source_linestrings + JOIN osm_shipway_linestring ON ( + affected_source_linestrings.source_id = osm_shipway_linestring.osm_id AND + name <> '' + ); + + -- 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, tags, subclass, layer, z_order + FROM osm_transportation_name_linestring m + JOIN osm_transportation_name_linestring_source_ids s ON (s.source = 1 AND 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_name_linestring m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + DELETE + FROM osm_transportation_name_linestring_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 tags, subclass, 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 tags, subclass, 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_name_linestring ADD COLUMN IF NOT EXISTS source_ids bigint[]; + + WITH inserted_linestrings AS ( + -- Merge LineStrings of each cluster and insert them + INSERT INTO osm_transportation_name_linestring(source, geometry, source_ids, tags, highway, subclass, + z_order) + SELECT 1 AS source, (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, tags, 'shipway' AS highway, subclass, min(z_order) AS z_order + FROM clustered_linestrings_to_merge + GROUP BY cluster_group, cluster, tags, subclass, layer + RETURNING source, 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_name_linestring_source_ids (source, id, source_id) + SELECT m.source, m.id, source_id + FROM ( + SELECT source, id, unnest(source_ids) AS source_id, geometry + FROM inserted_linestrings + ) m + JOIN osm_shipway_linestring s ON (m.source_id = s.osm_id) + WHERE ST_Intersects(s.geometry, m.geometry) + ON CONFLICT (source, 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_name_linestring DROP COLUMN IF EXISTS source_ids; + + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.shipway_changes; + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.updates_shipway; + + RAISE LOG 'Refresh transportation_name shipway done in %', age(clock_timestamp(), t); + + -- Update gen1, gen2, gen3 and gen4 tables + PERFORM update_transportation_name_linestring_gen(FALSE); + + RETURN NULL; +END; +$BODY$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION transportation_name.refresh_aerialway_linestring() RETURNS trigger AS +$BODY$ +DECLARE + t TIMESTAMP WITH TIME ZONE := clock_timestamp(); +BEGIN + RAISE LOG 'Refresh transportation_name aerialway'; + + -- REFRESH osm_transportation_name_linestring from osm_aerialway_linestring + + -- Analyze tracking and source tables before performing update + ANALYZE transportation_name.name_changes; + ANALYZE osm_aerialway_linestring; + + -- 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_name_linestring_source_ids m + WHERE m.source = 2 AND EXISTS( + SELECT NULL + FROM transportation_name.aerialway_changes 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_name_linestring m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + DELETE + FROM osm_transportation_name_linestring_source_ids m + USING affected_merged_linestrings + WHERE affected_merged_linestrings.id = m.id; + + -- Analyze the tables affected by the delete-query in order to speed up subsequent queries + ANALYZE osm_transportation_name_linestring; + ANALYZE osm_transportation_name_linestring_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_id, NULL::INTEGER AS id, geometry, + transportation_name_tags( + NULL::geometry, tags, name, name_en, name_de + ) AS tags, aerialway AS subclass, layer, z_order + 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_name.aerialway_changes WHERE is_old IS FALSE + ORDER BY source_id + ) affected_source_linestrings + JOIN osm_aerialway_linestring ON ( + affected_source_linestrings.source_id = osm_aerialway_linestring.osm_id AND + name <> '' + ); + + -- 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, tags, subclass, layer, z_order + FROM osm_transportation_name_linestring m + JOIN osm_transportation_name_linestring_source_ids s ON (s.source = 2 AND 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_name_linestring m + USING linestrings_to_merge + WHERE m.id = linestrings_to_merge.id; + DELETE + FROM osm_transportation_name_linestring_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 tags, subclass, 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 tags, subclass, 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_name_linestring ADD COLUMN IF NOT EXISTS source_ids bigint[]; + + WITH inserted_linestrings AS ( + -- Merge LineStrings of each cluster and insert them + INSERT INTO osm_transportation_name_linestring(source, geometry, source_ids, tags, highway, subclass, + z_order) + SELECT 2 AS source, (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, tags, 'aerialway' AS highway, subclass, min(z_order) AS z_order + FROM clustered_linestrings_to_merge + GROUP BY cluster_group, cluster, tags, subclass, layer + RETURNING source, 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_name_linestring_source_ids (source, id, source_id) + SELECT m.source, m.id, source_id + FROM ( + SELECT source, id, unnest(source_ids) AS source_id, geometry + FROM inserted_linestrings + ) m + JOIN osm_aerialway_linestring s ON (m.source_id = s.osm_id) + WHERE ST_Intersects(s.geometry, m.geometry) + ON CONFLICT (source, 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_name_linestring DROP COLUMN IF EXISTS source_ids; + + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.aerialway_changes; + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.updates_aerialway; + + RAISE LOG 'Refresh transportation_name aerialway done in %', age(clock_timestamp(), t); + + -- Update gen1, gen2, gen3 and gen4 tables + PERFORM update_transportation_name_linestring_gen(FALSE); + + RETURN NULL; +END; +$BODY$ LANGUAGE plpgsql; CREATE TRIGGER trigger_store_transportation_name_network AFTER INSERT OR UPDATE OR DELETE @@ -702,15 +1453,59 @@ CREATE TRIGGER trigger_store_transportation_name_network FOR EACH ROW EXECUTE PROCEDURE transportation_name.name_network_store(); +CREATE TRIGGER trigger_store_transportation_name_shipway + AFTER INSERT OR UPDATE OR DELETE + ON osm_shipway_linestring + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.name_shipway_store(); + +CREATE TRIGGER trigger_store_transportation_name_aerialway + AFTER INSERT OR UPDATE OR DELETE + ON osm_aerialway_linestring + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.name_aerialway_store(); + +CREATE TRIGGER trigger_store_transportation_name_linestring + AFTER INSERT OR UPDATE OR DELETE + ON osm_transportation_name_linestring + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.name_linestring_store(); + CREATE TRIGGER trigger_flag_name AFTER INSERT ON transportation_name.name_changes FOR EACH STATEMENT EXECUTE PROCEDURE transportation_name.flag_name(); +CREATE TRIGGER trigger_flag_shipway + AFTER INSERT + ON transportation_name.shipway_changes + FOR EACH STATEMENT +EXECUTE PROCEDURE transportation_name.flag_shipway(); + +CREATE TRIGGER trigger_flag_aerialway + AFTER INSERT + ON transportation_name.aerialway_changes + FOR EACH STATEMENT +EXECUTE PROCEDURE transportation_name.flag_aerialway(); + CREATE CONSTRAINT TRIGGER trigger_refresh_name AFTER INSERT ON transportation_name.updates_name INITIALLY DEFERRED FOR EACH ROW EXECUTE PROCEDURE transportation_name.refresh_name(); + +CREATE CONSTRAINT TRIGGER trigger_refresh_shipway + AFTER INSERT + ON transportation_name.updates_shipway + INITIALLY DEFERRED + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.refresh_shipway_linestring(); + +CREATE CONSTRAINT TRIGGER trigger_refresh_aerialway + AFTER INSERT + ON transportation_name.updates_aerialway + INITIALLY DEFERRED + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.refresh_aerialway_linestring();