Add network type to transportation_name layer, adjust 'ref' attribute
This commit is contained in:
parent
3fa68ebef1
commit
5db1b0e80e
@ -9,7 +9,7 @@ RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, ref tex
|
|||||||
COALESCE(NULLIF(name_en, ''), NULLIF(name, '')) AS name_en,
|
COALESCE(NULLIF(name_en, ''), NULLIF(name, '')) AS name_en,
|
||||||
NULLIF(ref, ''), NULLIF(LENGTH(ref), 0) AS ref_length,
|
NULLIF(ref, ''), NULLIF(LENGTH(ref), 0) AS ref_length,
|
||||||
--TODO: The road network of the road is not yet implemented
|
--TODO: The road network of the road is not yet implemented
|
||||||
NULL::text AS network,
|
network::text,
|
||||||
highway_class(highway) AS class
|
highway_class(highway) AS class
|
||||||
FROM (
|
FROM (
|
||||||
|
|
||||||
|
|||||||
@ -6,10 +6,28 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation_name.updates;
|
|||||||
-- to allow for nice label rendering
|
-- to allow for nice label rendering
|
||||||
-- Because this works well for roads that do not have relations as well
|
-- 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;
|
CREATE MATERIALIZED VIEW osm_transportation_name_network AS (
|
||||||
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen2 CASCADE;
|
SELECT
|
||||||
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_linestring_gen3 CASCADE;
|
hl.geometry,
|
||||||
|
hl.osm_id,
|
||||||
|
hl.name,
|
||||||
|
COALESCE(NULLIF(hl.name_en, ''), hl.name) AS name_en,
|
||||||
|
rm.network_type,
|
||||||
|
CASE
|
||||||
|
WHEN rm.network_type is not null
|
||||||
|
then rm.ref::text
|
||||||
|
else hl.ref
|
||||||
|
end as ref,
|
||||||
|
hl.highway,
|
||||||
|
ROW_NUMBER() OVER(PARTITION BY hl.osm_id
|
||||||
|
ORDER BY rm.network_type) AS "rank",
|
||||||
|
hl.z_order
|
||||||
|
FROM osm_highway_linestring hl
|
||||||
|
left join osm_route_member rm on (rm.member = hl.osm_id)
|
||||||
|
);
|
||||||
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist(geometry);
|
||||||
|
|
||||||
|
|
||||||
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
|
-- etldoc: osm_highway_linestring -> osm_transportation_name_linestring
|
||||||
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
|
CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
|
||||||
@ -17,28 +35,29 @@ CREATE MATERIALIZED VIEW osm_transportation_name_linestring AS (
|
|||||||
(ST_Dump(geometry)).geom AS geometry,
|
(ST_Dump(geometry)).geom AS geometry,
|
||||||
-- NOTE: The osm_id is no longer the original one which can make it difficult
|
-- NOTE: The osm_id is no longer the original one which can make it difficult
|
||||||
-- to lookup road names by OSM ID
|
-- to lookup road names by OSM ID
|
||||||
member_osm_ids[0] AS osm_id,
|
member_osm_ids[1] AS osm_id,
|
||||||
member_osm_ids,
|
member_osm_ids,
|
||||||
name,
|
name,
|
||||||
name_en,
|
name_en,
|
||||||
ref,
|
ref,
|
||||||
highway,
|
highway,
|
||||||
network,
|
network_type AS network,
|
||||||
z_order
|
z_order
|
||||||
FROM (
|
FROM (
|
||||||
SELECT
|
SELECT
|
||||||
ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
ST_LineMerge(ST_Collect(geometry)) AS geometry,
|
||||||
hl.name,
|
name,
|
||||||
COALESCE(NULLIF(hl.name_en, ''), hl.name) AS name_en,
|
name_en,
|
||||||
hl.ref,
|
ref,
|
||||||
hl.highway,
|
highway,
|
||||||
min(rm.network) AS network, --should be improved, may be part of more networks
|
network_type,
|
||||||
min(hl.z_order) AS z_order,
|
min(z_order) AS z_order,
|
||||||
array_agg(DISTINCT hl.osm_id) AS member_osm_ids
|
array_agg(DISTINCT osm_id) AS member_osm_ids
|
||||||
FROM osm_highway_linestring hl
|
FROM osm_transportation_name_network
|
||||||
left join osm_route_member rm on (rm.member = hl.osm_id)
|
WHERE ("rank"=1 OR "rank" is null)
|
||||||
WHERE (hl.name <> '' OR hl.ref <> '')
|
AND (name <> '' OR ref <> '')
|
||||||
group by hl.name, name_en, hl.ref, hl.highway
|
AND NULLIF(highway, '') IS NOT NULL
|
||||||
|
group by name, name_en, ref, highway, network_type
|
||||||
) AS highway_union
|
) AS highway_union
|
||||||
);
|
);
|
||||||
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist(geometry);
|
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_geometry_idx ON osm_transportation_name_linestring USING gist(geometry);
|
||||||
|
|||||||
@ -1,9 +1,15 @@
|
|||||||
|
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_name_network CASCADE;
|
||||||
|
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;
|
||||||
|
|
||||||
DO $$
|
DO $$
|
||||||
BEGIN
|
BEGIN
|
||||||
BEGIN
|
BEGIN
|
||||||
ALTER TABLE osm_route_member ADD COLUMN network_type text;
|
ALTER TABLE osm_route_member ADD COLUMN network_type text;
|
||||||
EXCEPTION
|
EXCEPTION
|
||||||
WHEN duplicate_column THEN RAISE NOTICE 'column omt_type already exists in network_type.';
|
WHEN duplicate_column THEN RAISE NOTICE 'column network_type already exists in network_type.';
|
||||||
END;
|
END;
|
||||||
END;
|
END;
|
||||||
$$
|
$$
|
||||||
@ -13,9 +19,9 @@ $$
|
|||||||
UPDATE osm_route_member
|
UPDATE osm_route_member
|
||||||
SET network_type =
|
SET network_type =
|
||||||
CASE
|
CASE
|
||||||
WHEN network = 'US:I' THEN 'us-interstate'
|
WHEN network = 'US:I' THEN 'us-interstate'::route_network_type
|
||||||
WHEN network = 'US:US' THEN 'us-highway'
|
WHEN network = 'US:US' THEN 'us-highway'::route_network_type
|
||||||
WHEN network LIKE 'US:__' THEN 'us-state'
|
WHEN network LIKE 'US:__' THEN 'us-state'::route_network_type
|
||||||
ELSE NULL
|
ELSE NULL
|
||||||
END
|
END
|
||||||
;
|
;
|
||||||
|
|||||||
@ -12,7 +12,7 @@ layer:
|
|||||||
name_en: The english `name:en` value if available.
|
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 road.
|
||||||
ref_length: Length of the `ref` field. Useful for having a shield icon as background for labeling motorways.
|
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.
|
network: The network type derived from [`network`](http://wiki.openstreetmap.org/wiki/Key:network) tag of the road.
|
||||||
class:
|
class:
|
||||||
description: |
|
description: |
|
||||||
Distinguish between more and less important roads.
|
Distinguish between more and less important roads.
|
||||||
@ -32,7 +32,7 @@ layer:
|
|||||||
datasource:
|
datasource:
|
||||||
geometry_field: geometry
|
geometry_field: geometry
|
||||||
srid: 900913
|
srid: 900913
|
||||||
query: (SELECT geometry, name, name_en, ref, ref_length, class::text FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
|
query: (SELECT geometry, name, name_en, ref, ref_length, network::text, class::text FROM layer_transportation_name(!bbox!, z(!scale_denominator!))) AS t
|
||||||
schema:
|
schema:
|
||||||
- ./network_type.sql
|
- ./network_type.sql
|
||||||
- ./merge_highways.sql
|
- ./merge_highways.sql
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user