From c5f05e7c3a156d2754d105308bcb7f974492ef02 Mon Sep 17 00:00:00 2001 From: stirringhalo Date: Thu, 5 Jan 2017 08:59:15 -0500 Subject: [PATCH] Functions and triggers for state, country and city ranks --- layers/place/merge_city_rank.sql | 105 ++++++++++++++++++++-------- layers/place/merge_country_rank.sql | 92 +++++++++++++++++------- layers/place/merge_state_rank.sql | 84 ++++++++++++++++------ 3 files changed, 204 insertions(+), 77 deletions(-) diff --git a/layers/place/merge_city_rank.sql b/layers/place/merge_city_rank.sql index 9c68a7e..78587ab 100644 --- a/layers/place/merge_city_rank.sql +++ b/layers/place/merge_city_rank.sql @@ -1,38 +1,81 @@ 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; --- etldoc: ne_10m_populated_places -> osm_city_point --- etldoc: osm_city_point -> osm_city_point +CREATE FUNCTION update_osm_city_point() RETURNS VOID AS $$ +BEGIN -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; + -- 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; + + -- 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 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'; + SELECT 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..95a164a 100644 --- a/layers/place/merge_country_rank.sql +++ b/layers/place/merge_country_rank.sql @@ -3,32 +3,74 @@ ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_c -- 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 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 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'; + SELECT 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..d204a21 100644 --- a/layers/place/merge_state_rank.sql +++ b/layers/place/merge_state_rank.sql @@ -3,28 +3,70 @@ ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_const -- 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 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 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'; + SELECT 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();