When OSM roads in the `transportation_name` layer are stitched together, their grouping does not consider all `name:*` tags.
As a result, roads with different `name:*` tags may be stitched together.
The `waterway` layer performs the grouping properly, for the same purpose:
1685eaccbd/layers/waterway/update_important_waterway.sql (L34)
Co-authored-by: Frédéric Rodrigo <fred.rodrigo@gmail.com>
317 lines
12 KiB
PL/PgSQL
317 lines
12 KiB
PL/PgSQL
-- 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
|
|
|
|
|
|
-- etldoc: osm_highway_linestring -> osm_transportation_name_network
|
|
-- etldoc: osm_route_member -> osm_transportation_name_network
|
|
CREATE TABLE IF NOT EXISTS osm_transportation_name_network AS
|
|
SELECT
|
|
geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
"level",
|
|
layer,
|
|
indoor,
|
|
network_type,
|
|
z_order
|
|
FROM (
|
|
SELECT 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",
|
|
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,
|
|
CASE
|
|
WHEN rm.network_type IS NOT NULL AND nullif(rm.ref::text, '') IS NOT NULL
|
|
THEN rm.ref::text
|
|
ELSE NULLIF(hl.ref, '')
|
|
END AS ref,
|
|
hl.highway,
|
|
hl.construction,
|
|
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,
|
|
ROW_NUMBER() OVER (PARTITION BY hl.osm_id
|
|
ORDER BY rm.network_type) AS "rank",
|
|
hl.z_order
|
|
FROM osm_highway_linestring hl
|
|
LEFT JOIN osm_route_member rm ON
|
|
rm.member = hl.osm_id
|
|
WHERE (hl.name <> '' OR hl.ref <> '')
|
|
AND NULLIF(hl.highway, '') IS NOT NULL
|
|
) AS t
|
|
WHERE ("rank" = 1 OR "rank" IS NULL);
|
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id);
|
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist (geometry);
|
|
|
|
|
|
-- etldoc: osm_transportation_name_network -> osm_transportation_name_linestring
|
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS
|
|
(
|
|
SELECT (ST_Dump(geometry)).geom AS geometry,
|
|
NULL::bigint AS osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags || get_basic_names(tags, geometry) AS "tags",
|
|
ref,
|
|
highway,
|
|
construction,
|
|
"level",
|
|
layer,
|
|
indoor,
|
|
network_type AS network,
|
|
z_order
|
|
FROM (
|
|
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags || hstore( -- store results of osml10n_street_abbrev_* above
|
|
ARRAY ['name', name, 'name:en', name_en, 'name:de', name_de]) AS tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
"level",
|
|
layer,
|
|
indoor,
|
|
network_type,
|
|
min(z_order) AS z_order
|
|
FROM osm_transportation_name_network
|
|
GROUP BY name, name_en, name_de, tags, ref, highway, construction, "level", layer, indoor, network_type
|
|
) AS highway_union
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist (geometry);
|
|
|
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_highway_partial_idx
|
|
ON osm_transportation_name_linestring (highway, construction)
|
|
WHERE highway IN ('motorway', 'trunk', 'construction');
|
|
|
|
-- etldoc: osm_transportation_name_linestring -> osm_transportation_name_linestring_gen1
|
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 50) AS geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order
|
|
FROM osm_transportation_name_linestring
|
|
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
|
|
AND ST_Length(geometry) > 8000
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
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_gen1_highway_partial_idx
|
|
ON osm_transportation_name_linestring_gen1 (highway, construction)
|
|
WHERE highway IN ('motorway', 'trunk', 'construction');
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen1 -> osm_transportation_name_linestring_gen2
|
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 120) AS geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order
|
|
FROM osm_transportation_name_linestring_gen1
|
|
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
|
|
AND ST_Length(geometry) > 14000
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
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_gen2_highway_partial_idx
|
|
ON osm_transportation_name_linestring_gen2 (highway, construction)
|
|
WHERE highway IN ('motorway', 'trunk', 'construction');
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
|
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 200) AS geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order
|
|
FROM osm_transportation_name_linestring_gen2
|
|
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
|
|
AND ST_Length(geometry) > 20000
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
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_gen3_highway_partial_idx
|
|
ON osm_transportation_name_linestring_gen3 (highway, construction)
|
|
WHERE highway IN ('motorway', 'construction');
|
|
|
|
-- etldoc: osm_transportation_name_linestring_gen3 -> osm_transportation_name_linestring_gen4
|
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen4 AS
|
|
(
|
|
SELECT ST_Simplify(geometry, 500) AS geometry,
|
|
osm_id,
|
|
name,
|
|
name_en,
|
|
name_de,
|
|
tags,
|
|
ref,
|
|
highway,
|
|
construction,
|
|
network,
|
|
z_order
|
|
FROM osm_transportation_name_linestring_gen3
|
|
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
|
|
AND ST_Length(geometry) > 20000
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
|
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx ON osm_transportation_name_linestring_gen4 USING gist (geometry);
|
|
|
|
-- Handle updates
|
|
|
|
CREATE SCHEMA IF NOT EXISTS transportation_name;
|
|
|
|
-- Trigger to update "osm_transportation_name_network" from "osm_route_member" and "osm_highway_linestring"
|
|
|
|
CREATE TABLE IF NOT EXISTS transportation_name.network_changes
|
|
(
|
|
osm_id bigint,
|
|
UNIQUE (osm_id)
|
|
);
|
|
|
|
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;
|
|
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
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;
|
|
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TABLE IF NOT EXISTS transportation_name.updates_network
|
|
(
|
|
id serial PRIMARY KEY,
|
|
t text,
|
|
UNIQUE (t)
|
|
);
|
|
CREATE OR REPLACE FUNCTION transportation_name.flag_network() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
INSERT INTO transportation_name.updates_network(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION transportation_name.refresh_network() RETURNS trigger AS
|
|
$$
|
|
BEGIN
|
|
RAISE LOG 'Refresh transportation_name';
|
|
PERFORM update_osm_route_member();
|
|
|
|
-- 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;
|
|
|
|
INSERT INTO osm_transportation_name_network
|
|
SELECT 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",
|
|
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,
|
|
CASE
|
|
WHEN rm.network_type IS NOT NULL AND NULLIF(rm.ref::text, '') IS NOT NULL
|
|
THEN rm.ref::text
|
|
ELSE NULLIF(hl.ref, '')
|
|
END AS ref,
|
|
hl.highway,
|
|
hl.construction,
|
|
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,
|
|
ROW_NUMBER() OVER (PARTITION BY hl.osm_id
|
|
ORDER BY rm.network_type) AS "rank",
|
|
hl.z_order
|
|
FROM osm_highway_linestring hl
|
|
JOIN transportation_name.network_changes AS c ON
|
|
hl.osm_id = c.osm_id
|
|
LEFT JOIN osm_route_member rm ON
|
|
rm.member = hl.osm_id;
|
|
|
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring;
|
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen1;
|
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2;
|
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen3;
|
|
REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen4;
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM transportation_name.network_changes;
|
|
-- noinspection SqlWithoutWhere
|
|
DELETE FROM transportation_name.updates_network;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
CREATE TRIGGER trigger_store_transportation_route_member
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_route_member
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE transportation_name.route_member_store();
|
|
|
|
CREATE TRIGGER trigger_store_transportation_highway_linestring
|
|
AFTER INSERT OR UPDATE OR DELETE
|
|
ON osm_highway_linestring
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE transportation_name.highway_linestring_store();
|
|
|
|
CREATE TRIGGER trigger_flag_transportation_name
|
|
AFTER INSERT
|
|
ON transportation_name.network_changes
|
|
FOR EACH STATEMENT
|
|
EXECUTE PROCEDURE transportation_name.flag_network();
|
|
|
|
CREATE CONSTRAINT TRIGGER trigger_refresh_network
|
|
AFTER INSERT
|
|
ON transportation_name.updates_network
|
|
INITIALLY DEFERRED
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE transportation_name.refresh_network();
|