From 7484744f12b530c5dd463464b209104c65e13c0b Mon Sep 17 00:00:00 2001 From: Gabe Wolofsky <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 7 Feb 2024 22:43:01 +0000 Subject: [PATCH 1/3] #862 much faster version of aggregate_15_min_mvt --- .../function-aggregate-volumes_15min_mvt.sql | 107 +++++++++++------- 1 file changed, 65 insertions(+), 42 deletions(-) diff --git a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql index bbfdf7347..ca32f1987 100644 --- a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql +++ b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql @@ -15,70 +15,93 @@ DECLARE BEGIN -WITH aggregate_insert AS ( - INSERT INTO miovision_api.volumes_15min_mvt( - intersection_uid, datetime_bin, classification_uid, leg, movement_uid, volume - ) +WITH temp AS ( + -- Cross product of dates, intersections, legal movement for cars, bikes, and peds to aggregate SELECT im.intersection_uid, dt.datetime_bin, im.classification_uid, im.leg, im.movement_uid, - CASE - --set unacceptable gaps as nulls - WHEN un.datetime_bin IS NOT NULL THEN NULL - --gap fill with zeros (restricted to certain modes in having clause) - ELSE (COALESCE(SUM(v.volume), 0)) - END AS volume - -- Cross product of dates, intersections, legal movement for cars, bikes, and peds to aggregate + 0 AS volume FROM miovision_api.intersection_movements AS im CROSS JOIN generate_series( start_date, end_date - interval '15 minutes', interval '15 minutes' ) AS dt(datetime_bin) - JOIN miovision_api.intersections AS mai USING (intersection_uid) - --To avoid aggregating unacceptable gaps - LEFT JOIN miovision_api.unacceptable_gaps AS un ON - un.intersection_uid = im.intersection_uid - --remove the 15 minute bin containing any unacceptable gaps - AND dt.datetime_bin = un.datetime_bin + WHERE + --0 padding for certain modes (padding) + im.classification_uid IN (1,2,6,10) + AND im.intersection_uid = ANY(target_intersections) + + UNION ALL + + --real volumes + SELECT + v.intersection_uid, + datetime_bin_15(v.datetime_bin) AS datetime_bin, + v.classification_uid, + v.leg, + v.movement_uid, + SUM(volume) --To get 1min bins - LEFT JOIN miovision_api.volumes AS v ON - --help query choose correct partition + FROM miovision_api.volumes AS v + --only common movements + JOIN miovision_api.intersection_movements USING (intersection_uid, classification_uid, leg, movement_uid) + WHERE v.datetime_bin >= start_date AND v.datetime_bin < end_date - AND v.datetime_bin >= dt.datetime_bin - AND v.datetime_bin < dt.datetime_bin + interval '15 minutes' - AND v.intersection_uid = im.intersection_uid - AND v.classification_uid = im.classification_uid - AND v.leg = im.leg - AND v.movement_uid = im.movement_uid + --exclude movements already aggregated + AND v.volume_15min_mvt_uid IS NULL + AND v.intersection_uid = ANY(target_intersections) + GROUP BY + v.intersection_uid, + datetime_bin_15(v.datetime_bin), + v.classification_uid, + v.leg, + v.movement_uid +), + +aggregate_insert AS ( + INSERT INTO miovision_api.volumes_15min_mvt( + intersection_uid, datetime_bin, classification_uid, leg, movement_uid, volume + ) + SELECT DISTINCT ON (v.intersection_uid, v.datetime_bin, v.classification_uid, v.leg, v.movement_uid) + v.intersection_uid, + v.datetime_bin, + v.classification_uid, + v.leg, + v.movement_uid, + CASE + --set unacceptable gaps as nulls + WHEN un.datetime_bin IS NOT NULL THEN NULL + --gap fill with zeros (restricted to certain modes in temp CTE) + ELSE v.volume + END AS volume + FROM temp AS v + JOIN miovision_api.intersections AS i USING (intersection_uid) + --set unacceptable gaps as null + LEFT JOIN miovision_api.unacceptable_gaps AS un USING (intersection_uid, datetime_bin) WHERE -- Only include dates during which intersection is active -- (excludes entire day it was added/removed) - dt.datetime_bin > mai.date_installed + interval '1 day' + v.datetime_bin > i.date_installed + interval '1 day' AND ( - mai.date_decommissioned IS NULL - OR (dt.datetime_bin < mai.date_decommissioned - interval '1 day') + i.date_decommissioned IS NULL + OR (v.datetime_bin < i.date_decommissioned - interval '1 day') ) - --exclude movements already aggregated - AND v.volume_15min_mvt_uid IS NULL - AND im.intersection_uid = ANY(target_intersections) - GROUP BY - im.intersection_uid, - dt.datetime_bin, - im.classification_uid, - im.leg, - im.movement_uid, - un.datetime_bin - HAVING - --retain 0s for certain modes (padding) - im.classification_uid IN (1,2,6,10) - OR SUM(v.volume) > 0 + ORDER BY + v.intersection_uid, + v.datetime_bin, + v.classification_uid, + v.leg, + v.movement_uid, + --select real value instead of padding value if available + v.volume DESC RETURNING intersection_uid, volume_15min_mvt_uid, datetime_bin, classification_uid, leg, movement_uid, volume ) + --To update foreign key for 1min bin table UPDATE miovision_api.volumes AS v SET volume_15min_mvt_uid = a_i.volume_15min_mvt_uid From ea0d5197b636a01ab092640d81665c34325c78af Mon Sep 17 00:00:00 2001 From: Gabe Wolofsky <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 7 Feb 2024 23:04:59 +0000 Subject: [PATCH 2/3] #862 fix small gt to gte bug --- .../sql/function/function-aggregate-volumes_15min_mvt.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql index ca32f1987..e954c3d1a 100644 --- a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql +++ b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql @@ -86,7 +86,7 @@ aggregate_insert AS ( WHERE -- Only include dates during which intersection is active -- (excludes entire day it was added/removed) - v.datetime_bin > i.date_installed + interval '1 day' + v.datetime_bin >= i.date_installed + interval '1 day' AND ( i.date_decommissioned IS NULL OR (v.datetime_bin < i.date_decommissioned - interval '1 day') @@ -130,4 +130,4 @@ GRANT EXECUTE ON FUNCTION miovision_api.aggregate_15_min_mvt(date, date, integer TO miovision_api_bot; GRANT EXECUTE ON FUNCTION miovision_api.aggregate_15_min_mvt(date, date, integer []) -TO miovision_admins; +TO miovision_admins; \ No newline at end of file From 80892307ca63909bf10badb4e301eacde33e68aa Mon Sep 17 00:00:00 2001 From: Gabe Wolofsky <80077912+gabrielwol@users.noreply.github.com> Date: Wed, 7 Feb 2024 23:10:56 +0000 Subject: [PATCH 3/3] #862 remove already aggregated filter - we use clear function instead now --- .../function-aggregate-volumes_15min_mvt.sql | 41 ++++++++++--------- 1 file changed, 22 insertions(+), 19 deletions(-) diff --git a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql index e954c3d1a..3337618f6 100644 --- a/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql +++ b/volumes/miovision/sql/function/function-aggregate-volumes_15min_mvt.sql @@ -44,16 +44,15 @@ WITH temp AS ( v.classification_uid, v.leg, v.movement_uid, - SUM(volume) - --To get 1min bins + SUM(volume) FROM miovision_api.volumes AS v - --only common movements - JOIN miovision_api.intersection_movements USING (intersection_uid, classification_uid, leg, movement_uid) + --only aggregate common movements + JOIN miovision_api.intersection_movements USING ( + intersection_uid, classification_uid, leg, movement_uid + ) WHERE v.datetime_bin >= start_date AND v.datetime_bin < end_date - --exclude movements already aggregated - AND v.volume_15min_mvt_uid IS NULL AND v.intersection_uid = ANY(target_intersections) GROUP BY v.intersection_uid, @@ -67,22 +66,26 @@ aggregate_insert AS ( INSERT INTO miovision_api.volumes_15min_mvt( intersection_uid, datetime_bin, classification_uid, leg, movement_uid, volume ) - SELECT DISTINCT ON (v.intersection_uid, v.datetime_bin, v.classification_uid, v.leg, v.movement_uid) - v.intersection_uid, - v.datetime_bin, - v.classification_uid, - v.leg, - v.movement_uid, - CASE - --set unacceptable gaps as nulls - WHEN un.datetime_bin IS NOT NULL THEN NULL - --gap fill with zeros (restricted to certain modes in temp CTE) - ELSE v.volume - END AS volume + SELECT DISTINCT ON ( + v.intersection_uid, v.datetime_bin, v.classification_uid, v.leg, v.movement_uid + ) + v.intersection_uid, + v.datetime_bin, + v.classification_uid, + v.leg, + v.movement_uid, + CASE + --set unacceptable gaps as nulls + WHEN un.datetime_bin IS NOT NULL THEN NULL + --gap fill with zeros (restricted to certain modes in temp CTE) + ELSE v.volume + END AS volume FROM temp AS v JOIN miovision_api.intersections AS i USING (intersection_uid) --set unacceptable gaps as null - LEFT JOIN miovision_api.unacceptable_gaps AS un USING (intersection_uid, datetime_bin) + LEFT JOIN miovision_api.unacceptable_gaps AS un USING ( + intersection_uid, datetime_bin + ) WHERE -- Only include dates during which intersection is active -- (excludes entire day it was added/removed)