Skip to content

Commit

Permalink
Output more feature properties (#188)
Browse files Browse the repository at this point in the history
Properties include:
- operator, traffic mode and radio for railway lines
- UIC ref for stations
- speed value for speed signals
- deactivated for speed and electricity signals
- voltage and frequency for electricity signals
  • Loading branch information
hiddewie authored Dec 28, 2024
1 parent adbab16 commit afb1a55
Show file tree
Hide file tree
Showing 7 changed files with 176 additions and 75 deletions.
1 change: 1 addition & 0 deletions features/electrification_signals.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ tags:
- 'railway:signal:electricity:for'
- 'railway:signal:electricity:turn_direction'
- 'railway:signal:electricity:voltage'
- 'railway:signal:electricity:frequency'

features:

Expand Down
60 changes: 34 additions & 26 deletions import/openrailwaymap.lua
Original file line number Diff line number Diff line change
Expand Up @@ -138,8 +138,8 @@ local railway_line = osm2pgsql.define_table({
{ column = 'future_frequency', type = 'real' },
{ column = 'future_voltage', type = 'integer' },
{ column = 'gauges', sql_type = 'text[]' },
{ column = 'loading_gauge', sql_type = 'text' },
{ column = 'track_class', sql_type = 'text' },
{ column = 'loading_gauge', type = 'text' },
{ column = 'track_class', type = 'text' },
{ column = 'reporting_marks', sql_type = 'text[]' },
{ column = 'construction_railway', type = 'text' },
{ column = 'proposed_railway', type = 'text' },
Expand All @@ -151,6 +151,9 @@ local railway_line = osm2pgsql.define_table({
{ column = 'preserved_railway', type = 'text' },
{ column = 'train_protection', type = 'text' },
{ column = 'train_protection_rank', type = 'smallint' },
{ column = 'operator', sql_type = 'text[]' },
{ column = 'traffic_mode', type = 'text' },
{ column = 'radio', type = 'text' },
},
})

Expand Down Expand Up @@ -319,6 +322,30 @@ function electrification_state(tags)
return nil, nil, nil
end

-- Split a value and turn it into a raw SQL array (quoted and comma-delimited)
function split_semicolon_to_sql_array(value)
local result = '{'

local first = true
if value then
for part in string.gmatch(value, '[^;]+') do
if part then

if first then
first = false
else
result = result .. ','
end

-- Raw SQL array syntax
result = result .. "\"" .. part:gsub("\"", "\\\"") .. "\""
end
end
end

return result .. '}'
end

-- TODO clean up unneeded tags

local railway_station_values = osm2pgsql.make_check_values_func({'station', 'halt', 'tram_stop', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site'})
Expand Down Expand Up @@ -539,28 +566,6 @@ function osm2pgsql.process_way(object)

local current_electrification_state, voltage, frequency, future_voltage, future_frequency = electrification_state(tags)

local gauges = {}
local gauge_tag = tags['gauge'] or tags['construction:gauge']
if gauge_tag then
for gauge in string.gmatch(gauge_tag, '[^;]+') do
if gauge then
-- Raw SQL array syntax
table.insert(gauges, "\"" .. gauge:gsub("\"", "\\\"") .. "\"")
end
end
end

local reporting_marks = {}
local reporting_marks_tag = tags['reporting_marks']
if reporting_marks_tag then
for reporting_mark in string.gmatch(reporting_marks_tag, '[^;]+') do
if reporting_mark then
-- Raw SQL array syntax
table.insert(reporting_marks, "\"" .. reporting_mark:gsub("\"", "\\\"") .. "\"")
end
end
end

local preferred_direction = tags['railway:preferred_direction']
local dominant_speed, speed_label = dominant_speed_label(preferred_direction, tags['maxspeed'], tags['maxspeed:forward'], tags['maxspeed:backward'])

Expand Down Expand Up @@ -590,10 +595,10 @@ function osm2pgsql.process_way(object)
voltage = voltage,
future_frequency = future_frequency,
future_voltage = future_voltage,
gauges = '{' .. table.concat(gauges, ',') .. '}',
gauges = split_semicolon_to_sql_array(tags['gauge'] or tags['construction:gauge']),
loading_gauge = tags['loading_gauge'],
track_class = tags['railway:track_class'],
reporting_marks = '{' .. table.concat(reporting_marks, ',') .. '}',
reporting_marks = split_semicolon_to_sql_array(tags['reporting_marks']),
construction_railway = tags['construction:railway'],
proposed_railway = tags['proposed:railway'],
disused_railway = tags['disused:railway'],
Expand All @@ -604,6 +609,9 @@ function osm2pgsql.process_way(object)
preserved_railway = tags['preserved:railway'],
train_protection = railway_train_protection,
train_protection_rank = railway_train_protection_rank,
operator = split_semicolon_to_sql_array(tags['operator']),
traffic_mode = tags['railway:traffic_mode'],
radio = tags['railway:radio'],
})
end

Expand Down
86 changes: 59 additions & 27 deletions import/sql/get_station_importance.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,25 +5,34 @@
-- Get OSM IDs route relations referencing a stop position or a station/halt node
CREATE OR REPLACE VIEW stops_and_route_relations AS
SELECT
r.osm_id AS rel_id, sp.osm_id AS stop_id, sp.name AS stop_name, sp.way AS geom
FROM stop_positions AS sp
JOIN routes AS r
ON r.stop_ref_ids @> Array[sp.osm_id]
r.osm_id AS rel_id,
sp.osm_id AS stop_id,
sp.name AS stop_name,
sp.way AS geom
FROM stop_positions AS sp
JOIN routes AS r
ON r.stop_ref_ids @> Array[sp.osm_id]
WHERE sp.name IS NOT NULL;

-- Get OSM IDs of route relations referencing a platform (all except nodes)
CREATE OR REPLACE VIEW platforms_route_relations AS
SELECT
r.osm_id AS rel_id, sp.osm_id AS stop_id, sp.name AS stop_name, sp.way AS geom
r.osm_id AS rel_id,
sp.osm_id AS stop_id,
sp.name AS stop_name,
sp.way AS geom
FROM platforms AS sp
JOIN routes AS r
ON r.platform_ref_ids @> Array[-sp.osm_id];

-- Cluster stop positions with equal name
CREATE OR REPLACE VIEW stop_positions_and_their_routes_clustered AS
SELECT ST_CollectionExtract(unnest(ST_ClusterWithin(srr.geom, 400)), 1) AS geom, srr.stop_name AS stop_name, ARRAY_AGG(DISTINCT(srr.rel_id)) AS route_ids
FROM stops_and_route_relations AS srr
GROUP BY stop_name, geom;
SELECT
ST_CollectionExtract(unnest(ST_ClusterWithin(srr.geom, 400)), 1) AS geom,
srr.stop_name AS stop_name,
ARRAY_AGG(DISTINCT(srr.rel_id)) AS route_ids
FROM stops_and_route_relations AS srr
GROUP BY stop_name, geom;

-- Cluster platforms in close distance
CREATE OR REPLACE VIEW platforms_and_their_routes_clustered AS
Expand All @@ -42,19 +51,40 @@ CREATE OR REPLACE VIEW platforms_and_their_routes_clustered AS

-- Join clustered stop positions with station nodes
CREATE OR REPLACE VIEW station_nodes_stop_positions_rel_count AS
SELECT s.id as id, s.osm_id, s.name AS name, s.station as station, s.railway_ref as railway_ref, s.railway AS railway, sprc.route_ids AS route_ids, s.name_tags as name_tags, s.way AS way
FROM stations AS s
LEFT OUTER JOIN stop_positions_and_their_routes_clustered AS sprc
ON (sprc.stop_name = s.name AND ST_DWithin(s.way, sprc.geom, 400))
WHERE s.railway IN ('station', 'halt', 'tram_stop', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site');
SELECT
s.id as id,
s.osm_id,
s.name AS name,
s.station as station,
s.railway_ref as railway_ref,
s.uic_ref as uic_ref,
s.railway AS railway,
sprc.route_ids AS route_ids,
s.name_tags as name_tags,
s.way AS way
FROM stations AS s
LEFT OUTER JOIN stop_positions_and_their_routes_clustered AS sprc
ON (sprc.stop_name = s.name AND ST_DWithin(s.way, sprc.geom, 400))
WHERE s.railway IN ('station', 'halt', 'tram_stop', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site');

-- Join clustered platforms with station nodes
CREATE OR REPLACE VIEW station_nodes_platforms_rel_count AS
SELECT s.id as id, s.osm_id AS osm_id, s.name AS name, s.station as station, s.railway_ref as railway_ref, s.railway AS railway, sprc.route_ids AS route_ids, s.name_tags as name_tags, s.way AS way
FROM stations AS s
JOIN platforms_and_their_routes_clustered AS sprc
ON (ST_DWithin(s.way, sprc.geom, 60))
WHERE s.railway IN ('station', 'halt', 'tram_stop');
CREATE OR REPLACE VIEW
station_nodes_platforms_rel_count AS
SELECT
s.id as id,
s.osm_id AS osm_id,
s.name AS name,
s.station as station,
s.railway_ref as railway_ref,
s.uic_ref as uic_ref,
s.railway AS railway,
sprc.route_ids AS route_ids,
s.name_tags as name_tags,
s.way AS way
FROM stations AS s
JOIN platforms_and_their_routes_clustered AS sprc
ON (ST_DWithin(s.way, sprc.geom, 60))
WHERE s.railway IN ('station', 'halt', 'tram_stop');

-- Final table with station nodes and the number of route relations
-- needs about 3 to 4 minutes for whole Germany
Expand All @@ -66,6 +96,7 @@ CREATE MATERIALIZED VIEW IF NOT EXISTS stations_with_route_counts AS
name,
station,
railway_ref,
uic_ref,
railway,
route_count,
name_tags,
Expand All @@ -79,33 +110,34 @@ CREATE MATERIALIZED VIEW IF NOT EXISTS stations_with_route_counts AS
name,
station,
railway_ref,
uic_ref,
railway,
MAX(route_count) as route_count,
hstore(string_agg(nullif(name_tags::text, ''), ',')) as name_tags,
ST_RemoveRepeatedPoints(ST_Collect(way)) as way
FROM (
SELECT
*,
ST_ClusterDBSCAN(way, 400, 1) OVER (PARTITION BY name, station, railway_ref, railway) AS cluster_id
ST_ClusterDBSCAN(way, 400, 1) OVER (PARTITION BY name, station, railway_ref, uic_ref, railway) AS cluster_id
FROM (
SELECT MIN(id) as id, MIN(osm_id) as osm_id, name, station, railway_ref, railway, ARRAY_LENGTH(ARRAY_AGG(DISTINCT route_id), 1) AS route_count, name_tags, way
SELECT MIN(id) as id, MIN(osm_id) as osm_id, name, station, railway_ref, uic_ref, railway, ARRAY_LENGTH(ARRAY_AGG(DISTINCT route_id), 1) AS route_count, name_tags, way
FROM (
SELECT id, osm_id, name, station, railway_ref, railway, UNNEST(route_ids) AS route_id, name_tags, way
SELECT id, osm_id, name, station, railway_ref, uic_ref, railway, UNNEST(route_ids) AS route_id, name_tags, way
FROM station_nodes_stop_positions_rel_count
UNION ALL
SELECT id, osm_id, name, station, railway_ref, railway, UNNEST(route_ids) AS route_id, name_tags, way
SELECT id, osm_id, name, station, railway_ref, uic_ref, railway, UNNEST(route_ids) AS route_id, name_tags, way
FROM station_nodes_platforms_rel_count
) AS a
GROUP BY name, station, railway_ref, railway, way, name_tags
GROUP BY name, station, railway_ref, uic_ref, railway, way, name_tags
UNION ALL
SELECT id, osm_id, name, station, railway_ref, railway, 0 AS route_count, name_tags, way
SELECT id, osm_id, name, station, railway_ref, uic_ref, railway, 0 AS route_count, name_tags, way
FROM stations
WHERE railway IN ('station', 'halt', 'tram_stop', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site')
) AS grouped_facilities
) AS facilities
GROUP BY name, station, railway_ref, railway, cluster_id
GROUP BY name, station, railway_ref, uic_ref, railway, cluster_id
-- ORDER BY is required to ensure that the larger route_count is used.
ORDER BY name, station, railway_ref, railway, route_count DESC
ORDER BY name, station, railway_ref, uic_ref, railway, route_count DESC
) as source_facilities;

CREATE INDEX IF NOT EXISTS stations_with_route_counts_center_index
Expand Down
2 changes: 2 additions & 0 deletions import/sql/signals_with_azimuth.sql.js
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,8 @@ CREATE OR REPLACE VIEW signals_with_azimuth_view AS
signal_direction,
"railway:signal:speed_limit",
dominant_speed,
CASE WHEN "railway:signal:electricity:voltage" ~ '^[0-9]+$' then "railway:signal:electricity:voltage"::int ELSE NULL END as voltage,
CASE WHEN "railway:signal:electricity:frequency" ~ '^[0-9]+(\\.[0-9]+)?$' then "railway:signal:electricity:frequency"::real ELSE NULL END as frequency,
rank,
degrees(ST_Azimuth(
st_lineinterpolatepoint(sl.way, greatest(0, st_linelocatepoint(sl.way, ST_ClosestPoint(sl.way, s.way)) - 0.01)),
Expand Down
31 changes: 23 additions & 8 deletions import/sql/tile_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,10 @@ CREATE OR REPLACE VIEW railway_line_high AS
railway_to_int(gauge2) AS gaugeint2,
gauge2,
gauge_label,
loading_gauge
loading_gauge,
array_to_string(operator, ', ') as operator,
traffic_mode,
radio
FROM
(SELECT
id,
Expand Down Expand Up @@ -110,7 +113,10 @@ CREATE OR REPLACE VIEW railway_line_high AS
gauges[2] AS gauge1,
gauges[3] AS gauge2,
(select string_agg(gauge, ' | ') from unnest(gauges) as gauge where gauge ~ '^[0-9]+$') as gauge_label,
loading_gauge
loading_gauge,
operator,
traffic_mode,
radio
FROM railway_line
WHERE railway IN ('rail', 'tram', 'light_rail', 'subway', 'narrow_gauge', 'disused', 'abandoned', 'razed', 'construction', 'proposed', 'preserved')
) AS r
Expand Down Expand Up @@ -140,7 +146,8 @@ CREATE OR REPLACE VIEW standard_railway_text_stations_low AS
id,
osm_id,
center as way,
railway_ref as label
railway_ref as label,
uic_ref
FROM stations_with_route_counts
WHERE
railway = 'station'
Expand All @@ -154,7 +161,8 @@ CREATE OR REPLACE VIEW standard_railway_text_stations_med AS
id,
osm_id,
center as way,
railway_ref as label
railway_ref as label,
uic_ref
FROM stations_with_route_counts
WHERE
railway = 'station'
Expand Down Expand Up @@ -186,7 +194,8 @@ CREATE OR REPLACE VIEW standard_railway_text_stations AS
WHEN railway = 'crossover' THEN 700
ELSE 50
END AS rank,
count
count,
uic_ref
FROM stations_with_route_counts
WHERE railway IN ('station', 'halt', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site', 'tram_stop')
AND name IS NOT NULL
Expand All @@ -200,7 +209,8 @@ CREATE OR REPLACE VIEW standard_railway_grouped_stations AS
railway,
station,
railway_ref as label,
name
name,
uic_ref
FROM stations_with_route_counts
WHERE railway IN ('station', 'halt', 'service_station', 'yard', 'junction', 'spur_junction', 'crossover', 'site', 'tram_stop');

Expand Down Expand Up @@ -296,7 +306,9 @@ CREATE OR REPLACE VIEW speed_railway_signals AS
speed_feature_type as type,
azimuth,
(signal_direction = 'both') as direction_both,
ref
ref,
deactivated,
dominant_speed as speed
FROM signals_with_azimuth
WHERE railway = 'signal'
AND speed_feature IS NOT NULL
Expand Down Expand Up @@ -384,7 +396,10 @@ CREATE OR REPLACE VIEW electrification_signals AS
electrification_feature as feature,
azimuth,
(signal_direction = 'both') as direction_both,
ref
ref,
deactivated,
voltage,
frequency
FROM signals_with_azimuth
WHERE
railway = 'signal'
Expand Down
Loading

0 comments on commit afb1a55

Please sign in to comment.