diff --git a/layers/housenumber/housenumber_centroid.sql b/layers/housenumber/housenumber_centroid.sql index 8a81d6a..29c687e 100644 --- a/layers/housenumber/housenumber_centroid.sql +++ b/layers/housenumber/housenumber_centroid.sql @@ -1,4 +1,45 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_housenumber_point; +DROP TRIGGER IF EXISTS trigger_refresh ON housenumber.updates; -- etldoc: osm_housenumber_point -> osm_housenumber_point -UPDATE osm_housenumber_point SET geometry=topoint(geometry) -WHERE ST_GeometryType(geometry) <> 'ST_Point'; +CREATE OR REPLACE FUNCTION convert_housenumber_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_housenumber_point SET geometry=topoint(geometry) WHERE ST_GeometryType(geometry) <> 'ST_Point'; +END; +$$ LANGUAGE plpgsql; + +SELECT convert_housenumber_point(); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS housenumber; + +CREATE TABLE IF NOT EXISTS housenumber.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION housenumber.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO housenumber.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION housenumber.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh housenumber'; + PERFORM convert_housenumber_point(); + DELETE FROM housenumber.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_housenumber_point + FOR EACH STATEMENT + EXECUTE PROCEDURE housenumber.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON housenumber.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE housenumber.refresh(); diff --git a/layers/place/island_polygon_update.sql b/layers/place/island_polygon_update.sql index 7b5c44c..ef937a5 100644 --- a/layers/place/island_polygon_update.sql +++ b/layers/place/island_polygon_update.sql @@ -1,5 +1,46 @@ --- etldoc: osm_island_polygon -> osm_island_polygon -UPDATE osm_island_polygon SET geometry=topoint(geometry) -WHERE ST_GeometryType(geometry) <> 'ST_Point'; +DROP TRIGGER IF EXISTS trigger_flag ON osm_island_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON place_island.updates; -ANALYZE osm_island_polygon; +-- 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=topoint(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/merge_city_rank.sql b/layers/place/merge_city_rank.sql index 9c68a7e..fa91994 100644 --- a/layers/place/merge_city_rank.sql +++ b/layers/place/merge_city_rank.sql @@ -1,38 +1,82 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_city_point; +DROP TRIGGER IF EXISTS trigger_refresh ON place_city.updates; CREATE EXTENSION IF NOT EXISTS unaccent; --- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 ) --- etldoc: osm_city_point -> osm_city_point -UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL; +CREATE OR REPLACE FUNCTION update_osm_city_point() RETURNS VOID AS $$ +BEGIN --- etldoc: ne_10m_populated_places -> osm_city_point --- etldoc: osm_city_point -> osm_city_point + -- Clear OSM key:rank ( https://github.com/openmaptiles/openmaptiles/issues/108 ) + -- etldoc: osm_city_point -> osm_city_point + UPDATE osm_city_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL; -WITH important_city_point AS ( - SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank, ne.labelrank - FROM ne_10m_populated_places AS ne, osm_city_point AS osm - WHERE - ( - ne.name ILIKE osm.name OR - ne.name ILIKE osm.name_en OR - ne.namealt ILIKE osm.name OR - ne.namealt ILIKE osm.name_en OR - ne.meganame ILIKE osm.name OR - ne.meganame ILIKE osm.name_en OR - ne.gn_ascii ILIKE osm.name OR - ne.gn_ascii ILIKE osm.name_en OR - ne.nameascii ILIKE osm.name OR - ne.nameascii ILIKE osm.name_en OR - ne.name = unaccent(osm.name) - ) - AND osm.place IN ('city', 'town', 'village') - AND ST_DWithin(ne.geometry, osm.geometry, 50000) -) -UPDATE osm_city_point AS osm --- Move scalerank to range 1 to 10 and merge scalerank 5 with 6 since not enough cities --- are in the scalerank 5 bucket -SET "rank" = CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END -FROM important_city_point AS ne -WHERE osm.osm_id = ne.osm_id; + -- etldoc: ne_10m_populated_places -> osm_city_point + -- etldoc: osm_city_point -> osm_city_point + + WITH important_city_point AS ( + SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank, ne.labelrank + FROM ne_10m_populated_places AS ne, osm_city_point AS osm + WHERE + ( + ne.name ILIKE osm.name OR + ne.name ILIKE osm.name_en OR + ne.namealt ILIKE osm.name OR + ne.namealt ILIKE osm.name_en OR + ne.meganame ILIKE osm.name OR + ne.meganame ILIKE osm.name_en OR + ne.gn_ascii ILIKE osm.name OR + ne.gn_ascii ILIKE osm.name_en OR + ne.nameascii ILIKE osm.name OR + ne.nameascii ILIKE osm.name_en OR + ne.name = unaccent(osm.name) + ) + AND osm.place IN ('city', 'town', 'village') + AND ST_DWithin(ne.geometry, osm.geometry, 50000) + ) + UPDATE osm_city_point AS osm + -- Move scalerank to range 1 to 10 and merge scalerank 5 with 6 since not enough cities + -- are in the scalerank 5 bucket + SET "rank" = CASE WHEN scalerank <= 5 THEN scalerank + 1 ELSE scalerank END + FROM important_city_point AS ne + WHERE osm.osm_id = ne.osm_id; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_city_point(); CREATE INDEX IF NOT EXISTS osm_city_point_rank_idx ON osm_city_point("rank"); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_city; + +CREATE TABLE IF NOT EXISTS place_city.updates(id serial primary key, t text, unique (t)); +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; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_city.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_city rank'; + PERFORM update_osm_city_point(); + DELETE FROM place_city.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_city_point + FOR EACH STATEMENT + EXECUTE PROCEDURE place_city.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_city.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_city.refresh(); diff --git a/layers/place/merge_country_rank.sql b/layers/place/merge_country_rank.sql index f1489e3..afc14ea 100644 --- a/layers/place/merge_country_rank.sql +++ b/layers/place/merge_country_rank.sql @@ -1,34 +1,79 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_country_point; +DROP TRIGGER IF EXISTS trigger_refresh ON place_country.updates; + ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_constraint; -- etldoc: ne_10m_admin_0_countries -> osm_country_point -- etldoc: osm_country_point -> osm_country_point -WITH important_country_point AS ( - SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank - FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm - WHERE - -- We only match whether the point is within the Natural Earth polygon - -- because name matching is to difficult since OSM does not contain good - -- enough coverage of ISO codesy - ST_Within(osm.geometry, ne.geometry) - -- We leave out tiny countries - AND ne.scalerank <= 1 -) -UPDATE osm_country_point AS osm --- Normalize both scalerank and labelrank into a ranking system from 1 to 6 --- where the ranks are still distributed uniform enough across all countries -SET "rank" = LEAST(6, CEILING((scalerank + labelrank)/2.0)) -FROM important_country_point AS ne -WHERE osm.osm_id = ne.osm_id; +CREATE OR REPLACE FUNCTION update_osm_country_point() RETURNS VOID AS $$ +BEGIN -UPDATE osm_country_point AS osm -SET "rank" = 6 -WHERE "rank" IS NULL; + WITH important_country_point AS ( + SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank + FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm + WHERE + -- We only match whether the point is within the Natural Earth polygon + -- because name matching is to difficult since OSM does not contain good + -- enough coverage of ISO codesy + ST_Within(osm.geometry, ne.geometry) + -- We leave out tiny countries + AND ne.scalerank <= 1 + ) + UPDATE osm_country_point AS osm + -- Normalize both scalerank and labelrank into a ranking system from 1 to 6 + -- where the ranks are still distributed uniform enough across all countries + SET "rank" = LEAST(6, CEILING((scalerank + labelrank)/2.0)) + FROM important_country_point AS ne + WHERE osm.osm_id = ne.osm_id; --- TODO: This shouldn't be necessary? The rank function makes something wrong... -UPDATE osm_country_point AS osm -SET "rank" = 1 -WHERE "rank" = 0; + UPDATE osm_country_point AS osm + SET "rank" = 6 + WHERE "rank" IS NULL; -ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); + -- TODO: This shouldn't be necessary? The rank function makes something wrong... + UPDATE osm_country_point AS osm + SET "rank" = 1 + WHERE "rank" = 0; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_country_point(); + +-- ALTER TABLE osm_country_point ADD CONSTRAINT osm_country_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); CREATE INDEX IF NOT EXISTS osm_country_point_rank_idx ON osm_country_point("rank"); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_country; + +CREATE TABLE IF NOT EXISTS place_country.updates(id serial primary key, t text, unique (t)); +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; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_country.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_country rank'; + PERFORM update_osm_country_point(); + DELETE FROM place_country.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_country_point + FOR EACH STATEMENT + EXECUTE PROCEDURE place_country.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_country.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_country.refresh(); diff --git a/layers/place/merge_state_rank.sql b/layers/place/merge_state_rank.sql index 54e6803..fcf3279 100644 --- a/layers/place/merge_state_rank.sql +++ b/layers/place/merge_state_rank.sql @@ -1,30 +1,75 @@ +DROP TRIGGER IF EXISTS trigger_flag ON osm_state_point; +DROP TRIGGER IF EXISTS trigger_refresh ON place_state.updates; + ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_constraint; -- etldoc: ne_10m_admin_1_states_provinces_shp -> osm_state_point -- etldoc: osm_state_point -> osm_state_point -WITH important_state_point AS ( - SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank - FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm - WHERE - -- We only match whether the point is within the Natural Earth polygon - -- because name matching is difficult - ST_Within(osm.geometry, ne.geometry) - -- We leave out leess important states - AND ne.scalerank <= 3 AND ne.labelrank <= 2 -) -UPDATE osm_state_point AS osm --- Normalize both scalerank and labelrank into a ranking system from 1 to 6. -SET "rank" = LEAST(6, CEILING((scalerank + labelrank + datarank)/3.0)) -FROM important_state_point AS ne -WHERE osm.osm_id = ne.osm_id; +CREATE OR REPLACE FUNCTION update_osm_state_point() RETURNS VOID AS $$ +BEGIN --- TODO: This shouldn't be necessary? The rank function makes something wrong... -UPDATE osm_state_point AS osm -SET "rank" = 1 -WHERE "rank" = 0; + WITH important_state_point AS ( + SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, ne.scalerank, ne.labelrank, ne.datarank + FROM ne_10m_admin_1_states_provinces_shp AS ne, osm_state_point AS osm + WHERE + -- We only match whether the point is within the Natural Earth polygon + -- because name matching is difficult + ST_Within(osm.geometry, ne.geometry) + -- We leave out leess important states + AND ne.scalerank <= 3 AND ne.labelrank <= 2 + ) + UPDATE osm_state_point AS osm + -- Normalize both scalerank and labelrank into a ranking system from 1 to 6. + SET "rank" = LEAST(6, CEILING((scalerank + labelrank + datarank)/3.0)) + FROM important_state_point AS ne + WHERE osm.osm_id = ne.osm_id; -DELETE FROM osm_state_point WHERE "rank" IS NULL; + -- TODO: This shouldn't be necessary? The rank function makes something wrong... + UPDATE osm_state_point AS osm + SET "rank" = 1 + WHERE "rank" = 0; -ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); + DELETE FROM osm_state_point WHERE "rank" IS NULL; + +END; +$$ LANGUAGE plpgsql; + +SELECT update_osm_state_point(); + +-- ALTER TABLE osm_state_point ADD CONSTRAINT osm_state_point_rank_constraint CHECK("rank" BETWEEN 1 AND 6); CREATE INDEX IF NOT EXISTS osm_state_point_rank_idx ON osm_state_point("rank"); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS place_state; + +CREATE TABLE IF NOT EXISTS place_state.updates(id serial primary key, t text, unique (t)); +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; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION place_state.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh place_state rank'; + PERFORM update_osm_state_point(); + DELETE FROM place_state.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_state_point + FOR EACH STATEMENT + EXECUTE PROCEDURE place_state.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON place_state.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE place_state.refresh(); diff --git a/layers/poi/poi_polygon_update.sql b/layers/poi/poi_polygon_update.sql index 1e5073d..22484ac 100644 --- a/layers/poi/poi_polygon_update.sql +++ b/layers/poi/poi_polygon_update.sql @@ -1,5 +1,47 @@ --- etldoc: osm_poi_polygon -> osm_poi_polygon -UPDATE osm_poi_polygon SET geometry=topoint(geometry) -WHERE ST_GeometryType(geometry) <> 'ST_Point'; +DROP TRIGGER IF EXISTS trigger_flag ON osm_poi_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON poi.updates; -ANALYZE osm_poi_polygon; +-- etldoc: osm_poi_polygon -> osm_poi_polygon + +CREATE OR REPLACE FUNCTION convert_poi_point() RETURNS VOID AS $$ +BEGIN + UPDATE osm_poi_polygon SET geometry=topoint(geometry) 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/transportation_name/merge_highways.sql b/layers/transportation_name/merge_highways.sql index c834c17..7ad1f16 100644 --- a/layers/transportation_name/merge_highways.sql +++ b/layers/transportation_name/merge_highways.sql @@ -1,16 +1,18 @@ - -DROP TABLE IF EXISTS osm_transportation_name_linestring CASCADE; -DROP TABLE IF EXISTS osm_transportation_name_linestring_gen1 CASCADE; -DROP TABLE IF EXISTS osm_transportation_name_linestring_gen2 CASCADE; -DROP TABLE IF EXISTS osm_transportation_name_linestring_gen3 CASCADE; +DROP TRIGGER IF EXISTS trigger_flag 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 -- Because this works well for roads that do not have relations as well +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; + -- etldoc: osm_highway_linestring -> osm_transportation_name_linestring -CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS ( +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 @@ -35,11 +37,10 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring AS ( GROUP BY name, 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 TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS ( +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 @@ -47,7 +48,7 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen1 AS ( 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 TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS ( +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 @@ -55,9 +56,46 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring_gen2 AS ( 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 TABLE IF NOT EXISTS osm_transportation_name_linestring_gen3 AS ( +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 ); CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen3_geometry_idx ON osm_transportation_name_linestring_gen3 USING gist(geometry); + +-- Handle updates + +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$ +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 + EXECUTE PROCEDURE transportation_name.refresh(); diff --git a/layers/water_name/water_lakeline.sql b/layers/water_name/water_lakeline.sql index 16522e8..d9c58ea 100644 --- a/layers/water_name/water_lakeline.sql +++ b/layers/water_name/water_lakeline.sql @@ -1,9 +1,11 @@ - -DROP TABLE IF EXISTS osm_water_lakeline CASCADE; +DROP TRIGGER IF EXISTS trigger_flag_line ON osm_water_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON water_lakeline.updates; -- etldoc: osm_water_polygon -> osm_water_lakeline -- etldoc: lake_centerline -> osm_water_lakeline -CREATE TABLE IF NOT EXISTS osm_water_lakeline AS ( +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, ST_Area(wp.geometry) AS area @@ -11,5 +13,38 @@ CREATE TABLE IF NOT EXISTS osm_water_lakeline AS ( INNER JOIN lake_centerline ll ON wp.osm_id = ll.osm_id WHERE wp.name <> '' ); - CREATE INDEX IF NOT EXISTS osm_water_lakeline_geometry_idx ON osm_water_lakeline USING gist(geometry); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS water_lakeline; + +CREATE TABLE IF NOT EXISTS water_lakeline.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION water_lakeline.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO water_lakeline.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION water_lakeline.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh water_lakeline'; + REFRESH MATERIALIZED VIEW osm_water_lakeline; + DELETE FROM water_lakeline.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag_line + AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon + FOR EACH STATEMENT + EXECUTE PROCEDURE water_lakeline.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON water_lakeline.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE water_lakeline.refresh(); diff --git a/layers/water_name/water_point.sql b/layers/water_name/water_point.sql index 498a6e8..4870879 100644 --- a/layers/water_name/water_point.sql +++ b/layers/water_name/water_point.sql @@ -1,9 +1,11 @@ - -DROP TABLE IF EXISTS osm_water_point CASCADE; +DROP TRIGGER IF EXISTS trigger_flag_point ON osm_water_polygon; +DROP TRIGGER IF EXISTS trigger_refresh ON water_point.updates; -- etldoc: osm_water_polygon -> osm_water_point -- etldoc: lake_centerline -> osm_water_point -CREATE TABLE IF NOT EXISTS osm_water_point AS ( +DROP MATERIALIZED VIEW IF EXISTS osm_water_point CASCADE; + +CREATE MATERIALIZED VIEW osm_water_point AS ( SELECT wp.osm_id, topoint(wp.geometry) AS geometry, wp.name, wp.name_en, ST_Area(wp.geometry) AS area @@ -11,5 +13,38 @@ CREATE TABLE IF NOT EXISTS osm_water_point AS ( LEFT JOIN lake_centerline ll ON wp.osm_id = ll.osm_id WHERE ll.osm_id IS NULL AND wp.name <> '' ); - CREATE INDEX IF NOT EXISTS osm_water_point_geometry_idx ON osm_water_point USING gist (geometry); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS water_point; + +CREATE TABLE IF NOT EXISTS water_point.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION water_point.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO water_point.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION water_point.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh water_point'; + REFRESH MATERIALIZED VIEW osm_water_point; + DELETE FROM water_point.updates; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag_point + AFTER INSERT OR UPDATE OR DELETE ON osm_water_polygon + FOR EACH STATEMENT + EXECUTE PROCEDURE water_point.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON water_point.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE water_point.refresh(); diff --git a/layers/waterway/merge_waterway.sql b/layers/waterway/merge_waterway.sql index 604e004..5cf6ab0 100644 --- a/layers/waterway/merge_waterway.sql +++ b/layers/waterway/merge_waterway.sql @@ -1,15 +1,17 @@ - -DROP TABLE IF EXISTS osm_important_waterway_linestring CASCADE; -DROP TABLE IF EXISTS osm_important_waterway_linestring_gen1 CASCADE; -DROP TABLE IF EXISTS osm_important_waterway_linestring_gen2 CASCADE; -DROP TABLE IF EXISTS osm_important_waterway_linestring_gen3 CASCADE; +DROP TRIGGER IF EXISTS trigger_flag ON osm_waterway_linestring; +DROP TRIGGER IF EXISTS trigger_refresh ON waterway.updates; -- We merge the waterways by name like the highways -- This helps to drop not important rivers (since they do not have a name) -- and also makes it possible to filter out too short rivers -- etldoc: osm_waterway_linestring -> osm_important_waterway_linestring -CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS ( +DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring CASCADE; +DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen1 CASCADE; +DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen2 CASCADE; +DROP MATERIALIZED VIEW IF EXISTS osm_important_waterway_linestring_gen3 CASCADE; + +CREATE MATERIALIZED VIEW osm_important_waterway_linestring AS ( SELECT (ST_Dump(geometry)).geom AS geometry, name @@ -22,11 +24,10 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring AS ( GROUP BY name ) AS waterway_union ); - CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_geometry_idx ON osm_important_waterway_linestring USING gist(geometry); -- etldoc: osm_important_waterway_linestring -> osm_important_waterway_linestring_gen1 -CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS ( +CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen1 AS ( SELECT ST_Simplify(geometry, 60) AS geometry, name FROM osm_important_waterway_linestring WHERE ST_Length(geometry) > 1000 @@ -34,7 +35,7 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen1 AS ( CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen1_geometry_idx ON osm_important_waterway_linestring_gen1 USING gist(geometry); -- etldoc: osm_important_waterway_linestring_gen1 -> osm_important_waterway_linestring_gen2 -CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS ( +CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen2 AS ( SELECT ST_Simplify(geometry, 100) AS geometry, name FROM osm_important_waterway_linestring_gen1 WHERE ST_Length(geometry) > 4000 @@ -42,9 +43,49 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen2 AS ( CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen2_geometry_idx ON osm_important_waterway_linestring_gen2 USING gist(geometry); -- etldoc: osm_important_waterway_linestring_gen2 -> osm_important_waterway_linestring_gen3 -CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen3 AS ( +CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen3 AS ( SELECT ST_Simplify(geometry, 200) AS geometry, name FROM osm_important_waterway_linestring_gen2 WHERE ST_Length(geometry) > 8000 ); CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_gen3_geometry_idx ON osm_important_waterway_linestring_gen3 USING gist(geometry); + +-- Handle updates + +CREATE SCHEMA IF NOT EXISTS waterway; + +CREATE TABLE IF NOT EXISTS waterway.updates(id serial primary key, t text, unique (t)); +CREATE OR REPLACE FUNCTION waterway.flag() RETURNS trigger AS $$ +BEGIN + INSERT INTO waterway.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING; + RETURN null; +END; +$$ language plpgsql; + +CREATE OR REPLACE FUNCTION waterway.refresh() RETURNS trigger AS + $BODY$ + BEGIN + RAISE LOG 'Refresh waterway'; + REFRESH MATERIALIZED VIEW osm_important_waterway_linestring; + 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; + RETURN null; + END; + $BODY$ +language plpgsql; + +CREATE TRIGGER trigger_flag + AFTER INSERT OR UPDATE OR DELETE ON osm_waterway_linestring + FOR EACH STATEMENT + EXECUTE PROCEDURE waterway.flag(); + +CREATE CONSTRAINT TRIGGER trigger_refresh + AFTER INSERT ON waterway.updates + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE waterway.refresh(); + + +