diff --git a/layers/place/important_place.sql b/layers/place/important_place.sql new file mode 100644 index 00000000..3d9d5f4f --- /dev/null +++ b/layers/place/important_place.sql @@ -0,0 +1,22 @@ +CREATE TABLE IF NOT EXISTS osm_important_place_point AS ( + SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, osm.place, ne.scalerank, COALESCE(osm.population, ne.pop_min) AS population + FROM ne_10m_populated_places AS ne, osm_place_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 + ) + AND (osm.place = 'city' OR osm.place= 'town' OR osm.place = 'village') + AND ST_DWithin(ne.geom, osm.geometry, 50000) +); + +CREATE INDEX IF NOT EXISTS osm_important_place_point_geometry_idx ON osm_important_place_point USING gist(geometry); +CLUSTER osm_important_place_point USING osm_important_place_point_geometry_idx; diff --git a/layers/place/place.sql b/layers/place/place.sql index 2e0ef613..dc3b3e47 100644 --- a/layers/place/place.sql +++ b/layers/place/place.sql @@ -1,26 +1,3 @@ -CREATE TABLE IF NOT EXISTS osm_important_place_point AS ( - SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, osm.place, ne.scalerank, COALESCE(osm.population, ne.pop_min) AS population - FROM ne_10m_populated_places AS ne, osm_place_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 - ) - AND (osm.place = 'city' OR osm.place= 'town' OR osm.place = 'village') - AND ST_DWithin(ne.geom, osm.geometry, 50000) -); - -CREATE INDEX IF NOT EXISTS osm_important_place_point_geometry_idx ON osm_important_place_point USING gist(geometry); -CLUSTER osm_important_place_point USING osm_important_place_point_geometry_idx; - CREATE OR REPLACE VIEW place_z2 AS ( SELECT geometry, name, place, scalerank, population FROM osm_important_place_point diff --git a/layers/place/place.yaml b/layers/place/place.yaml index 896b715d..3a7c602e 100644 --- a/layers/place/place.yaml +++ b/layers/place/place.yaml @@ -9,6 +9,7 @@ layer: schema: - ./country.sql - ./state.sql + - ./important_place.sql - ./place.sql datasources: - type: imposm3