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

1053 transform miovision open issues to table #1075

Merged
merged 15 commits into from
Nov 28, 2024
Merged
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
2 changes: 2 additions & 0 deletions volumes/miovision/api/intersection_tmc.py
Original file line number Diff line number Diff line change
Expand Up @@ -455,6 +455,8 @@ def agg_zero_volume_anomalous_ranges(conn, time_period, intersections = None):
cur.execute(anomalous_range_sql, query_params)
logger.info('Aggregation of zero volume periods into anomalous_ranges table complete for intersections %s',
[x.uid for x in intersections])
#update the table used for manual QC
cur.execute("SELECT miovision_api.update_open_issues();")
except psycopg2.Error as exc:
logger.exception(exc)
sys.exit(1)
Expand Down
2 changes: 1 addition & 1 deletion volumes/miovision/api/readme.md
Original file line number Diff line number Diff line change
Expand Up @@ -277,7 +277,7 @@ This task group completes various Miovision aggregations.
- `find_gaps_task` clears and then populates `miovision_api.unacceptable_gaps` using `intersection_tmc.find_gaps` function.
- `aggregate_15_min_mvt_task` clears and then populates `miovision_api.volumes_15min_mvt` using `intersection_tmc.aggregate_15_min_mvt` function.
- `aggregate_15_min_task` clears and then populates `miovision_api.volumes_15min` using `intersection_tmc.aggregate_15_min` function.
- `zero_volume_anomalous_ranges_task` identifies intersection / classification combos with zero volumes and adds/updates `miovision_api.anomalous_ranges` accordingly.
- `zero_volume_anomalous_ranges_task` identifies intersection / classification combos with zero volumes and adds/updates `miovision_api.anomalous_ranges` accordingly. Also refreshes `miovision_api.open_issues` table used for manual QC.
- `aggregate_volumes_daily_task` clears and then populates `miovision_api.volumes_daily` using `intersection_tmc.aggregate_volumes_daily` function.
- `get_report_dates_task` clears and then populates `miovision_api.report_dates` using `intersection_tmc.get_report_dates` function.

Expand Down
Original file line number Diff line number Diff line change
@@ -1,25 +1,29 @@
WITH ongoing_outages AS (
WITH all_outages AS (
SELECT COUNT(*) AS cnt
FROM miovision_api.open_issues
WHERE COALESCE(classification_uid, 0) != 2
),

total_outages AS (
SELECT
i.intersection_name || ' (id: `' || i.id || '`) - data last received: `'
|| MAX(v.dt::date) || '` (' || '{{ macros.ds_add(ds, 6) }}'::date --noqa: TMP, LT05
- MAX(v.dt::date) || ' days)' AS descrip
FROM miovision_api.volumes_daily_unfiltered AS v
|| oi.range_start || '` (' || CURRENT_DATE - oi.range_start || ' days)' AS descrip
FROM miovision_api.open_issues AS oi
JOIN miovision_api.intersections AS i USING (intersection_uid)
WHERE i.date_decommissioned IS NULL
GROUP BY
i.intersection_uid,
i.intersection_name
HAVING
MAX(v.dt)
< '{{ macros.ds_add(ds, 6) }}'::date --noqa: TMP
- interval '{{ params.min_duration }}' --noqa: TMP
WHERE oi.classification_uid IS NULL
)

SELECT
COUNT(ongoing_outages.*) < 1 AS _check,
CASE WHEN COUNT(ongoing_outages.*) = 1 THEN 'There is ' ELSE 'There are ' END
|| COALESCE(COUNT(ongoing_outages.*), 0)
|| CASE WHEN COUNT(ongoing_outages.*) = 1 THEN ' ongoing outage.' ELSE ' ongoing outages.'
(SELECT cnt FROM all_outages) < 1 AS _check,

Check failure on line 17 in volumes/miovision/sql/data_checks/select-ongoing_intersection_outages.sql

View workflow job for this annotation

GitHub Actions / SQLFluff Lint

SQLFluff

RF02: Unqualified reference 'cnt' found in select with more than one referenced table/view.
CASE WHEN COUNT(total_outages.*) = 1 THEN 'There is ' ELSE 'There are ' END
|| COALESCE(COUNT(total_outages.*), 0)
|| CASE
WHEN
COUNT(total_outages.*) = 1 THEN ' full outages.' ELSE ' full outages '
|| 'and '
|| (SELECT cnt FROM all_outages

Check failure on line 24 in volumes/miovision/sql/data_checks/select-ongoing_intersection_outages.sql

View workflow job for this annotation

GitHub Actions / SQLFluff Lint

SQLFluff

RF02: Unqualified reference 'cnt' found in select with more than one referenced table/view.
)
|| ' partial outages. See `miovision_api.open_issues`.'
END AS summ, --gap_threshold
array_agg(ongoing_outages.descrip) AS gaps
FROM ongoing_outages
array_agg(total_outages.descrip) AS gaps
FROM total_outages
137 changes: 137 additions & 0 deletions volumes/miovision/sql/function/function-update-open_issues.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,137 @@
--DROP FUNCTION miovision_api.update_open_issues;
CREATE OR REPLACE FUNCTION miovision_api.update_open_issues()
RETURNS void
LANGUAGE PLPGSQL

AS $BODY$

BEGIN

WITH alerts AS (
SELECT
ar.uid,
string_agg(DISTINCT alerts.alert, '; '::text) AS alerts
FROM miovision_api.anomalous_ranges AS ar
JOIN miovision_api.alerts
ON alerts.intersection_uid = ar.intersection_uid
AND tsrange(alerts.start_time, alerts.end_time)
&& tsrange(ar.range_start, ar.range_end)
GROUP BY ar.uid
),

open_issues AS (
SELECT
ar.uid,
ar.intersection_uid,
i.id AS intersection_id,
i.api_name AS intersection_name,
ar.classification_uid,
CASE
WHEN ar.classification_uid = 2 THEN 'Bicycle TMC'
WHEN ar.classification_uid = 10 THEN 'Bicycle Approach'
WHEN ar.classification_uid IS NULL THEN 'All modes'
ELSE c.classification
END,
ar.leg,
ar.range_start::date,
(current_timestamp AT TIME ZONE 'EST5EDT')::date - ar.range_start::date AS num_days,
ar.notes,
SUM(v.volume) AS volume,
alerts.alerts
FROM miovision_api.anomalous_ranges AS ar
--keep rows with null classification_uid
LEFT JOIN miovision_api.classifications AS c USING (classification_uid)
--omit null intersection_uids. These will go under discontinuities.
JOIN miovision_api.intersections AS i USING (intersection_uid)
--find last week volume
LEFT JOIN miovision_api.volumes AS v
ON ar.intersection_uid = v.intersection_uid
--volume within the last 7 days and after AR started
AND v.datetime_bin >= ar.range_start
--prune the partitions
AND v.datetime_bin >= current_date - interval '7 days'
AND (
ar.classification_uid = v.classification_uid
OR ar.classification_uid IS NULL
)
AND (
ar.leg = v.leg
OR ar.leg IS NULL
)
LEFT JOIN alerts ON alerts.uid = ar.uid
WHERE
ar.problem_level <> 'valid-caveat'
--currently active
AND (
ar.range_end IS NULL
OR (
ar.notes LIKE '%identified by a daily airflow process%'
AND ar.range_end = (current_timestamp AT TIME ZONE 'EST5EDT')::date --today
)
)
GROUP BY
ar.uid,
ar.intersection_uid,
i.id,
i.api_name,
ar.classification_uid,
c.classification,
ar.range_start,
ar.notes,
alerts.alerts
ORDER BY
ar.intersection_uid,
ar.range_start,
ar.classification_uid
),

closed AS (
DELETE FROM miovision_api.open_issues
WHERE uid NOT IN (SELECT uid FROM open_issues)
)
leo-oxu marked this conversation as resolved.
Show resolved Hide resolved

MERGE INTO miovision_api.open_issues AS oir
USING open_issues AS oi
ON oir.uid = oi.uid
WHEN MATCHED THEN
UPDATE SET
intersection_uid = oi.intersection_uid,
intersection_id = oi.intersection_id,
intersection_name = oi.intersection_name,
classification_uid = oi.classification_uid,
classification = oi.classification,
leg = oi.leg,
range_start = oi.range_start,
num_days = oi.num_days,
notes = oi.notes,
volume = oi.volume,
alerts = oi.alerts
WHEN NOT MATCHED THEN
INSERT (
uid, intersection_uid, intersection_id, intersection_name, classification_uid,
classification, leg, range_start, num_days, notes, volume, alerts
) VALUES (
oi.uid, oi.intersection_uid, oi.intersection_id, oi.intersection_name,
oi.classification_uid, oi.classification, oi.leg, oi.range_start, oi.num_days, oi.notes,
oi.volume, oi.alerts
);

EXECUTE FORMAT(
'COMMENT ON TABLE miovision_api.open_issues IS %L',
'Last updated ' || to_char(now() AT TIME ZONE 'EST5EDT', 'yyyy-mm-dd HH24:MI')
|| ' using `SELECT miovision_api.update_open_issues();`.'
|| ' This is performed automatically once per day by `miovision_pull` DAG.'
);

END
$BODY$;

COMMENT ON FUNCTION miovision_api.update_open_issues() IS
'A function to update miovision_api.open_issues. '
'Run daily via miovision_pull Airflow DAG.';

ALTER FUNCTION miovision_api.update_open_issues() OWNER TO miovision_admins;

GRANT EXECUTE ON FUNCTION miovision_api.update_open_issues() TO MIOVISION_API_BOT;
GRANT EXECUTE ON FUNCTION miovision_api.update_open_issues() TO MIOVISION_DATA_DETECTIVES;

33 changes: 29 additions & 4 deletions volumes/miovision/sql/readme.md
Original file line number Diff line number Diff line change
Expand Up @@ -9,14 +9,15 @@
- [`movements`](#movements)
- [`volumes`](#volumes)
- [Aggregated Data](#aggregated-data)
- [`volumes_15min_mvt` (Use view `volumes_15min_mvt_filtered` to exclude anomalous\_ranges)](#volumes_15min_mvt-use-view-volumes_15min_mvt_filtered-to-exclude-anomalous_ranges)
- [`volumes_15min` (Use view `volumes_15min_filtered` to exclude anomalous\_ranges)](#volumes_15min-use-view-volumes_15min_filtered-to-exclude-anomalous_ranges)
- [`volumes_15min_mvt`](#volumes_15min_mvt)
- [`volumes_15min`](#volumes_15min)
- [`miovision_api.volumes_daily`](#miovision_apivolumes_daily)
- [`unacceptable_gaps`](#unacceptable_gaps)
- [`gapsize_lookup`](#gapsize_lookup)
- [Reference Tables](#reference-tables)
- [`miovision_api.breaks`](#miovision_apibreaks)
- [`miovision_api.anomalous_ranges`](#miovision_apianomalous_ranges)
- [`miovision_api.open_issues`](#miovision_apiopen_issues)
- [`miovision_api.anomaly_investigation_levels` and `miovision_api.anomaly_problem_levels`](#miovision_apianomaly_investigation_levels-and-miovision_apianomaly_problem_levels)
- [`movement_map`](#movement_map)
- [`periods`](#periods)
Expand Down Expand Up @@ -232,7 +233,8 @@ Data are aggregated from 1-minute volume data into two types of 15-minute volume
}
```

### `volumes_15min_mvt` (Use view `volumes_15min_mvt_filtered` to exclude anomalous_ranges)
### `volumes_15min_mvt`
**(Use view `volumes_15min_mvt_filtered` to exclude anomalous_ranges)**

`volumes_15min_mvt` contains data aggregated into 15 minute bins. In order to make averaging hourly volumes simpler, the volume can be `NULL` (for all modes) or `0` for classifications 1, 2, 6, 10 (which corresponds to light vehicles, bicycles (classifications 2 and 10) and pedestrians).

Expand Down Expand Up @@ -260,7 +262,8 @@ Please see [this diagram](../getting_started.md#Vehicle-Movements) for a visuali

- A *Unique constraint* was added to `miovision_api.volumes_15min_mvt` table based on `intersection_uid`, `datetime_bin`, `classification_uid`, `leg` and `movement_uid`.

### `volumes_15min` (Use view `volumes_15min_filtered` to exclude anomalous_ranges)
### `volumes_15min`
**(Use view `volumes_15min_filtered` to exclude anomalous_ranges)**

Data table storing ATR versions of the 15-minute turning movement data. Data in
`volumes` is stored in TMC format, so must be converted to ATR to be included in
Expand Down Expand Up @@ -368,6 +371,28 @@ The `anomalous_ranges` table is used to log issues related to specific intersect
| problem_level | references `miovision_api.anomaly_problem_levels`; indicates the degree or nature of the problem. e.g. valid with a caveat vs do-not-use under any circumstance |
| leg | Intersection leg which is affected by range. Null refers to all legs. |

### `miovision_api.open_issues`

`open_issues` is a complementary table to `anomalous_ranges`. It is similar to a view of anomalous ranges which are currently open, except it is a table to allow interactive editing in PgAdmin. Each day via Airflow DAG, issues which are no longer active are removed, but the "logged" and "reviewer_notes" columns remain and other columns may be updated.

| column_name | data_type | sample |
|:-------------------|:------------|:-------------------------------------------------------------------------------------------------------|
| uid | smallint | 1797 |
| intersection_uid | smallint | 1 |
| intersection_id | text | 8184ba7d-a2e3-4a1c-b70f-31da15e7462a |
| intersection_name | text | Bathurst Street and Adelaide Street West |
| classification_uid | smallint | 2 |
| classification | text | Bicycle TMC |
| leg | text | W |
| range_start | date | 2024-11-20 |
| num_days | integer | 8 |
| notes | text | Zero counts, identified by a daily airflow process running function miovision_api.identify_zero_counts |
| volume | bigint | |
| alerts | text | |
| logged | boolean | |
| reviewer_notes | text | |


### `miovision_api.anomaly_investigation_levels` and `miovision_api.anomaly_problem_levels`
These two tables are used to enforce standardized descriptions in the `investigation_level` and `problem_level` columns of `anomalous_ranges`.

Expand Down
34 changes: 34 additions & 0 deletions volumes/miovision/sql/table/create-table-open_issues.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
-- Table: miovision_api.open_issues
-- DROP TABLE IF EXISTS miovision_api.open_issues;

CREATE TABLE IF NOT EXISTS miovision_api.open_issues
(
uid smallint NOT NULL,
intersection_uid smallint,
intersection_id text COLLATE pg_catalog."default",
intersection_name text COLLATE pg_catalog."default",
classification_uid smallint,
classification text COLLATE pg_catalog."default",
leg text COLLATE pg_catalog."default",
range_start date,
num_days integer,
notes text COLLATE pg_catalog."default",
volume bigint,
alerts text COLLATE pg_catalog."default",
logged boolean,
reviewer_notes text,
CONSTRAINT open_issues_review_pkey PRIMARY KEY (uid)
)

TABLESPACE pg_default;

ALTER TABLE miovision_api.open_issues OWNER TO miovision_api_bot;

GRANT ALL ON TABLE miovision_api.open_issues TO miovision_admins;
GRANT INSERT, SELECT, UPDATE, DELETE ON TABLE miovision_api.open_issues TO miovision_api_bot;

REVOKE ALL ON TABLE miovision_api.open_issues FROM bdit_humans;
GRANT SELECT ON TABLE miovision_api.open_issues TO bdit_humans;

REVOKE ALL ON TABLE miovision_api.open_issues FROM ckousin;
GRANT UPDATE ON TABLE miovision_api.open_issues TO ckousin;
92 changes: 0 additions & 92 deletions volumes/miovision/sql/views/create-view-open_issues.sql

This file was deleted.