Skip to content
Open
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
99 changes: 54 additions & 45 deletions volumes/miovision/geojson/mio_intersections.geojson

Large diffs are not rendered by default.

20 changes: 20 additions & 0 deletions volumes/miovision/sql/updates/update-date.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
-- Drop temp table if it exists
DROP TABLE IF EXISTS temp_min_dates;

-- Recreate temp table with restriction to specific intersection_uids
CREATE TEMP TABLE temp_min_dates AS
SELECT
intersection_uid,
MIN(datetime_bin)::date AS min_datetime
FROM miovision_api.volumes
WHERE intersection_uid IN (4440, 4441, 4442, 4443, 4444, 4445, 4446, 4447, 4439)
GROUP BY intersection_uid;

-- Create index
CREATE INDEX idx_temp_intersection_uid ON temp_min_dates (intersection_uid);

-- Perform the update
UPDATE miovision_api.intersections AS i
SET date_installed = t.min_datetime
FROM temp_min_dates AS t
WHERE i.intersection_uid = t.intersection_uid;
39 changes: 39 additions & 0 deletions volumes/miovision/sql/updates/update-int_id-px-geom.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
WITH intersections (id, intersection_name_api) AS (
VALUES
('3a6c4b1b-91cc-4600-8b9e-f3416839397b', 'The Queensway and The East Mall'),
('ae52ca3c-9a25-4c2c-a726-24388616fe54', 'Lawrence Ave E and Fortune Gate'),
('c85d49f2-bd4a-4649-b967-ce24e39ac102', 'Lawrence Ave E and Galloway Rd'),
('0f37f5c0-9eb0-45d8-80cf-bd3d3718c2d4', 'Lawrence Ave E and Mossbank Dr'),
('0b4e1e39-a9e9-46a3-895f-0f21924c0e54', 'Lawrence Ave E and Scarborough Golf Club Road'),
('01150688-deb1-4565-a0da-236ed77cad12', 'Orton Park Rd and Lawrence Ave E'),
('0726384f-e753-4826-9ef2-72a817776ca5', 'Overture Rd and Lawrence Ave E'),
('843d1d1f-5350-4aaf-a764-ec8ebf847673', 'Greenholm Circuit and Lawrence Ave E'),
('5de86391-7559-48e3-aa46-7cfe0b28bd05', 'The Queensway and The West Mall')
Comment on lines +3 to +11
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

While I was QCing this one I noticed 3 intersections were being tagged to the same intersection at Lawrence/Yonge.
Needed to change the abbreviations to get correct matches: Greenholm Crct, Scarborough Golf Club Rd, Fortune Gt.

),

enriched_data AS (
SELECT
i.id,
SPLIT_PART(i.intersection_name_api, ' and ', 1) AS street_main,
SPLIT_PART(i.intersection_name_api, ' and ', 2) AS street_cross,
g.int_result[3] AS int_id,
ts.px::int AS px,
ts.geom
FROM intersections AS i
JOIN gis._get_intersection_id(
SPLIT_PART(i.intersection_name_api, ' and ', 1),
SPLIT_PART(i.intersection_name_api, ' and ', 2),
0
) AS g (int_result) ON TRUE
LEFT JOIN gis.traffic_signal AS ts ON ts.node_id = g.int_result[3]
)

UPDATE miovision_api.intersections AS target
SET
px = enriched_data.px,
geom = enriched_data.geom,
int_id = enriched_data.int_id,
street_main = enriched_data.street_main,
street_cross = enriched_data.street_cross
FROM enriched_data
WHERE target.id = enriched_data.id;
28 changes: 28 additions & 0 deletions volumes/miovision/sql/updates/update-intersection_name.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
UPDATE miovision_api.intersections
SET
intersection_name = CASE
WHEN api_name = 'Greenholm Circuit and Lawrence Avenue East' THEN 'Lawrence / Greenholm'
WHEN api_name = 'Lawrence Avenue East and Fortune Gate' THEN 'Lawrence / Fortune Gate'
WHEN api_name = 'Lawrence Avenue East and Galloway Road' THEN 'Lawrence / Galloway'
WHEN api_name = 'Lawrence Avenue East and Mossbank Drive' THEN 'Lawrence / Mossbank'
WHEN
api_name = 'Lawrence Avenue East and Scarborough Golf Club Road'
THEN 'Lawrence / Scarborough Golf Club'
WHEN api_name = 'Orton Park Road and Lawrence Avenue East' THEN 'Lawrence / Orton Park'
WHEN api_name = 'Overture Road and Lawrence Avenue East' THEN 'Lawrence / Overture'
WHEN api_name = 'The Queensway and The East Mall' THEN 'The Queensway / The East Mall'
WHEN api_name = 'The Queensway and The West Mall' THEN 'The Queensway / The West Mall'

END
WHERE api_name IN (
'Greenholm Circuit and Lawrence Avenue East',
'Lawrence Avenue East and Fortune Gate',
'Lawrence Avenue East and Galloway Road',
'Lawrence Avenue East and Mossbank Drive',
'Lawrence Avenue East and Scarborough Golf Club Road',
'Orton Park Road and Lawrence Avenue East',
'Overture Road and Lawrence Avenue East',
'The Queensway and The East Mall',
'The Queensway and The West Mall'

);
23 changes: 23 additions & 0 deletions volumes/miovision/sql/updates/update-leg_restricted.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
UPDATE miovision_api.intersections
SET
s_leg_restricted = CASE
WHEN api_name = 'Lawrence Avenue East and Fortune Gate' THEN TRUE
WHEN api_name = 'Lawrence Avenue East and Mossbank Drive' THEN TRUE
WHEN api_name = 'Orton Park Road and Lawrence Avenue East' THEN TRUE

END
WHERE api_name IN (
'Lawrence Avenue East and Fortune Gate',
'Lawrence Avenue East and Mossbank Drive',
'Orton Park Road and Lawrence Avenue East'
);

UPDATE miovision_api.intersections
SET
n_leg_restricted = CASE
WHEN api_name = 'Overture Road and Lawrence Avenue East' THEN TRUE

END
WHERE api_name IN (
'Overture Road and Lawrence Avenue East'
);
70 changes: 70 additions & 0 deletions volumes/miovision/sql/updates/update-street_cross.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,70 @@
UPDATE miovision_api.intersections
SET
street_cross = CASE
WHEN api_name = 'Cherry Street and Lake Shore Boulevard East' THEN 'Cherry Street'
WHEN api_name = 'Eglinton Avenue East and Yonge Street' THEN 'Yonge Street'
WHEN api_name = 'Eglinton Avenue West and Avenue Road' THEN 'Avenue Road'
WHEN api_name = 'Eglinton Avenue West and Bathurst Street' THEN 'Bathurst Street'
WHEN api_name = 'Eglinton Avenue West and Keele Street' THEN 'Keele Street'
WHEN api_name = 'Fleet Street and Fort York Boulevard' THEN 'Fort York Boulevard'
WHEN api_name = 'Fleet Street and Strachan Avenue' THEN 'Strachan Avenue'
WHEN api_name = 'The Queensway and The East Mall' THEN 'The East Mall'
WHEN api_name = 'The Queensway and The West Mall' THEN 'The West Mall'
WHEN
api_name = 'The Queensway and 427 Ramp / Sherway Gardens Road'
THEN '427 Ramp / Sherway Gardens Road'
WHEN
api_name = 'The Queensway and North Queen Street / Private Access'
THEN 'North Queen Street / Private Access'
WHEN api_name = 'The Queensway at 60m East of Algie Ave' THEN '60m East of Algie Ave'
WHEN
api_name = 'The Queensway at Atomic Avenue and Private Access'
THEN 'Atomic Avenue and Private Access'
WHEN api_name = 'Yonge Street and Bloor Street' THEN 'Bloor Street'
WHEN api_name = 'Yonge Street and Dundas Street' THEN 'Dundas Street'
WHEN api_name = 'Yonge Street and MacPherson Avenue' THEN 'MacPherson Avenue'
WHEN api_name = 'Greenholm Circuit and Lawrence Avenue East' THEN 'Greenholm Circuit'
WHEN api_name = 'Lawrence Avenue East and Fortune Gate' THEN 'Fortune Gate'
WHEN api_name = 'Lawrence Avenue East and Galloway Road' THEN 'Galloway Road'
WHEN api_name = 'Lawrence Avenue East and Mossbank Drive' THEN 'Mossbank Drive'
WHEN
api_name = 'Lawrence Avenue East and Scarborough Golf Club Road'
THEN 'Scarborough Golf Club Road'
WHEN api_name = 'Orton Park Road and Lawrence Avenue East' THEN 'Orton Park Road'
WHEN api_name = 'Overture Road and Lawrence Avenue East' THEN 'Overture Road'
WHEN
api_name = 'The Queensway and 230 M East of The East Mall'
THEN '230 M East of The East Mall'
WHEN
api_name = 'The Queensway and 240m East of The West Mall'
THEN '240m East of The West Mall'

END
WHERE api_name IN (
'Cherry Street and Lake Shore Boulevard East',
'Eglinton Avenue East and Yonge Street',
'Eglinton Avenue West and Avenue Road',
'Eglinton Avenue West and Bathurst Street',
'Eglinton Avenue West and Keele Street',
'Fleet Street and Fort York Boulevard',
'Fleet Street and Strachan Avenue',
'The Queensway and The East Mall',
'The Queensway and The West Mall',
'The Queensway and 427 Ramp / Sherway Gardens Road',
'The Queensway and North Queen Street / Private Access',
'The Queensway at 60m East of Algie Ave',
'The Queensway at Atomic Avenue and Private Access',
'Yonge Street and Bloor Street',
'Yonge Street and Dundas Street',
'Greenholm Circuit and Lawrence Avenue East',
'Lawrence Avenue East and Fortune Gate',
'Lawrence Avenue East and Galloway Road',
'Lawrence Avenue East and Mossbank Drive',
'Lawrence Avenue East and Scarborough Golf Club Road',
'Orton Park Road and Lawrence Avenue East',
'Overture Road and Lawrence Avenue East',
'The Queensway and 230 M East of The East Mall',
'The Queensway and 240m East of The West Mall',
'Yonge Street and MacPherson Avenue'

);
62 changes: 62 additions & 0 deletions volumes/miovision/sql/updates/update-street_main.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
UPDATE miovision_api.intersections
SET
street_main = CASE
WHEN
api_name = 'Cherry Street and Lake Shore Boulevard East'
THEN 'Lake Shore Boulevard East'
WHEN api_name = 'Eglinton Avenue East and Yonge Street' THEN 'Eglinton Avenue East'
WHEN api_name = 'Eglinton Avenue West and Avenue Road' THEN 'Eglinton Avenue West'
WHEN api_name = 'Eglinton Avenue West and Bathurst Street' THEN 'Eglinton Avenue West'
WHEN api_name = 'Eglinton Avenue West and Keele Street' THEN 'Eglinton Avenue West'
WHEN api_name = 'Fleet Street and Fort York Boulevard' THEN 'Fleet Street'
WHEN api_name = 'Fleet Street and Strachan Avenue' THEN 'Fleet Street'
WHEN api_name = 'The Queensway and The East Mall' THEN 'The Queensway'
WHEN api_name = 'The Queensway and The West Mall' THEN 'The Queensway'
WHEN api_name = 'The Queensway and 427 Ramp / Sherway Gardens Road' THEN 'The Queensway'
WHEN api_name = 'The Queensway and North Queen Street / Private Access' THEN 'The Queensway'
WHEN api_name = 'The Queensway at 60m East of Algie Ave' THEN 'The Queensway'
WHEN api_name = 'The Queensway at Atomic Avenue and Private Access' THEN 'The Queensway'
WHEN api_name = 'Yonge Street and Bloor Street' THEN 'Yonge Street'
WHEN api_name = 'Yonge Street and Dundas Street' THEN 'Yonge Street'
WHEN api_name = 'Yonge Street and MacPherson Avenue' THEN 'Yonge Street'
WHEN api_name = 'Greenholm Circuit and Lawrence Avenue East' THEN 'Lawrence Avenue East'
WHEN api_name = 'Lawrence Avenue East and Fortune Gate' THEN 'Lawrence Avenue East'
WHEN api_name = 'Lawrence Avenue East and Galloway Road' THEN 'Lawrence Avenue East'
WHEN api_name = 'Lawrence Avenue East and Mossbank Drive' THEN 'Lawrence Avenue East'
WHEN
api_name = 'Lawrence Avenue East and Scarborough Golf Club Road'
THEN 'Lawrence Avenue East'
WHEN api_name = 'Orton Park Road and Lawrence Avenue East' THEN 'Lawrence Avenue East'
WHEN api_name = 'Overture Road and Lawrence Avenue East' THEN 'Lawrence Avenue East'
WHEN api_name = 'The Queensway and 230 M East of The East Mall' THEN 'The Queensway'
WHEN api_name = 'The Queensway and 240m East of The West Mall' THEN 'The Queensway'

END
WHERE api_name IN (
'Cherry Street and Lake Shore Boulevard East',
'Eglinton Avenue East and Yonge Street',
'Eglinton Avenue West and Avenue Road',
'Eglinton Avenue West and Bathurst Street',
'Eglinton Avenue West and Keele Street',
'Fleet Street and Fort York Boulevard',
'Fleet Street and Strachan Avenue',
'The Queensway and The East Mall',
'The Queensway and The West Mall',
'The Queensway and 427 Ramp / Sherway Gardens Road',
'The Queensway and North Queen Street / Private Access',
'The Queensway at 60m East of Algie Ave',
'The Queensway at Atomic Avenue and Private Access',
'Yonge Street and Bloor Street',
'Yonge Street and Dundas Street',
'Greenholm Circuit and Lawrence Avenue East',
'Lawrence Avenue East and Fortune Gate',
'Lawrence Avenue East and Galloway Road',
'Lawrence Avenue East and Mossbank Drive',
'Lawrence Avenue East and Scarborough Golf Club Road',
'Orton Park Road and Lawrence Avenue East',
'Overture Road and Lawrence Avenue East',
'The Queensway and 230 M East of The East Mall',
'The Queensway and 240m East of The West Mall',
'Yonge Street and MacPherson Avenue'

);
31 changes: 27 additions & 4 deletions volumes/miovision/update_intersections/readme.md
Original file line number Diff line number Diff line change
Expand Up @@ -40,10 +40,28 @@ Look at the table [`miovision_api.intersections`](../readme.md#intersections) to
The `intersection_name` is an internal name following the convention `[E / W street name] / [N / S street name]`.

3. **date installed**
`date_installed` is the *date of the first row of data from the location* (so if the first row has a `datetime_bin` of '2020-10-05 12:15', the `date_installed` is '2020-10-05'). `date_installed` can be found by querying:
to update `date_installed`, the following script can be run, where the temp table contains the first date of which a recording was made for a specific intersection_uid (previously defined). The output is then joined on the intersections table:

```sql
SELECT MIN(datetime_bin)::date FROM miovision_api.volumes WHERE intersection_uid = 122;
-- Drop temp table if it exists
DROP TABLE IF EXISTS temp_min_dates;

-- Recreate temp table with restriction to specific intersection_uids
CREATE TEMP TABLE temp_min_dates AS
SELECT intersection_uid, MIN(datetime_bin)::date AS min_datetime
FROM miovision_api.volumes
WHERE intersection_uid IN ('intersection_uids you want to input')
GROUP BY intersection_uid;

-- Create index
CREATE INDEX idx_temp_intersection_uid ON temp_min_dates(intersection_uid);
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nice update on this sql. You don't need to add an index here because this is a very small table. Indexes work like textbook indexes, to help identify which chapter/page to look at, but in this example your textbook is one paragraph.


-- Perform the update
UPDATE miovision_api.intersections AS i
SET date_installed = t.min_datetime
FROM temp_min_dates AS t
WHERE i.intersection_uid = t.intersection_uid;

```

4. **date_decommissioned**
Expand Down Expand Up @@ -169,7 +187,7 @@ We need to find out all valid movements for the new intersections from the data


3. **Add additional modes to `intersection_movements`**
The step before only include valid intersection movements for
The step before only includes valid intersection movements for
`classification_uid IN (1,2,6,10)` which are light vehicles, cyclists and
pedestrians. The reason is that the counts for other mode may not pass the
mark of having 20 distinct datetime_bin. However, we know that if vehicles
Expand Down Expand Up @@ -200,7 +218,12 @@ We need to find out all valid movements for the new intersections from the data
```

4. **Review `intersection_movements`**
Once the above is finished, we have completed updating the table [`miovision_api.intersection_movements`](../readme.md#intersection_movements). **Though, the valid movements should be manually reviewed.**
Once the above is finished, we have completed updating the table [`miovision_api.intersection_movements`](../readme.md#intersection_movements). **Though, the valid movements should be manually reviewed looking at the following criteria.**

- are there any major vehicle movements missing: through/left/right
- are there any ped movements missing: clockwise/ccw
- if any of these are missing, investigate and see if that movement is legitimately not allowed (usually through the leg restriction clause of the intersection - should be updated before)

Below is an example script + output you can use to aggregate movements into a more readable format for QC. In particular look for intersections with very short lists of valid movements, or no valid movements for certain classifications.

| intersection_uid | leg | movements |
Expand Down
Loading