Major breakthrough, just some artifacting to resolve
This commit is contained in:
@@ -23,7 +23,7 @@ tables:
|
||||
key: aeroway
|
||||
type: string
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
mapping:
|
||||
aeroway:
|
||||
- aerodrome
|
||||
|
||||
@@ -3,7 +3,7 @@
|
||||
-- etldoc: ne_110m_admin_0_boundary_lines_land -> boundary_z0
|
||||
|
||||
CREATE OR REPLACE VIEW boundary_z0 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
SELECT geometry, 2 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_110m_admin_0_boundary_lines_land
|
||||
);
|
||||
|
||||
@@ -11,10 +11,10 @@ CREATE OR REPLACE VIEW boundary_z0 AS (
|
||||
-- etldoc: ne_50m_admin_1_states_provinces_lines -> boundary_z1
|
||||
|
||||
CREATE OR REPLACE VIEW boundary_z1 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
SELECT geometry, 2 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_50m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
SELECT geometry, 4 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_50m_admin_1_states_provinces_lines
|
||||
WHERE scalerank <= 2
|
||||
);
|
||||
@@ -24,102 +24,108 @@ CREATE OR REPLACE VIEW boundary_z1 AS (
|
||||
-- etldoc: ne_50m_admin_1_states_provinces_lines -> boundary_z3
|
||||
|
||||
CREATE OR REPLACE VIEW boundary_z3 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
SELECT geometry, 2 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_50m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
SELECT geometry, 4 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_50m_admin_1_states_provinces_lines
|
||||
);
|
||||
|
||||
|
||||
-- etldoc: ne_10m_admin_0_boundary_lines_land -> boundary_z4
|
||||
-- etldoc: ne_10m_admin_1_states_provinces_lines_shp -> boundary_z4
|
||||
-- etldoc: osm_border_linestring_gen10 -> boundary_z4
|
||||
|
||||
CREATE OR REPLACE VIEW boundary_z4 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
SELECT geometry, 2 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_10m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
SELECT geometry, 4 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_10m_admin_1_states_provinces_lines_shp
|
||||
WHERE scalerank <= 3 AND featurecla = 'Adm-1 boundary'
|
||||
UNION ALL
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen10
|
||||
WHERE maritime=true AND admin_level <= 2
|
||||
);
|
||||
|
||||
-- etldoc: ne_10m_admin_0_boundary_lines_land -> boundary_z5
|
||||
-- etldoc: ne_10m_admin_1_states_provinces_lines_shp -> boundary_z5
|
||||
-- etldoc: osm_border_linestring_gen9 -> boundary_z5
|
||||
|
||||
CREATE OR REPLACE VIEW boundary_z5 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
SELECT geometry, 2 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_10m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
SELECT geometry, 4 AS admin_level, false AS disputed, false AS maritime
|
||||
FROM ne_10m_admin_1_states_provinces_lines_shp
|
||||
WHERE scalerank <= 7 AND featurecla = 'Adm-1 boundary'
|
||||
UNION ALL
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen9
|
||||
WHERE maritime=true AND admin_level <= 2
|
||||
);
|
||||
|
||||
-- etldoc: ne_10m_admin_0_boundary_lines_land -> boundary_z6
|
||||
-- etldoc: ne_10m_admin_1_states_provinces_lines_shp -> boundary_z6
|
||||
|
||||
-- etldoc: osm_border_linestring_gen8 -> boundary_z6
|
||||
CREATE OR REPLACE VIEW boundary_z6 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
FROM ne_10m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
FROM ne_10m_admin_1_states_provinces_lines_shp
|
||||
WHERE scalerank <= 9 AND featurecla = 'Adm-1 boundary'
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen8
|
||||
WHERE admin_level <= 4
|
||||
);
|
||||
|
||||
-- etldoc: ne_10m_admin_0_boundary_lines_land -> boundary_z7
|
||||
-- etldoc: ne_10m_admin_1_states_provinces_lines_shp -> boundary_z7
|
||||
-- etldoc: osm_border_linestring_gen7 -> boundary_z7
|
||||
CREATE OR REPLACE VIEW boundary_z7 AS (
|
||||
SELECT geometry, 2 AS admin_level
|
||||
FROM ne_10m_admin_0_boundary_lines_land
|
||||
UNION ALL
|
||||
SELECT geometry, 4 AS admin_level
|
||||
FROM ne_10m_admin_1_states_provinces_lines_shp
|
||||
WHERE featurecla = 'Adm-1 boundary'
|
||||
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen7
|
||||
WHERE admin_level <= 4
|
||||
);
|
||||
|
||||
-- etldoc: osm_boundary_linestring_gen5 -> boundary_z8
|
||||
-- etldoc: osm_border_linestring_gen6 -> boundary_z8
|
||||
CREATE OR REPLACE VIEW boundary_z8 AS (
|
||||
SELECT geometry, admin_level
|
||||
FROM osm_boundary_linestring_gen5
|
||||
WHERE admin_level <= 4 AND ST_Length(geometry) > 1000
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen6
|
||||
WHERE admin_level <= 4
|
||||
);
|
||||
|
||||
-- etldoc: osm_boundary_linestring_gen4 -> boundary_z9
|
||||
-- etldoc: osm_border_linestring_gen5 -> boundary_z9
|
||||
CREATE OR REPLACE VIEW boundary_z9 AS (
|
||||
SELECT geometry, admin_level
|
||||
FROM osm_boundary_linestring_gen4
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen5
|
||||
WHERE admin_level <= 6
|
||||
);
|
||||
|
||||
-- etldoc: osm_boundary_linestring_gen3 -> boundary_z10
|
||||
-- etldoc: osm_border_linestring_gen4 -> boundary_z10
|
||||
CREATE OR REPLACE VIEW boundary_z10 AS (
|
||||
SELECT geometry, admin_level
|
||||
FROM osm_boundary_linestring_gen3
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen4
|
||||
WHERE admin_level <= 6
|
||||
);
|
||||
|
||||
-- etldoc: osm_boundary_linestring_gen2 -> boundary_z11
|
||||
-- etldoc: osm_border_linestring_gen3 -> boundary_z11
|
||||
CREATE OR REPLACE VIEW boundary_z11 AS (
|
||||
SELECT geometry, admin_level
|
||||
FROM osm_boundary_linestring_gen2
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen3
|
||||
WHERE admin_level <= 8
|
||||
);
|
||||
|
||||
-- etldoc: osm_boundary_linestring_gen1 -> boundary_z12
|
||||
-- etldoc: osm_border_linestring_gen2 -> boundary_z12
|
||||
CREATE OR REPLACE VIEW boundary_z12 AS (
|
||||
SELECT geometry, admin_level
|
||||
FROM osm_boundary_linestring_gen1
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen2
|
||||
);
|
||||
|
||||
-- etldoc: osm_border_linestring_gen1 -> boundary_z12
|
||||
CREATE OR REPLACE VIEW boundary_z13 AS (
|
||||
SELECT geometry, admin_level, disputed, maritime
|
||||
FROM osm_border_linestring_gen1
|
||||
);
|
||||
|
||||
-- etldoc: layer_boundary[shape=record fillcolor=lightpink, style="rounded,filled",
|
||||
-- etldoc: label="<sql> layer_boundary |<z0> z0 |<z1_2> z1_2 | <z3> z3 | <z4> z4 | <z5> z5 | <z6> z6 | <z7> z7 | <z8> z8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13+"]
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_boundary (bbox geometry, zoom_level int)
|
||||
RETURNS TABLE(geometry geometry, admin_level int) AS $$
|
||||
SELECT geometry, admin_level FROM (
|
||||
RETURNS TABLE(geometry geometry, admin_level int, disputed int, maritime int) AS $$
|
||||
SELECT geometry, admin_level, disputed::int, maritime::int FROM (
|
||||
-- etldoc: boundary_z0 -> layer_boundary:z0
|
||||
SELECT * FROM boundary_z0 WHERE geometry && bbox AND zoom_level = 0
|
||||
UNION ALL
|
||||
@@ -156,7 +162,7 @@ RETURNS TABLE(geometry geometry, admin_level int) AS $$
|
||||
-- etldoc: boundary_z12 -> layer_boundary:z12
|
||||
SELECT * FROM boundary_z12 WHERE geometry && bbox AND zoom_level = 12
|
||||
UNION ALL
|
||||
-- etldoc: boundary_z12 -> layer_boundary:z13
|
||||
SELECT * FROM boundary_z12 WHERE geometry && bbox AND zoom_level >= 13
|
||||
-- etldoc: boundary_z13 -> layer_boundary:z13
|
||||
SELECT * FROM boundary_z13 WHERE geometry && bbox AND zoom_level >= 13
|
||||
) AS zoom_levels;
|
||||
$$ LANGUAGE SQL IMMUTABLE;
|
||||
|
||||
@@ -15,12 +15,16 @@ layer:
|
||||
At low zoom levels the Natural Earth boundaries are mapped to the equivalent admin levels.
|
||||
disputed:
|
||||
description: |
|
||||
Mark with `1` if the boundary is disputed.
|
||||
Mark with `1` if the border is disputed.
|
||||
values: [0, 1]
|
||||
maritime:
|
||||
description: |
|
||||
Mark with `1` if it is a maritime border.
|
||||
values: [0, 1]
|
||||
buffer_size: 4
|
||||
datasource:
|
||||
geometry_field: geometry
|
||||
query: (SELECT geometry, admin_level FROM layer_boundary(!bbox!, z(!scale_denominator!))) AS t
|
||||
query: (SELECT geometry, admin_level, disputed, maritime FROM layer_boundary(!bbox!, z(!scale_denominator!))) AS t
|
||||
schema:
|
||||
- ./boundary.sql
|
||||
datasources:
|
||||
|
||||
@@ -37,9 +37,10 @@ tables:
|
||||
name: admin_level
|
||||
type: integer
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "admin_level", "__nil__" ]
|
||||
- [ "natural", "coastline" ]
|
||||
reject:
|
||||
natural: ["coastline"]
|
||||
require:
|
||||
admin_level: ["__any__"]
|
||||
mapping:
|
||||
boundary:
|
||||
- administrative
|
||||
|
||||
@@ -1,6 +1,50 @@
|
||||
-- etldoc: layer_building[shape=record fillcolor=lightpink, style="rounded,filled",
|
||||
-- etldoc: label="layer_building | <z13> z13 | <z14_> z14+ " ] ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION as_numeric(text) RETURNS NUMERIC AS $$
|
||||
-- Inspired by http://stackoverflow.com/questions/16195986/isnumeric-with-postgresql/16206123#16206123
|
||||
DECLARE test NUMERIC;
|
||||
BEGIN
|
||||
test = $1::NUMERIC;
|
||||
RETURN test;
|
||||
EXCEPTION WHEN others THEN
|
||||
RETURN -1;
|
||||
END;
|
||||
$$ STRICT
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_building_relation_building_idx ON osm_building_relation(building);
|
||||
|
||||
CREATE OR REPLACE VIEW osm_all_buildings AS (
|
||||
-- etldoc: osm_building_relation -> layer_building:z14_
|
||||
SELECT member AS osm_id,geometry,
|
||||
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
|
||||
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
|
||||
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
|
||||
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level
|
||||
FROM
|
||||
osm_building_relation WHERE building = ''
|
||||
UNION ALL
|
||||
-- etldoc: osm_building_polygon -> layer_building:z14_
|
||||
SELECT osm_id,geometry,
|
||||
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
|
||||
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
|
||||
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
|
||||
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level
|
||||
FROM
|
||||
osm_building_polygon obp WHERE EXISTS (SELECT 1 FROM osm_building_multipolygon obm WHERE obp.osm_id = obm.osm_id)
|
||||
UNION ALL
|
||||
-- etldoc: osm_building_polygon -> layer_building:z14_
|
||||
SELECT osm_id,geometry,
|
||||
|
||||
COALESCE(nullif(as_numeric(height),-1),nullif(as_numeric(buildingheight),-1)) as height,
|
||||
COALESCE(nullif(as_numeric(min_height),-1),nullif(as_numeric(buildingmin_height),-1)) as min_height,
|
||||
COALESCE(nullif(as_numeric(levels),-1),nullif(as_numeric(buildinglevels),-1)) as levels,
|
||||
COALESCE(nullif(as_numeric(min_level),-1),nullif(as_numeric(buildingmin_level),-1)) as min_level
|
||||
FROM
|
||||
osm_building_polygon WHERE osm_id >= 0
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_building(bbox geometry, zoom_level int)
|
||||
RETURNS TABLE(geometry geometry, osm_id bigint, render_height int, render_min_height int) AS $$
|
||||
SELECT geometry, osm_id, render_height, render_min_height
|
||||
@@ -13,12 +57,15 @@ RETURNS TABLE(geometry geometry, osm_id bigint, render_height int, render_min_he
|
||||
WHERE zoom_level = 13 AND geometry && bbox AND area > 1400
|
||||
UNION ALL
|
||||
-- etldoc: osm_building_polygon -> layer_building:z14_
|
||||
SELECT
|
||||
osm_id, geometry,
|
||||
greatest(5, COALESCE(height, levels*3.66,5))::int AS render_height,
|
||||
greatest(0, COALESCE(min_height, min_level*3.66,0))::int AS render_min_height
|
||||
FROM osm_building_polygon
|
||||
SELECT DISTINCT ON (osm_id)
|
||||
osm_id, geometry,
|
||||
ceil( COALESCE(height, levels*3.66,5))::int AS render_height,
|
||||
floor(COALESCE(min_height, min_level*3.66,0))::int AS render_min_height FROM
|
||||
osm_all_buildings
|
||||
WHERE zoom_level >= 14 AND geometry && bbox
|
||||
) AS zoom_levels
|
||||
ORDER BY render_height ASC, ST_YMin(geometry) DESC;
|
||||
$$ LANGUAGE SQL IMMUTABLE;
|
||||
|
||||
-- not handled: where a building outline covers building parts
|
||||
|
||||
|
||||
@@ -6,6 +6,9 @@ generalized_tables:
|
||||
sql_filter: area>1400.0
|
||||
tolerance: 10.0
|
||||
|
||||
tags:
|
||||
load_all: true
|
||||
|
||||
tables:
|
||||
|
||||
# etldoc: imposm3 -> osm_building_polygon
|
||||
@@ -16,22 +19,37 @@ tables:
|
||||
- name: geometry
|
||||
type: validated_geometry
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
- name: building
|
||||
key: building
|
||||
type: string
|
||||
- name: buildingpart
|
||||
key: building:part
|
||||
type: string
|
||||
- name: buildingheight
|
||||
key: building:height
|
||||
type: string
|
||||
- name: buildingmin_height
|
||||
key: building:min_height
|
||||
type: string
|
||||
- name: buildinglevels
|
||||
key: building:levels
|
||||
type: string
|
||||
- name: buildingmin_level
|
||||
key: building:min_level
|
||||
type: string
|
||||
- name: height
|
||||
key: height
|
||||
type: integer
|
||||
type: string
|
||||
- name: min_height
|
||||
key: min_height
|
||||
type: integer
|
||||
type: string
|
||||
- name: levels
|
||||
key: building:levels
|
||||
type: integer
|
||||
key: levels
|
||||
type: string
|
||||
- name: min_level
|
||||
key: building:min_level
|
||||
type: integer
|
||||
key: min_level
|
||||
type: string
|
||||
mapping:
|
||||
building:part:
|
||||
- __any__
|
||||
@@ -42,8 +60,184 @@ tables:
|
||||
- terminal
|
||||
- hangar
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "building", "no" ]
|
||||
- [ "building", "none" ]
|
||||
- [ "building", "No" ]
|
||||
reject:
|
||||
building: ["no","none","No"]
|
||||
building:part: ["no","none","No"]
|
||||
type: polygon
|
||||
|
||||
# etldoc: imposm3 -> osm_building_relation
|
||||
building_relation:
|
||||
fields:
|
||||
- name: osm_id
|
||||
type: id
|
||||
- name: geometry
|
||||
type: validated_geometry
|
||||
- name: area
|
||||
type: webmerc_area
|
||||
- name: building
|
||||
key: building
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingpart
|
||||
key: building:part
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingheight
|
||||
key: building:height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: height
|
||||
key: height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingmin_height
|
||||
key: building:min_height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: min_height
|
||||
key: min_height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildinglevels
|
||||
key: building:levels
|
||||
type: string
|
||||
from_member: true
|
||||
- name: levels
|
||||
key: levels
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingmin_level
|
||||
key: building:min_level
|
||||
type: string
|
||||
from_member: true
|
||||
- name: min_level
|
||||
key: min_level
|
||||
type: string
|
||||
from_member: true
|
||||
- name: relbuildingheight
|
||||
key: building:height
|
||||
type: string
|
||||
- name: relheight
|
||||
key: height
|
||||
type: string
|
||||
- name: relbuildingmin_height
|
||||
key: building:min_height
|
||||
type: string
|
||||
- name: relmin_height
|
||||
key: min_height
|
||||
type: string
|
||||
- name: relbuildinglevels
|
||||
key: building:levels
|
||||
type: string
|
||||
- name: rellevels
|
||||
key: levels
|
||||
type: string
|
||||
- name: relbuildingmin_level
|
||||
key: building:min_level
|
||||
type: string
|
||||
- name: relmin_level
|
||||
key: min_level
|
||||
type: string
|
||||
- name: member
|
||||
type: member_id
|
||||
- name: index
|
||||
type: member_index
|
||||
- name: role
|
||||
type: member_role
|
||||
from_member: true
|
||||
- name: type
|
||||
type: member_type
|
||||
mapping:
|
||||
type: [building]
|
||||
type: relation_member
|
||||
|
||||
# etldoc: imposm3 -> osm_building_multipolygon
|
||||
building_multipolygon:
|
||||
fields:
|
||||
- name: osm_id
|
||||
type: id
|
||||
- name: geometry
|
||||
type: validated_geometry
|
||||
- name: area
|
||||
type: webmerc_area
|
||||
- name: building
|
||||
key: building
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingpart
|
||||
key: building:part
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingheight
|
||||
key: building:height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: height
|
||||
key: height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingmin_height
|
||||
key: building:min_height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: min_height
|
||||
key: min_height
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildinglevels
|
||||
key: building:levels
|
||||
type: string
|
||||
from_member: true
|
||||
- name: levels
|
||||
key: levels
|
||||
type: string
|
||||
from_member: true
|
||||
- name: buildingmin_level
|
||||
key: building:min_level
|
||||
type: string
|
||||
from_member: true
|
||||
- name: min_level
|
||||
key: min_level
|
||||
type: string
|
||||
from_member: true
|
||||
- name: relbuildingheight
|
||||
key: building:height
|
||||
type: string
|
||||
- name: relheight
|
||||
key: height
|
||||
type: string
|
||||
- name: relbuildingmin_height
|
||||
key: building:min_height
|
||||
type: string
|
||||
- name: relmin_height
|
||||
key: min_height
|
||||
type: string
|
||||
- name: relbuildinglevels
|
||||
key: building:levels
|
||||
type: string
|
||||
- name: rellevels
|
||||
key: levels
|
||||
type: string
|
||||
- name: relbuildingmin_level
|
||||
key: building:min_level
|
||||
type: string
|
||||
- name: relmin_level
|
||||
key: min_level
|
||||
type: string
|
||||
- name: member
|
||||
type: member_id
|
||||
- name: index
|
||||
type: member_index
|
||||
- name: role
|
||||
type: member_role
|
||||
from_member: true
|
||||
- name: type
|
||||
type: member_type
|
||||
mapping:
|
||||
type: [multipolygon]
|
||||
filters:
|
||||
reject:
|
||||
building: ["no","none","No"]
|
||||
building:part: ["no","none","No"]
|
||||
type: relation_member
|
||||
|
||||
|
||||
@@ -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=ST_PointOnSurface(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();
|
||||
|
||||
@@ -58,7 +58,7 @@ tables:
|
||||
key: wetland
|
||||
type: string
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
mapping:
|
||||
landuse:
|
||||
- allotments
|
||||
|
||||
@@ -39,7 +39,7 @@ tables:
|
||||
key: leisure
|
||||
type: string
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
mapping:
|
||||
amenity:
|
||||
- school
|
||||
|
||||
@@ -67,7 +67,7 @@ tables:
|
||||
key: boundary
|
||||
type: string
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
mapping:
|
||||
leisure:
|
||||
- nature_reserve
|
||||
|
||||
@@ -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=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();
|
||||
|
||||
@@ -21,7 +21,7 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, class t
|
||||
osm_id, geometry, name, COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
||||
'country' AS class, "rank", NULL::int AS capital
|
||||
FROM osm_country_point
|
||||
WHERE geometry && bbox AND "rank" <= zoom_level AND name <> ''
|
||||
WHERE geometry && bbox AND "rank" <= zoom_level + 1 AND name <> ''
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_state_point -> layer_place:z0_3
|
||||
|
||||
@@ -56,8 +56,8 @@ tables:
|
||||
- *name
|
||||
- *name_en
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- continent
|
||||
@@ -82,8 +82,8 @@ tables:
|
||||
- *name_ja
|
||||
- *rank
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- country
|
||||
@@ -97,7 +97,7 @@ tables:
|
||||
- name: geometry
|
||||
type: geometry
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
- *name
|
||||
- *name_en
|
||||
- *name_de
|
||||
@@ -110,8 +110,8 @@ tables:
|
||||
- *name_ja
|
||||
- *rank
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- island
|
||||
@@ -136,8 +136,8 @@ tables:
|
||||
- *name_ja
|
||||
- *rank
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- island
|
||||
@@ -171,8 +171,8 @@ tables:
|
||||
type: string
|
||||
- *rank
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- state
|
||||
@@ -206,8 +206,8 @@ tables:
|
||||
type: string
|
||||
- *rank
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- city
|
||||
|
||||
@@ -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();
|
||||
|
||||
@@ -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();
|
||||
|
||||
@@ -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();
|
||||
|
||||
@@ -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=ST_PointOnSurface(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();
|
||||
|
||||
@@ -96,6 +96,24 @@ RETURNS TABLE(osm_id bigint, geometry geometry, class text, ramp int, oneway int
|
||||
)
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_railway_linestring_gen2 -> layer_transportation:z11"
|
||||
SELECT
|
||||
osm_id, geometry, NULL AS highway, railway,
|
||||
service_value(service) AS service,
|
||||
is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order
|
||||
FROM osm_railway_linestring_gen2
|
||||
WHERE zoom_level = 11 AND (railway='rail' AND service = '')
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_railway_linestring_gen1 -> layer_transportation:z12"
|
||||
SELECT
|
||||
osm_id, geometry, NULL AS highway, railway,
|
||||
service_value(service) AS service,
|
||||
is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order
|
||||
FROM osm_railway_linestring_gen1
|
||||
WHERE zoom_level = 12 AND (railway='rail' AND service = '')
|
||||
UNION ALL
|
||||
|
||||
-- etldoc: osm_railway_linestring -> layer_transportation:z13
|
||||
-- etldoc: osm_railway_linestring -> layer_transportation:z14_
|
||||
SELECT
|
||||
|
||||
@@ -1,6 +1,16 @@
|
||||
|
||||
generalized_tables:
|
||||
|
||||
# etldoc: imposm3 -> osm_railway_linestring_gen2
|
||||
railway_linestring_gen2:
|
||||
source: railway_linestring_gen1
|
||||
tolerance: 40.0
|
||||
|
||||
# etldoc: imposm3 -> osm_railway_linestring_gen1
|
||||
railway_linestring_gen1:
|
||||
source: railway_linestring
|
||||
sql_filter: railway='rail' AND service=''
|
||||
tolerance: 20.0
|
||||
|
||||
# etldoc: imposm3 -> osm_highway_linestring_gen4
|
||||
highway_linestring_gen4:
|
||||
source: highway_linestring_gen3
|
||||
|
||||
@@ -3,8 +3,10 @@
|
||||
-- etldoc: label="layer_transportation_name | <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_transportation_name(bbox geometry, zoom_level integer)
|
||||
RETURNS TABLE(osm_id bigint, geometry geometry, name text, ref text, ref_length int, network text, class text) AS $$
|
||||
SELECT osm_id, geometry, name,
|
||||
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, ref text, ref_length int, network text, class text) AS $$
|
||||
SELECT osm_id, geometry,
|
||||
NULLIF(name, '') AS name,
|
||||
COALESCE(NULLIF(name_en, ''), NULLIF(name, '')) AS name_en,
|
||||
NULLIF(ref, ''), NULLIF(LENGTH(ref), 0) AS ref_length,
|
||||
--TODO: The road network of the road is not yet implemented
|
||||
NULL::text AS network,
|
||||
|
||||
@@ -1,63 +1,103 @@
|
||||
|
||||
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 (
|
||||
SELECT
|
||||
(ST_Dump(geometry)).geom AS geometry,
|
||||
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
|
||||
-- to lookup road names by OSM ID
|
||||
member_osm_ids[0] AS osm_id,
|
||||
member_osm_ids,
|
||||
name,
|
||||
member_osm_ids[0] AS osm_id,
|
||||
member_osm_ids,
|
||||
name,
|
||||
name_en,
|
||||
ref,
|
||||
highway,
|
||||
z_order
|
||||
FROM (
|
||||
SELECT
|
||||
ST_LineMerge(ST_Union(geometry)) AS geometry,
|
||||
name,
|
||||
highway,
|
||||
z_order
|
||||
FROM (
|
||||
SELECT
|
||||
ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
||||
name,
|
||||
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
||||
ref,
|
||||
highway,
|
||||
min(z_order) AS z_order,
|
||||
array_agg(DISTINCT osm_id) AS member_osm_ids
|
||||
FROM osm_highway_linestring
|
||||
highway,
|
||||
min(z_order) AS z_order,
|
||||
array_agg(DISTINCT osm_id) AS member_osm_ids
|
||||
FROM osm_highway_linestring
|
||||
-- We only care about highways (not railways) for labeling
|
||||
WHERE (name <> '' OR ref <> '') AND NULLIF(highway, '') IS NOT NULL
|
||||
GROUP BY name, highway, ref
|
||||
) AS highway_union
|
||||
WHERE (name <> '' OR ref <> '') AND NULLIF(highway, '') IS NOT NULL
|
||||
GROUP BY name, name_en, 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 (
|
||||
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen1 AS (
|
||||
SELECT ST_Simplify(geometry, 50) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, z_order
|
||||
FROM osm_transportation_name_linestring
|
||||
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 8000
|
||||
);
|
||||
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 (
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen2 AS (
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, z_order
|
||||
FROM osm_transportation_name_linestring_gen1
|
||||
WHERE highway IN ('motorway','trunk') AND ST_Length(geometry) > 14000
|
||||
);
|
||||
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 (
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, ref, highway, z_order
|
||||
CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen3 AS (
|
||||
SELECT ST_Simplify(geometry, 120) AS geometry, osm_id, member_osm_ids, name, name_en, 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();
|
||||
|
||||
@@ -9,6 +9,7 @@ layer:
|
||||
srs: +proj=merc +a=6378137 +b=6378137 +lat_ts=0.0 +lon_0=0.0 +x_0=0.0 +y_0=0.0 +k=1.0 +units=m +nadgrids=@null +wktext +no_defs +over
|
||||
fields:
|
||||
name: The OSM [`name`](http://wiki.openstreetmap.org/wiki/Highways#Names_and_references) value of the highway.
|
||||
name_en: The english `name:en` value if available.
|
||||
ref: The OSM [`ref`](http://wiki.openstreetmap.org/wiki/Key:ref) tag of the motorway or road.
|
||||
ref_length: Length of the `ref` field. Useful for having a shield icon as background for labeling motorways.
|
||||
network: The OSM [`network`](http://wiki.openstreetmap.org/wiki/Key:network) tag of the road.
|
||||
@@ -31,7 +32,7 @@ layer:
|
||||
datasource:
|
||||
geometry_field: geometry
|
||||
srid: 900913
|
||||
query: (SELECT geometry, name, ref, ref_length, class::text FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
|
||||
query: (SELECT geometry, name, name_en, ref, ref_length, class::text FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
|
||||
schema:
|
||||
- ./merge_highways.sql
|
||||
- ./layer.sql
|
||||
|
||||
@@ -40,7 +40,7 @@ tables:
|
||||
- name: geometry
|
||||
type: validated_geometry
|
||||
- name: area
|
||||
type: pseudoarea
|
||||
type: webmerc_area
|
||||
- key: name
|
||||
name: name
|
||||
type: string
|
||||
@@ -57,8 +57,8 @@ tables:
|
||||
key: waterway
|
||||
type: string
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "covered", "yes" ]
|
||||
reject:
|
||||
covered: ["yes"]
|
||||
mapping:
|
||||
landuse:
|
||||
- reservoir
|
||||
|
||||
@@ -12,12 +12,21 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, class t
|
||||
AND ((zoom_level BETWEEN 9 AND 13 AND LineLabel(zoom_level, NULLIF(name, ''), geometry))
|
||||
OR (zoom_level >= 14))
|
||||
-- etldoc: osm_water_point -> layer_water_name:z9_13
|
||||
-- etldoc: osm_water_point -> layer_water_name:z14_
|
||||
-- etldoc: osm_water_point -> layer_water_name:z14_
|
||||
UNION ALL
|
||||
SELECT osm_id, geometry, name, name_en, 'lake'::text AS class
|
||||
FROM osm_water_point
|
||||
WHERE geometry && bbox AND (
|
||||
(zoom_level BETWEEN 9 AND 13 AND area > 70000*2^(20-zoom_level))
|
||||
OR (zoom_level >= 14)
|
||||
)
|
||||
-- etldoc: osm_marine_point -> layer_water_name:z0_14_
|
||||
UNION ALL
|
||||
SELECT osm_id, geometry, name, name_en, place::text AS class
|
||||
FROM osm_marine_point
|
||||
WHERE geometry && bbox AND (
|
||||
place = 'ocean'
|
||||
OR (zoom_level >= 1 AND zoom_level <= "rank" AND "rank" IS NOT NULL)
|
||||
OR (zoom_level >= 8)
|
||||
);
|
||||
$$ LANGUAGE SQL IMMUTABLE;
|
||||
|
||||
@@ -16,9 +16,12 @@ tables:
|
||||
- name: place
|
||||
key: place
|
||||
type: string
|
||||
- name: rank
|
||||
key: rank
|
||||
type: integer
|
||||
filters:
|
||||
exclude_tags:
|
||||
- [ "name", "__nil__" ]
|
||||
require:
|
||||
name: ["__any__"]
|
||||
mapping:
|
||||
place:
|
||||
- ocean
|
||||
|
||||
61
layers/water_name/merge_marine_rank.sql
Normal file
61
layers/water_name/merge_marine_rank.sql
Normal file
@@ -0,0 +1,61 @@
|
||||
DROP TRIGGER IF EXISTS trigger_flag ON osm_marine_point;
|
||||
DROP TRIGGER IF EXISTS trigger_refresh ON water_name_marine.updates;
|
||||
|
||||
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
|
||||
UPDATE osm_marine_point AS osm SET "rank" = NULL WHERE "rank" IS NOT NULL;
|
||||
|
||||
-- etldoc: ne_10m_geography_marine_polys -> osm_marine_point
|
||||
-- etldoc: osm_marine_point -> osm_marine_point
|
||||
|
||||
WITH important_marine_point AS (
|
||||
SELECT osm.geometry, osm.osm_id, osm.name, osm.name_en, ne.scalerank
|
||||
FROM ne_10m_geography_marine_polys AS ne, osm_marine_point AS osm
|
||||
WHERE ne.name ILIKE osm.name
|
||||
)
|
||||
UPDATE osm_marine_point AS osm
|
||||
SET "rank" = scalerank
|
||||
FROM important_marine_point AS ne
|
||||
WHERE osm.osm_id = ne.osm_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
SELECT update_osm_marine_point();
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_marine_point_rank_idx ON osm_marine_point("rank");
|
||||
|
||||
-- Handle updates
|
||||
CREATE SCHEMA IF NOT EXISTS water_name_marine;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS water_name_marine.updates(id serial primary key, t text, unique (t));
|
||||
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;
|
||||
$$ language plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION water_name_marine.refresh() RETURNS trigger AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
RAISE LOG 'Refresh water_name_marine rank';
|
||||
PERFORM update_osm_marine_point();
|
||||
DELETE FROM water_name_marine.updates;
|
||||
RETURN null;
|
||||
END;
|
||||
$BODY$
|
||||
language plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_flag
|
||||
AFTER INSERT OR UPDATE OR DELETE ON osm_marine_point
|
||||
FOR EACH STATEMENT
|
||||
EXECUTE PROCEDURE water_name_marine.flag();
|
||||
|
||||
CREATE CONSTRAINT TRIGGER trigger_refresh
|
||||
AFTER INSERT ON water_name_marine.updates
|
||||
INITIALLY DEFERRED
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE water_name_marine.refresh();
|
||||
@@ -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();
|
||||
|
||||
@@ -12,13 +12,14 @@ layer:
|
||||
At the moment only `lake` since no ocean parts are labelled. *Reserved for future use*.
|
||||
values:
|
||||
- lake
|
||||
buffer_size: 8
|
||||
buffer_size: 64
|
||||
srs: +proj=merc +a=6378137 +b=6378137 +lat_ts=0.0 +lon_0=0.0 +x_0=0.0 +y_0=0.0 +k=1.0 +units=m +nadgrids=@null +wktext +no_defs +over
|
||||
datasource:
|
||||
geometry_field: geometry
|
||||
srid: 900913
|
||||
query: (SELECT geometry, name, name_en, class FROM layer_water_name(!bbox!, z(!scale_denominator!))) AS t
|
||||
schema:
|
||||
- ./merge_marine_rank.sql
|
||||
- ./water_lakeline.sql
|
||||
- ./water_point.sql
|
||||
- ./layer.sql
|
||||
|
||||
@@ -1,15 +1,50 @@
|
||||
|
||||
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.osm_id, ST_PointOnSurface(wp.geometry) AS geometry,
|
||||
wp.name, wp.name_en, 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 <> ''
|
||||
);
|
||||
|
||||
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();
|
||||
|
||||
@@ -1,50 +1,91 @@
|
||||
|
||||
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
|
||||
name, name_en
|
||||
FROM (
|
||||
SELECT
|
||||
ST_LineMerge(ST_Union(geometry)) AS geometry,
|
||||
name
|
||||
name, COALESCE(NULLIF(name_en, ''), name) AS name_en
|
||||
FROM osm_waterway_linestring
|
||||
WHERE name <> '' AND waterway = 'river'
|
||||
GROUP BY name
|
||||
GROUP BY name, name_en
|
||||
) 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 (
|
||||
SELECT ST_Simplify(geometry, 60) AS geometry, name
|
||||
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen1 AS (
|
||||
SELECT ST_Simplify(geometry, 60) AS geometry, name, name_en
|
||||
FROM osm_important_waterway_linestring
|
||||
WHERE ST_Length(geometry) > 1000
|
||||
);
|
||||
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 (
|
||||
SELECT ST_Simplify(geometry, 100) AS geometry, name
|
||||
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen2 AS (
|
||||
SELECT ST_Simplify(geometry, 100) AS geometry, name, name_en
|
||||
FROM osm_important_waterway_linestring_gen1
|
||||
WHERE ST_Length(geometry) > 4000
|
||||
);
|
||||
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 (
|
||||
SELECT ST_Simplify(geometry, 200) AS geometry, name
|
||||
CREATE MATERIALIZED VIEW osm_important_waterway_linestring_gen3 AS (
|
||||
SELECT ST_Simplify(geometry, 200) AS geometry, name, name_en
|
||||
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();
|
||||
|
||||
|
||||
|
||||
|
||||
@@ -1,60 +1,66 @@
|
||||
|
||||
-- etldoc: ne_110m_rivers_lake_centerlines -> waterway_z3
|
||||
CREATE OR REPLACE VIEW waterway_z3 AS (
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_110m_rivers_lake_centerlines
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
|
||||
FROM ne_110m_rivers_lake_centerlines
|
||||
WHERE featurecla = 'River'
|
||||
);
|
||||
|
||||
-- etldoc: ne_50m_rivers_lake_centerlines -> waterway_z4
|
||||
CREATE OR REPLACE VIEW waterway_z4 AS (
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_50m_rivers_lake_centerlines
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
|
||||
FROM ne_50m_rivers_lake_centerlines
|
||||
WHERE featurecla = 'River'
|
||||
);
|
||||
|
||||
-- etldoc: ne_10m_rivers_lake_centerlines -> waterway_z6
|
||||
CREATE OR REPLACE VIEW waterway_z6 AS (
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name FROM ne_10m_rivers_lake_centerlines
|
||||
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en
|
||||
FROM ne_10m_rivers_lake_centerlines
|
||||
WHERE featurecla = 'River'
|
||||
);
|
||||
|
||||
-- etldoc: osm_important_waterway_linestring_gen3 -> waterway_z9
|
||||
CREATE OR REPLACE VIEW waterway_z9 AS (
|
||||
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen3
|
||||
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen3
|
||||
);
|
||||
|
||||
-- etldoc: osm_important_waterway_linestring_gen2 -> waterway_z10
|
||||
CREATE OR REPLACE VIEW waterway_z10 AS (
|
||||
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen2
|
||||
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen2
|
||||
);
|
||||
|
||||
-- etldoc:osm_important_waterway_linestring_gen1 -> waterway_z11
|
||||
CREATE OR REPLACE VIEW waterway_z11 AS (
|
||||
SELECT geometry, 'river'::text AS class, name FROM osm_important_waterway_linestring_gen1
|
||||
SELECT geometry, 'river'::text AS class, name, name_en FROM osm_important_waterway_linestring_gen1
|
||||
);
|
||||
|
||||
-- etldoc: osm_waterway_linestring -> waterway_z12
|
||||
CREATE OR REPLACE VIEW waterway_z12 AS (
|
||||
SELECT geometry, waterway AS class, name FROM osm_waterway_linestring
|
||||
SELECT geometry, waterway AS class, name, name_en FROM osm_waterway_linestring
|
||||
WHERE waterway IN ('river', 'canal')
|
||||
);
|
||||
|
||||
-- etldoc: osm_waterway_linestring -> waterway_z13
|
||||
CREATE OR REPLACE VIEW waterway_z13 AS (
|
||||
SELECT geometry, waterway::text AS class, name FROM osm_waterway_linestring
|
||||
SELECT geometry, waterway::text AS class, name, name_en FROM osm_waterway_linestring
|
||||
WHERE waterway IN ('river', 'canal', 'stream', 'drain', 'ditch')
|
||||
);
|
||||
|
||||
-- etldoc: osm_waterway_linestring -> waterway_z14
|
||||
CREATE OR REPLACE VIEW waterway_z14 AS (
|
||||
SELECT geometry, waterway::text AS class, name FROM osm_waterway_linestring
|
||||
SELECT geometry, waterway::text AS class, name, name_en FROM osm_waterway_linestring
|
||||
);
|
||||
|
||||
-- etldoc: layer_waterway[shape=record fillcolor=lightpink, style="rounded,filled",
|
||||
-- etldoc: label="layer_waterway | <z3> z3 |<z4_5> z4-z5 |<z6_8> z6-8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14> z14+" ];
|
||||
|
||||
CREATE OR REPLACE FUNCTION layer_waterway(bbox geometry, zoom_level int)
|
||||
RETURNS TABLE(geometry geometry, class text, name text) AS $$
|
||||
SELECT geometry, class, NULLIF(name, '') AS name FROM (
|
||||
RETURNS TABLE(geometry geometry, class text, name text, name_en text) AS $$
|
||||
SELECT geometry, class,
|
||||
NULLIF(name, '') AS name,
|
||||
COALESCE(NULLIF(name_en, ''), name) AS name_en
|
||||
FROM (
|
||||
-- etldoc: waterway_z3 -> layer_waterway:z3
|
||||
SELECT * FROM waterway_z3 WHERE zoom_level = 3
|
||||
UNION ALL
|
||||
|
||||
@@ -10,6 +10,7 @@ layer:
|
||||
name: |
|
||||
The OSM [`name`](http://wiki.openstreetmap.org/wiki/Key:name) value of the waterway.
|
||||
The `name` field may be empty for NaturalEarth data or at lower zoom levels.
|
||||
name_en: The english `name:en` value if available.
|
||||
class:
|
||||
description: |
|
||||
The original value of the [`waterway`](http://wiki.openstreetmap.org/wiki/Key:waterway) tag.
|
||||
@@ -21,7 +22,7 @@ layer:
|
||||
- ditch
|
||||
datasource:
|
||||
geometry_field: geometry
|
||||
query: (SELECT geometry, name, class FROM layer_waterway(!bbox!, z(!scale_denominator!))) AS t
|
||||
query: (SELECT geometry, name, name_en, class FROM layer_waterway(!bbox!, z(!scale_denominator!))) AS t
|
||||
schema:
|
||||
- ./merge_waterway.sql
|
||||
- ./waterway.sql
|
||||
|
||||
Reference in New Issue
Block a user