openmaptiles/layers/transportation_name/merge_highways.sql

104 wiersze
4.6 KiB
MySQL
Czysty Zwykły widok Historia

DROP TRIGGER IF EXISTS trigger_flag ON osm_highway_linestring;
DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates;
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
2017-01-05 17:47:10 +00:00
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen1 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen2 CASCADE;
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
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,
name_en,
ref,
highway,
z_order
FROM (
SELECT
ST_LineMerge(ST_Collect(geometry)) AS geometry,
name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
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, name_en, highway, ref
) AS highway_union
);
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 (
2017-01-18 15:13:37 +00:00
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, z_order
FROM osm_transportation_name_linestring
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
);
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 (
2017-01-18 15:13:37 +00:00
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, z_order
FROM osm_transportation_name_linestring_gen1
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
);
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 (
2017-01-18 15:13:37 +00:00
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, z_order
FROM osm_transportation_name_linestring_gen2
WHERE highway = 'motorway' AND ST_Length(geometry) > 20000
);
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry);
-- Handle updates
2017-01-05 17:47:10 +00:00
CREATE SCHEMA IF NOT EXISTS transportation_name;
CREATE TABLE IF NOT EXISTS transportation_name.updates(id serial primary key, t text, unique (t));
CREATE OR REPLACE FUNCTION transportation_name.flag() RETURNS trigger AS $$
BEGIN
INSERT INTO transportation_name.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN null;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS
$BODY$
BEGIN
RAISE LOG 'Refresh transportation_name';
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;
DELETE FROM transportation_name.updates;
RETURN null;
END;
$BODY$
2017-01-04 04:35:39 +00:00
language plpgsql;
CREATE TRIGGER trigger_flag
AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring
FOR EACH STATEMENT
EXECUTE PROCEDURE transportation_name.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT ON transportation_name.updates
INITIALLY DEFERRED
FOR EACH ROW
2017-01-05 17:47:10 +00:00
EXECUTE PROCEDURE transportation_name.refresh();