Skip to content

Commit

Permalink
#68 #61 Update daily table and function to exclude filter
Browse files Browse the repository at this point in the history
  • Loading branch information
chmnata committed Oct 25, 2022
1 parent e83e277 commit 53a52dc
Show file tree
Hide file tree
Showing 2 changed files with 15 additions and 8 deletions.
19 changes: 12 additions & 7 deletions data_aggregation/sql/function_generate_network_daily.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,12 +30,13 @@ tt_hr AS (
SELECT segment_id,
dt,
hr,
CASE WHEN SUM(link_length) >= 0.8 * total_length
THEN SUM(link_length / spd_avg * 3.6 ) * total_length / SUM(link_length)
ELSE
NULL
END AS segment_avg_tt
sum(num_bin) as num_bin
SUM(link_length / spd_avg * 3.6 ) * total_length / SUM(link_length) AS segment_avg_tt,
SUM(link_length) AS length_w_data,
CASE WHEN SUM(link_length) >= 0.8 * total_length
THEN True
ELSE False
END AS valid,
sum(num_bin) AS num_bin

FROM speed_links
INNER JOIN congestion.network_segments USING (segment_id)
Expand All @@ -52,9 +53,11 @@ SELECT segment_id,
dt,
hr,
round(segment_avg_tt::numeric, 2) as tt,
length_w_data,
valid,
num_bin

FROM tt_hr
WHERE segment_avg_tt IS NOT NULL

$BODY$;

Expand All @@ -63,5 +66,7 @@ ALTER FUNCTION congestion.generate_network_daily(date)

GRANT EXECUTE ON FUNCTION congestion.generate_network_daily(date) TO congestion_admins;
GRANT EXECUTE ON FUNCTION congestion.generate_network_daily(date) TO congestion_bot;
REVOKE EXECUTE ON FUNCTION congestion.generate_network_daily(date) TO bdit_humans;

COMMENT ON FUNCTION congestion.generate_network_daily(date)
IS 'Function that aggregate network segments hourly travel time for each day. Runs everyday through an airflow process.';
4 changes: 3 additions & 1 deletion data_aggregation/sql/network_segments_daily.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,8 +3,10 @@ CREATE TABLE IF NOT EXISTS congestion.network_segments_daily
(
segment_id integer NOT NULL,
dt date NOT NULL,
hr numeric,
hr numeric NOT NULL,
tt numeric NOT NULL,
length_w_data numeric NOT NULL,
valid boolean NOT NULL,
num_bins integer NOT NULL
) PARTITION BY RANGE (dt);

Expand Down

0 comments on commit 53a52dc

Please sign in to comment.