diff --git a/layers/mountain_peak/mountain_peak.yaml b/layers/mountain_peak/mountain_peak.yaml index ff78b87c..8d829107 100644 --- a/layers/mountain_peak/mountain_peak.yaml +++ b/layers/mountain_peak/mountain_peak.yaml @@ -16,7 +16,7 @@ layer: srid: 900913 query: (SELECT osm_id, geometry, name, name_en, name_de, {name_languages}, ele, ele_ft, rank FROM layer_mountain_peak(!bbox!, z(!scale_denominator!), !pixel_width!)) AS t schema: - - ./name.sql + - ./update_peak_point.sql - ./layer.sql datasources: - type: imposm3 diff --git a/layers/mountain_peak/name.sql b/layers/mountain_peak/name.sql deleted file mode 100644 index 7d527a86..00000000 --- a/layers/mountain_peak/name.sql +++ /dev/null @@ -1,4 +0,0 @@ -DO $$ -BEGIN - update osm_peak_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); -END $$; diff --git a/layers/mountain_peak/update_peak_point.sql b/layers/mountain_peak/update_peak_point.sql new file mode 100644 index 00000000..72f8e6c4 --- /dev/null +++ b/layers/mountain_peak/update_peak_point.sql @@ -0,0 +1,48 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_peak_point; +DROP TRIGGER IF EXISTS trigger_refresh ON mountain_peak_point.updates; + +-- etldoc: osm_peak_point -> osm_peak_point +CREATE OR REPLACE FUNCTION update_osm_peak_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_peak_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_peak_point(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS mountain_peak_point; + +CREATE TABLE IF NOT EXISTS mountain_peak_point.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION mountain_peak_point.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO mountain_peak_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION mountain_peak_point.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh mountain_peak_point'; + PERFORM update_osm_peak_point(); + DELETE FROM mountain_peak_point.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_peak_point + FOR EACH STATEMENT + EXECUTE PROCEDURE mountain_peak_point.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON mountain_peak_point.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE mountain_peak_point.refresh(); diff --git a/layers/place/island_polygon_update.sql b/layers/place/island_polygon_update.sql deleted file mode 100644 index 91e6b368..00000000 --- a/layers/place/island_polygon_update.sql +++ /dev/null @@ -1,46 +0,0 @@ -DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon; -DROP TRIGGER IF EXISTS trigger_refresh ON place_island.updates; - --- etldoc: osm_island_polygon -> osm_island_polygon -CREATE OR REPLACE FUNCTION convert_island_polygon_point() RETURNS VOID AS $$ -BEGIN - UPDATE osm_island_polygon SET geometry=ST_PointOnSurface(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point'; - ANALYZE osm_island_polygon; -END; -$$ LANGUAGE plpgsql; - -SELECT convert_island_polygon_point(); - --- Handle updates - -CREATE SCHEMA IF NOT EXISTS place_island; - -CREATE TABLE IF NOT EXISTS place_island.updates(id serial primary key, t text, unique (t)); -CREATE OR REPLACE FUNCTION place_island.flag() RETURNS trigger AS $$ -BEGIN - INSERT INTO place_island.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; - RETURN null; -END; -$$ language plpgsql; - -CREATE OR REPLACE FUNCTION place_island.refresh() RETURNS trigger AS - $BODY$ - BEGIN - RAISE LOG 'Refresh place_island'; - PERFORM convert_island_polygon_point(); - DELETE FROM place_island.updates; - RETURN null; - END; - $BODY$ -language plpgsql; - -CREATE TRIGGER trigger_flag - AFTER INSERT OR UPDATE OR DELETE ON osm_island_polygon - FOR EACH STATEMENT - EXECUTE PROCEDURE place_island.flag(); - -CREATE CONSTRAINT TRIGGER trigger_refresh - AFTER INSERT ON place_island.updates - INITIALLY DEFERRED - FOR EACH ROW - EXECUTE PROCEDURE place_island.refresh(); diff --git a/layers/place/name.sql b/layers/place/name.sql deleted file mode 100644 index 878114dc..00000000 --- a/layers/place/name.sql +++ /dev/null @@ -1,9 +0,0 @@ -DO $$ -BEGIN - update osm_continent_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_country_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_island_polygon SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_island_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_state_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_city_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); -END $$; diff --git a/layers/place/place.yaml b/layers/place/place.yaml index 7d19507f..edb8cfa1 100644 --- a/layers/place/place.yaml +++ b/layers/place/place.yaml @@ -55,15 +55,16 @@ layer: geometry_field: geometry query: (SELECT geometry, name, name_en, name_de, {name_languages}, class, rank, capital FROM layer_place(!bbox!, z(!scale_denominator!), !pixel_width!)) AS t schema: - - ./name.sql - ./types.sql - ./capital.sql - ./city.sql - - ./island_polygon_update.sql - ./island_rank.sql - - ./merge_country_rank.sql - - ./merge_city_rank.sql - - ./merge_state_rank.sql + - ./update_continent_point.sql + - ./update_country_point.sql + - ./update_island_polygon.sql + - ./update_island_point.sql + - ./update_state_point.sql + - ./update_city_point.sql - ./layer.sql datasources: - type: imposm3 diff --git a/layers/place/merge_city_rank.sql b/layers/place/update_city_point.sql similarity index 91% rename from layers/place/merge_city_rank.sql rename to layers/place/update_city_point.sql index fa91994d..825f5431 100644 --- a/layers/place/merge_city_rank.sql +++ b/layers/place/update_city_point.sql @@ -7,7 +7,7 @@ CREATE OR REPLACE FUNCTION update_osm_city_point() RETURNS VOID AS $$ BEGIN -- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 ) - -- etldoc: osm_city_point -> osm_city_point + -- etldoc: osm_city_point -> osm_city_point UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL; -- etldoc: ne_10m_populated_places -> osm_city_point @@ -40,6 +40,10 @@ BEGIN FROM important_city_point AS ne WHERE osm.osm_id = ne.osm_id; + UPDATE osm_city_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + END; $$ LANGUAGE plpgsql; @@ -56,7 +60,7 @@ CREATE OR REPLACE FUNCTION place_city.flag() RETURNS trigger AS $$ BEGIN INSERT INTO place_city.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; RETURN null; -END; +END; $$ language plpgsql; CREATE OR REPLACE FUNCTION place_city.refresh() RETURNS trigger AS diff --git a/layers/place/update_continent_point.sql b/layers/place/update_continent_point.sql new file mode 100644 index 00000000..7f4dd111 --- /dev/null +++ b/layers/place/update_continent_point.sql @@ -0,0 +1,48 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_continent_point; +DROP TRIGGER IF EXISTS trigger_refresh ON place_continent_point.updates; + +-- etldoc: osm_continent_point -> osm_continent_point +CREATE OR REPLACE FUNCTION update_osm_continent_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_continent_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_continent_point(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_continent_point; + +CREATE TABLE IF NOT EXISTS place_continent_point.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION place_continent_point.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO place_continent_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_continent_point.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_continent_point'; + PERFORM update_osm_continent_point(); + DELETE FROM place_continent_point.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_continent_point + FOR EACH STATEMENT + EXECUTE PROCEDURE place_continent_point.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_continent_point.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_continent_point.refresh(); diff --git a/layers/place/merge_country_rank.sql b/layers/place/update_country_point.sql similarity index 93% rename from layers/place/merge_country_rank.sql rename to layers/place/update_country_point.sql index afc14eaa..d56c6581 100644 --- a/layers/place/merge_country_rank.sql +++ b/layers/place/update_country_point.sql @@ -36,6 +36,10 @@ BEGIN SET "rank" = 1 WHERE "rank" = 0; + UPDATE osm_country_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + END; $$ LANGUAGE plpgsql; @@ -53,7 +57,7 @@ CREATE OR REPLACE FUNCTION place_country.flag() RETURNS trigger AS $$ BEGIN INSERT INTO place_country.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; RETURN null; -END; +END; $$ language plpgsql; CREATE OR REPLACE FUNCTION place_country.refresh() RETURNS trigger AS diff --git a/layers/place/update_island_point.sql b/layers/place/update_island_point.sql new file mode 100644 index 00000000..87968ace --- /dev/null +++ b/layers/place/update_island_point.sql @@ -0,0 +1,48 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_island_point; +DROP TRIGGER IF EXISTS trigger_refresh ON place_island_point.updates; + +-- etldoc: osm_island_point -> osm_island_point +CREATE OR REPLACE FUNCTION update_osm_island_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_island_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_island_point(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_island_point; + +CREATE TABLE IF NOT EXISTS place_island_point.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION place_island_point.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO place_island_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_island_point.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_island_point'; + PERFORM update_osm_island_point(); + DELETE FROM place_island_point.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_island_point + FOR EACH STATEMENT + EXECUTE PROCEDURE place_island_point.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_island_point.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_island_point.refresh(); diff --git a/layers/place/update_island_polygon.sql b/layers/place/update_island_polygon.sql new file mode 100644 index 00000000..e31da822 --- /dev/null +++ b/layers/place/update_island_polygon.sql @@ -0,0 +1,51 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON place_island_polygon.updates; + +-- etldoc: osm_island_polygon -> osm_island_polygon +CREATE OR REPLACE FUNCTION update_osm_island_polygon() RETURNS VOID AS $$ +BEGIN + UPDATE osm_island_polygon SET geometry=ST_PointOnSurface(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point'; + + UPDATE osm_island_polygon + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + + ANALYZE osm_island_polygon; +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_island_polygon(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_island_polygon; + +CREATE TABLE IF NOT EXISTS place_island_polygon.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION place_island_polygon.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO place_island_polygon.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_island_polygon.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_island_polygon'; + PERFORM update_osm_island_polygon(); + DELETE FROM place_island_polygon.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_island_polygon + FOR EACH STATEMENT + EXECUTE PROCEDURE place_island_polygon.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_island_polygon.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_island_polygon.refresh(); diff --git a/layers/place/merge_state_rank.sql b/layers/place/update_state_point.sql similarity index 93% rename from layers/place/merge_state_rank.sql rename to layers/place/update_state_point.sql index fcf3279e..e33af425 100644 --- a/layers/place/merge_state_rank.sql +++ b/layers/place/update_state_point.sql @@ -32,6 +32,10 @@ BEGIN DELETE FROM osm_state_point WHERE "rank" IS NULL; + UPDATE osm_state_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + END; $$ LANGUAGE plpgsql; @@ -49,7 +53,7 @@ CREATE OR REPLACE FUNCTION place_state.flag() RETURNS trigger AS $$ BEGIN INSERT INTO place_state.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; RETURN null; -END; +END; $$ language plpgsql; CREATE OR REPLACE FUNCTION place_state.refresh() RETURNS trigger AS diff --git a/layers/poi/name.sql b/layers/poi/name.sql deleted file mode 100644 index 06d23f89..00000000 --- a/layers/poi/name.sql +++ /dev/null @@ -1,5 +0,0 @@ -DO $$ -BEGIN - update osm_poi_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_poi_polygon SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); -END $$; diff --git a/layers/poi/poi.yaml b/layers/poi/poi.yaml index d149d71a..a8c0db9d 100644 --- a/layers/poi/poi.yaml +++ b/layers/poi/poi.yaml @@ -36,9 +36,8 @@ layer: srid: 900913 query: (SELECT geometry, name, name_en, name_de, {name_languages}, class, subclass, rank FROM layer_poi(!bbox!, z(!scale_denominator!), !pixel_width!)) AS t schema: - - ./poi_update.sql - - ./name.sql - - ./poi_polygon_update.sql + - ./update_poi_polygon.sql + - ./update_poi_point.sql - ./class.sql - ./layer.sql datasources: diff --git a/layers/poi/poi_polygon_update.sql b/layers/poi/poi_polygon_update.sql deleted file mode 100644 index 7154092e..00000000 --- a/layers/poi/poi_polygon_update.sql +++ /dev/null @@ -1,53 +0,0 @@ -DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon; -DROP TRIGGER IF EXISTS trigger_refresh ON poi.updates; - --- etldoc: osm_poi_polygon -> osm_poi_polygon - -CREATE OR REPLACE FUNCTION convert_poi_point() RETURNS VOID AS $$ -BEGIN - UPDATE osm_poi_polygon - SET geometry = - CASE WHEN ST_NPoints(ST_ConvexHull(geometry))=ST_NPoints(geometry) - THEN ST_Centroid(geometry) - ELSE ST_PointOnSurface(geometry) - END - WHERE ST_GeometryType(geometry) <> 'ST_Point'; - ANALYZE osm_poi_polygon; -END; -$$ LANGUAGE plpgsql; - -SELECT convert_poi_point(); - --- Handle updates - -CREATE SCHEMA IF NOT EXISTS poi; - -CREATE TABLE IF NOT EXISTS poi.updates(id serial primary key, t text, unique (t)); -CREATE OR REPLACE FUNCTION poi.flag() RETURNS trigger AS $$ -BEGIN - INSERT INTO poi.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; - RETURN null; -END; -$$ language plpgsql; - -CREATE OR REPLACE FUNCTION poi.refresh() RETURNS trigger AS - $BODY$ - BEGIN - RAISE LOG 'Refresh poi'; - PERFORM convert_poi_point(); - DELETE FROM poi.updates; - RETURN null; - END; - $BODY$ -language plpgsql; - -CREATE TRIGGER trigger_flag - AFTER INSERT OR UPDATE OR DELETE ON osm_poi_polygon - FOR EACH STATEMENT - EXECUTE PROCEDURE poi.flag(); - -CREATE CONSTRAINT TRIGGER trigger_refresh - AFTER INSERT ON poi.updates - INITIALLY DEFERRED - FOR EACH ROW - EXECUTE PROCEDURE poi.refresh(); diff --git a/layers/poi/poi_update.sql b/layers/poi/poi_update.sql deleted file mode 100644 index 75d6e9c2..00000000 --- a/layers/poi/poi_update.sql +++ /dev/null @@ -1,6 +0,0 @@ -UPDATE osm_poi_point - SET subclass = 'subway' - WHERE station = 'subway' and subclass='station'; -UPDATE osm_poi_polygon - SET subclass = 'subway' - WHERE station = 'subway' and subclass='station'; diff --git a/layers/poi/update_poi_point.sql b/layers/poi/update_poi_point.sql new file mode 100644 index 00000000..b38c680a --- /dev/null +++ b/layers/poi/update_poi_point.sql @@ -0,0 +1,52 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_point; +DROP TRIGGER IF EXISTS trigger_refresh ON poi_point.updates; + +-- etldoc: osm_poi_point -> osm_poi_point +CREATE OR REPLACE FUNCTION update_osm_poi_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_poi_point + SET subclass = 'subway' + WHERE station = 'subway' and subclass='station'; + + UPDATE osm_poi_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_poi_point(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS poi_point; + +CREATE TABLE IF NOT EXISTS poi_point.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION poi_point.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO poi_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION poi_point.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh poi_point'; + PERFORM update_osm_poi_point(); + DELETE FROM poi_point.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_poi_point + FOR EACH STATEMENT + EXECUTE PROCEDURE poi_point.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON poi_point.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE poi_point.refresh(); diff --git a/layers/poi/update_poi_polygon.sql b/layers/poi/update_poi_polygon.sql new file mode 100644 index 00000000..a27b8690 --- /dev/null +++ b/layers/poi/update_poi_polygon.sql @@ -0,0 +1,62 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON poi_polygon.updates; + +-- etldoc: osm_poi_polygon -> osm_poi_polygon + +CREATE OR REPLACE FUNCTION update_poi_polygon() RETURNS VOID AS $$ +BEGIN + UPDATE osm_poi_polygon + SET geometry = + CASE WHEN ST_NPoints(ST_ConvexHull(geometry))=ST_NPoints(geometry) + THEN ST_Centroid(geometry) + ELSE ST_PointOnSurface(geometry) + END + WHERE ST_GeometryType(geometry) <> 'ST_Point'; + + UPDATE osm_poi_polygon + SET subclass = 'subway' + WHERE station = 'subway' and subclass='station'; + + UPDATE osm_poi_polygon + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + + ANALYZE osm_poi_polygon; +END; +$$ LANGUAGE plpgsql; + +SELECT update_poi_polygon(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS poi_polygon; + +CREATE TABLE IF NOT EXISTS poi_polygon.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION poi_polygon.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO poi_polygon.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION poi_polygon.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh poi_polygon'; + PERFORM update_poi_polygon(); + DELETE FROM poi_polygon.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_poi_polygon + FOR EACH STATEMENT + EXECUTE PROCEDURE poi_polygon.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON poi_polygon.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE poi_polygon.refresh(); diff --git a/layers/transportation/transportation.yaml b/layers/transportation/transportation.yaml index 6349810c..0733be26 100644 --- a/layers/transportation/transportation.yaml +++ b/layers/transportation/transportation.yaml @@ -64,7 +64,7 @@ layer: query: (SELECT geometry, class, oneway, ramp, brunnel, service FROM layer_transportation(!bbox!, z(!scale_denominator!))) AS t schema: - ./class.sql - - ./merge_highways.sql + - ./update_transportation_merge.sql - ./layer.sql datasources: - type: imposm3 diff --git a/layers/transportation/merge_highways.sql b/layers/transportation/update_transportation_merge.sql similarity index 97% rename from layers/transportation/merge_highways.sql rename to layers/transportation/update_transportation_merge.sql index 32d5c613..6cae6ead 100644 --- a/layers/transportation/merge_highways.sql +++ b/layers/transportation/update_transportation_merge.sql @@ -6,7 +6,7 @@ DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen6 CASCAD DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen7 CASCADE; -DROP TRIGGER IF EXISTS trigger_flag2 ON osm_highway_linestring; +DROP TRIGGER IF EXISTS trigger_flag_transportation ON osm_highway_linestring; DROP TRIGGER IF EXISTS trigger_refresh ON transportation.updates; -- Instead of using relations to find out the road names we @@ -120,7 +120,7 @@ $$ language plpgsql; CREATE OR REPLACE FUNCTION transportation.refresh() RETURNS trigger AS $BODY$ BEGIN - RAISE LOG 'Refresh transportation'; + RAISE NOTICE 'Refresh transportation'; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen3; REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen4; @@ -133,7 +133,7 @@ CREATE OR REPLACE FUNCTION transportation.refresh() RETURNS trigger AS $BODY$ language plpgsql; -CREATE TRIGGER trigger_flag2 +CREATE TRIGGER trigger_flag_transportation AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring FOR EACH STATEMENT EXECUTE PROCEDURE transportation.flag(); diff --git a/layers/transportation_name/network_type.sql b/layers/transportation_name/network_type.sql index af61517d..32509918 100644 --- a/layers/transportation_name/network_type.sql +++ b/layers/transportation_name/network_type.sql @@ -28,57 +28,3 @@ DO $$ END; $$ ; - --- create GBR relations (so we can use it in the same way as other relations) -DO $$ -DECLARE gbr_geom geometry; -BEGIN - select st_buffer(geometry, 10000) into gbr_geom from ne_10m_admin_0_countries where iso_a2 = 'GB'; - delete from osm_route_member where network IN('omt-gb-motorway', 'omt-gb-trunk'); - - insert into osm_route_member (member, ref, network) - ( - SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-motorway' - from osm_highway_linestring hw - where length(hw.ref)>0 and ST_Intersects(hw.geometry, gbr_geom) - and hw.highway IN ('motorway') - ) UNION ( - SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-trunk' - from osm_highway_linestring hw - where length(hw.ref)>0 and ST_Intersects(hw.geometry, gbr_geom) - and hw.highway IN ('trunk') - ) - ; -END $$; - - - --- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes -UPDATE osm_route_member -SET network_type = - CASE - WHEN network = 'US:I' THEN 'us-interstate'::route_network_type - WHEN network = 'US:US' THEN 'us-highway'::route_network_type - WHEN network LIKE 'US:__' THEN 'us-state'::route_network_type - -- https://en.wikipedia.org/wiki/Trans-Canada_Highway - -- TODO: improve hierarchical queries using - -- http://www.openstreetmap.org/relation/1307243 - -- however the relation does not cover the whole Trans-Canada_Highway - WHEN - (network = 'CA:transcanada') OR - (network = 'CA:BC:primary' AND ref IN ('16')) OR - (name = 'Yellowhead Highway (AB)' AND ref IN ('16')) OR - (network = 'CA:SK' AND ref IN ('16')) OR - (network = 'CA:ON:primary' AND ref IN ('17', '417')) OR - (name = 'Route Transcanadienne (QC)') OR - (network = 'CA:NB' AND ref IN ('2', '16')) OR - (network = 'CA:PEI' AND ref IN ('1')) OR - (network = 'CA:NS' AND ref IN ('104', '105')) OR - (network = 'CA:NL:R' AND ref IN ('1')) OR - (name = ' Trans-Canada Highway (Super)') - THEN 'ca-transcanada'::route_network_type - WHEN network = 'omt-gb-motorway' THEN 'gb-motorway'::route_network_type - WHEN network = 'omt-gb-trunk' THEN 'gb-trunk'::route_network_type - ELSE NULL - END -; diff --git a/layers/transportation_name/transportation_name.yaml b/layers/transportation_name/transportation_name.yaml index c1c608f8..dc0fa8da 100644 --- a/layers/transportation_name/transportation_name.yaml +++ b/layers/transportation_name/transportation_name.yaml @@ -49,7 +49,8 @@ layer: query: (SELECT geometry, name, name_en, name_de, {name_languages}, ref, ref_length, network::text, class::text FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t schema: - ./network_type.sql - - ./merge_highways.sql + - ./update_route_member.sql + - ./update_transportation_name.sql - ./layer.sql datasources: - type: imposm3 diff --git a/layers/transportation_name/update_route_member.sql b/layers/transportation_name/update_route_member.sql new file mode 100644 index 00000000..74b18310 --- /dev/null +++ b/layers/transportation_name/update_route_member.sql @@ -0,0 +1,73 @@ +DROP TRIGGER IF EXISTS trigger_flag_transportation_name ON osm_route_member; + + +-- create GBR relations (so we can use it in the same way as other relations) +CREATE OR REPLACE FUNCTION update_gbr_route_members() RETURNS VOID AS $$ +DECLARE gbr_geom geometry; +BEGIN + select st_buffer(geometry, 10000) into gbr_geom from ne_10m_admin_0_countries where iso_a2 = 'GB'; + delete from osm_route_member where network IN('omt-gb-motorway', 'omt-gb-trunk'); + + insert into osm_route_member (member, ref, network) + ( + SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-motorway' + from osm_highway_linestring hw + where length(hw.ref)>0 and ST_Intersects(hw.geometry, gbr_geom) + and hw.highway IN ('motorway') + ) UNION ( + SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-trunk' + from osm_highway_linestring hw + where length(hw.ref)>0 and ST_Intersects(hw.geometry, gbr_geom) + and hw.highway IN ('trunk') + ) + ; +END; +$$ LANGUAGE plpgsql; + + +-- etldoc: osm_route_member -> osm_route_member +CREATE OR REPLACE FUNCTION update_osm_route_member() RETURNS VOID AS $$ +BEGIN + PERFORM update_gbr_route_members(); + + -- see http://wiki.openstreetmap.org/wiki/Relation:route#Road_routes + UPDATE osm_route_member + SET network_type = + CASE + WHEN network = 'US:I' THEN 'us-interstate'::route_network_type + WHEN network = 'US:US' THEN 'us-highway'::route_network_type + WHEN network LIKE 'US:__' THEN 'us-state'::route_network_type + -- https://en.wikipedia.org/wiki/Trans-Canada_Highway + -- TODO: improve hierarchical queries using + -- http://www.openstreetmap.org/relation/1307243 + -- however the relation does not cover the whole Trans-Canada_Highway + WHEN + (network = 'CA:transcanada') OR + (network = 'CA:BC:primary' AND ref IN ('16')) OR + (name = 'Yellowhead Highway (AB)' AND ref IN ('16')) OR + (network = 'CA:SK' AND ref IN ('16')) OR + (network = 'CA:ON:primary' AND ref IN ('17', '417')) OR + (name = 'Route Transcanadienne (QC)') OR + (network = 'CA:NB' AND ref IN ('2', '16')) OR + (network = 'CA:PEI' AND ref IN ('1')) OR + (network = 'CA:NS' AND ref IN ('104', '105')) OR + (network = 'CA:NL:R' AND ref IN ('1')) OR + (name = ' Trans-Canada Highway (Super)') + THEN 'ca-transcanada'::route_network_type + WHEN network = 'omt-gb-motorway' THEN 'gb-motorway'::route_network_type + WHEN network = 'omt-gb-trunk' THEN 'gb-trunk'::route_network_type + ELSE NULL + END + ; + +END; +$$ LANGUAGE plpgsql; + +CREATE INDEX IF NOT EXISTS osm_route_member_network_idx ON osm_route_member("network"); +CREATE INDEX IF NOT EXISTS osm_route_member_member_idx ON osm_route_member("member"); +CREATE INDEX IF NOT EXISTS osm_route_member_name_idx ON osm_route_member("name"); +CREATE INDEX IF NOT EXISTS osm_route_member_ref_idx ON osm_route_member("ref"); + +SELECT update_osm_route_member(); + +CREATE INDEX IF NOT EXISTS osm_route_member_network_type_idx ON osm_route_member("network_type"); diff --git a/layers/transportation_name/merge_highways.sql b/layers/transportation_name/update_transportation_name.sql similarity index 94% rename from layers/transportation_name/merge_highways.sql rename to layers/transportation_name/update_transportation_name.sql index 9b9c1269..c040e009 100644 --- a/layers/transportation_name/merge_highways.sql +++ b/layers/transportation_name/update_transportation_name.sql @@ -1,4 +1,4 @@ -DROP TRIGGER IF EXISTS trigger_flag ON osm_highway_linestring; +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 @@ -130,6 +130,8 @@ CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS $BODY$ BEGIN RAISE LOG 'Refresh transportation_name'; + PERFORM update_osm_route_member(); + REFRESH MATERIALIZED VIEW osm_transportation_name_network; REFRESH MATERIALIZED VIEW osm_transportation_name_linestring; REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen1; REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2; @@ -141,7 +143,12 @@ CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS $BODY$ language plpgsql; -CREATE TRIGGER trigger_flag +CREATE TRIGGER trigger_flag_transportation_name + AFTER INSERT OR UPDATE OR DELETE ON osm_route_member + FOR EACH STATEMENT + EXECUTE PROCEDURE transportation_name.flag(); + +CREATE TRIGGER trigger_flag_transportation_name AFTER INSERT OR UPDATE OR DELETE ON osm_highway_linestring FOR EACH STATEMENT EXECUTE PROCEDURE transportation_name.flag(); diff --git a/layers/water_name/name.sql b/layers/water_name/name.sql deleted file mode 100644 index 09ae1c6b..00000000 --- a/layers/water_name/name.sql +++ /dev/null @@ -1,5 +0,0 @@ -DO $$ -BEGIN - update osm_marine_point SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); - update osm_water_polygon SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); -END $$; diff --git a/layers/water_name/merge_marine_rank.sql b/layers/water_name/update_marine_point.sql similarity index 88% rename from layers/water_name/merge_marine_rank.sql rename to layers/water_name/update_marine_point.sql index 45566cfd..9af47fc7 100644 --- a/layers/water_name/merge_marine_rank.sql +++ b/layers/water_name/update_marine_point.sql @@ -5,7 +5,7 @@ CREATE EXTENSION IF NOT EXISTS unaccent; CREATE OR REPLACE FUNCTION update_osm_marine_point() RETURNS VOID AS $$ BEGIN - -- etldoc: osm_marine_point -> osm_marine_point + -- etldoc: osm_marine_point -> osm_marine_point UPDATE osm_marine_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL; -- etldoc: ne_10m_geography_marine_polys -> osm_marine_point @@ -20,6 +20,11 @@ BEGIN SET "rank" = scalerank FROM important_marine_point AS ne WHERE osm.osm_id = ne.osm_id; + + UPDATE osm_marine_point + SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry) + WHERE COALESCE(tags->'name:latin', tags->'name:nonlatin', tags->'name_int') IS NULL; + END; $$ LANGUAGE plpgsql; @@ -35,7 +40,7 @@ CREATE OR REPLACE FUNCTION water_name_marine.flag() RETURNS trigger AS $$ BEGIN INSERT INTO water_name_marine.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; RETURN null; -END; +END; $$ language plpgsql; CREATE OR REPLACE FUNCTION water_name_marine.refresh() RETURNS trigger AS diff --git a/layers/water_name/water_lakeline.sql b/layers/water_name/update_water_lakeline.sql similarity index 92% rename from layers/water_name/water_lakeline.sql rename to layers/water_name/update_water_lakeline.sql index 94a10cea..1faeff8c 100644 --- a/layers/water_name/water_lakeline.sql +++ b/layers/water_name/update_water_lakeline.sql @@ -8,7 +8,9 @@ DROP MATERIALIZED VIEW IF EXISTS osm_water_lakeline CASCADE; CREATE MATERIALIZED VIEW osm_water_lakeline AS ( SELECT wp.osm_id, ll.wkb_geometry AS geometry, - name, name_en, name_de, tags, ST_Area(wp.geometry) AS area + name, name_en, name_de, + slice_language_tags(tags) || get_basic_names(tags, ll.wkb_geometry) AS tags, + ST_Area(wp.geometry) AS area FROM osm_water_polygon AS wp INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id WHERE wp.name <> '' diff --git a/layers/water_name/water_point.sql b/layers/water_name/update_water_point.sql similarity index 89% rename from layers/water_name/water_point.sql rename to layers/water_name/update_water_point.sql index 490ce03e..ec6c5bdd 100644 --- a/layers/water_name/water_point.sql +++ b/layers/water_name/update_water_point.sql @@ -8,7 +8,9 @@ DROP MATERIALIZED VIEW IF EXISTS osm_water_point CASCADE; CREATE MATERIALIZED VIEW osm_water_point AS ( SELECT wp.osm_id, ST_PointOnSurface(wp.geometry) AS geometry, - wp.name, wp.name_en, wp.name_de, wp.tags, ST_Area(wp.geometry) AS area + wp.name, wp.name_en, wp.name_de, + slice_language_tags(wp.tags) || get_basic_names(wp.tags, ST_PointOnSurface(wp.geometry)) AS tags, + ST_Area(wp.geometry) AS area FROM osm_water_polygon AS wp LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id WHERE ll.osm_id IS NULL AND wp.name <> '' diff --git a/layers/water_name/water_name.yaml b/layers/water_name/water_name.yaml index 72e6a274..d499f482 100644 --- a/layers/water_name/water_name.yaml +++ b/layers/water_name/water_name.yaml @@ -20,10 +20,9 @@ layer: srid: 900913 query: (SELECT geometry, name, name_en, name_de, {name_languages}, class FROM layer_water_name(!bbox!, z(!scale_denominator!))) AS t schema: - - ./name.sql - - ./merge_marine_rank.sql - - ./water_lakeline.sql - - ./water_point.sql + - ./update_marine_point.sql + - ./update_water_lakeline.sql + - ./update_water_point.sql - ./layer.sql datasources: - type: imposm3 diff --git a/layers/waterway/name.sql b/layers/waterway/name.sql index 93fe793c..f2a144f5 100644 --- a/layers/waterway/name.sql +++ b/layers/waterway/name.sql @@ -1,4 +1,7 @@ DO $$ BEGIN update osm_waterway_linestring SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen1 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen2 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen3 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); END $$; diff --git a/layers/waterway/merge_waterway.sql b/layers/waterway/update_important_waterway.sql similarity index 84% rename from layers/waterway/merge_waterway.sql rename to layers/waterway/update_important_waterway.sql index beb66374..e1900435 100644 --- a/layers/waterway/merge_waterway.sql +++ b/layers/waterway/update_important_waterway.sql @@ -1,5 +1,5 @@ DROP TRIGGER IF EXISTS trigger_flag ON osm_waterway_linestring; -DROP TRIGGER IF EXISTS trigger_refresh ON waterway.updates; +DROP TRIGGER IF EXISTS trigger_refresh ON waterway_important.updates; -- We merge the waterways by name like the highways -- This helps to drop not important rivers (since they do not have a name) @@ -60,17 +60,17 @@ CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx O -- Handle updates -CREATE SCHEMA IF NOT EXISTS waterway; +CREATE SCHEMA IF NOT EXISTS waterway_important; -CREATE TABLE IF NOT EXISTS waterway.updates(id serial primary key, t text, unique (t)); -CREATE OR REPLACE FUNCTION waterway.flag() RETURNS trigger AS $$ +CREATE TABLE IF NOT EXISTS waterway_important.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION waterway_important.flag() RETURNS trigger AS $$ BEGIN - INSERT INTO waterway.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + INSERT INTO waterway_important.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; RETURN null; END; $$ language plpgsql; -CREATE OR REPLACE FUNCTION waterway.refresh() RETURNS trigger AS +CREATE OR REPLACE FUNCTION waterway_important.refresh() RETURNS trigger AS $BODY$ BEGIN RAISE LOG 'Refresh waterway'; @@ -78,7 +78,7 @@ CREATE OR REPLACE FUNCTION waterway.refresh() RETURNS trigger AS REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen1; REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen2; REFRESH MATERIALIZED VIEW osm_important_waterway_linestring_gen3; - DELETE FROM waterway.updates; + DELETE FROM waterway_important.updates; RETURN null; END; $BODY$ @@ -87,10 +87,10 @@ language plpgsql; CREATE TRIGGER trigger_flag AFTER INSERT OR UPDATE OR DELETE ON osm_waterway_linestring FOR EACH STATEMENT - EXECUTE PROCEDURE waterway.flag(); + EXECUTE PROCEDURE waterway_important.flag(); CREATE CONSTRAINT TRIGGER trigger_refresh - AFTER INSERT ON waterway.updates + AFTER INSERT ON waterway_important.updates INITIALLY DEFERRED FOR EACH ROW - EXECUTE PROCEDURE waterway.refresh(); + EXECUTE PROCEDURE waterway_important.refresh(); diff --git a/layers/waterway/update_waterway_linestring.sql b/layers/waterway/update_waterway_linestring.sql new file mode 100644 index 00000000..fbeec538 --- /dev/null +++ b/layers/waterway/update_waterway_linestring.sql @@ -0,0 +1,28 @@ +DROP TRIGGER IF EXISTS trigger_refresh ON osm_waterway_linestring; + +DO $$ +BEGIN + update osm_waterway_linestring SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen1 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen2 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); + update osm_waterway_linestring_gen3 SET tags = slice_language_tags(tags) || get_basic_names(tags, geometry); +END $$; + + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS waterway_linestring; +CREATE OR REPLACE FUNCTION waterway_linestring.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE NOTICE 'Refresh waterway_linestring %', NEW.osm_id; + NEW.tags = slice_language_tags(NEW.tags) || get_basic_names(NEW.tags, NEW.geometry); + RETURN NEW; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_refresh + BEFORE INSERT OR UPDATE ON osm_waterway_linestring + FOR EACH ROW + EXECUTE PROCEDURE waterway_linestring.refresh(); diff --git a/layers/waterway/waterway.yaml b/layers/waterway/waterway.yaml index 263485a9..ff0e8c9d 100644 --- a/layers/waterway/waterway.yaml +++ b/layers/waterway/waterway.yaml @@ -26,7 +26,8 @@ layer: query: (SELECT geometry, name, name_en, name_de, {name_languages}, class FROM layer_waterway(!bbox!, z(!scale_denominator!))) AS t schema: - ./name.sql - - ./merge_waterway.sql + - ./update_waterway_linestring.sql + - ./update_important_waterway.sql - ./waterway.sql datasources: - type: imposm3