Skip to content

Commit

Permalink
#52 Add data aggregation sql and functions for segment version 6
Browse files Browse the repository at this point in the history
  • Loading branch information
chmnata committed Jun 8, 2021
1 parent 1a28f93 commit 79b0051
Show file tree
Hide file tree
Showing 6 changed files with 425 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,83 @@
-- FUNCTION: congestion.generate_citywide_tti_daily(date)

-- DROP FUNCTION congestion.generate_citywide_tti_daily(date);

CREATE OR REPLACE FUNCTION congestion.generate_citywide_tti_daily(
_dt date)
RETURNS void
LANGUAGE 'sql'

COST 100
VOLATILE SECURITY DEFINER
AS $BODY$

WITH speed_links AS (
SELECT segment_id,
link_dir,
length AS link_length,
(TIMESTAMP WITHOUT TIME ZONE 'epoch' +
INTERVAL '1 second' * (floor((extract('epoch' from tx)) / 1800) * 1800)) AS datetime_bin,
harmean(mean) AS spd_avg,
COUNT(DISTINCT tx) AS count

FROM here.ta
INNER JOIN congestion.segment_links_v6_21_1 USING (link_dir)

WHERE (tx >= _dt AND tx < _dt + INTERVAL '1 day' )

GROUP BY segment_id, link_dir, datetime_bin, length
),


daily AS (
SELECT segment_id,
datetime_bin,
CASE WHEN SUM(link_length) >= 0.8 * b.length
THEN SUM(link_length / spd_avg * 3.6 ) * b.length / SUM(link_length)
ELSE
NULL
END AS segment_tt_avg

FROM speed_links
INNER JOIN congestion.segments_v6 b USING (segment_id)

WHERE link_length / spd_avg IS NOT NULL

GROUP BY segment_id, datetime_bin, b.length
ORDER BY segment_id, datetime_bin
),

seg_tti AS (
SELECT segment_id,
datetime_bin::date AS dt,
datetime_bin::time without time zone AS time_bin,
CASE WHEN highway.segment_id IS NOT NULL
THEN tti.segment_tt_avg/b.tt_baseline_10pct_corr
ELSE
tti.segment_tt_avg/b.tt_baseline_25pct_corr
END AS tti

FROM daily tti
LEFT JOIN congestion.tt_segments_baseline_v6_2019f b USING (segment_id)
LEFT JOIN congestion.highway_segments_v6 highway USING (segment_id)
)

INSERT INTO congestion.citywide_tti_daily(dt, time_bin, num_segments, tti)
SELECT dt,
time_bin,
count(seg_tti.segment_id) AS num_segments,
sum(seg_tti.tti * segments_v5.length * sqrt(segment_aadt_final.aadt)) / sum(segments_v5.length * sqrt(segment_aadt_final.aadt)) AS tti

FROM seg_tti
INNER JOIN congestion.segments_v6 USING (segment_id)
INNER JOIN covid.segment_aadt_final USING (segment_id)

WHERE time_bin <@ '[06:00:00, 23:00:00]'::timerange

GROUP BY dt, time_bin
ORDER BY dt, time_bin

$BODY$;

ALTER FUNCTION congestion.generate_citywide_tti_daily(date)
OWNER TO congestion_admins;
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
-- FUNCTION: congestion.generate_segments_bi_monthly(date)

-- DROP FUNCTION congestion.generate_segments_bi_monthly(date);

CREATE OR REPLACE FUNCTION congestion.generate_segments_bi_monthly(
_dt date)
RETURNS void
LANGUAGE 'sql'

COST 100
VOLATILE SECURITY DEFINER
AS $BODY$

/*
speed_links: Produces estimates of the average speed for each 60-minute bin for each individual link (link_dir)
*/
WITH speed_links AS (
SELECT segment_id,
link_dir,
date_trunc('hour',tx) AS datetime_bin,
harmean(mean) AS spd_avg,
length AS link_length,
COUNT (DISTINCT tx) AS count

FROM here.ta
INNER JOIN congestion.segment_links_v6_21_1 using (link_dir)
LEFT JOIN ref.holiday hol ON hol.dt = tx::date

WHERE hol.dt IS NULL AND
date_part('isodow'::text, tx::date) < 6 AND
(tx < _dt AND tx >= ( _dt - '1 mon'::interval))

GROUP BY segment_id, link_dir, datetime_bin, link_length),

/*
seg_tt: Produces estimates of the average travel time for each 60-minute bin for each individual segment (segment_id)
*/
seg_tt AS (
SELECT segment_id,
datetime_bin,
CASE WHEN SUM(link_length) >= 0.8 * b.length
THEN SUM(link_length / spd_avg * 3.6 ) * b.length / SUM(link_length)
END AS segment_tt_avg

FROM speed_links
INNER JOIN congestion.segments_v6 b USING (segment_id)

GROUP BY segment_id, datetime_bin, b.length
ORDER BY segment_id, datetime_bin
)


/*
Final output: Inserts an estimate of the segment buffer index (BI) into congestion.segments_bi_monthly, where at least 80% of the segments (by distance) has observations at the link (link_id) level
*/
INSERT INTO congestion.segments_bi_monthly

SELECT a.segment_id,
date_trunc('month', datetime_bin) AS month,
datetime_bin::time without time zone AS time_bin,
count(a.datetime_bin) AS num_bins,
avg(a.segment_tt_avg) AS avg_tt,
percentile_cont(0.95::double precision) WITHIN GROUP (ORDER BY a.segment_tt_avg) AS pct_95,
(percentile_cont(0.95::double precision) WITHIN GROUP (ORDER BY a.segment_tt_avg) - avg(a.segment_tt_avg))/ avg(a.segment_tt_avg) AS bi

FROM seg_tt a

GROUP BY a.segment_id, month, time_bin
ORDER BY a.segment_id, month, time_bin

$BODY$;

ALTER FUNCTION congestion.generate_segments_bi_monthly(date)
OWNER TO congestion_admins;
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
-- FUNCTION: congestion.generate_segments_tti_weekly(date)

-- DROP FUNCTION congestion.generate_segments_tti_weekly(date);

CREATE OR REPLACE FUNCTION congestion.generate_segments_tti_weekly(
_dt date)
RETURNS void
LANGUAGE 'sql'

COST 100
VOLATILE SECURITY DEFINER
AS $BODY$

/*
speed_links: Produces estimates of the average speed for each 30-minute bin for each individual link (link_dir)
*/
WITH speed_links AS (
SELECT segment_id,
link_dir,
length AS link_length,
(TIMESTAMP WITHOUT TIME ZONE 'epoch' +
INTERVAL '1 second' * (floor((extract('epoch' from tx)) / 1800) * 1800)) AS datetime_bin,
harmean(mean) AS spd_avg,
COUNT (DISTINCT tx) AS count

FROM here.ta
INNER JOIN congestion.segment_links_v6_21_1 USING (link_dir)
LEFT JOIN ref.holiday hol ON hol.dt = tx::date

WHERE hol.dt IS NULL AND
(tx < _dt AND tx >= ( _dt - '1 week'::interval))

GROUP BY segment_id, link_dir, datetime_bin, length
),

/*
tt_30: Produces estimates of the average travel time for each 30-minute bin for each individual segment (segment_id), where at least 80% of the segment (by distance) has observations at the link (link_dir) level
*/
tt_30 AS (
SELECT segment_id,
datetime_bin,
CASE WHEN date_part('isodow', datetime_bin)::int <@ '[1,6)'::int4range
THEN 'Weekday'
ELSE
'Weekend'
END as day_type,
CASE WHEN SUM(link_length) >= 0.8 * b.length
THEN SUM(link_length / spd_avg * 3.6 ) * b.length / SUM(link_length)
ELSE
NULL
END AS segment_tt_avg

FROM speed_links
INNER JOIN congestion.segments_v6 b USING (segment_id)

GROUP BY segment_id, datetime_bin, b.length, day_type
ORDER BY segment_id, datetime_bin
),

/*
weekly_tt: Produces estimates of the average travel time for each week for each 30-minute bin by segment (segment_id)
*/
weekly_tt AS (
SELECT a.segment_id,
a.datetime_bin::time without time zone AS time_bin,
count(a.datetime_bin) AS num_bins,
date_trunc('week'::text, a.datetime_bin) AS week,
day_type,
b.seg_length,
avg(a.segment_tt_avg) AS avg_tt,
CASE
WHEN highway.segment_id IS NOT NULL
THEN b.tt_baseline_10pct
ELSE
b.tt_baseline_25pct
END AS baseline_tt

FROM tt_30 a
LEFT JOIN congestion.tt_segments_baseline_v6_2019 b USING (segment_id)
LEFT JOIN congestion.highway_segments_v6 highway USING (segment_id)

GROUP BY a.segment_id, week, highway.segment_id, time_bin, day_type,
b.seg_length, b.tt_baseline_10pct, b.tt_baseline_25pct
ORDER BY a.segment_id, week, time_bin
)

/*
Final Output: Inserts an estimate of the segment TTI into congestion.segments_tti_weekly
*/
INSERT INTO congestion.segments_tti_weekly
SELECT tti.segment_id,
tti.week,
tti.day_type,
tti.time_bin,
tti.num_bins AS tti_num_bins,
tti.avg_tt,
tti.avg_tt / tti.baseline_tt AS tti
FROM weekly_tt tti


$BODY$;

ALTER FUNCTION congestion.generate_segments_tti_weekly(date)
OWNER TO congestion_admins;
67 changes: 67 additions & 0 deletions congestion_data_aggregation/grid_v6/tt_segments_30min_v6_2019.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
CREATE TABLE congestion.tt_segments_30min_v6_2019 AS

WITH X AS
(
SELECT a.segment_id,
a.link_dir,
a.datetime_bin,
ST_length(ST_transform(here.geom, 2952)) AS link_length,
a.spd_avg_all, a.spd_avg_hc,
a.spd_med_all, a.spd_med_hc,
ST_length(ST_transform(here.geom, 2952)) / a.spd_avg_all * 3.6 AS link_tt_avg_all,
ST_length(ST_transform(here.geom, 2952)) / a.spd_avg_hc * 3.6 AS link_tt_avg_hc,
ST_length(ST_transform(here.geom, 2952)) / a.spd_med_all * 3.6 AS link_tt_med_all,
ST_length(ST_transform(here.geom, 2952)) / a.spd_med_hc * 3.6 AS link_tt_med_hc,
b.length AS seg_length
FROM congestion.speeds_links_30_v6 a
INNER JOIN congestion.segments_v6 b USING (segment_id)
INNER JOIN here.routing_streets_21_1 here USING (link_dir)
GROUP BY segment_id, link_dir, datetime_bin, link_length, spd_avg_all, spd_avg_hc, spd_med_all, spd_med_hc, b.length
ORDER BY segment_id, link_dir
)

, Y AS ( --all=all confidence level
SELECT segment_id, datetime_bin,
CASE WHEN SUM(link_length) >= 0.8 * seg_length
THEN SUM(link_tt_avg_all) * seg_length / SUM(link_length)
END AS segment_tt_avg_all ,

CASE WHEN SUM(link_length) >= 0.8 * seg_length
THEN SUM(link_tt_med_all) * seg_length / SUM(link_length)
END AS segment_tt_med_all ,

SUM(link_length) / seg_length * 100 AS data_pct_all
FROM X
GROUP BY segment_id, datetime_bin, seg_length
ORDER BY segment_id, datetime_bin
)

, Z AS ( --hc=high confidence >= 30
SELECT segment_id, datetime_bin,
CASE WHEN SUM(link_length) >= 0.8 * seg_length
THEN SUM(link_tt_avg_hc) * seg_length / SUM(link_length)
END AS segment_tt_avg_hc ,

CASE WHEN SUM(link_length) >= 0.8 * seg_length
THEN SUM(link_tt_med_hc) * seg_length / SUM(link_length)
END AS segment_tt_med_hc ,

SUM(link_length) / seg_length * 100 AS data_pct_hc
FROM X
WHERE link_tt_avg_hc IS NOT NULL
AND link_tt_med_hc IS NOT NULL
GROUP BY segment_id, datetime_bin, seg_length
ORDER BY segment_id, datetime_bin
)

SELECT Y.segment_id,
Y.datetime_bin,
segment_tt_avg_all,
segment_tt_med_all,
data_pct_all,
segment_tt_avg_hc,
segment_tt_med_hc,
data_pct_hc
FROM Y
LEFT JOIN Z
USING (segment_id, datetime_bin)
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
CREATE TABLE congestion.tt_segments_baseline_v6_2019 AS

WITH daytime AS
(SELECT segment_id,
PERCENTILE_CONT (0.10) WITHIN GROUP (ORDER BY segment_tt_avg_hc ASC) AS tt_baseline_10pct,
PERCENTILE_CONT (0.15) WITHIN GROUP (ORDER BY segment_tt_avg_hc ASC) AS tt_baseline_15pct,
PERCENTILE_CONT (0.20) WITHIN GROUP (ORDER BY segment_tt_avg_hc ASC) AS tt_baseline_20pct,
PERCENTILE_CONT (0.25) WITHIN GROUP (ORDER BY segment_tt_avg_hc ASC) AS tt_baseline_25pct,
PERCENTILE_CONT (0.25) WITHIN GROUP (ORDER BY segment_tt_med_hc ASC) AS tt_baseline_25pct_med

FROM congestion.tt_segments_30min_v6_2019
WHERE datetime_bin::time BETWEEN '07:00:00' AND '20:59:59'
GROUP BY segment_id
),

overnight AS
(SELECT segment_id,
AVG(segment_tt_avg_hc) AS tt_baseline_overnight,
AVG(segment_tt_med_hc) AS tt_baseline_overnight_med
FROM congestion.tt_segments_30min_v6_2019
WHERE datetime_bin::time >= '22:00:00'
OR datetime_bin::time < '06:00:00'
GROUP BY segment_id
ORDER BY segment_id)

SELECT daytime.segment_id, segments.length AS seg_length,
tt_baseline_overnight,
tt_baseline_overnight_med,
tt_baseline_10pct,
tt_baseline_15pct,
tt_baseline_20pct,
tt_baseline_25pct,
tt_baseline_25pct_med,

segments.length / overnight.tt_baseline_overnight * 3.6 AS spd_baseline_overnight,
segments.length / overnight.tt_baseline_overnight_med * 3.6 AS spd_baseline_overnight_med,
segments.length / daytime.tt_baseline_10pct * 3.6 AS spd_baseline_10pct,
segments.length / daytime.tt_baseline_15pct * 3.6 AS spd_baseline_15pct,
segments.length / daytime.tt_baseline_20pct * 3.6 AS spd_baseline_20pct,
segments.length / daytime.tt_baseline_25pct * 3.6 AS spd_baseline_25pct,
segments.length / daytime.tt_baseline_25pct_med * 3.6 AS spd_baseline_25pct_med

FROM daytime
JOIN overnight USING (segment_id)
JOIN congestion.segments_v6 segments USING (segment_id)
Loading

0 comments on commit 79b0051

Please sign in to comment.