Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

951 identify high miovision volumes #958

Draft
wants to merge 3 commits into
base: master
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
90 changes: 90 additions & 0 deletions volumes/miovision/sql/function/function-miovision_doubling.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,90 @@
CREATE OR REPLACE FUNCTION gwolofs.miovision_doubling_summary(end_date date)
RETURNS TABLE (
_check boolean,
summ text,
summary text []
) AS
$$

WITH doublings AS (
SELECT
dt,
intersection_uid,
classification_uid,
this_week_volume,
previous_week_volume,
CASE WHEN dt = 1 + lag(dt, 1) OVER (
PARTITION BY intersection_uid, classification_uid ORDER BY dt
) THEN 0 ELSE 1 END AS run_bool
FROM gwolofs.miovision_doublings
),

runs AS (
SELECT
intersection_uid,
classification_uid,
dt,
this_week_volume,
previous_week_volume,
SUM(run_bool) OVER (
PARTITION BY intersection_uid, classification_uid ORDER BY dt
) AS run_id
FROM doublings
ORDER BY intersection_uid, classification_uid, dt
),

runs_ranked AS (
SELECT
intersection_uid,
classification_uid,
dt,
this_week_volume,
previous_week_volume,
rank() OVER (
PARTITION BY intersection_uid, classification_uid, run_id ORDER BY dt
) AS run_rank
FROM runs
),

warnings AS (
SELECT
i.intersection_name || ' (' || rr.intersection_uid || ')' AS intersection,
CASE
WHEN rr.classification_uid = 2 THEN 'Bicycle TMC'
WHEN rr.classification_uid = 10 THEN 'Bicycle Approach'
ELSE c.classification
END AS classification,
dt,
this_week_volume,
previous_week_volume
FROM runs_ranked AS rr
JOIN miovision_api.intersections AS i USING (intersection_uid)
JOIN miovision_api.classifications AS c USING (classification_uid)
WHERE
--notify on every 7th day
mod(run_rank-1, 7) = 0
--alerts in last 7 days
AND dt >= end_date - interval '7 days'

)

SELECT
NOT(COUNT(*) > 0) AS _check,
'Volumes have doubled week over week in the following ' || COUNT(*)
|| CASE WHEN COUNT(*) = 1 THEN ' cases:' ELSE ' case:' END AS summ,
array_agg(
'`' || intersection || '`, `'
|| classification
|| '`, volume: `' || to_char(this_week_volume, 'FM9,999,999')
|| ' (last week: ' || to_char(previous_week_volume, 'FM9,999,999') || ')`'
) AS summary
FROM warnings;

$$
LANGUAGE SQL;

Check failure on line 84 in volumes/miovision/sql/function/function-miovision_doubling.sql

View workflow job for this annotation

GitHub Actions / SQLFluff Lint

SQLFluff

CP02: Unquoted identifiers must be consistently lower case.

ALTER FUNCTION gwolofs.miovision_doubling_summary(date) OWNER TO miovision_admins;
GRANT EXECUTE ON FUNCTION gwolofs.miovision_doubling_summary(date) TO miovision_api_bot;

COMMENT ON FUNCTION gwolofs.miovision_doubling_summary(date)
IS '(in development) Function to identify when Miovision volumes have doubled week over week.';
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
CREATE OR REPLACE FUNCTION gwolofs.miovision_doubling_insert(end_date date)
RETURNS VOID

Check failure on line 2 in volumes/miovision/sql/function/function-miovision_doubling_insert.sql

View workflow job for this annotation

GitHub Actions / SQLFluff Lint

SQLFluff

CP05: Datatypes must be lower case.
AS $$

INSERT INTO gwolofs.miovision_doublings (
intersection_uid, classification_uid, dt, this_week_volume,
previous_week_volume, this_week_days, previous_week_days
)
SELECT
vd.intersection_uid,
vd.classification_uid,
end_date AS dt,
SUM(vd.daily_volume) FILTER (WHERE w.this_week) AS this_week_volume,
SUM(vd.daily_volume) FILTER (WHERE NOT w.this_week) AS previous_week_volume,
COUNT(DISTINCT vd.dt::date) FILTER (WHERE w.this_week) AS this_week_days,
COUNT(DISTINCT vd.dt::date) FILTER (WHERE NOT w.this_week) AS previous_week_days
FROM miovision_api.volumes_daily_unfiltered AS vd,
LATERAL(
SELECT dt >= end_date + interval '1 day' - interval '7 days' AS this_week
) AS w
WHERE
vd.classification_uid IN (1,2,6,10)
AND vd.dt >= end_date + interval '1 day' - interval '14 days'
AND vd.dt < end_date + interval '1 day'
GROUP BY
vd.intersection_uid,
vd.classification_uid
HAVING
--doubling of volume week over week
SUM(vd.daily_volume) FILTER (WHERE w.this_week)
>= 2 * SUM(vd.daily_volume) FILTER (WHERE NOT w.this_week)
--last week (denominator) has all 7 days of data
--this week having less than 7 days is OK (=worse)
AND COUNT(DISTINCT vd.dt::date) FILTER (WHERE NOT w.this_week) = 7
--last week volume greater than 1000
AND SUM(vd.daily_volume) FILTER (WHERE NOT w.this_week) > 1000
ON CONFLICT (intersection_uid, classification_uid, dt)
DO UPDATE SET
this_week_volume = EXCLUDED.this_week_volume,
previous_week_volume = EXCLUDED.previous_week_volume,
this_week_days = EXCLUDED.this_week_days,
previous_week_days = EXCLUDED.previous_week_days;

$$
LANGUAGE SQL;

ALTER FUNCTION gwolofs.miovision_doubling_insert(date) OWNER TO miovision_admins;
GRANT EXECUTE ON FUNCTION gwolofs.miovision_doubling_insert(date) TO miovision_api_bot;

Check failure on line 48 in volumes/miovision/sql/function/function-miovision_doubling_insert.sql

View workflow job for this annotation

GitHub Actions / SQLFluff Lint

SQLFluff

CP02: Unquoted identifiers must be consistently upper case.

COMMENT ON FUNCTION gwolofs.miovision_doubling_insert(date)
IS '(in development) Function to identify when Miovision volumes have doubled week over week.'
14 changes: 14 additions & 0 deletions volumes/miovision/sql/table/create-table-miovision_doublings.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
CREATE TABLE gwolofs.miovision_doublings (
intersection_uid integer,
classification_uid integer,
dt date,
this_week_volume integer,
previous_week_volume integer,
this_week_days smallint,
previous_week_days smallint,
CONSTRAINT mio_doubling_pkey PRIMARY KEY (intersection_uid, classification_uid, dt)
)

ALTER TABLE gwolofs.miovision_doublings OWNER TO gwolofs;

GRANT SELECT ON gwolofs.miovision_doublings TO miovision_admins, miovision_api_bot;
Loading