194 lines
7.4 KiB
PL/PgSQL
194 lines
7.4 KiB
PL/PgSQL
-- 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_nuts 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_nuts CASCADE;
|
|
CREATE MATERIALIZED VIEW osm_boundary_polygon_nuts AS
|
|
(
|
|
SELECT r.osm_id as relation_id,
|
|
r.name,
|
|
r.name_en,
|
|
r.name_nl,
|
|
r.name_de,
|
|
r.name_fr,
|
|
r.admin_level,
|
|
p.geometry
|
|
FROM (
|
|
SELECT relation_id,
|
|
ST_BuildArea(ST_Node(ST_Collect(geometry))) as geometry
|
|
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_administrative_relation as r on r.osm_id = p.relation_id
|
|
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
|
|
CREATE INDEX IF NOT EXISTS osm_boundary_polygon_idx ON osm_boundary_polygon_nuts 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.osm_id,
|
|
b.geometry,
|
|
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
|
|
-- All other are stored as low priority NUTS, for future reference
|
|
ELSE 1000 + r.admin_level
|
|
END as nuts_level,
|
|
COALESCE(NULLIF(r.name_en,''), NULLIF(r.name,''), NULL) as 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
|
|
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_nuts 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;
|
|
|
|
|
|
/*
|
|
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,
|
|
*/
|