[WIP] NUTS layer:

Municipalities, Provinces, Regions etc as linestrings (with polygons used in intermediate step) representing what is left/right of the border
This commit is contained in:
2021-06-16 21:12:35 +02:00
parent 2a39e1ebfe
commit 7a239b66cf
10 changed files with 882 additions and 24 deletions

View File

@@ -115,10 +115,112 @@ tables:
name: maritime
type: bool
from_member: true
- name: index
type: member_index
- name: role
type: member_role
- name: type
type: member_type
mapping:
type: [boundary]
filters:
require:
#admin_level: ['2']
#admin_level: ['2'] # this used to be specified, re-enable if bugs show up with country borders
admin_level: [__any__]
claimed_by: [__any__]
boundary: ['administrative'] # Filters out boundary administrative_fraction and religious_administration
# FOr NUTS in linestring version
administrative_relation:
type: relation
columns:
- name: osm_id
type: id
- key: name
name: name
type: string
- key: boundary
name: boundary
type: string
- key: admin_level
name: admin_level
type: integer
mapping:
boundary: [ 'administrative' ]
filters:
require:
admin_level: [ __any__ ]
administrative_member:
type: relation_member
columns:
- name: relation_id
type: id
- name: boundary_id
type: id
from_member: true
- key: admin_level
name: admin_level
type: integer
- key: maritime
name: maritime
type: bool
from_member: true
- name: index
type: member_index
- name: role
type: member_role
- name: type
type: member_type
mapping:
type: [boundary]
filters:
require:
admin_level: [__any__]
boundary: ['administrative']
administrative_boundary:
type: linestring
columns:
- name: osm_id
type: id
- name: geometry
type: geometry
- key: admin_level
name: admin_level
type: integer
mapping:
boundary: [ 'administrative' ]
filters:
require:
admin_level: [ __any__ ]
# not currently used
# # etldoc: imposm3 -> osm_adm_boundary_relation
# adm_boundary_relation:
# type: relation
# columns:
# - name: relation_id
# type: id
# - key: name
# name: name
# type: string
# - key: admin_level
# name: admin_level
# type: integer
# - key: border_type
# name: border_type
# type: string
# - key: default_language
# name: default_language
# type: string
# - key: website
# name: website
# type: string
# mapping:
# type: [boundary]
# filters:
# require:
# boundary: ['administrative']
# admin_level: [__any__]

182
layers/boundary/nuts.sql Normal file
View File

@@ -0,0 +1,182 @@
-- This is very crude and not finetuned yet
-- This statement can be deleted after the border importer image stops creating this object as a table
DO
$$
BEGIN
DROP TABLE IF EXISTS osm_boundary_polygon CASCADE;
EXCEPTION
WHEN wrong_object_type THEN
END;
$$ LANGUAGE plpgsql;
-- etldoc: osm_border_linestring -> osm_border_linestring_gen_z13
-- etldoc: osm_border_linestring_adm -> osm_border_linestring_gen_z13
DROP MATERIALIZED VIEW IF EXISTS osm_boundary_polygon CASCADE;
CREATE MATERIALIZED VIEW osm_boundary_polygon AS
(
SELECT
r.relation_id,
r.name,
CASE
WHEN r.admin_level = 10 THEN 6
WHEN r.admin_level = 9 THEN 5
WHEN r.admin_level = 8 THEN 4
WHEN r.admin_level = 7 THEN 3
WHEN r.admin_level = 6 THEN 2
WHEN r.admin_level = 4 THEN 1
-- No admin_level =3?
WHEN r.admin_level = 2 THEN 0
ELSE null
END as nuts_level,
p.geometry
FROM (
SELECT
relation_id,
ST_BuildArea(ST_Node(ST_Collect(geometry))) as geometry,
min(id) as minid -- Used just to join to one relation, could've also used subquery with LIMIT 1
FROM osm_border_disp_relation
WHERE (role = 'outer' or role = 'inner')
AND ST_GeometryType(geometry)='ST_LineString'
GROUP BY relation_id
) as p
LEFT JOIN osm_border_disp_relation as r on p.minid = r.id
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_boundary_polygon_idx ON osm_boundary_polygon USING gist (geometry);
-- etldoc: osm_border_linestring -> osm_border_linestring_gen_z13
-- etldoc: osm_border_linestring_adm -> osm_border_linestring_gen_z13
DROP MATERIALIZED VIEW IF EXISTS osm_boundary_linestring CASCADE;
CREATE MATERIALIZED VIEW osm_boundary_linestring AS
SELECT
osm_id,
geometry,
nuts_level,
nuts->>'l_nuts_0_name' as l_nuts_0_name,
nuts->>'l_nuts_1_name' as l_nuts_1_name,
nuts->>'l_nuts_2_name' as l_nuts_2_name,
nuts->>'l_nuts_3_name' as l_nuts_3_name,
nuts->>'l_nuts_4_name' as l_nuts_4_name,
nuts->>'l_nuts_5_name' as l_nuts_5_name,
nuts->>'r_nuts_0_name' as r_nuts_0_name,
nuts->>'r_nuts_1_name' as r_nuts_1_name,
nuts->>'r_nuts_2_name' as r_nuts_2_name,
nuts->>'r_nuts_3_name' as r_nuts_3_name,
nuts->>'r_nuts_4_name' as r_nuts_4_name,
nuts->>'r_nuts_5_name' as r_nuts_5_name
-- Shouldnt be needed for the map
-- nuts->'l_nuts_1_id' as l_nuts_1_id,
-- nuts->'l_nuts_2_id' as l_nuts_2_id,
-- nuts->'l_nuts_3_id' as l_nuts_3_id,
-- nuts->'l_nuts_4_id' as l_nuts_4_id,
-- nuts->'l_nuts_5_id' as l_nuts_5_id,
-- nuts->'r_nuts_1_id' as r_nuts_1_id,
-- nuts->'r_nuts_2_id' as r_nuts_2_id,
-- nuts->'r_nuts_3_id' as r_nuts_3_id,
-- nuts->'r_nuts_4_id' as r_nuts_4_id,
-- nuts->'r_nuts_5_id' as r_nuts_5_id
FROM (
SELECT
osm_id,
geometry,
MIN(nuts_level) as nuts_level,
jsonb_object_agg(
CONCAT(side, '_nuts_', nuts_level, '_name'), name
)
|| jsonb_object_agg(
CONCAT(side, '_nuts_', nuts_level, '_id'), -relation_id
) as nuts
FROM (
SELECT
b.*,
m.maritime,
m.index,
m.role,
m.admin_level,
r.nuts_level,
r.name,
r.relation_id,
CASE
WHEN
ST_Within(
ST_OffsetCurve(
(ST_LineSubString(b.geometry, 0.499,0.501)), 10, 'quad_segs=4 join=mitre'
),
r.geometry
)
THEN 'r'
WHEN
ST_Within(
ST_OffsetCurve(
(ST_LineSubString(b.geometry, 0.499,0.501)), -10, 'quad_segs=4 join=mitre'
),
r.geometry
)
THEN 'l'
ELSE 'unknown' -- TODO: Debug if this ever happens, if so our method isn't fool proof
END as side,
r.geometry as relation
FROM
osm_administrative_boundary as b
INNER JOIN osm_administrative_member as m
ON b.osm_id = m.boundary_id
INNER JOIN osm_boundary_polygon as r
ON m.relation_id = r.relation_id
) as g
GROUP BY osm_id, geometry
) as p /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_boundary_linestring_idx ON osm_boundary_linestring USING gist (geometry);
-- etldoc: layer_boundary[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="<sql> layer_boundary |<z0> z0 |<z1> z1 |<z2> z2 | <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_nuts(bbox geometry, zoom_level int)
RETURNS TABLE
(
geometry geometry,
nuts_level int,
l_nuts_0_name text,
l_nuts_1_name text,
l_nuts_2_name text,
l_nuts_3_name text,
l_nuts_4_name text,
l_nuts_5_name text,
r_nuts_0_name text,
r_nuts_1_name text,
r_nuts_2_name text,
r_nuts_3_name text,
r_nuts_4_name text,
r_nuts_5_name text
)
AS
$$
SELECT
geometry,
nuts_level,
l_nuts_0_name,
l_nuts_1_name,
l_nuts_2_name,
l_nuts_3_name,
l_nuts_4_name,
l_nuts_5_name,
r_nuts_0_name,
r_nuts_1_name,
r_nuts_2_name,
r_nuts_3_name,
r_nuts_4_name,
r_nuts_5_name
FROM osm_boundary_linestring
WHERE geometry && bbox
AND zoom_level >
( CASE
WHEN nuts_level=0 THEN 2
WHEN nuts_level=1 THEN 4
WHEN nuts_level=2 THEN 6
WHEN nuts_level=3 THEN 6
WHEN nuts_level=4 THEN 8
WHEN nuts_level=5 THEN 10
END )
$$ LANGUAGE SQL STABLE
-- STRICT
PARALLEL SAFE;

49
layers/boundary/nuts.yaml Normal file
View File

@@ -0,0 +1,49 @@
layer:
id: "nuts"
description: |
Contains administrative boundaries as linestrings (municipalities, counties, provinces, ...)
Administrative regions are translated to their equivalent NUTS/LAU classification
Fields indicate which NUTS-region is to the left and right of the linestring
fields:
nuts_level:
The mininum NUTS/LAU classification this linestring is part of.
NUTS only goes to 3 thus LAU 1 & 2 are mapped as NUTS 4 & 5.
NUTS 0 = Countries
NUTS 1 = Regions (e.g. Vlaams-brabant)
NUTS 2 = Provinces (e.g. Limburg)
NUTS 3 = Administrative arrondissements (e.g. Antwerpen, best to ignore these)
NUTS 4 = Municipalities (e.g. Lummen)
NUTS 5 = Villages/Suburbs (e.g. Linkhout)
l_nuts_0_name: |
Country on the left side of the linestring
l_nuts_1_name: |
Region on the left side of the linestring
l_nuts_2_name: |
Province on the left side of the linestring
l_nuts_3_name: |
Administrative arrondissement on the left side of the linestring
l_nuts_4_name: |
Municipality on the left side of the linestring
l_nuts_5_name: |
Village/suburb on the left side of the linestring
r_nuts_0_name: |
Country on the right side of the linestring
r_nuts_1_name: |
Region on the right side of the linestring
r_nuts_2_name: |
Province on the right side of the linestring
r_nuts_3_name: |
Administrative arrondissement on the right side of the linestring
r_nuts_4_name: |
Municipality on the right side of the linestring
r_nuts_5_name: |
Village/suburb on the right side of the linestring
buffer_size: 4
datasource:
geometry_field: geometry
query: (SELECT geometry, nuts_level, l_nuts_0_name, l_nuts_1_name, l_nuts_2_name, l_nuts_3_name, l_nuts_4_name, l_nuts_5_name, r_nuts_0_name, r_nuts_1_name, r_nuts_2_name, r_nuts_3_name, r_nuts_4_name, r_nuts_5_name FROM layer_nuts(!bbox!, z(!scale_denominator!))) AS t
schema:
- ./nuts.sql
datasources:
- type: imposm3
mapping_file: ./mapping.yaml

View File

@@ -0,0 +1,26 @@
layer:
id: "nuts"
description: |
Contains administrative boundaries as polygons (municipalities, counties, provinces, ...)
Administrative regions are translated to their equivalent NUTS/LAU classification
fields:
nuts_level:
The NUTS/LAU classification this polygon fall in.
NUTS only goes to 3 thus LAU 1 & 2 are mapped as NUTS 4 & 5.
NUTS 0 = Countries
NUTS 1 = Regions (e.g. Vlaams-brabant)
NUTS 2 = Provinces (e.g. Limburg)
NUTS 3 = Administrative arrondissements (e.g. Antwerpen, best to ignore these)
NUTS 4 = Municipalities (e.g. Lummen)
NUTS 5 = Villages/Suburbs (e.g. Linkhout)
name: |
Name of the region
buffer_size: 4
datasource:
geometry_field: geometry
query: (SELECT geometry, nuts_level, name FROM osm_boundary_polygon) AS t
schema:
- ./nuts.sql
datasources:
- type: imposm3
mapping_file: ./mapping.yaml