Skip to content

Commit

Permalink
#905 sql dump
Browse files Browse the repository at this point in the history
  • Loading branch information
gabrielwol committed Mar 20, 2024
1 parent 406db7c commit a839c4c
Show file tree
Hide file tree
Showing 3 changed files with 345 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
124 changes: 124 additions & 0 deletions volumes/miovision/sql/open_data/create-view-miovision_wide_tmc.sql
Original file line number Diff line number Diff line change
@@ -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
*/

0 comments on commit a839c4c

Please sign in to comment.