diff --git a/layers/transportation_name/layer.sql b/layers/transportation_name/layer.sql index de1d55fa..a2a619f0 100644 --- a/layers/transportation_name/layer.sql +++ b/layers/transportation_name/layer.sql @@ -18,9 +18,14 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, ref tex highway_class(highway) AS class FROM ( - -- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z8 + -- etldoc: osm_transportation_name_linestring_gen4 -> layer_transportation_name:z6 + SELECT * FROM osm_transportation_name_linestring_gen4 + WHERE zoom_level = 6 + UNION ALL + + -- etldoc: osm_transportation_name_linestring_gen3 -> layer_transportation_name:z7z8 SELECT * FROM osm_transportation_name_linestring_gen3 - WHERE zoom_level = 8 + WHERE zoom_level BETWEEN 7 AND 8 UNION ALL -- etldoc: osm_transportation_name_linestring_gen2 -> layer_transportation_name:z9 diff --git a/layers/transportation_name/merge_highways.sql b/layers/transportation_name/merge_highways.sql index 0e7c8f74..6cdb50a6 100644 --- a/layers/transportation_name/merge_highways.sql +++ b/layers/transportation_name/merge_highways.sql @@ -80,12 +80,20 @@ CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen2_geometry_idx -- etldoc: osm_transportation_name_linestring_gen2 -> osm_transportation_name_linestring_gen3 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, network, z_order + SELECT ST_Simplify(geometry, 200) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, network, 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); +-- etldoc: osm_transportation_name_linestring_gen3 -> osm_transportation_name_linestring_gen4 +CREATE MATERIALIZED VIEW osm_transportation_name_linestring_gen4 AS ( + SELECT ST_Simplify(geometry, 500) AS geometry, osm_id, member_osm_ids, name, name_en, ref, highway, network, z_order + FROM osm_transportation_name_linestring_gen3 + WHERE highway = 'motorway' AND ST_Length(geometry) > 20000 +); +CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_gen4_geometry_idx ON osm_transportation_name_linestring_gen4 USING gist(geometry); + -- Handle updates CREATE SCHEMA IF NOT EXISTS transportation_name; @@ -106,6 +114,7 @@ CREATE OR REPLACE FUNCTION transportation_name.refresh() RETURNS trigger AS REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen1; REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen2; REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen3; + REFRESH MATERIALIZED VIEW osm_transportation_name_linestring_gen4; DELETE FROM transportation_name.updates; RETURN null; END; diff --git a/layers/transportation_name/network_type.sql b/layers/transportation_name/network_type.sql index 238b4c81..af61517d 100644 --- a/layers/transportation_name/network_type.sql +++ b/layers/transportation_name/network_type.sql @@ -3,6 +3,7 @@ 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; +DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen4 CASCADE; DO $$ BEGIN diff --git a/layers/transportation_name/tmp.sql b/layers/transportation_name/tmp.sql new file mode 100644 index 00000000..8485d7f5 --- /dev/null +++ b/layers/transportation_name/tmp.sql @@ -0,0 +1,138 @@ +select ref, highway, network, + case + when network is not null + then network::text + when length(coalesce(ref, ''))>0 + then 'motorway' + end as shield +from osm_transportation_name_linestring; + + + +SELECT + rm.network, + rm.ref::text as network_ref, + hl.ref as road_ref, + hl.highway, + ROW_NUMBER() OVER(PARTITION BY hl.osm_id + ORDER BY rm.network) AS "rank" +FROM osm_highway_linestring hl +left join osm_route_member rm on (rm.member = hl.osm_id) +; + +select network, count(*) +from osm_route_member +group by network; + +select network, ref, count(*) +from osm_route_member +group by network, ref +order by network, ref; + +select * +from osm_route_member +where ref::int < 3; + + +select ref, network, name, count(*) +from osm_route_member +where name like '%Trans-Canada Highway%' +group by ref, network, name; + + +select ref, count(*) +from osm_highway_linestring +group by (ref) +order by count(*) desc; + +select ref, highway, count(*) +from osm_highway_linestring +where length(ref)>0 +and ref like 'A%' or ref like 'M%' +group by ref, highway +order by count(*) desc; + +select ref, count(*) +from osm_highway_linestring +where length(ref)>0 +and ref like 'A%' or ref like 'M%' +group by ref +order by count(*) desc; + + +select ref, count(*) +from osm_highway_linestring +where length(ref)>0 +and highway = 'motorway' +group by ref +order by count(*) desc; + +select count(hw.*) +from osm_highway_linestring hw CROSS JOIN ne_10m_admin_0_countries c +where c.iso_a2 = 'GB' +AND ST_Intersects(hw.geometry, c.geometry); + +select hw.osm_id, hw.name, hw.ref +from osm_highway_linestring hw CROSS JOIN ne_10m_admin_0_countries c +where c.iso_a2 = 'GB' +AND not ST_Intersects(hw.geometry, c.geometry); + + + +select count(*) +from osm_highway_linestring; + + +select * from ne_10m_admin_0_countries; +select name, ST_GeometryType(geometry) from ne_10m_admin_0_countries where iso_a2 = 'GB'; +select geometry from ne_10m_admin_0_countries where iso_a2 = 'GB'; + + +with gb_geom as (select geometry from ne_10m_admin_0_countries where iso_a2 = 'GB') + select hw.osm_id, hw.name, hw.ref + from osm_highway_linestring hw + where not ST_Intersects(hw.geometry, gb_geom); + + +DO $$ +DECLARE gbr_geom geometry; +BEGIN + select geometry into gbr_geom from ne_10m_admin_0_countries where iso_a2 = 'GB'; + select hw.osm_id, hw.name, hw.ref + from osm_highway_linestring hw + where not ST_Intersects(hw.geometry, gbr_geom); + -- ... +END $$; + + +DO $$ +DECLARE gbr_geom geometry; +BEGIN + select st_buffer(geometry, 1000) into gbr_geom from ne_10m_admin_0_countries where iso_a2 = 'GB'; + delete from osm_route_member where network IN('omt-gb-motorway', 'omt-gb-trunk'); + + insert into osm_route_member (member, ref, network) + ( + SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-motorway' + from osm_highway_linestring hw + where length(hw.ref)>0 and ST_Intersects(hw.geometry, gbr_geom) + and hw.highway IN ('motorway') + ) UNION ( + SELECT hw.osm_id, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-trunk' + from osm_highway_linestring hw + where length(hw.ref)>0 + and hw.highway IN ('trunk') + ) + ; +END $$; + + +SELECT hw.osm_id, hw.ref, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-motorway' +from osm_highway_linestring hw +where length(hw.ref)>0 + and hw.highway IN ('motorway'); + + SELECT hw.osm_id, hw.ref, substring(hw.ref from E'^[AM][0-9AM()]+'), 'omt-gb-trunk' + from osm_highway_linestring hw + where length(hw.ref)>0 + and hw.highway IN ('trunk'); diff --git a/layers/transportation_name/transportation_name.yaml b/layers/transportation_name/transportation_name.yaml index d7a015c0..f1e679ba 100644 --- a/layers/transportation_name/transportation_name.yaml +++ b/layers/transportation_name/transportation_name.yaml @@ -10,9 +10,22 @@ layer: 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: The OSM [`ref`](http://wiki.openstreetmap.org/wiki/Key:ref) tag of the motorway or its network. ref_length: Length of the `ref` field. Useful for having a shield icon as background for labeling motorways. - network: The network type derived from [`network`](http://wiki.openstreetmap.org/wiki/Key:network) tag of the road. + network: + description: | + The network type derived mainly from [`network`](http://wiki.openstreetmap.org/wiki/Key:network) tag of the road. + See more info about [`us-*`](http://wiki.openstreetmap.org/wiki/Road_signs_in_the_United_States), + [`ca-transcanada`](https://en.wikipedia.org/wiki/Trans-Canada_Highway), + or [`gb-*`](http://wiki.openstreetmap.org/wiki/United_Kingdom_Tagging_Guidelines#UK_roads). + values: + - us-interstate + - us-highway + - us-state + - ca-transcanada + - gb-motorway + - gb-trunk + - motorway (default) class: description: | Distinguish between more and less important roads.