Emit all roads in obs_roads layer regardless of filter, generate only their statistics with filters

This commit is contained in:
Paul Bienkowski 2022-07-26 08:51:59 +02:00
parent c02b40b0d3
commit dcfcd21c96

View file

@ -20,12 +20,13 @@ RETURNS TABLE(
SELECT SELECT
road.way_id::bigint as way_id, road.way_id::bigint as way_id,
road.geometry as geometry, road.geometry as geometry,
avg(distance_overtaker) as distance_overtaker_mean, e.distance_overtaker_mean,
min(distance_overtaker) as distance_overtaker_min, e.distance_overtaker_min,
max(distance_overtaker) as distance_overtaker_max, e.distance_overtaker_max,
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY distance_overtaker) as distance_overtaker_median, e.distance_overtaker_median,
array_agg(distance_overtaker) as distance_overtaker_array, e.distance_overtaker_array,
count(overtaking_event.id)::int as distance_overtaker_count, e.distance_overtaker_count,
-- Since this is just one field we can subquery directly inline
( (
SELECT count(road_usage.id) from road_usage SELECT count(road_usage.id) from road_usage
JOIN track ON track.id = road_usage.track_id JOIN track ON track.id = road_usage.track_id
@ -36,14 +37,52 @@ RETURNS TABLE(
) as usage_count, ) as usage_count,
r.dir as direction, r.dir as direction,
road.zone::zone_type as zone, road.zone::zone_type as zone,
-- Generate the "offset" column to be 0 for undirectional roads
case when road.directionality = 0 then r.dir else 0 end as offset_direction case when road.directionality = 0 then r.dir else 0 end as offset_direction
FROM road FROM road
-- This JOIN duplicates directional roads with r.reversed set to TRUE and
-- FALSE, but keeps undirectional roads single.
LEFT JOIN (VALUES (-1, TRUE), (1, FALSE), (0, FALSE)) AS r(dir, rev) ON (abs(r.dir) != road.directionality) LEFT JOIN (VALUES (-1, TRUE), (1, FALSE), (0, FALSE)) AS r(dir, rev) ON (abs(r.dir) != road.directionality)
FULL OUTER JOIN overtaking_event ON (road.way_id = overtaking_event.way_id and (road.directionality != 0 or overtaking_event.direction_reversed = r.rev))
JOIN track ON overtaking_event.track_id = track.id -- instead of a subquery, we join in a table that gives us overtaking
WHERE road.geometry && bbox -- statistics by way_id, filtered by user_id and time
AND (user_id is NULL or user_id = track.author_id) LEFT JOIN (
SELECT
overtaking_event.way_id as way_id,
overtaking_event.direction_reversed as direction_reversed,
avg(overtaking_event.distance_overtaker) as distance_overtaker_mean,
min(overtaking_event.distance_overtaker) as distance_overtaker_min,
max(overtaking_event.distance_overtaker) as distance_overtaker_max,
-- complicated way of saying "median" :)
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY overtaking_event.distance_overtaker) as distance_overtaker_median,
-- get all single values as well
array_agg(overtaking_event.distance_overtaker) as distance_overtaker_array,
count(overtaking_event.id)::int as distance_overtaker_count
FROM overtaking_event
JOIN track ON track.id = overtaking_event.track_id
WHERE (user_id is NULL or track.author_id = user_id)
AND overtaking_event.time BETWEEN COALESCE(min_time, '1900-01-01'::timestamp) AND COALESCE(max_time, '2100-01-01'::timestamp) AND overtaking_event.time BETWEEN COALESCE(min_time, '1900-01-01'::timestamp) AND COALESCE(max_time, '2100-01-01'::timestamp)
GROUP BY road.name, road.way_id, road.geometry, road.directionality, road.zone, r.dir, r.rev; GROUP BY overtaking_event.way_id, overtaking_event.direction_reversed
) e on (e.way_id = road.way_id and (road.directionality != 0 or e.direction_reversed = r.rev))
WHERE road.geometry && bbox
GROUP BY
road.name,
road.way_id,
road.geometry,
road.directionality,
road.zone,
r.dir,
r.rev,
e.way_id,
e.direction_reversed,
e.distance_overtaker_mean,
e.distance_overtaker_min,
e.distance_overtaker_max,
e.distance_overtaker_median,
e.distance_overtaker_array,
e.distance_overtaker_count
;
$$ LANGUAGE SQL IMMUTABLE; $$ LANGUAGE SQL IMMUTABLE;