From 6513ed16334d258c33f58be2bd9796d2078192c7 Mon Sep 17 00:00:00 2001 From: lukasmartinelli Date: Sat, 29 Oct 2016 10:36:57 +0200 Subject: [PATCH] Merge scaleranks for countries and states --- layers/place/mapping.yaml | 23 +++++----------- ...erge_scalerank.sql => merge_city_rank.sql} | 22 ---------------- layers/place/merge_country_rank.sql | 26 +++++++++++++++++++ layers/place/merge_state_rank.sql | 25 ++++++++++++++++++ layers/place/place.yaml | 4 ++- 5 files changed, 61 insertions(+), 39 deletions(-) rename layers/place/{merge_scalerank.sql => merge_city_rank.sql} (55%) create mode 100644 layers/place/merge_country_rank.sql create mode 100644 layers/place/merge_state_rank.sql diff --git a/layers/place/mapping.yaml b/layers/place/mapping.yaml index 6b4fd3e6..2c0303b5 100644 --- a/layers/place/mapping.yaml +++ b/layers/place/mapping.yaml @@ -4,11 +4,11 @@ name_field: &name type: string name_en_field: &name_en name: name_en - key: name_en + key: name:en type: string -scalerank_field: &scalerank - name: scalerank - key: scalerank +rank_field: &rank + name: rank + key: rank type: integer tables: country_point: @@ -20,13 +20,7 @@ tables: type: geometry - *name - *name_en - - name: name_int - key: int_name - type: string - - name: country_code_fips - key: country_code_fips - type: string - - *scalerank + - *rank filters: exclude_tags: - [ "name", "__nil__" ] @@ -48,13 +42,10 @@ tables: - name: is_in_country_code key: is_in:country_code type: string - - name: name_abbreviation - key: name:abbreviation - type: string - name: ref key: ref type: string - - *scalerank + - *rank filters: exclude_tags: - [ "name", "__nil__" ] @@ -76,7 +67,7 @@ tables: - key: population name: population type: integer - - *scalerank + - *rank filters: exclude_tags: - [ "name", "__nil__" ] diff --git a/layers/place/merge_scalerank.sql b/layers/place/merge_city_rank.sql similarity index 55% rename from layers/place/merge_scalerank.sql rename to layers/place/merge_city_rank.sql index 44b23097..fc8ec81d 100644 --- a/layers/place/merge_scalerank.sql +++ b/layers/place/merge_city_rank.sql @@ -1,25 +1,3 @@ -WITH important_country_point AS ( - SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank - FROM ne_10m_admin_0_countries AS ne, osm_country_point AS osm - WHERE - ( - ne.name ILIKE osm.name OR - ne.name ILIKE osm.name_en OR - ne.adm0_a3 ILIKE osm.country_code_fips - ) - AND ST_Within(osm.geometry, ne.geom) -) -UPDATE osm_country_point AS osm -SET scalerank = ne.scalerank -FROM important_country_point AS ne -WHERE osm.osm_id = ne.osm_id; - -DELETE FROM osm_state_point -WHERE is_in_country IN ('United Kingdom', 'USA', 'Россия', 'Brasil', 'China', 'India') - OR is_in_country_code IN ('AU', 'CN', 'IN', 'BR', 'US'); - -CREATE INDEX IF NOT EXISTS osm_country_point_scalerank_idx ON osm_country_point(scalerank); - WITH important_city_point AS ( SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank FROM ne_10m_populated_places AS ne, osm_city_point AS osm diff --git a/layers/place/merge_country_rank.sql b/layers/place/merge_country_rank.sql new file mode 100644 index 00000000..8e0a2f2c --- /dev/null +++ b/layers/place/merge_country_rank.sql @@ -0,0 +1,26 @@ +WITH important_country_point AS ( + SELECT osm.geometry, osm.osm_id, osm.name, COALESCE(NULLIF(osm.name_en, ''), ne.name) AS name_en, 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 codes + ST_Within(osm.geometry, ne.geom) + -- We leave out tiny countries + AND ne.scalerank <= 1 +) +UPDATE osm_country_point AS osm +-- We merge the labelrank not scalerank because it is more fine grained +-- and allows styling more important countries bigger than others +SET "rank" = ne.labelrank +FROM important_country_point AS ne +WHERE osm.osm_id = ne.osm_id; + +UPDATE osm_country_point AS osm +SET "rank" = 6 +WHERE "rank" <= 0 OR "rank" > 6 OR "rank" IS NULL; + +ALTER TABLE osm_country_point DROP CONSTRAINT IF EXISTS osm_country_point_rank_constraint; +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"); diff --git a/layers/place/merge_state_rank.sql b/layers/place/merge_state_rank.sql new file mode 100644 index 00000000..054c9df7 --- /dev/null +++ b/layers/place/merge_state_rank.sql @@ -0,0 +1,25 @@ +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 + 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.geom) + -- We leave out leess important states + AND ne.scalerank <= 3 AND ne.labelrank <= 2 +) +UPDATE osm_state_point AS osm +-- We merge the labelrank not scalerank because it is more fine grained +SET "rank" = ne.labelrank +FROM important_state_point AS ne +WHERE osm.osm_id = ne.osm_id; + +UPDATE osm_state_point AS osm +SET "rank" = 6 +WHERE "rank" <= 0 OR "rank" > 6; + +DELETE FROM osm_state_point WHERE "rank" IS NULL; + +ALTER TABLE osm_state_point DROP CONSTRAINT IF EXISTS osm_state_point_rank_constraint; +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"); diff --git a/layers/place/place.yaml b/layers/place/place.yaml index e53a9b21..204f25f5 100644 --- a/layers/place/place.yaml +++ b/layers/place/place.yaml @@ -18,7 +18,9 @@ schema: - ./city.sql - ./country.sql - ./state.sql - - ./merge_scalerank.sql + - ./merge_country_rank.sql + - ./merge_city_rank.sql + - ./merge_state_rank.sql - ./place.sql datasources: - type: imposm3