openmaptiles/layers/transportation_name/merge_highways.sql

84 wiersze
3.5 KiB
MySQL
Czysty Zwykły widok Historia

2016-12-28 23:19:54 +00:00
-- 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
2016-12-04 01:52:52 +00:00
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
SELECT
(ST_Dump(geometry)).geom AS geometry,
-- NOTE: The osm_id is no longer the original one which can make it difficult
-- to lookup road names by OSM ID
member_osm_ids[0] AS osm_id,
member_osm_ids,
name,
ref,
highway,
z_order
FROM (
SELECT
ST_LineMerge(ST_Union(geometry)) AS geometry,
name,
ref,
highway,
min(z_order) AS z_order,
array_agg(DISTINCT osm_id) AS member_osm_ids
FROM osm_highway_linestring
-- We only care about highways (not railways) for labeling
WHERE (name <> '' OR ref <> '') AND NULLIF(highway, '') IS NOT NULL
GROUP BY name, highway, ref
) AS highway_union
) WITH NO DATA;
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 MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS (
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
) WITH NO DATA;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen1_geometry_idx ON osm_transportation_name_linestring_gen1 USING gist(geometry);
-- 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, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring_gen1
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
) WITH NO DATA;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx ON osm_transportation_name_linestring_gen2 USING gist(geometry);
-- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS (
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
FROM osm_transportation_name_linestring_gen2
WHERE highway = 'motorway' AND ST_Length(geometry) > 20000
) WITH NO DATA;
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry);
--- Triggers
CREATE OR REPLACE FUNCTION refresh_osm_transportation_name_linestring() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh osm_highway_linestring based tables';
2017-01-04 16:49:14 +00:00
REFRESH MATERIALIZED VIEW CONCURRENTLY osm_transportation_name_linestring;
REFRESH MATERIALIZED VIEW CONCURRENTLY osm_transportation_name_linestring_gen1;
REFRESH MATERIALIZED VIEW CONCURRENTLY osm_transportation_name_linestring_gen2;
REFRESH MATERIALIZED VIEW CONCURRENTLY osm_transportation_name_linestring_gen3;
RETURN null;
END;
$BODY$
2017-01-04 04:35:39 +00:00
language plpgsql;
CREATE TRIGGER trigger_refresh_osm_transportation_name_linestring
AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring
FOR EACH STATEMENT
2017-01-04 04:35:39 +00:00
EXECUTE PROCEDURE refresh_osm_transportation_name_linestring();