From 8b6e69e440a3fce5e22ef3442028f9bc86dba9d0 Mon Sep 17 00:00:00 2001 From: Brian Sperlongano Date: Mon, 20 Sep 2021 12:40:36 -0400 Subject: [PATCH] BUGFIX: Ignore duplicate route concurrencies (#1233) While troubleshooting #1230, I discovered that there were cases where a way was a member of the same route relation more than once, such as: https://www.openstreetmap.org/way/17439235 This segment would end up showing duplicate highway shields in a rendered style, which is not desirable. While I personally think this style of tagging is wrong, it's a relatively easy fix to remove those duplicates. This PR replaces `ROW_NUMBER()` with `DENSE_RANK()` in the concurrency index generation code and adds a `DISTINCT` constraint on the concurrency join to handle multiple member rows with the same concurrency index. Since I was in this file, I also fixed the copy/paste error in generating the route names. Screenshot from database showing correct mapping: ![image](https://user-images.githubusercontent.com/3254090/133725554-1aa5dbbc-59a8-4674-a446-b92adb96c2a1.png) --- layers/transportation/update_route_member.sql | 2 +- layers/transportation_name/update_transportation_name.sql | 5 +++-- 2 files changed, 4 insertions(+), 3 deletions(-) diff --git a/layers/transportation/update_route_member.sql b/layers/transportation/update_route_member.sql index 5f453aea..c7801f72 100644 --- a/layers/transportation/update_route_member.sql +++ b/layers/transportation/update_route_member.sql @@ -85,7 +85,7 @@ ALTER TABLE osm_route_member ADD COLUMN IF NOT EXISTS concurrency_index int; INSERT INTO osm_route_member (id, concurrency_index) SELECT id, - ROW_NUMBER() over (PARTITION BY member ORDER BY network_type, network, LENGTH(ref), ref) AS concurrency_index + DENSE_RANK() over (PARTITION BY member ORDER BY network_type, network, LENGTH(ref), ref) AS concurrency_index FROM osm_route_member ON CONFLICT (id) DO UPDATE SET concurrency_index = EXCLUDED.concurrency_index; diff --git a/layers/transportation_name/update_transportation_name.sql b/layers/transportation_name/update_transportation_name.sql index bef2d8ef..56457318 100644 --- a/layers/transportation_name/update_transportation_name.sql +++ b/layers/transportation_name/update_transportation_name.sql @@ -25,7 +25,8 @@ SELECT route_1, route_2, route_3, route_4, route_5, route_6, z_order FROM ( - SELECT hl.geometry, + SELECT DISTINCT ON (hl.osm_id) + hl.geometry, hl.osm_id, CASE WHEN length(hl.name) > 15 THEN osml10n_street_abbrev_all(hl.name) ELSE NULLIF(hl.name, '') END AS "name", CASE WHEN length(hl.name_en) > 15 THEN osml10n_street_abbrev_en(hl.name_en) ELSE NULLIF(hl.name_en, '') END AS "name_en", @@ -48,7 +49,7 @@ FROM ( NULLIF(rm3.network, '') || '=' || COALESCE(rm3.ref, '') AS route_3, NULLIF(rm4.network, '') || '=' || COALESCE(rm4.ref, '') AS route_4, NULLIF(rm5.network, '') || '=' || COALESCE(rm5.ref, '') AS route_5, - NULLIF(rm6.network, '') || '=' || NULLIF(rm6.ref, '') AS route_6, + NULLIF(rm6.network, '') || '=' || COALESCE(rm6.ref, '') AS route_6, hl.z_order FROM osm_highway_linestring hl LEFT OUTER JOIN osm_route_member rm1 ON rm1.member = hl.osm_id AND rm1.concurrency_index=1