Implement concurrent highway routes (#1152)

Fixes #1128

This PR adds 6 new columns to the `transportation_name` column, named `route_1` through `route_6`.  These columns contain route information for a section of roadway.  The value is stored in the form **network=ref**.  For example, Interstate 95 in the United States would be `US:I=95`.  Thus, each `route_N` value contains enough information to render a highway shield.  Since a section of road can be a part of more than one route, the `route_2`, `route_3`, etc, will contain the 2nd, 3rd, etc., concurrent routes.

The technical approach was to extend the change in #1135, which added ordered concurrency indexes to the `osm_route_member` table by joining up to the the first six entries to the `osm_transportation_name_network` table.  In addition, that PR provided a ranking system for concurrent highways, ordering first by `network_type` (for example, `us-interstate`, `us-state`, etc), then alphabetically by network name, and then by ref in ascending order.  This ordering of concurrent route memberships is now exposed in this PR in the sequential `route_N` values, meaning that rendered concurrent highway shields will be reasonably sorted.

The renderings below were generated using this branch of OpenMapTiles, as well as a separate branch of openstreetmap-americana:
https://github.com/ZeLonewolf/openstreetmap-americana/tree/openmaptilers-new-features-test

The rendering approach is to use the [formatted expressions](https://maplibre.org/maplibre-gl-js-docs/style-spec/expressions/) feature in mapLibre to insert images into a string of text.  Blank shields are added to the sprite sheet for all possible route networks.  Next, a [styleimagemissing](https://maplibre.org/maplibre-gl-js-docs/api/map/) callback is registered.  As each shield ID is requested, the callback retrieves the sprite shield blank associated with the route's network, draw the `ref` text on the shield, and insert the complete shield back into the map.

Of note, this approach currently results in shields which are rotated about the road rather than being viewport aligned.  This issue is currently documented as maplibre/maplibre-gl-js#188.  A separate repository (https://github.com/ZeLonewolf/maplibre-shield-rotation-sample) has been created as a test case to fix this rotation issue.

Adding route concurrency information to OpenMapTiles would be a major step forward in achieving comprehensive highway shield renderings in a vector map!

**Renderings**:

![routes_1](https://user-images.githubusercontent.com/3254090/126054350-fa7475a7-1b60-4989-bbc2-107678e6c73b.png)
![routes_2](https://user-images.githubusercontent.com/3254090/126054351-fe73bc70-d75f-4ab5-8365-0ee3c3d3eab0.png)
![routes_3](https://user-images.githubusercontent.com/3254090/126054353-a1e74c8f-df21-423c-a300-b7f1a7c9231c.png)
![routes_4](https://user-images.githubusercontent.com/3254090/126054355-6b5dcc83-c611-42b3-bb67-d4f26d789744.png)
pull/1154/head^2
Brian Sperlongano 2021-07-26 08:28:36 -04:00 zatwierdzone przez GitHub
rodzic 3c15679555
commit b011b27e52
Nie znaleziono w bazie danych klucza dla tego podpisu
ID klucza GPG: 4AEE18F83AFDEB23
3 zmienionych plików z 144 dodań i 27 usunięć

Wyświetl plik

@ -12,6 +12,12 @@ CREATE OR REPLACE FUNCTION layer_transportation_name(bbox geometry, zoom_level i
ref text,
ref_length int,
network text,
route_1 text,
route_2 text,
route_3 text,
route_4 text,
route_5 text,
route_6 text,
class text,
subclass text,
brunnel text,
@ -28,13 +34,13 @@ SELECT geometry,
tags,
ref,
NULLIF(LENGTH(ref), 0) AS ref_length,
--TODO: The road network of the road is not yet implemented
CASE
WHEN network IS NOT NULL
THEN network::text
WHEN length(coalesce(ref, '')) > 0
THEN 'road'
END AS network,
route_1, route_2, route_3, route_4, route_5, route_6,
highway_class(highway, '', subclass) AS class,
CASE
WHEN highway IS NOT NULL AND highway_class(highway, '', subclass) = 'path'
@ -96,6 +102,7 @@ FROM (
subclass,
brunnel,
network,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order,
layer,
"level",
@ -118,6 +125,7 @@ FROM (
subclass,
brunnel,
network,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order,
layer,
"level",
@ -139,6 +147,7 @@ FROM (
subclass,
brunnel,
network,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order,
layer,
"level",
@ -163,6 +172,12 @@ FROM (
'junction'::text AS subclass,
NULL AS brunnel,
NULL AS network,
NULL::text AS route_1,
NULL::text AS route_2,
NULL::text AS route_3,
NULL::text AS route_4,
NULL::text AS route_5,
NULL::text AS route_6,
z_order,
layer,
NULL::int AS level,

Wyświetl plik

@ -93,10 +93,16 @@ layer:
value of [`indoor`](http://wiki.openstreetmap.org/wiki/Key:indoor) tag.
values:
- 1
route_1: 1st route concurrency.
route_2: 2nd route concurrency.
route_3: 3rd route concurrency.
route_4: 4th route concurrency.
route_5: 5th route concurrency.
route_6: 6th route concurrency.
datasource:
geometry_field: geometry
srid: 900913
query: (SELECT geometry, name, name_en, name_de, {name_languages}, ref, ref_length, network::text, class::text, subclass, brunnel, layer, level, indoor FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
query: (SELECT geometry, name, name_en, name_de, {name_languages}, ref, ref_length, network::text, class::text, subclass, brunnel, layer, level, indoor, route_1, route_2, route_3, route_4, route_5, route_6 FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
schema:
- ./network_type.sql
- ./highway_classification.sql

Wyświetl plik

@ -22,6 +22,7 @@ SELECT
layer,
indoor,
network_type,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order
FROM (
SELECT hl.geometry,
@ -30,10 +31,10 @@ FROM (
CASE WHEN length(hl.name_en) > 15 THEN osml10n_street_abbrev_en(hl.name_en) ELSE NULLIF(hl.name_en, '') END AS "name_en",
CASE WHEN length(hl.name_de) > 15 THEN osml10n_street_abbrev_de(hl.name_de) ELSE NULLIF(hl.name_de, '') END AS "name_de",
slice_language_tags(hl.tags) AS tags,
rm.network_type,
rm1.network_type,
CASE
WHEN rm.network_type IS NOT NULL AND nullif(rm.ref::text, '') IS NOT NULL
THEN rm.ref::text
WHEN rm1.network_type IS NOT NULL AND nullif(rm1.ref::text, '') IS NOT NULL
THEN rm1.ref::text
ELSE NULLIF(hl.ref, '')
END AS ref,
hl.highway,
@ -42,10 +43,21 @@ FROM (
CASE WHEN highway IN ('footway', 'steps') THEN layer END AS layer,
CASE WHEN highway IN ('footway', 'steps') THEN level END AS level,
CASE WHEN highway IN ('footway', 'steps') THEN indoor END AS indoor,
NULLIF(rm1.network, '') || '=' || COALESCE(rm1.ref, '') AS route_1,
NULLIF(rm2.network, '') || '=' || COALESCE(rm2.ref, '') AS route_2,
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,
hl.z_order
FROM osm_highway_linestring hl
LEFT OUTER JOIN osm_route_member rm ON rm.member = hl.osm_id AND rm.concurrency_index=1
WHERE (hl.name <> '' OR hl.ref <> '' OR rm.ref <> '')
LEFT OUTER JOIN osm_route_member rm1 ON rm1.member = hl.osm_id AND rm1.concurrency_index=1
LEFT OUTER JOIN osm_route_member rm2 ON rm2.member = hl.osm_id AND rm2.concurrency_index=2
LEFT OUTER JOIN osm_route_member rm3 ON rm3.member = hl.osm_id AND rm3.concurrency_index=3
LEFT OUTER JOIN osm_route_member rm4 ON rm4.member = hl.osm_id AND rm4.concurrency_index=4
LEFT OUTER JOIN osm_route_member rm5 ON rm5.member = hl.osm_id AND rm5.concurrency_index=5
LEFT OUTER JOIN osm_route_member rm6 ON rm6.member = hl.osm_id AND rm6.concurrency_index=6
WHERE (hl.name <> '' OR hl.ref <> '' OR rm1.ref <> '' OR rm1.network <> '')
AND NULLIF(hl.highway, '') IS NOT NULL
) AS t;
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id);
@ -68,6 +80,7 @@ SELECT (ST_Dump(geometry)).geom AS geometry,
layer,
indoor,
network_type AS network,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order
FROM (
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
@ -86,10 +99,12 @@ FROM (
layer,
indoor,
network_type,
route_1, route_2, route_3, route_4, route_5, route_6,
min(z_order) AS z_order
FROM osm_transportation_name_network
WHERE name <> '' OR ref <> ''
GROUP BY name, name_en, name_de, tags, ref, highway, subclass, "level", layer, indoor, network_type
GROUP BY name, name_en, name_de, tags, ref, highway, subclass, "level", layer, indoor, network_type,
route_1, route_2, route_3, route_4, route_5, route_6
) AS highway_union
;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_name_ref_idx ON osm_transportation_name_linestring (coalesce(name, ''), coalesce(ref, ''));
@ -111,6 +126,7 @@ SELECT ST_Simplify(geometry, 50) AS geometry,
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'))
@ -138,6 +154,7 @@ SELECT ST_Simplify(geometry, 120) AS geometry,
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'))
@ -165,6 +182,7 @@ SELECT ST_Simplify(geometry, 200) AS geometry,
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')
@ -192,6 +210,7 @@ SELECT ST_Simplify(geometry, 500) AS geometry,
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')
@ -282,6 +301,7 @@ BEGIN
layer,
indoor,
network_type,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order
FROM (
SELECT hl.geometry,
@ -292,8 +312,8 @@ BEGIN
slice_language_tags(hl.tags) AS tags,
rm.network_type,
CASE
WHEN rm.network_type IS NOT NULL AND NULLIF(rm.ref::text, '') IS NOT NULL
THEN rm.ref::text
WHEN rm1.network_type IS NOT NULL AND nullif(rm1.ref::text, '') IS NOT NULL
THEN rm1.ref::text
ELSE NULLIF(hl.ref, '')
END AS ref,
hl.highway,
@ -302,6 +322,7 @@ BEGIN
CASE WHEN highway IN ('footway', 'steps') THEN layer END AS layer,
CASE WHEN highway IN ('footway', 'steps') THEN level END AS level,
CASE WHEN highway IN ('footway', 'steps') THEN indoor END AS indoor,
route_1, route_2, route_3, route_4, route_5, route_6,
hl.z_order
FROM osm_highway_linestring hl
JOIN transportation_name.network_changes AS c ON
@ -364,7 +385,13 @@ CREATE TABLE IF NOT EXISTS transportation_name.name_changes
level integer,
layer integer,
indoor boolean,
network_type route_network_type
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
);
CREATE OR REPLACE FUNCTION transportation_name.name_network_store() RETURNS trigger AS
@ -373,16 +400,20 @@ BEGIN
IF (tg_op IN ('DELETE', 'UPDATE'))
THEN
INSERT INTO transportation_name.name_changes(is_old, osm_id, name, name_en, name_de, ref, highway, subclass,
brunnel, level, layer, indoor, network_type)
VALUES (TRUE, old.osm_id, old.name, old.name_en, old.name_de, old.ref, old.highway, old.subclass,
old.brunnel, old.level, old.layer, old.indoor, old.network_type);
brunnel, level, layer, indoor, network_type,
route_1, route_2, route_3, route_4, route_5, route_6)
VALUES (TRUE, old.osm_id, old.name, old.name_en, old.name_de, old.tags, old.highway, old.subclass,
old.brunnel, 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);
END IF;
IF (tg_op IN ('UPDATE', 'INSERT'))
THEN
INSERT INTO transportation_name.name_changes(is_old, osm_id, name, name_en, name_de, ref, highway, subclass,
brunnel, level, layer, indoor, network_type)
brunnel, level, layer, indoor, network_type,
route_1, route_2, route_3, route_4, route_5, route_6)
VALUES (FALSE, new.osm_id, new.name, new.name_en, new.name_de, new.ref, new.highway, new.subclass,
new.brunnel, new.level, new.layer, new.indoor, new.network_type);
new.brunnel, 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);
END IF;
RETURN NULL;
END;
@ -413,7 +444,8 @@ BEGIN
-- 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 (name, name_en, name_de, ref, highway, subclass, brunnel, level, layer, indoor, network_type)
SELECT DISTINCT ON (name, name_en, name_de, ref, highway, subclass, brunnel, level, layer, indoor, network_type,
route_1, route_2, route_3, route_4, route_5, route_6)
name,
name_en,
name_de,
@ -425,6 +457,7 @@ BEGIN
layer,
indoor,
network_type,
route_1, route_2, route_3, route_4, route_5, route_6,
coalesce(name, ref) AS name_ref
FROM ((
SELECT DISTINCT ON (osm_id) *
@ -455,7 +488,13 @@ BEGIN
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.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;
INSERT INTO osm_transportation_name_linestring
SELECT (ST_Dump(geometry)).geom AS geometry,
@ -472,6 +511,7 @@ BEGIN
layer,
indoor,
network_type AS network,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order
FROM (
SELECT ST_LineMerge(ST_Collect(n.geometry)) AS geometry,
@ -489,6 +529,7 @@ BEGIN
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
@ -503,7 +544,14 @@ BEGIN
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
GROUP BY n.name, n.name_en, n.name_de, n.ref, n.highway, n.subclass, n.brunnel, n.level, n.layer, n.indoor, n.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.name, n.name_en, n.name_de, n.ref, n.highway, n.subclass, n.brunnel, 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;
-- REFRESH osm_transportation_name_linestring_gen1
@ -518,7 +566,13 @@ BEGIN
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.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;
INSERT INTO osm_transportation_name_linestring_gen1
SELECT n.*
@ -532,7 +586,13 @@ BEGIN
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.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;
-- REFRESH osm_transportation_name_linestring_gen2
DELETE FROM osm_transportation_name_linestring_gen2 AS n
@ -546,7 +606,13 @@ BEGIN
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.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;
INSERT INTO osm_transportation_name_linestring_gen2
SELECT n.*
@ -560,7 +626,13 @@ BEGIN
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.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;
-- REFRESH osm_transportation_name_linestring_gen3
DELETE FROM osm_transportation_name_linestring_gen3 AS n
@ -574,7 +646,13 @@ BEGIN
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.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;
INSERT INTO osm_transportation_name_linestring_gen3
SELECT n.*
@ -588,7 +666,13 @@ BEGIN
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.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;
-- REFRESH osm_transportation_name_linestring_gen4
DELETE FROM osm_transportation_name_linestring_gen4 AS n
@ -602,7 +686,13 @@ BEGIN
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.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;
INSERT INTO osm_transportation_name_linestring_gen4
SELECT n.*
@ -616,7 +706,13 @@ BEGIN
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.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;
DROP TABLE name_changes_compact;
DELETE FROM transportation_name.name_changes;