From a839c4c50d2514f61b18142b12dbd228b1adaf8f Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 20 Mar 2024 21:23:48 +0000 Subject: [PATCH 01/13] #905 sql dump --- .../create-view-miovision_15min_volume.sql | 58 +++++++ .../create-view-miovision_monthly_summary.sql | 163 ++++++++++++++++++ .../create-view-miovision_wide_tmc.sql | 124 +++++++++++++ 3 files changed, 345 insertions(+) create mode 100644 volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql create mode 100644 volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql create mode 100644 volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql diff --git a/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql b/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql new file mode 100644 index 000000000..561831763 --- /dev/null +++ b/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql @@ -0,0 +1,58 @@ +CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( + + SELECT + v15.intersection_uid, + i.api_name AS intersection_long_name, + v15.datetime_bin AS datetime_15min, + CASE + WHEN cl.classification = 'Light' THEN 'Light Auto' + WHEN cl.classification IN ('SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus') THEN 'Truck/Bus' + ELSE cl.classification -- 'Bicycle', 'Pedestrian' + END AS classification_type, + v15.leg AS approach, + mov.movement_name AS movement, + SUM(v15.volume) AS volume_15min + --exclude notes (manual text field) + --array_agg(ar.notes ORDER BY ar.range_start, ar.uid) FILTER (WHERE ar.uid IS NOT NULL) AS anomalous_range_caveats + FROM miovision_api.volumes_15min_mvt AS v15 + JOIN miovision_api.intersections AS i USING (intersection_uid) + JOIN miovision_api.classifications AS cl USING (classification_uid) + JOIN miovision_api.movements AS mov USING (movement_uid) + --anti-join anomalous_ranges + LEFT JOIN miovision_api.anomalous_ranges AS ar ON + ( + ar.intersection_uid = v15.intersection_uid + OR ar.intersection_uid IS NULL + ) AND ( + ar.classification_uid = v15.classification_uid + OR ar.classification_uid IS NULL + ) + AND v15.datetime_bin >= ar.range_start + AND ( + v15.datetime_bin < ar.range_end + OR ar.range_end IS NULL + ) + GROUP BY + v15.intersection_uid, + i.api_name, + v15.datetime_bin, + classification_type, + v15.leg, + mov.movement_name + HAVING + NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] + AND SUM(v15.volume) > 0 --confirm + ORDER BY + v15.intersection_uid, + classification_type, + v15.datetime_bin, + v15.leg +); + +--testing, indexes work +--50s for 1 day, 40 minutes for 1 month (5M rows) +SELECT * +FROM gwolofs.miovision_15min_open_data +WHERE + datetime_15min >= '2024-01-01'::date + AND datetime_15min < '2024-01-02'::date; \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql b/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql new file mode 100644 index 000000000..2e110f48b --- /dev/null +++ b/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql @@ -0,0 +1,163 @@ +--need to think more about grouping modes. + +DROP TABLE gwolofs.miovision_open_data_monthly; +CREATE TABLE gwolofs.miovision_open_data_monthly AS + +--replace with query of miovision_api.volumes_daily? +WITH daily_volumes AS ( + SELECT + v.intersection_uid, + v.datetime_bin::date AS dt, + c.class_type, + --v.leg, + SUM(v.volume) AS total_vol, + COUNT(DISTINCT v.datetime_bin) + FROM miovision_api.volumes_15min_mvt AS v + JOIN miovision_api.classifications AS c USING (classification_uid) + WHERE + v.datetime_bin >= '2024-02-01'::date + AND v.datetime_bin < '2024-03-01'::date + AND date_part('isodow', v.datetime_bin) <= 5 --weekday + AND c.class_type IS NOT NULL + GROUP BY + v.intersection_uid, + c.class_type, + dt--, + --v.leg + --these counts are very low for trucks, etc, doesn't work as a filter + --HAVING COUNT(DISTINCT datetime_bin) >= 92 --4 15minute bins present + ORDER BY + v.intersection_uid, + c.class_type, + --v.leg, + dt +), + +v15 AS ( + --group multiple classifications together by classtype + SELECT + v.intersection_uid, + v.datetime_bin, + c.class_type, --need to refine this grouping + --v.leg, + SUM(v.volume) AS vol_15min + FROM miovision_api.volumes_15min_mvt AS v + JOIN miovision_api.classifications AS c USING (classification_uid) + WHERE + datetime_bin >= '2024-02-01'::date + AND datetime_bin < '2024-03-01'::date + AND date_part('isodow', datetime_bin) IN (1,2,3,4,5) --weekday + AND class_type IS NOT NULL + --AND classification_uid NOT IN (2,10) --exclude bikes due to reliability + GROUP BY + v.intersection_uid, + c.class_type, + v.datetime_bin--, + --v.leg + --HAVING COUNT(DISTINCT datetime_bin) = 4 --can't use this filter for the non-auto modes +), + +hourly_data AS ( + --find rolling 1 hour volume + SELECT + intersection_uid, + --leg, + class_type, + datetime_bin, + datetime_bin::date AS dt, + CASE WHEN date_part('hour', datetime_bin) < 12 THEN 'AM' ELSE 'PM' END AS am_pm, + vol_15min, + SUM(vol_15min) OVER ( + PARTITION BY intersection_uid, class_type --, leg + ORDER BY datetime_bin + RANGE BETWEEN '45 minutes' PRECEDING AND CURRENT ROW + ) AS hr_vol + FROM v15 +), + +highest_daily_volume AS ( + --find highest volume each day + SELECT + intersection_uid, + --leg, + class_type, + am_pm, + dt, + MAX(hr_vol) AS max_hr_volume + FROM hourly_data + GROUP BY + intersection_uid, + --leg, + class_type, + am_pm, + dt +), + +anomalous_ranges_classtype AS ( + SELECT + ar.uid, + c.class_type, + ar.classification_uid, + ar.intersection_uid, + ar.range_start, + ar.range_end, + ar.notes, + ar.problem_level + FROM miovision_api.anomalous_ranges AS ar + LEFT JOIN miovision_api.classifications AS c USING (classification_uid) +) + +SELECT + coalesce(dv.intersection_uid, hv.intersection_uid) AS intersection, + --coalesce(dv.leg, hv.leg) AS leg, + date_trunc('month', coalesce(dv.dt, hv.dt)) AS mnth, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Vehicles'), 0) AS avg_daily_vol_veh, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Pedestrians'), 0) AS avg_daily_vol_ped, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Cyclists'), 0) AS avg_daily_vol_bike, + COUNT(dv.*) FILTER (WHERE dv.class_type = 'Vehicles') AS veh_n_days, + COUNT(dv.*) FILTER (WHERE dv.class_type = 'Pedestrians') AS ped_n_days, + COUNT(dv.*) FILTER (WHERE dv.class_type = 'Cyclists') AS bike_n_days, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_veh, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_ped, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_bike, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'AM') AS veh_n_am_hrs, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'AM') AS ped_n_am_hrs, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'AM') AS bike_n_am_hrs, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_veh, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_ped, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_bike, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'PM') AS veh_n_pm_hrs, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'PM') AS ped_n_pm_hrs, + COUNT(hv.*) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'PM') AS bike_n_pm_hrs, + array_agg(DISTINCT ar.notes) FILTER (WHERE ar.uid IS NOT NULL) AS notes +FROM daily_volumes AS dv +FULL JOIN highest_daily_volume AS hv USING (intersection_uid, dt, class_type--, leg + ) +LEFT JOIN ref.holiday AS hol + ON hol.dt = coalesce(dv.dt, hv.dt) +LEFT JOIN anomalous_ranges_classtype ar ON + ( + ar.intersection_uid = coalesce(dv.intersection_uid, hv.intersection_uid) + OR ar.intersection_uid IS NULL + ) AND ( + ar.class_type = coalesce(dv.class_type, hv.class_type) + OR ar.class_type IS NULL + ) + AND coalesce(dv.dt, hv.dt) >= ar.range_start + AND ( + coalesce(dv.dt, hv.dt) < ar.range_end + OR ar.range_end IS NULL + ) +WHERE hol.holiday IS NULL +GROUP BY + coalesce(dv.intersection_uid, hv.intersection_uid), + --coalesce(dv.leg, hv.leg), + date_trunc('month', coalesce(dv.dt, hv.dt)) +--need to refine anomalous_range exclusions, move earlier +--HAVING NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] -- 344 vs 163! --need to exclude at a previous stage +ORDER BY + coalesce(dv.intersection_uid, hv.intersection_uid), + --coalesce(dv.leg, hv.leg), + date_trunc('month', coalesce(dv.dt, hv.dt)); + +SELECT * FROM gwolofs.miovision_open_data_monthly; \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql new file mode 100644 index 000000000..40de5b28e --- /dev/null +++ b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql @@ -0,0 +1,124 @@ +--Would prefer to omit this, unless we *really* want it for comparison with existing short term TMC open data. + +--include u-turns? +--bikes +--motorized vehicles/streetcars? + +CREATE OR REPLACE VIEW gwolofs.miovision_open_data_wide_15min AS ( + +SELECT + v.intersection_uid, + v.datetime_bin, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'N'), 0) AS nx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'S'), 0) AS sx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'E'), 0) AS ex_peds, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'W'), 0) AS wx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'N'), 0) AS nx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'S'), 0) AS sx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'E'), 0) AS ex_bike, + COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'W'), 0) AS wx_bike +FROM miovision_api.volumes_15min_mvt AS v +JOIN miovision_api.classifications AS c USING (classification_uid) +JOIN miovision_api.movements AS m USING (movement_uid) +WHERE + datetime_bin >= '2024-02-01'::date + AND datetime_bin < '2024-03-01'::date + --AND intersection_uid = 1 + --AND classification_uid NOT IN (2,10) --exclude bikes due to reliability +GROUP BY + v.intersection_uid, + v.datetime_bin +ORDER BY + v.intersection_uid, + v.datetime_bin +); + +SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; + +/* query used for query development! + +SELECT col_name FROM ( +SELECT + 'COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = ' || movement_uid::text || + ' AND classification_uid = ANY (ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || + ' AND leg = ''' || leg || '''), 0) AS ' || + dir || '_' || + CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' WHEN 'MotorizedVehicle' THEN 'truck' END || '_' || + CASE movement_name WHEN 'left' THEN 'l' WHEN 'thru' THEN 't' WHEN 'right' THEN 'r' END || ',' AS col_name +FROM miovision_api.movements +CROSS JOIN miovision_api.classifications +CROSS JOIN (VALUES + ('sb', 'S', 1), ('nb', 'N', 2), ('wb', 'W', 3), ('eb', 'E', 4) +) AS directions(dir, leg, dir_order) +WHERE + classification_uid NOT IN (2,6,8,10) --bikes, peds, workvans (dne) + --AND movement_uid NOT IN (7,8) --entrances, exits + AND movement_uid IN (1,2,3) +GROUP BY + CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, + CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' WHEN 'MotorizedVehicle' THEN 'truck' END, + dir_order, + dir, + leg, + movement_uid +ORDER BY + CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, + dir_order, + CASE movement_name WHEN 'left' THEN 3 WHEN 'thru' THEN 2 WHEN 'right' THEN 1 END +) AS vehs + +UNION ALL + +SELECT col_name FROM ( + SELECT + 'COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = ' || classification_uid::text || + ' AND leg = ''' || leg || '''), 0) AS ' || + dir || '_' || + CASE classification WHEN 'Bicycle' THEN 'bike' WHEN 'Pedestrian' THEN 'peds' END || ',' AS col_name + FROM miovision_api.classifications + CROSS JOIN (VALUES + ('sx', 'S', 2), ('nx', 'N', 1), ('wx', 'W', 4), ('ex', 'E', 3) + ) AS directions(dir, leg, dir_order) + WHERE + classification_uid IN (2,6) --bikes, peds + ORDER BY + CASE classification WHEN 'Pedestrian' THEN 1 WHEN 'bike' THEN 2 END, + dir_order +) AS bikes_n_peds +*/ \ No newline at end of file From 917a298fbb696870a7a5548aa4a9af9dd225f487 Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Fri, 22 Mar 2024 18:48:14 +0000 Subject: [PATCH 02/13] #905 add entry/exit legs to 15min data --- .../create-view-miovision_15min_volume.sql | 36 ++++++++++++++++--- 1 file changed, 32 insertions(+), 4 deletions(-) diff --git a/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql b/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql index 561831763..31c391a36 100644 --- a/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql +++ b/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql @@ -1,3 +1,14 @@ +--Review decisions: +--Classification Grouping and naming +--Include/Exclude bicycles? +--Include/Exclude buses/streetcars? +--Decision to not include manual anomalous_range 'valid_caveat' notes: SELECT +--Including entry/exit information to satisfy ATR related DRs. + --> providing exit leg and direction as extra columns rather + -- than extra rows to reduce potential for double counting. + +--DROP VIEW gwolofs.miovision_15min_open_data; + CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( SELECT @@ -9,8 +20,12 @@ CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( WHEN cl.classification IN ('SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus') THEN 'Truck/Bus' ELSE cl.classification -- 'Bicycle', 'Pedestrian' END AS classification_type, - v15.leg AS approach, + v15.leg AS entry_leg, + entries.dir AS entry_dir, mov.movement_name AS movement, + --assign exits for peds, bike entry only movements + COALESCE(exits.leg_new, v15.leg) AS exit_leg, + COALESCE(exits.dir, entries.dir) AS exit_dir, SUM(v15.volume) AS volume_15min --exclude notes (manual text field) --array_agg(ar.notes ORDER BY ar.range_start, ar.uid) FILTER (WHERE ar.uid IS NOT NULL) AS anomalous_range_caveats @@ -18,7 +33,17 @@ CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( JOIN miovision_api.intersections AS i USING (intersection_uid) JOIN miovision_api.classifications AS cl USING (classification_uid) JOIN miovision_api.movements AS mov USING (movement_uid) - --anti-join anomalous_ranges + -- TMC to ATR crossover table for e + LEFT JOIN miovision_api.movement_map AS entries ON + entries.leg_old = v15.leg + AND entries.movement_uid = v15.movement_uid + AND entries.leg_new <> substr(entries.dir, 1, 1) --eg. E leg going West is an entry + -- TMC to ATR crossover table + LEFT JOIN miovision_api.movement_map AS exits ON + exits.leg_old = v15.leg + AND exits.movement_uid = v15.movement_uid + AND exits.leg_new = substr(exits.dir, 1, 1) --eg. E leg going East is an exit + --anti-join anomalous_ranges. See HAVING clause. LEFT JOIN miovision_api.anomalous_ranges AS ar ON ( ar.intersection_uid = v15.intersection_uid @@ -37,8 +62,11 @@ CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( i.api_name, v15.datetime_bin, classification_type, - v15.leg, - mov.movement_name + movement, + entry_leg, + entry_dir, + exit_dir, + exit_leg HAVING NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] AND SUM(v15.volume) > 0 --confirm From d76d8a6293678594d8b9ff80534255a00c035e0c Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Fri, 22 Mar 2024 21:59:27 +0000 Subject: [PATCH 03/13] #905 split in to table definitions, functions --- ...ction-insert_miovision_open_data_15min.sql | 150 +++++++++++++ ...rt_miovision_open_data_monthly_summary.sql | 203 ++++++++++++++++++ ...create-table-miovision_open_data_15min.sql | 36 ++++ ...le-miovision_open_data_monthly_summary.sql | 40 ++++ .../create-view-miovision_15min_volume.sql | 86 -------- .../create-view-miovision_monthly_summary.sql | 163 -------------- 6 files changed, 429 insertions(+), 249 deletions(-) create mode 100644 volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql create mode 100644 volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql create mode 100644 volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql create mode 100644 volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql delete mode 100644 volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql delete mode 100644 volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql diff --git a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql new file mode 100644 index 000000000..ac7e970b5 --- /dev/null +++ b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql @@ -0,0 +1,150 @@ +--Review decisions: +--Classification Grouping and naming +--Include/Exclude bicycles? +--Include/Exclude buses/streetcars? +--Decision to not include manual anomalous_range 'valid_caveat' notes: SELECT +--Including entry/exit information to satisfy ATR related DRs. + --> providing exit leg and direction as extra columns rather + -- than extra rows to reduce potential for double counting. + +--DROP FUNCTION gwolofs.insert_miovision_15min_open_data; + +CREATE OR REPLACE FUNCTION gwolofs.insert_miovision_15min_open_data( + _date date, + intersections integer[] DEFAULT ARRAY[]::integer[]) + RETURNS void + LANGUAGE 'plpgsql' + COST 100 + VOLATILE PARALLEL UNSAFE +AS $BODY$ + + DECLARE + target_intersections integer [] = miovision_api.get_intersections_uids(intersections); + n_deleted int; + n_inserted int; + _month date = date_trunc('month', _date); + + BEGIN + + WITH deleted AS ( + DELETE FROM gwolofs.miovision_15min_open_data + WHERE + datetime_15min >= _month + AND datetime_15min < _month + interval '1 month' + AND intersection_uid = ANY(target_intersections) + RETURNING * + ) + + SELECT COUNT(*) INTO n_deleted + FROM deleted; + + RAISE NOTICE 'Deleted % rows from gwolofs.miovision_15min_open_data for month %.', n_deleted, _month; + + WITH inserted AS ( + INSERT INTO gwolofs.miovision_15min_open_data ( + intersection_uid, intersection_long_name, datetime_15min, classification_type, + entry_leg, entry_dir, movement, exit_leg, exit_dir, volume_15min + ) + SELECT + v15.intersection_uid, + i.api_name AS intersection_long_name, + v15.datetime_bin AS datetime_15min, + CASE + WHEN cl.classification = 'Light' THEN 'Light Auto' + WHEN cl.classification IN ( + 'SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus' + ) THEN 'Truck/Bus' + ELSE cl.classification -- 'Bicycle', 'Pedestrian' + END AS classification_type, + v15.leg AS entry_leg, + entries.dir AS entry_dir, + mov.movement_name AS movement, + --assign exits for peds, bike entry only movements + COALESCE(exits.leg_new, v15.leg) AS exit_leg, + COALESCE(exits.dir, entries.dir) AS exit_dir, + SUM(v15.volume) AS volume_15min + --exclude notes (manual text field) + --array_agg(ar.notes ORDER BY ar.range_start, ar.uid) FILTER (WHERE ar.uid IS NOT NULL) AS anomalous_range_caveats + FROM miovision_api.volumes_15min_mvt AS v15 + JOIN miovision_api.intersections AS i USING (intersection_uid) + JOIN miovision_api.classifications AS cl USING (classification_uid) + JOIN miovision_api.movements AS mov USING (movement_uid) + -- TMC to ATR crossover table for e + LEFT JOIN miovision_api.movement_map AS entries ON + entries.leg_old = v15.leg + AND entries.movement_uid = v15.movement_uid + AND entries.leg_new <> substr(entries.dir, 1, 1) --eg. E leg going West is an entry + -- TMC to ATR crossover table + LEFT JOIN miovision_api.movement_map AS exits ON + exits.leg_old = v15.leg + AND exits.movement_uid = v15.movement_uid + AND exits.leg_new = substr(exits.dir, 1, 1) --eg. E leg going East is an exit + --anti-join anomalous_ranges. See HAVING clause. + LEFT JOIN miovision_api.anomalous_ranges AS ar ON + ( + ar.intersection_uid = v15.intersection_uid + OR ar.intersection_uid IS NULL + ) AND ( + ar.classification_uid = v15.classification_uid + OR ar.classification_uid IS NULL + ) + AND v15.datetime_bin >= ar.range_start + AND ( + v15.datetime_bin < ar.range_end + OR ar.range_end IS NULL + ) + WHERE + v15.datetime_bin >= _month + AND v15.datetime_bin < _month + interval '1 month' + AND v15.intersection_uid = ANY(target_intersections) + GROUP BY + v15.intersection_uid, + i.api_name, + v15.datetime_bin, + classification_type, + movement, + entry_leg, + entry_dir, + exit_dir, + exit_leg + HAVING + NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] + AND SUM(v15.volume) > 0 --confirm + ORDER BY + v15.intersection_uid, + classification_type, + v15.datetime_bin, + v15.leg + --fail on conflict + RETURNING * + ) + + SELECT COUNT(*) INTO n_inserted + FROM inserted; + + RAISE NOTICE 'Inserted % rows into gwolofs.miovision_15min_open_data for month %.', n_inserted, _month; + +END; +$BODY$; + +ALTER FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +OWNER TO gwolofs; + +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +TO miovision_admins; + +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +TO miovision_api_bot; + +REVOKE ALL ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +FROM PUBLIC; + +COMMENT ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +IS 'Function for first deleting then inserting monthly 15 +minute open data volumes into gwolofs.miovision_15min_open_data. +Contains an optional intersection parameter in case one just one +intersection needs to be refreshed.'; + +--testing, indexes work +--~50s for 1 day, ~40 minutes for 1 month (5M rows) +SELECT gwolofs.insert_miovision_15min_open_data('2024-02-01'::date); \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql new file mode 100644 index 000000000..c05a5f934 --- /dev/null +++ b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql @@ -0,0 +1,203 @@ +--DROP FUNCTION gwolofs.insert_miovision_open_data_monthly_summary; + +CREATE OR REPLACE FUNCTION gwolofs.insert_miovision_open_data_monthly_summary( + _date date, + intersections integer[] DEFAULT ARRAY[]::integer[]) + RETURNS void + LANGUAGE 'plpgsql' + COST 100 + VOLATILE PARALLEL UNSAFE +AS $BODY$ + + DECLARE + target_intersections integer [] = miovision_api.get_intersections_uids(intersections); + n_deleted int; + n_inserted int; + _month date = date_trunc('month', _date); + + BEGIN + + WITH deleted AS ( + DELETE FROM gwolofs.miovision_open_data_monthly_summary + WHERE + mnth = _month + AND intersection_uid = ANY(target_intersections) + RETURNING * + ) + + SELECT COUNT(*) INTO n_deleted + FROM deleted; + + RAISE NOTICE 'Deleted % rows from gwolofs.miovision_15min_open_data for month %.', n_deleted, _month; + + WITH daily_volumes AS ( + SELECT + vd.dt, + vd.intersection_uid, + CASE + WHEN cl.classification = 'Light' THEN 'Light Auto' + WHEN cl.classification IN ('SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus') THEN 'Truck/Bus' + ELSE cl.classification -- 'Bicycle', 'Pedestrian' + END AS classification_type, + --daily volume with long gaps imputted + SUM(coalesce(daily_volume,0) + coalesce(avg_historical_gap_vol,0)) AS total_vol + --omits anomalous_ranges + FROM miovision_api.volumes_daily AS vd + JOIN miovision_api.classifications AS cl USING (classification_uid) + WHERE + vd.isodow <= 5 + AND vd.holiday IS false + AND vd.dt >= _month + AND vd.dt < _month + interval '1 month' + AND vd.intersection_uid = ANY(target_intersections) + --AND classification_uid NOT IN (2,7,10) --exclude bikes due to reliability? + GROUP BY + vd.dt, + vd.intersection_uid, + vd.intersection_uid, + classification_type + ), + + v15 AS ( + --15 minute volumes grouped by classification_type + SELECT + v.intersection_uid, + v.datetime_bin, + CASE + WHEN cl.classification = 'Light' THEN 'Light Auto' + WHEN cl.classification IN ('SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus') THEN 'Truck/Bus' + ELSE cl.classification -- 'Bicycle', 'Pedestrian' + END AS classification_type, + SUM(v.volume) AS vol_15min + FROM miovision_api.volumes_15min_mvt AS v + JOIN miovision_api.classifications AS cl USING (classification_uid) + --anti join holidays + LEFT JOIN ref.holiday AS hol ON hol.dt = v.datetime_bin::date + --anti join anomalous ranges. See HAVING clause. + --NOTE: this method is omitting the whole classification_type if + --one classification is missing. May be undesired. + LEFT JOIN miovision_api.anomalous_ranges ar ON + ( + ar.intersection_uid = v.intersection_uid + OR ar.intersection_uid IS NULL + ) AND ( + ar.classification_uid = v.classification_uid + OR ar.classification_uid IS NULL + ) + AND v.datetime_bin >= ar.range_start + AND ( + v.datetime_bin < ar.range_end + OR ar.range_end IS NULL + ) + WHERE + v.datetime_bin >= _month + AND v.datetime_bin < _month + interval '1 month' + AND v.intersection_uid = ANY(target_intersections) + AND hol.holiday IS NULL + AND date_part('isodow', v.datetime_bin) <= 5 --weekday + --AND classification_uid NOT IN (2,7,10) --exclude bikes due to reliability? + GROUP BY + v.intersection_uid, + classification_type, + v.datetime_bin + ), + + hourly_data AS ( + --find rolling 1 hour volume + SELECT + intersection_uid, + classification_type, + datetime_bin, + datetime_bin::date AS dt, + CASE WHEN date_part('hour', datetime_bin) < 12 THEN 'AM' ELSE 'PM' END AS am_pm, + vol_15min, + SUM(vol_15min) OVER ( + PARTITION BY intersection_uid, classification_type + ORDER BY datetime_bin + RANGE BETWEEN '45 minutes' PRECEDING AND CURRENT ROW + ) AS hr_vol + FROM v15 + ), + + highest_daily_volume AS ( + --find highest volume each day + SELECT + intersection_uid, + classification_type, + am_pm, + dt, + MAX(hr_vol) AS max_hr_volume + FROM hourly_data + GROUP BY + intersection_uid, + classification_type, + am_pm, + dt + ), + + inserted AS ( + INSERT INTO gwolofs.miovision_open_data_monthly_summary ( + intersection_uid, intersection_long_name, mnth, avg_daily_vol_auto, avg_daily_vol_truckbus, avg_daily_vol_ped, avg_daily_vol_bike, + avg_am_peak_hour_vol_auto, avg_am_peak_hour_vol_truckbus, avg_am_peak_hour_vol_ped, avg_am_peak_hour_vol_bike, + avg_pm_peak_hour_vol_auto, avg_pm_peak_hour_vol_truckbus, avg_pm_peak_hour_vol_ped, avg_pm_peak_hour_vol_bike + ) + SELECT + coalesce(dv.intersection_uid, hv.intersection_uid) AS intersection_uid, + i.api_name AS intersection_long_name, + date_trunc('month', coalesce(dv.dt, hv.dt)) AS mnth, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.classification_type = 'Light Auto'), 0) AS avg_daily_vol_auto, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.classification_type = 'Truck/Bus'), 0) AS avg_daily_vol_truckbus, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.classification_type = 'Pedestrians'), 0) AS avg_daily_vol_ped, + ROUND(AVG(dv.total_vol) FILTER (WHERE dv.classification_type = 'Cyclists'), 0) AS avg_daily_vol_bike, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Light Auto' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_auto, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Truck/Bus' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_truckbus, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Pedestrians' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_ped, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Cyclists' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_bike, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Light Auto' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_auto, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Truck/Bus' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_truckbus, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Pedestrians' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_ped, + ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.classification_type = 'Cyclists' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_bike + --array_agg(DISTINCT ar.notes) FILTER (WHERE ar.uid IS NOT NULL) AS notes + FROM daily_volumes AS dv + FULL JOIN highest_daily_volume AS hv USING (intersection_uid, dt, classification_type) + LEFT JOIN miovision_api.intersections AS i ON + i.intersection_uid = coalesce(dv.intersection_uid, hv.intersection_uid) + GROUP BY + coalesce(dv.intersection_uid, hv.intersection_uid), + i.api_name, + date_trunc('month', coalesce(dv.dt, hv.dt)) + ORDER BY + coalesce(dv.intersection_uid, hv.intersection_uid), + date_trunc('month', coalesce(dv.dt, hv.dt)) + RETURNING * + ) + + SELECT COUNT(*) INTO n_inserted + FROM inserted; + + RAISE NOTICE 'Inserted % rows into gwolofs.miovision_open_data_monthly_summary for month %.', n_inserted, _month; + +END; +$BODY$; + +ALTER FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +OWNER TO gwolofs; + +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +TO miovision_admins; + +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +TO miovision_api_bot; + +REVOKE ALL ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +FROM PUBLIC; + +COMMENT ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +IS 'Function for first deleting then inserting monthly summary miovision +open data into gwolofs.miovision_open_data_monthly_summary. +Contains an optional intersection parameter in case one just one +intersection needs to be refreshed.'; + +--testing, indexes work +--~50s for 1 day, ~40 minutes for 1 month (5M rows) +SELECT gwolofs.insert_miovision_open_data_monthly_summary('2024-02-01'::date); \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql new file mode 100644 index 000000000..51d742fa7 --- /dev/null +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql @@ -0,0 +1,36 @@ +-- DROP TABLE IF EXISTS gwolofs.miovision_15min_open_data; + +CREATE TABLE IF NOT EXISTS gwolofs.miovision_15min_open_data +( + intersection_uid integer NOT NULL, + intersection_long_name text COLLATE pg_catalog."default", + datetime_15min timestamp without time zone NOT NULL, + classification_type text COLLATE pg_catalog."default" NOT NULL, + entry_leg text COLLATE pg_catalog."default" NOT NULL, + entry_dir text COLLATE pg_catalog."default", + movement text COLLATE pg_catalog."default" NOT NULL, + exit_leg text COLLATE pg_catalog."default", + exit_dir text COLLATE pg_catalog."default", + volume_15min smallint, + CONSTRAINT miovision_open_data_15min_pkey PRIMARY KEY ( + intersection_uid, datetime_15min, classification_type, entry_leg, movement + ) +) + +TABLESPACE pg_default; + +ALTER TABLE IF EXISTS gwolofs.miovision_15min_open_data +OWNER TO gwolofs; + +REVOKE ALL ON TABLE gwolofs.miovision_15min_open_data FROM bdit_humans; + +GRANT SELECT ON TABLE gwolofs.miovision_15min_open_data TO bdit_humans; + +GRANT ALL ON TABLE gwolofs.miovision_15min_open_data TO gwolofs; + +GRANT ALL ON TABLE gwolofs.miovision_15min_open_data TO miovision_admins; + +COMMENT ON TABLE gwolofs.miovision_15min_open_data +IS 'Table to store Miovision 15min open data. Updated monthly. +Schema is a blend of TMC and ATR style data to cover different +types of data requests.'; \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql new file mode 100644 index 000000000..28d64e0cf --- /dev/null +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql @@ -0,0 +1,40 @@ +-- DROP TABLE gwolofs.miovision_open_data_monthly_summary;\ + +CREATE TABLE gwolofs.miovision_open_data_monthly_summary ( + intersection_uid integer, + intersection_long_name text, + mnth date, + avg_daily_vol_auto numeric, + avg_daily_vol_truckbus numeric, + avg_daily_vol_ped numeric, + avg_daily_vol_bike numeric, + avg_am_peak_hour_vol_auto numeric, + avg_am_peak_hour_vol_truckbus numeric, + avg_am_peak_hour_vol_ped numeric, + avg_am_peak_hour_vol_bike numeric, + avg_pm_peak_hour_vol_auto numeric, + avg_pm_peak_hour_vol_truckbus numeric, + avg_pm_peak_hour_vol_ped numeric, + avg_pm_peak_hour_vol_bike numeric, + CONSTRAINT miovision_open_data_monthly_summary_pkey PRIMARY KEY ( + intersection_uid, intersection_long_name, mnth + ) +) + +TABLESPACE pg_default; + +ALTER TABLE IF EXISTS gwolofs.miovision_open_data_monthly_summary +OWNER TO gwolofs; + +REVOKE ALL ON TABLE gwolofs.miovision_open_data_monthly_summary FROM bdit_humans; + +GRANT SELECT ON TABLE gwolofs.miovision_open_data_monthly_summary TO bdit_humans; + +GRANT ALL ON TABLE gwolofs.miovision_open_data_monthly_summary TO gwolofs; + +GRANT ALL ON TABLE gwolofs.miovision_open_data_monthly_summary TO miovision_admins; + +COMMENT ON TABLE gwolofs.miovision_open_data_monthly_summary +IS 'Table to store Miovision monthly summary open data. +Contains an approachable monthly-intersection summary of +avg daily and avg peak AM/PM hour volumes by mode.'; \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql b/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql deleted file mode 100644 index 31c391a36..000000000 --- a/volumes/miovision/sql/open_data/create-view-miovision_15min_volume.sql +++ /dev/null @@ -1,86 +0,0 @@ ---Review decisions: ---Classification Grouping and naming ---Include/Exclude bicycles? ---Include/Exclude buses/streetcars? ---Decision to not include manual anomalous_range 'valid_caveat' notes: SELECT ---Including entry/exit information to satisfy ATR related DRs. - --> providing exit leg and direction as extra columns rather - -- than extra rows to reduce potential for double counting. - ---DROP VIEW gwolofs.miovision_15min_open_data; - -CREATE OR REPLACE VIEW gwolofs.miovision_15min_open_data AS ( - - SELECT - v15.intersection_uid, - i.api_name AS intersection_long_name, - v15.datetime_bin AS datetime_15min, - CASE - WHEN cl.classification = 'Light' THEN 'Light Auto' - WHEN cl.classification IN ('SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus') THEN 'Truck/Bus' - ELSE cl.classification -- 'Bicycle', 'Pedestrian' - END AS classification_type, - v15.leg AS entry_leg, - entries.dir AS entry_dir, - mov.movement_name AS movement, - --assign exits for peds, bike entry only movements - COALESCE(exits.leg_new, v15.leg) AS exit_leg, - COALESCE(exits.dir, entries.dir) AS exit_dir, - SUM(v15.volume) AS volume_15min - --exclude notes (manual text field) - --array_agg(ar.notes ORDER BY ar.range_start, ar.uid) FILTER (WHERE ar.uid IS NOT NULL) AS anomalous_range_caveats - FROM miovision_api.volumes_15min_mvt AS v15 - JOIN miovision_api.intersections AS i USING (intersection_uid) - JOIN miovision_api.classifications AS cl USING (classification_uid) - JOIN miovision_api.movements AS mov USING (movement_uid) - -- TMC to ATR crossover table for e - LEFT JOIN miovision_api.movement_map AS entries ON - entries.leg_old = v15.leg - AND entries.movement_uid = v15.movement_uid - AND entries.leg_new <> substr(entries.dir, 1, 1) --eg. E leg going West is an entry - -- TMC to ATR crossover table - LEFT JOIN miovision_api.movement_map AS exits ON - exits.leg_old = v15.leg - AND exits.movement_uid = v15.movement_uid - AND exits.leg_new = substr(exits.dir, 1, 1) --eg. E leg going East is an exit - --anti-join anomalous_ranges. See HAVING clause. - LEFT JOIN miovision_api.anomalous_ranges AS ar ON - ( - ar.intersection_uid = v15.intersection_uid - OR ar.intersection_uid IS NULL - ) AND ( - ar.classification_uid = v15.classification_uid - OR ar.classification_uid IS NULL - ) - AND v15.datetime_bin >= ar.range_start - AND ( - v15.datetime_bin < ar.range_end - OR ar.range_end IS NULL - ) - GROUP BY - v15.intersection_uid, - i.api_name, - v15.datetime_bin, - classification_type, - movement, - entry_leg, - entry_dir, - exit_dir, - exit_leg - HAVING - NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] - AND SUM(v15.volume) > 0 --confirm - ORDER BY - v15.intersection_uid, - classification_type, - v15.datetime_bin, - v15.leg -); - ---testing, indexes work ---50s for 1 day, 40 minutes for 1 month (5M rows) -SELECT * -FROM gwolofs.miovision_15min_open_data -WHERE - datetime_15min >= '2024-01-01'::date - AND datetime_15min < '2024-01-02'::date; \ No newline at end of file diff --git a/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql b/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql deleted file mode 100644 index 2e110f48b..000000000 --- a/volumes/miovision/sql/open_data/create-view-miovision_monthly_summary.sql +++ /dev/null @@ -1,163 +0,0 @@ ---need to think more about grouping modes. - -DROP TABLE gwolofs.miovision_open_data_monthly; -CREATE TABLE gwolofs.miovision_open_data_monthly AS - ---replace with query of miovision_api.volumes_daily? -WITH daily_volumes AS ( - SELECT - v.intersection_uid, - v.datetime_bin::date AS dt, - c.class_type, - --v.leg, - SUM(v.volume) AS total_vol, - COUNT(DISTINCT v.datetime_bin) - FROM miovision_api.volumes_15min_mvt AS v - JOIN miovision_api.classifications AS c USING (classification_uid) - WHERE - v.datetime_bin >= '2024-02-01'::date - AND v.datetime_bin < '2024-03-01'::date - AND date_part('isodow', v.datetime_bin) <= 5 --weekday - AND c.class_type IS NOT NULL - GROUP BY - v.intersection_uid, - c.class_type, - dt--, - --v.leg - --these counts are very low for trucks, etc, doesn't work as a filter - --HAVING COUNT(DISTINCT datetime_bin) >= 92 --4 15minute bins present - ORDER BY - v.intersection_uid, - c.class_type, - --v.leg, - dt -), - -v15 AS ( - --group multiple classifications together by classtype - SELECT - v.intersection_uid, - v.datetime_bin, - c.class_type, --need to refine this grouping - --v.leg, - SUM(v.volume) AS vol_15min - FROM miovision_api.volumes_15min_mvt AS v - JOIN miovision_api.classifications AS c USING (classification_uid) - WHERE - datetime_bin >= '2024-02-01'::date - AND datetime_bin < '2024-03-01'::date - AND date_part('isodow', datetime_bin) IN (1,2,3,4,5) --weekday - AND class_type IS NOT NULL - --AND classification_uid NOT IN (2,10) --exclude bikes due to reliability - GROUP BY - v.intersection_uid, - c.class_type, - v.datetime_bin--, - --v.leg - --HAVING COUNT(DISTINCT datetime_bin) = 4 --can't use this filter for the non-auto modes -), - -hourly_data AS ( - --find rolling 1 hour volume - SELECT - intersection_uid, - --leg, - class_type, - datetime_bin, - datetime_bin::date AS dt, - CASE WHEN date_part('hour', datetime_bin) < 12 THEN 'AM' ELSE 'PM' END AS am_pm, - vol_15min, - SUM(vol_15min) OVER ( - PARTITION BY intersection_uid, class_type --, leg - ORDER BY datetime_bin - RANGE BETWEEN '45 minutes' PRECEDING AND CURRENT ROW - ) AS hr_vol - FROM v15 -), - -highest_daily_volume AS ( - --find highest volume each day - SELECT - intersection_uid, - --leg, - class_type, - am_pm, - dt, - MAX(hr_vol) AS max_hr_volume - FROM hourly_data - GROUP BY - intersection_uid, - --leg, - class_type, - am_pm, - dt -), - -anomalous_ranges_classtype AS ( - SELECT - ar.uid, - c.class_type, - ar.classification_uid, - ar.intersection_uid, - ar.range_start, - ar.range_end, - ar.notes, - ar.problem_level - FROM miovision_api.anomalous_ranges AS ar - LEFT JOIN miovision_api.classifications AS c USING (classification_uid) -) - -SELECT - coalesce(dv.intersection_uid, hv.intersection_uid) AS intersection, - --coalesce(dv.leg, hv.leg) AS leg, - date_trunc('month', coalesce(dv.dt, hv.dt)) AS mnth, - ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Vehicles'), 0) AS avg_daily_vol_veh, - ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Pedestrians'), 0) AS avg_daily_vol_ped, - ROUND(AVG(dv.total_vol) FILTER (WHERE dv.class_type = 'Cyclists'), 0) AS avg_daily_vol_bike, - COUNT(dv.*) FILTER (WHERE dv.class_type = 'Vehicles') AS veh_n_days, - COUNT(dv.*) FILTER (WHERE dv.class_type = 'Pedestrians') AS ped_n_days, - COUNT(dv.*) FILTER (WHERE dv.class_type = 'Cyclists') AS bike_n_days, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_veh, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_ped, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'AM'), 0) AS avg_am_peak_hour_vol_bike, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'AM') AS veh_n_am_hrs, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'AM') AS ped_n_am_hrs, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'AM') AS bike_n_am_hrs, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_veh, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_ped, - ROUND(AVG(hv.max_hr_volume) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'PM'), 0) AS avg_pm_peak_hour_vol_bike, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Vehicles' AND hv.am_pm = 'PM') AS veh_n_pm_hrs, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Pedestrians' AND hv.am_pm = 'PM') AS ped_n_pm_hrs, - COUNT(hv.*) FILTER (WHERE hv.class_type = 'Cyclists' AND hv.am_pm = 'PM') AS bike_n_pm_hrs, - array_agg(DISTINCT ar.notes) FILTER (WHERE ar.uid IS NOT NULL) AS notes -FROM daily_volumes AS dv -FULL JOIN highest_daily_volume AS hv USING (intersection_uid, dt, class_type--, leg - ) -LEFT JOIN ref.holiday AS hol - ON hol.dt = coalesce(dv.dt, hv.dt) -LEFT JOIN anomalous_ranges_classtype ar ON - ( - ar.intersection_uid = coalesce(dv.intersection_uid, hv.intersection_uid) - OR ar.intersection_uid IS NULL - ) AND ( - ar.class_type = coalesce(dv.class_type, hv.class_type) - OR ar.class_type IS NULL - ) - AND coalesce(dv.dt, hv.dt) >= ar.range_start - AND ( - coalesce(dv.dt, hv.dt) < ar.range_end - OR ar.range_end IS NULL - ) -WHERE hol.holiday IS NULL -GROUP BY - coalesce(dv.intersection_uid, hv.intersection_uid), - --coalesce(dv.leg, hv.leg), - date_trunc('month', coalesce(dv.dt, hv.dt)) ---need to refine anomalous_range exclusions, move earlier ---HAVING NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] -- 344 vs 163! --need to exclude at a previous stage -ORDER BY - coalesce(dv.intersection_uid, hv.intersection_uid), - --coalesce(dv.leg, hv.leg), - date_trunc('month', coalesce(dv.dt, hv.dt)); - -SELECT * FROM gwolofs.miovision_open_data_monthly; \ No newline at end of file From aeed63c2e1ab35fcc0ad39408c9816d55e2f9a9c Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Fri, 22 Mar 2024 22:16:16 +0000 Subject: [PATCH 04/13] #905 add a monthly dag --- dags/miovision_open_data.py | 83 +++++++++++++++++++++++++++++++++++++ 1 file changed, 83 insertions(+) create mode 100644 dags/miovision_open_data.py diff --git a/dags/miovision_open_data.py b/dags/miovision_open_data.py new file mode 100644 index 000000000..8ba4f3522 --- /dev/null +++ b/dags/miovision_open_data.py @@ -0,0 +1,83 @@ +r"""### Monthly Miovision Open Data DAG +Pipeline to run monthly Miovision aggregations for Open Data. +""" +import sys +import os + +from airflow.decorators import dag, task +from datetime import timedelta +from airflow.models import Variable +from airflow.providers.postgres.operators.postgres import PostgresOperator +from airflow.macros import ds_format + +import logging +import pendulum + +try: + repo_path = os.path.abspath(os.path.dirname(os.path.dirname(os.path.realpath(__file__)))) + sys.path.insert(0, repo_path) + from dags.dag_functions import task_fail_slack_alert, send_slack_msg +except: + raise ImportError("Cannot import DAG helper functions.") + +LOGGER = logging.getLogger(__name__) +logging.basicConfig(level=logging.DEBUG) + +DAG_NAME = 'miovision_open_data' +DAG_OWNERS = Variable.get('dag_owners', deserialize_json=True).get(DAG_NAME, ["Unknown"]) + +default_args = { + 'owner': ','.join(DAG_OWNERS), + 'depends_on_past':False, + #set earlier start_date + catchup when ready? + 'start_date': pendulum.datetime(2023, 12, 18, tz="America/Toronto"), + 'email_on_failure': False, + 'email_on_success': False, + 'retries': 0, + 'retry_delay': timedelta(minutes=5), + 'on_failure_callback': task_fail_slack_alert +} + +@dag( + dag_id=DAG_NAME, + default_args=default_args, + schedule='0 14 3 * *', # 2pm, 3rd day of each month + catchup=False, + tags=["miovision", "open_data"], + doc_md=__doc__ +) +def miovision_open_data_dag(): + + #considered whether it should have an external task sensor + #for the first of the month. Decided it should run later + #to give time for anomalous_range updates if any. + + refresh_monthly_open_data = PostgresOperator( + task_id='refresh_monthly_open_data', + sql="SELECT gwolofs.insert_miovision_open_data_monthly_summary('{{ macros.ds_format(ds, '%Y-%m-%d', '%Y-%m-01') }}'::date)", + postgres_conn_id='miovision_api_bot', + autocommit=True + ) + + refresh_15min_open_data = PostgresOperator( + task_id='refresh_15min_open_data', + sql="SELECT gwolofs.insert_miovision_15min_open_data('{{ macros.ds_format(ds, '%Y-%m-%d', '%Y-%m-01') }}'::date)", + postgres_conn_id='miovision_api_bot', + autocommit=True + ) + + @task( + retries=0, + trigger_rule='all_done', + doc_md="""A status message to report DAG success.""" + ) + def status_message(ds = None, **context): + mnth = ds_format(ds, '%Y-%m-%d', '%Y-%m-01') + send_slack_msg( + context=context, + msg=f":meow_miovision: :open_data_to: DAG ran successfully for {mnth} :white_check_mark:" + ) + + refresh_monthly_open_data >> refresh_15min_open_data >> status_message() + +miovision_open_data_dag() From 688b1bcfb0baff4f6ef5b46016c5de5a7af155bb Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Mon, 25 Mar 2024 14:46:27 +0000 Subject: [PATCH 05/13] #905 update permissions for api_bot --- .../sql/open_data/create-table-miovision_open_data_15min.sql | 3 +++ .../create-table-miovision_open_data_monthly_summary.sql | 5 ++++- 2 files changed, 7 insertions(+), 1 deletion(-) diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql index 51d742fa7..e1df6daea 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql @@ -30,6 +30,9 @@ GRANT ALL ON TABLE gwolofs.miovision_15min_open_data TO gwolofs; GRANT ALL ON TABLE gwolofs.miovision_15min_open_data TO miovision_admins; +GRANT SELECT, INSERT, DELETE ON TABLE gwolofs.miovision_15min_open_data +TO miovision_api_bot; + COMMENT ON TABLE gwolofs.miovision_15min_open_data IS 'Table to store Miovision 15min open data. Updated monthly. Schema is a blend of TMC and ATR style data to cover different diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql index 28d64e0cf..6b8c4d627 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql @@ -1,4 +1,4 @@ --- DROP TABLE gwolofs.miovision_open_data_monthly_summary;\ +-- DROP TABLE gwolofs.miovision_open_data_monthly_summary; CREATE TABLE gwolofs.miovision_open_data_monthly_summary ( intersection_uid integer, @@ -34,6 +34,9 @@ GRANT ALL ON TABLE gwolofs.miovision_open_data_monthly_summary TO gwolofs; GRANT ALL ON TABLE gwolofs.miovision_open_data_monthly_summary TO miovision_admins; +GRANT SELECT, INSERT, DELETE ON TABLE gwolofs.miovision_open_data_monthly_summary +TO miovision_api_bot; + COMMENT ON TABLE gwolofs.miovision_open_data_monthly_summary IS 'Table to store Miovision monthly summary open data. Contains an approachable monthly-intersection summary of From c44deb807fe2debd97d1d39880729800a420135e Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Mon, 25 Mar 2024 14:46:46 +0000 Subject: [PATCH 06/13] #905 add check_data_availability, update dag params --- dags/miovision_open_data.py | 30 +++++++++++++++++++++++++++--- 1 file changed, 27 insertions(+), 3 deletions(-) diff --git a/dags/miovision_open_data.py b/dags/miovision_open_data.py index 8ba4f3522..b5aff87f3 100644 --- a/dags/miovision_open_data.py +++ b/dags/miovision_open_data.py @@ -17,6 +17,7 @@ repo_path = os.path.abspath(os.path.dirname(os.path.dirname(os.path.realpath(__file__)))) sys.path.insert(0, repo_path) from dags.dag_functions import task_fail_slack_alert, send_slack_msg + from dags.custom_operators import SQLCheckOperatorWithReturnValue except: raise ImportError("Cannot import DAG helper functions.") @@ -30,7 +31,7 @@ 'owner': ','.join(DAG_OWNERS), 'depends_on_past':False, #set earlier start_date + catchup when ready? - 'start_date': pendulum.datetime(2023, 12, 18, tz="America/Toronto"), + 'start_date': pendulum.datetime(2024, 1, 1, tz="America/Toronto"), 'email_on_failure': False, 'email_on_success': False, 'retries': 0, @@ -42,7 +43,8 @@ dag_id=DAG_NAME, default_args=default_args, schedule='0 14 3 * *', # 2pm, 3rd day of each month - catchup=False, + catchup=True, + max_active_runs=1, tags=["miovision", "open_data"], doc_md=__doc__ ) @@ -52,6 +54,24 @@ def miovision_open_data_dag(): #for the first of the month. Decided it should run later #to give time for anomalous_range updates if any. + check_data_availability = SQLCheckOperatorWithReturnValue( + task_id="check_data_availability", + sql="""WITH daily_volumes AS ( + SELECT dt::date, COALESCE(SUM(daily_volume), 0) AS daily_volume + FROM generate_series('{{ macros.ds_format(ds, '%Y-%m-%d', '%Y-%m-01') }}'::date, + '{{ macros.ds_format(ds, '%Y-%m-%d', '%Y-%m-01') }}'::date + '1 month'::interval - '1 day'::interval, + '1 day'::interval) AS dates(dt) + LEFT JOIN miovision_api.volumes_daily_unfiltered USING (dt) + GROUP BY dt + ORDER BY dt + ) + + SELECT NOT(COUNT(*) > 0), 'Missing dates: ' || string_agg(dt::text, ', ') + FROM daily_volumes + WHERE daily_volume = 0""", + conn_id="miovision_api_bot" + ) + refresh_monthly_open_data = PostgresOperator( task_id='refresh_monthly_open_data', sql="SELECT gwolofs.insert_miovision_open_data_monthly_summary('{{ macros.ds_format(ds, '%Y-%m-%d', '%Y-%m-01') }}'::date)", @@ -78,6 +98,10 @@ def status_message(ds = None, **context): msg=f":meow_miovision: :open_data_to: DAG ran successfully for {mnth} :white_check_mark:" ) - refresh_monthly_open_data >> refresh_15min_open_data >> status_message() + ( + check_data_availability >> + [refresh_monthly_open_data, refresh_15min_open_data] >> + status_message() + ) miovision_open_data_dag() From 0926913bf71f13de096e810b71301a6a134a5d7a Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Mon, 25 Mar 2024 19:37:03 +0000 Subject: [PATCH 07/13] #905 add date indices --- .../sql/open_data/create-table-miovision_open_data_15min.sql | 3 +++ .../create-table-miovision_open_data_monthly_summary.sql | 3 +++ 2 files changed, 6 insertions(+) diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql index e1df6daea..404887c1c 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql @@ -19,6 +19,9 @@ CREATE TABLE IF NOT EXISTS gwolofs.miovision_15min_open_data TABLESPACE pg_default; +CREATE INDEX miovision_15min_od_dt_idx ON +gwolofs.miovision_15min_open_data USING brin (datetime_15min); + ALTER TABLE IF EXISTS gwolofs.miovision_15min_open_data OWNER TO gwolofs; diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql index 6b8c4d627..31e9a3d28 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql @@ -23,6 +23,9 @@ CREATE TABLE gwolofs.miovision_open_data_monthly_summary ( TABLESPACE pg_default; +CREATE INDEX miovision_monthly_od_dt_idx ON +gwolofs.miovision_open_data_monthly_summary USING brin (mnth); + ALTER TABLE IF EXISTS gwolofs.miovision_open_data_monthly_summary OWNER TO gwolofs; From 88f32601be98c9f7bee5bfd1525241eda927a5e8 Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Tue, 26 Mar 2024 16:09:52 +0000 Subject: [PATCH 08/13] #905 small update for readability --- ...ction-insert_miovision_open_data_15min.sql | 56 +++++++++++-------- 1 file changed, 32 insertions(+), 24 deletions(-) diff --git a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql index ac7e970b5..541fbb769 100644 --- a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql +++ b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql @@ -40,6 +40,24 @@ AS $BODY$ RAISE NOTICE 'Deleted % rows from gwolofs.miovision_15min_open_data for month %.', n_deleted, _month; + CREATE TEMP TABLE miovision_movement_map_new AS ( + SELECT + entries.movement_uid, + entries.leg_old AS leg, + entries.dir AS entry_dir, + mov.movement_name AS movement, + --assign exits for peds, bike entry only movements + COALESCE(exits.leg_new, entries.leg_old) AS exit_leg, + COALESCE(exits.dir, entries.dir) AS exit_dir + FROM miovision_api.movement_map AS entries + JOIN miovision_api.movements AS mov USING (movement_uid) + LEFT JOIN miovision_api.movement_map AS exits ON + exits.leg_old = entries.leg_old + AND exits.movement_uid = entries.movement_uid + AND exits.leg_new = substr(exits.dir, 1, 1) --eg. E leg going East is an exit + WHERE entries.leg_new <> substr(entries.dir, 1, 1) --eg. E leg going West is an entry + ); + WITH inserted AS ( INSERT INTO gwolofs.miovision_15min_open_data ( intersection_uid, intersection_long_name, datetime_15min, classification_type, @@ -55,30 +73,21 @@ AS $BODY$ 'SingleUnitTruck', 'ArticulatedTruck', 'MotorizedVehicle', 'Bus' ) THEN 'Truck/Bus' ELSE cl.classification -- 'Bicycle', 'Pedestrian' - END AS classification_type, + END AS classification_type, v15.leg AS entry_leg, - entries.dir AS entry_dir, - mov.movement_name AS movement, + mm.entry_dir, + mm.movement, + mm.exit_leg, + mm.exit_dir, --assign exits for peds, bike entry only movements - COALESCE(exits.leg_new, v15.leg) AS exit_leg, - COALESCE(exits.dir, entries.dir) AS exit_dir, SUM(v15.volume) AS volume_15min --exclude notes (manual text field) --array_agg(ar.notes ORDER BY ar.range_start, ar.uid) FILTER (WHERE ar.uid IS NOT NULL) AS anomalous_range_caveats FROM miovision_api.volumes_15min_mvt AS v15 - JOIN miovision_api.intersections AS i USING (intersection_uid) JOIN miovision_api.classifications AS cl USING (classification_uid) - JOIN miovision_api.movements AS mov USING (movement_uid) - -- TMC to ATR crossover table for e - LEFT JOIN miovision_api.movement_map AS entries ON - entries.leg_old = v15.leg - AND entries.movement_uid = v15.movement_uid - AND entries.leg_new <> substr(entries.dir, 1, 1) --eg. E leg going West is an entry + JOIN miovision_api.intersections AS i USING (intersection_uid) -- TMC to ATR crossover table - LEFT JOIN miovision_api.movement_map AS exits ON - exits.leg_old = v15.leg - AND exits.movement_uid = v15.movement_uid - AND exits.leg_new = substr(exits.dir, 1, 1) --eg. E leg going East is an exit + JOIN miovision_movement_map_new AS mm USING (movement_uid, leg) --anti-join anomalous_ranges. See HAVING clause. LEFT JOIN miovision_api.anomalous_ranges AS ar ON ( @@ -93,6 +102,7 @@ AS $BODY$ v15.datetime_bin < ar.range_end OR ar.range_end IS NULL ) + AND ar.problem_level IN ('do-not-use'::text, 'questionable'::text) WHERE v15.datetime_bin >= _month AND v15.datetime_bin < _month + interval '1 month' @@ -102,11 +112,11 @@ AS $BODY$ i.api_name, v15.datetime_bin, classification_type, - movement, - entry_leg, - entry_dir, - exit_dir, - exit_leg + v15.leg, + mm.entry_dir, + mm.movement, + mm.exit_leg, + mm.exit_dir HAVING NOT array_agg(ar.problem_level) && ARRAY['do-not-use'::text, 'questionable'::text] AND SUM(v15.volume) > 0 --confirm @@ -115,7 +125,6 @@ AS $BODY$ classification_type, v15.datetime_bin, v15.leg - --fail on conflict RETURNING * ) @@ -145,6 +154,5 @@ minute open data volumes into gwolofs.miovision_15min_open_data. Contains an optional intersection parameter in case one just one intersection needs to be refreshed.'; ---testing, indexes work ---~50s for 1 day, ~40 minutes for 1 month (5M rows) +--testing, around 50 minutes for 1 month (5M rows) SELECT gwolofs.insert_miovision_15min_open_data('2024-02-01'::date); \ No newline at end of file From 5e578a421f1561e203cc8b69a7f15ae09a3d11ac Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Tue, 26 Mar 2024 17:54:20 +0000 Subject: [PATCH 09/13] #905 fluff --- ...ction-insert_miovision_open_data_15min.sql | 29 +-- ...rt_miovision_open_data_monthly_summary.sql | 25 +-- ...create-table-miovision_open_data_15min.sql | 2 +- ...le-miovision_open_data_monthly_summary.sql | 2 +- .../create-view-miovision_wide_tmc.sql | 179 +++++++++++------- 5 files changed, 142 insertions(+), 95 deletions(-) diff --git a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql index 541fbb769..57021e8f4 100644 --- a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql +++ b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_15min.sql @@ -4,18 +4,19 @@ --Include/Exclude buses/streetcars? --Decision to not include manual anomalous_range 'valid_caveat' notes: SELECT --Including entry/exit information to satisfy ATR related DRs. - --> providing exit leg and direction as extra columns rather - -- than extra rows to reduce potential for double counting. +-->> providing exit leg and direction as extra columns rather +-->> than extra rows to reduce potential for double counting. --DROP FUNCTION gwolofs.insert_miovision_15min_open_data; CREATE OR REPLACE FUNCTION gwolofs.insert_miovision_15min_open_data( - _date date, - intersections integer[] DEFAULT ARRAY[]::integer[]) - RETURNS void - LANGUAGE 'plpgsql' - COST 100 - VOLATILE PARALLEL UNSAFE + _date date, + integer [] DEFAULT ARRAY[]::integer [] +) +RETURNS void +LANGUAGE 'plpgsql' +COST 100 +VOLATILE PARALLEL UNSAFE AS $BODY$ DECLARE @@ -136,19 +137,19 @@ AS $BODY$ END; $BODY$; -ALTER FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +ALTER FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer []) OWNER TO gwolofs; -GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer []) TO miovision_admins; -GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer []) TO miovision_api_bot; -REVOKE ALL ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) -FROM PUBLIC; +REVOKE ALL ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer []) +FROM public; -COMMENT ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer[]) +COMMENT ON FUNCTION gwolofs.insert_miovision_15min_open_data(date, integer []) IS 'Function for first deleting then inserting monthly 15 minute open data volumes into gwolofs.miovision_15min_open_data. Contains an optional intersection parameter in case one just one diff --git a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql index c05a5f934..bf64131aa 100644 --- a/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql +++ b/volumes/miovision/sql/open_data/create-function-insert_miovision_open_data_monthly_summary.sql @@ -1,12 +1,13 @@ --DROP FUNCTION gwolofs.insert_miovision_open_data_monthly_summary; CREATE OR REPLACE FUNCTION gwolofs.insert_miovision_open_data_monthly_summary( - _date date, - intersections integer[] DEFAULT ARRAY[]::integer[]) - RETURNS void - LANGUAGE 'plpgsql' - COST 100 - VOLATILE PARALLEL UNSAFE + _date date, + intersections integer [] DEFAULT ARRAY[]::integer [] +) +RETURNS void +LANGUAGE 'plpgsql' +COST 100 +VOLATILE PARALLEL UNSAFE AS $BODY$ DECLARE @@ -180,19 +181,19 @@ AS $BODY$ END; $BODY$; -ALTER FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +ALTER FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer []) OWNER TO gwolofs; -GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer []) TO miovision_admins; -GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +GRANT EXECUTE ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer []) TO miovision_api_bot; -REVOKE ALL ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) -FROM PUBLIC; +REVOKE ALL ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer []) +FROM public; -COMMENT ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer[]) +COMMENT ON FUNCTION gwolofs.insert_miovision_open_data_monthly_summary(date, integer []) IS 'Function for first deleting then inserting monthly summary miovision open data into gwolofs.miovision_open_data_monthly_summary. Contains an optional intersection parameter in case one just one diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql index 404887c1c..aeca73db1 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_15min.sql @@ -22,7 +22,7 @@ TABLESPACE pg_default; CREATE INDEX miovision_15min_od_dt_idx ON gwolofs.miovision_15min_open_data USING brin (datetime_15min); -ALTER TABLE IF EXISTS gwolofs.miovision_15min_open_data +ALTER TABLE IF EXISTS gwolofs.miovision_15min_open_data OWNER TO gwolofs; REVOKE ALL ON TABLE gwolofs.miovision_15min_open_data FROM bdit_humans; diff --git a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql index 31e9a3d28..331d1dc44 100644 --- a/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql +++ b/volumes/miovision/sql/open_data/create-table-miovision_open_data_monthly_summary.sql @@ -26,7 +26,7 @@ TABLESPACE pg_default; CREATE INDEX miovision_monthly_od_dt_idx ON gwolofs.miovision_open_data_monthly_summary USING brin (mnth); -ALTER TABLE IF EXISTS gwolofs.miovision_open_data_monthly_summary +ALTER TABLE IF EXISTS gwolofs.miovision_open_data_monthly_summary OWNER TO gwolofs; REVOKE ALL ON TABLE gwolofs.miovision_open_data_monthly_summary FROM bdit_humans; diff --git a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql index 40de5b28e..e17a62680 100644 --- a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql +++ b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql @@ -1,4 +1,5 @@ ---Would prefer to omit this, unless we *really* want it for comparison with existing short term TMC open data. +--Would prefer to omit this, unless we *really* want it for +--comparison with existing short term TMC open data. --include u-turns? --bikes @@ -6,67 +7,111 @@ CREATE OR REPLACE VIEW gwolofs.miovision_open_data_wide_15min AS ( -SELECT - v.intersection_uid, - v.datetime_bin, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'S'), 0) AS sb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'N'), 0) AS nb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'W'), 0) AS wb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[1]::int []) AND leg = 'E'), 0) AS eb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'S'), 0) AS sb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'N'), 0) AS nb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'W'), 0) AS wb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[4,5,9]::int []) AND leg = 'E'), 0) AS eb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'S'), 0) AS sb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'N'), 0) AS nb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'W'), 0) AS wb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 3 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 1 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = 2 AND classification_uid = ANY (ARRAY[3]::int []) AND leg = 'E'), 0) AS eb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'N'), 0) AS nx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'S'), 0) AS sx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'E'), 0) AS ex_peds, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 6 AND leg = 'W'), 0) AS wx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'N'), 0) AS nx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'S'), 0) AS sx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'E'), 0) AS ex_bike, - COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = 2 AND leg = 'W'), 0) AS wx_bike -FROM miovision_api.volumes_15min_mvt AS v -JOIN miovision_api.classifications AS c USING (classification_uid) -JOIN miovision_api.movements AS m USING (movement_uid) -WHERE - datetime_bin >= '2024-02-01'::date - AND datetime_bin < '2024-03-01'::date - --AND intersection_uid = 1 - --AND classification_uid NOT IN (2,10) --exclude bikes due to reliability -GROUP BY - v.intersection_uid, - v.datetime_bin -ORDER BY - v.intersection_uid, - v.datetime_bin + SELECT + v.intersection_uid, + v.datetime_bin, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 + AND v.leg = 'N'), 0) AS nx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 + AND v.leg = 'S'), 0) AS sx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 + AND v.leg = 'E'), 0) AS ex_peds, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 + AND v.leg = 'W'), 0) AS wx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 + AND v.leg = 'N'), 0) AS nx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 + AND v.leg = 'S'), 0) AS sx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 + AND v.leg = 'E'), 0) AS ex_bike, + COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 + AND v.leg = 'W'), 0) AS wx_bike + FROM miovision_api.volumes_15min_mvt AS v + JOIN miovision_api.classifications AS c USING (classification_uid) + JOIN miovision_api.movements AS m USING (movement_uid) + WHERE + datetime_bin >= '2024-02-01'::date + AND datetime_bin < '2024-03-01'::date + --AND intersection_uid = 1 + --AND v.classification_uid NOT IN (2,10) --exclude bikes due to reliability + GROUP BY + v.intersection_uid, + v.datetime_bin + ORDER BY + v.intersection_uid, + v.datetime_bin ); SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; @@ -75,9 +120,9 @@ SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE movement_uid = ' || movement_uid::text || - ' AND classification_uid = ANY (ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || - ' AND leg = ''' || leg || '''), 0) AS ' || + 'COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = ' || movement_uid::text || + ' AND v.classification_uid = ANY(ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || + ' AND v.leg = ''' || leg || '''), 0) AS ' || dir || '_' || CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' WHEN 'MotorizedVehicle' THEN 'truck' END || '_' || CASE movement_name WHEN 'left' THEN 'l' WHEN 'thru' THEN 't' WHEN 'right' THEN 'r' END || ',' AS col_name @@ -107,8 +152,8 @@ UNION ALL SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE classification_uid = ' || classification_uid::text || - ' AND leg = ''' || leg || '''), 0) AS ' || + 'COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = ' || classification_uid::text || + ' AND v.leg = ''' || leg || '''), 0) AS ' || dir || '_' || CASE classification WHEN 'Bicycle' THEN 'bike' WHEN 'Pedestrian' THEN 'peds' END || ',' AS col_name FROM miovision_api.classifications From 0c8a8b4ce49faa8df70b1076ffbb1c8a946e1d9a Mon Sep 17 00:00:00 2001 From: Gabe Wolofsky <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 10 Jul 2024 09:51:16 -0400 Subject: [PATCH 10/13] #905 sqlfluff --- .../create-view-miovision_wide_tmc.sql | 281 +++++++++++------- 1 file changed, 173 insertions(+), 108 deletions(-) diff --git a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql index e17a62680..f507cbc5e 100644 --- a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql +++ b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql @@ -10,122 +10,180 @@ CREATE OR REPLACE VIEW gwolofs.miovision_open_data_wide_15min AS ( SELECT v.intersection_uid, v.datetime_bin, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S'), 0) AS sb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N'), 0) AS nb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W'), 0) AS wb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E'), 0) AS eb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'S'), 0) AS sb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'N'), 0) AS nb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'W'), 0) AS wb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[4,5,9]::int []) AND v.leg = 'E'), 0) AS eb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S'), 0) AS sb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N'), 0) AS nb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W'), 0) AS wb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 3 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 1 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = 2 - AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E'), 0) AS eb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 - AND v.leg = 'N'), 0) AS nx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 - AND v.leg = 'S'), 0) AS sx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 - AND v.leg = 'E'), 0) AS ex_peds, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 6 - AND v.leg = 'W'), 0) AS wx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 - AND v.leg = 'N'), 0) AS nx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 - AND v.leg = 'S'), 0) AS sx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 - AND v.leg = 'E'), 0) AS ex_bike, - COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = 2 - AND v.leg = 'W'), 0) AS wx_bike + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + ), 0) AS sb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + ), 0) AS sb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + ), 0) AS sb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + ), 0) AS nb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + ), 0) AS nb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + ), 0) AS nb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + ), 0) AS wb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + ), 0) AS wb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + ), 0) AS wb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + ), 0) AS eb_car_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + ), 0) AS eb_car_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + ), 0) AS eb_car_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + ), 0) AS sb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + ), 0) AS sb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + ), 0) AS sb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + ), 0) AS nb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + ), 0) AS nb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + ), 0) AS nb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + ), 0) AS wb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + ), 0) AS wb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + ), 0) AS wb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + ), 0) AS eb_truck_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + ), 0) AS eb_truck_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + ), 0) AS eb_truck_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + ), 0) AS sb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + ), 0) AS sb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + ), 0) AS sb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + ), 0) AS nb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + ), 0) AS nb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + ), 0) AS nb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + ), 0) AS wb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + ), 0) AS wb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + ), 0) AS wb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + ), 0) AS eb_bus_r, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + ), 0) AS eb_bus_t, + COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + ), 0) AS eb_bus_l, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 6 + AND v.leg = 'N' + ), 0) AS nx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 6 + AND v.leg = 'S' + ), 0) AS sx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 6 + AND v.leg = 'E' + ), 0) AS ex_peds, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 6 + AND v.leg = 'W' + ), 0) AS wx_peds, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 2 + AND v.leg = 'N' + ), 0) AS nx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 2 + AND v.leg = 'S' + ), 0) AS sx_bike, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 2 + AND v.leg = 'E' + ), 0) AS ex_bike, + COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = 2 + AND v.leg = 'W' + ), 0) AS wx_bike FROM miovision_api.volumes_15min_mvt AS v - JOIN miovision_api.classifications AS c USING (classification_uid) - JOIN miovision_api.movements AS m USING (movement_uid) + --JOIN miovision_api.classifications AS c USING (classification_uid) + --JOIN miovision_api.movements AS m USING (movement_uid) WHERE - datetime_bin >= '2024-02-01'::date - AND datetime_bin < '2024-03-01'::date - --AND intersection_uid = 1 - --AND v.classification_uid NOT IN (2,10) --exclude bikes due to reliability + v.datetime_bin >= '2024-02-01'::date + AND v.datetime_bin < '2024-03-01'::date + --AND intersection_uid = 1 + --AND v.classification_uid NOT IN (2,10) --exclude bikes due to reliability GROUP BY v.intersection_uid, v.datetime_bin ORDER BY v.intersection_uid, v.datetime_bin -); +); -SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; +SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; --noqa: L044 /* query used for query development! SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE v.movement_uid = ' || movement_uid::text || - ' AND v.classification_uid = ANY(ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || - ' AND v.leg = ''' || leg || '''), 0) AS ' || + 'COALESCE(SUM(v.volume) FILTER (WHERE + v.movement_uid = ' || movement_uid::text || + ' AND v.classification_uid = ANY( + ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || + ' AND v.leg = ''' || leg || ''' +), 0) AS ' || dir || '_' || - CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' WHEN 'MotorizedVehicle' THEN 'truck' END || '_' || - CASE movement_name WHEN 'left' THEN 'l' WHEN 'thru' THEN 't' WHEN 'right' THEN 'r' END || ',' AS col_name + CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' + WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' + WHEN 'MotorizedVehicle' THEN 'truck' END || '_' || + CASE movement_name WHEN 'left' THEN 'l' + WHEN 'thru' THEN 't' WHEN 'right' THEN 'r' END || ',' AS col_name FROM miovision_api.movements CROSS JOIN miovision_api.classifications CROSS JOIN (VALUES @@ -136,14 +194,18 @@ WHERE --AND movement_uid NOT IN (7,8) --entrances, exits AND movement_uid IN (1,2,3) GROUP BY - CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, - CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' WHEN 'MotorizedVehicle' THEN 'truck' END, + CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 + WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, + CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' + WHEN 'SingleUnitTruck' THEN 'truck' WHEN 'ArticulatedTruck' THEN 'truck' + WHEN 'MotorizedVehicle' THEN 'truck' END, dir_order, dir, leg, movement_uid ORDER BY - CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, + CASE classification WHEN 'Light' THEN 1 WHEN 'Bus' THEN 3 WHEN 'SingleUnitTruck' THEN 2 + WHEN 'ArticulatedTruck' THEN 2 WHEN 'MotorizedVehicle' THEN 2 END, dir_order, CASE movement_name WHEN 'left' THEN 3 WHEN 'thru' THEN 2 WHEN 'right' THEN 1 END ) AS vehs @@ -152,12 +214,15 @@ UNION ALL SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE v.classification_uid = ' || classification_uid::text || - ' AND v.leg = ''' || leg || '''), 0) AS ' || + 'COALESCE(SUM(v.volume) FILTER (WHERE + v.classification_uid = ' || classification_uid::text || + ' AND v.leg = ''' || leg || ''' + ), 0) AS ' || dir || '_' || - CASE classification WHEN 'Bicycle' THEN 'bike' WHEN 'Pedestrian' THEN 'peds' END || ',' AS col_name + CASE classification WHEN 'Bicycle' THEN 'bike' + WHEN 'Pedestrian' THEN 'peds' END || ',' AS col_name FROM miovision_api.classifications - CROSS JOIN (VALUES + CROSS JOIN (VALUES ('sx', 'S', 2), ('nx', 'N', 1), ('wx', 'W', 4), ('ex', 'E', 3) ) AS directions(dir, leg, dir_order) WHERE From 053f9608e23c22cc02973335bfefd0fa950e07d6 Mon Sep 17 00:00:00 2001 From: Gabe Wolofsky <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 10 Jul 2024 11:49:51 -0400 Subject: [PATCH 11/13] #905 sqlfluff --- .../create-view-miovision_wide_tmc.sql | 326 ++++++++++++------ 1 file changed, 224 insertions(+), 102 deletions(-) diff --git a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql index f507cbc5e..0886322f4 100644 --- a/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql +++ b/volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql @@ -10,145 +10,261 @@ CREATE OR REPLACE VIEW gwolofs.miovision_open_data_wide_15min AS ( SELECT v.intersection_uid, v.datetime_bin, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'S' ), 0) AS sb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'S' ), 0) AS sb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'S' ), 0) AS sb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'N' ), 0) AS nb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'N' ), 0) AS nb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'N' ), 0) AS nb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'W' ), 0) AS wb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'W' ), 0) AS wb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'W' ), 0) AS wb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'E' ), 0) AS eb_car_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'E' ), 0) AS eb_car_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[1]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[1]::int []) + AND v.leg = 'E' ), 0) AS eb_car_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'S' ), 0) AS sb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'S' ), 0) AS sb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'S' ), 0) AS sb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'N' ), 0) AS nb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'N' ), 0) AS nb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'N' ), 0) AS nb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'W' ), 0) AS wb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'W' ), 0) AS wb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'W' ), 0) AS wb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'E' ), 0) AS eb_truck_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'E' ), 0) AS eb_truck_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[4, 5, 9]::int []) + AND v.leg = 'E' ), 0) AS eb_truck_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'S' ), 0) AS sb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'S' ), 0) AS sb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'S' ), 0) AS sb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'N' ), 0) AS nb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'N' ), 0) AS nb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'N' ), 0) AS nb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'W' ), 0) AS wb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'W' ), 0) AS wb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'W' ), 0) AS wb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 3 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 3 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'E' ), 0) AS eb_bus_r, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 1 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 1 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'E' ), 0) AS eb_bus_t, - COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = 2 AND v.classification_uid = ANY(ARRAY[3]::int []) AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = 2 + AND v.classification_uid = ANY(ARRAY[3]::int []) + AND v.leg = 'E' ), 0) AS eb_bus_l, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 6 - AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 6 + AND v.leg = 'N' ), 0) AS nx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 6 - AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 6 + AND v.leg = 'S' ), 0) AS sx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 6 - AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 6 + AND v.leg = 'E' ), 0) AS ex_peds, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 6 - AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 6 + AND v.leg = 'W' ), 0) AS wx_peds, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 2 - AND v.leg = 'N' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 2 + AND v.leg = 'N' ), 0) AS nx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 2 - AND v.leg = 'S' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 2 + AND v.leg = 'S' ), 0) AS sx_bike, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 2 - AND v.leg = 'E' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 2 + AND v.leg = 'E' ), 0) AS ex_bike, - COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = 2 - AND v.leg = 'W' + COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = 2 + AND v.leg = 'W' ), 0) AS wx_bike FROM miovision_api.volumes_15min_mvt AS v --JOIN miovision_api.classifications AS c USING (classification_uid) @@ -172,11 +288,14 @@ SELECT * FROM gwolofs.miovision_open_data_wide_15min LIMIT 10000; --noqa: L044 SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE - v.movement_uid = ' || movement_uid::text || + 'COALESCE(SUM(v.volume) FILTER ( + WHERE + v.movement_uid = ' + || movement_uid::text || ' AND v.classification_uid = ANY( ARRAY[' || string_agg(classification_uid::text, ',') || ']::int [])' || - ' AND v.leg = ''' || leg || ''' + ' + AND v.leg = ''' || leg || ''' ), 0) AS ' || dir || '_' || CASE classification WHEN 'Light' THEN 'car' WHEN 'Bus' THEN 'bus' @@ -214,9 +333,12 @@ UNION ALL SELECT col_name FROM ( SELECT - 'COALESCE(SUM(v.volume) FILTER (WHERE - v.classification_uid = ' || classification_uid::text || - ' AND v.leg = ''' || leg || ''' + 'COALESCE(SUM(v.volume) FILTER ( + WHERE + v.classification_uid = ' + || classification_uid::text || + ' + AND v.leg = ''' || leg || ''' ), 0) AS ' || dir || '_' || CASE classification WHEN 'Bicycle' THEN 'bike' From c1d5def3996c266483e4b9bb1af2c07f3cd3fce5 Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 4 Sep 2024 12:28:56 -0400 Subject: [PATCH 12/13] #905 update schedule to avoid afternoon update window --- dags/miovision_open_data.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/dags/miovision_open_data.py b/dags/miovision_open_data.py index b5aff87f3..e6c642490 100644 --- a/dags/miovision_open_data.py +++ b/dags/miovision_open_data.py @@ -42,7 +42,7 @@ @dag( dag_id=DAG_NAME, default_args=default_args, - schedule='0 14 3 * *', # 2pm, 3rd day of each month + schedule='0 10 3 * *', # 10am, 3rd day of each month catchup=True, max_active_runs=1, tags=["miovision", "open_data"], From f699ea67063f3dcdc76658f6d2e53ba991007188 Mon Sep 17 00:00:00 2001 From: gabrielwol <80077912+gabrielwol@users.noreply.github.com> Date: Fri, 4 Oct 2024 10:06:58 -0400 Subject: [PATCH 13/13] #905 all_done -> all_success trigger rule --- dags/miovision_open_data.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/dags/miovision_open_data.py b/dags/miovision_open_data.py index e6c642490..cac8d2c12 100644 --- a/dags/miovision_open_data.py +++ b/dags/miovision_open_data.py @@ -88,7 +88,7 @@ def miovision_open_data_dag(): @task( retries=0, - trigger_rule='all_done', + trigger_rule='all_success', doc_md="""A status message to report DAG success.""" ) def status_message(ds = None, **context):