diff --git a/layers/transportation_name/network_type.sql b/layers/transportation_name/network_type.sql index e207cb3..d46bc6a 100644 --- a/layers/transportation_name/network_type.sql +++ b/layers/transportation_name/network_type.sql @@ -1,5 +1,8 @@ -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_network CASCADE; -DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring CASCADE; +DROP TRIGGER IF EXISTS trigger_store_transportation_route_member ON osm_route_member; +DROP TRIGGER IF EXISTS trigger_store_transportation_highway_linestring ON osm_highway_linestring; +DROP TRIGGER IF EXISTS trigger_flag_transportation_name ON transportation_name.network_changes; +DROP TRIGGER IF EXISTS trigger_refresh_network ON transportation_name.updates_network; + 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; diff --git a/layers/transportation_name/update_transportation_name.sql b/layers/transportation_name/update_transportation_name.sql index 8a473fe..6526859 100644 --- a/layers/transportation_name/update_transportation_name.sql +++ b/layers/transportation_name/update_transportation_name.sql @@ -1,6 +1,3 @@ -DROP TRIGGER IF EXISTS trigger_flag_transportation_name ON osm_highway_linestring; -DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates; - -- 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 @@ -9,8 +6,7 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates; -- etldoc: osm_highway_linestring -> osm_transportation_name_network -- etldoc: osm_route_member -> osm_transportation_name_network -CREATE MATERIALIZED VIEW osm_transportation_name_network AS -( +CREATE TABLE IF NOT EXISTS osm_transportation_name_network AS SELECT hl.geometry, hl.osm_id, CASE WHEN length(hl.name) > 15 THEN osml10n_street_abbrev_all(hl.name) ELSE hl.name END AS "name", @@ -19,7 +15,7 @@ SELECT hl.geometry, hl.tags, rm.network_type, CASE - WHEN (rm.network_type IS NOT NULL AND nullif(rm.ref::text, '') IS NOT NULL) + WHEN rm.network_type IS NOT NULL AND nullif(rm.ref::text, '') IS NOT NULL THEN rm.ref::text ELSE hl.ref END AS ref, @@ -32,8 +28,10 @@ SELECT hl.geometry, 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) - ) /* DELAY_MATERIALIZED_VIEW_CREATION */; + LEFT JOIN osm_route_member rm ON + rm.member = hl.osm_id +; +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); @@ -179,52 +177,125 @@ CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx CREATE SCHEMA IF NOT EXISTS transportation_name; -CREATE TABLE IF NOT EXISTS transportation_name.updates +-- 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() RETURNS trigger AS +CREATE OR REPLACE FUNCTION transportation_name.flag_network() RETURNS trigger AS $$ BEGIN - INSERT INTO transportation_name.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + 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() RETURNS trigger AS +CREATE OR REPLACE FUNCTION transportation_name.refresh_network() RETURNS trigger AS $$ BEGIN RAISE LOG 'Refresh transportation_name'; PERFORM update_osm_route_member(); - REFRESH MATERIALIZED VIEW osm_transportation_name_network; + + -- 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 hl.name END AS "name", + CASE WHEN length(hl.name_en) > 15 THEN osml10n_street_abbrev_en(hl.name_en) ELSE hl.name_en END AS "name_en", + CASE WHEN length(hl.name_de) > 15 THEN osml10n_street_abbrev_de(hl.name_de) ELSE hl.name_de END AS "name_de", + hl.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 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.updates; + DELETE FROM transportation_name.network_changes; + -- noinspection SqlWithoutWhere + DELETE FROM transportation_name.updates_network; RETURN NULL; END; $$ LANGUAGE plpgsql; -CREATE TRIGGER trigger_flag_transportation_name + +CREATE TRIGGER trigger_store_transportation_route_member AFTER INSERT OR UPDATE OR DELETE ON osm_route_member - FOR EACH STATEMENT -EXECUTE PROCEDURE transportation_name.flag(); + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.route_member_store(); -CREATE TRIGGER trigger_flag_transportation_name +CREATE TRIGGER trigger_store_transportation_highway_linestring AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring - FOR EACH STATEMENT -EXECUTE PROCEDURE transportation_name.flag(); + FOR EACH ROW +EXECUTE PROCEDURE transportation_name.highway_linestring_store(); -CREATE CONSTRAINT TRIGGER trigger_refresh +CREATE TRIGGER trigger_flag_transportation_name AFTER INSERT - ON transportation_name.updates + 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(); +EXECUTE PROCEDURE transportation_name.refresh_network();