Skip to content

Commit

Permalink
Merge pull request #1547 from cityofaustin/timezone_bug_18930
Browse files Browse the repository at this point in the history
Timezone bug in VZE fatalities view and fix engineering area label
  • Loading branch information
roseeichelmann authored Sep 18, 2024
2 parents 4862517 + a384fb2 commit b7ddbbb
Show file tree
Hide file tree
Showing 6 changed files with 315 additions and 9 deletions.
10 changes: 5 additions & 5 deletions atd-vzd/metadata/databases/default/tables/public_crashes.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -92,7 +92,7 @@ select_permissions:
- crash_timestamp
- created_at
- created_by
- engineering_area
- engineering_area_id
- fhe_collsn_id
- id
- in_austin_full_purpose
Expand Down Expand Up @@ -162,7 +162,7 @@ select_permissions:
- crash_timestamp
- created_at
- created_by
- engineering_area
- engineering_area_id
- fhe_collsn_id
- id
- in_austin_full_purpose
Expand All @@ -189,7 +189,7 @@ select_permissions:
- council_district
- cris_crash_id
- crash_speed_limit
- engineering_area
- engineering_area_id
- fhe_collsn_id
- id
- intrsct_relat_id
Expand Down Expand Up @@ -251,7 +251,7 @@ select_permissions:
- crash_timestamp
- created_at
- created_by
- engineering_area
- engineering_area_id
- fhe_collsn_id
- id
- in_austin_full_purpose
Expand All @@ -277,7 +277,7 @@ select_permissions:
- txdot_rptable_fl
- council_district
- crash_speed_limit
- engineering_area
- engineering_area_id
- fhe_collsn_id
- id
- intrsct_relat_id
Expand Down
Original file line number Diff line number Diff line change
@@ -1,3 +1,31 @@
table:
name: engineering_areas
schema: public
select_permissions:
- role: editor
permission:
columns:
- area_id
- label
- updated_at
- geometry
filter: {}
comment: ""
- role: readonly
permission:
columns:
- area_id
- label
- updated_at
- geometry
filter: {}
comment: ""
- role: vz-admin
permission:
columns:
- area_id
- label
- updated_at
- geometry
filter: {}
comment: ""
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,15 @@ object_relationships:
remote_table:
name: crashes
schema: public
- name: engineering_area
using:
manual_configuration:
column_mapping:
engineering_area_id: area_id
insertion_order: null
remote_table:
name: engineering_areas
schema: public
- name: recommendation
using:
manual_configuration:
Expand All @@ -37,7 +46,7 @@ select_permissions:
- ytd_fatality
- crash_pk
- cris_crash_id
- engineering_area
- engineering_area_id
- person_id
- unit_id
- case_id
Expand All @@ -58,7 +67,7 @@ select_permissions:
- ytd_fatality
- crash_pk
- cris_crash_id
- engineering_area
- engineering_area_id
- person_id
- unit_id
- case_id
Expand All @@ -79,7 +88,7 @@ select_permissions:
- ytd_fatality
- crash_pk
- cris_crash_id
- engineering_area
- engineering_area_id
- person_id
- unit_id
- case_id
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,133 @@
alter table "public"."crashes" rename column "engineering_area_id" to "engineering_area";

create or replace function public.crashes_set_spatial_attributes()
returns trigger
language plpgsql
as $$
begin
if (new.latitude is not null and new.longitude is not null) then
-- save lat/lon into geometry col
new.position = st_setsrid(st_makepoint(new.longitude, new.latitude), 4326);
--
-- get location polygon id
--
if (new.rpt_road_part_id != 2 and upper(ltrim(new.rpt_hwy_num)) in ('35', '183','183A','1','290','71','360','620','45','130')) then
-- use level 5 polygon
new.location_id = (
select
location_id
from
public.atd_txdot_locations
where
location_group = 2 -- level 5
and st_contains(geometry, new.position)
limit 1);
else
-- use the other polygons
new.location_id = (
select
location_id
from
public.atd_txdot_locations
where
location_group = 1 -- not level 5
and st_contains(geometry, new.position)
limit 1);
end if;

raise debug 'found location: % compared to previous location: %', new.location_id, old.location_id;
--
-- check if in austin full purpose jurisdiction
--
new.in_austin_full_purpose = st_contains((select geometry from atd_jurisdictions where id = 5), new.position);
raise debug 'in austin full purpose: % compared to previous: %', new.in_austin_full_purpose, old.in_austin_full_purpose;
--
-- get council district
--
new.council_district = (
select
council_district
from
public.council_districts
where
st_contains(geometry, new.position)
limit 1);
raise debug 'council_district: % compared to previous: %', new.council_district, old.council_district;
--
-- get engineering area
--
new.engineering_area = (
select
area_id
from
public.engineering_areas
where
st_contains(geometry, new.position)
limit 1);
raise debug 'engineering_area: % compared to previous: %', new.engineering_area, old.engineering_area;
else
raise debug 'setting location id and council district to null';
-- nullify position column
new.position = null;
-- reset location id
new.location_id = null;
-- use city id to determine full purpose jurisdiction
new.in_austin_full_purpose = coalesce(new.rpt_city_id = 22, false);
raise debug 'setting in_austin_full_purpose based on city id: %', new.in_austin_full_purpose;
-- reset council district
new.council_district = null;
-- reset engineering area
new.engineering_area = null;
end if;
return new;
end;
$$;

drop view if exists fatalities_view cascade;

create or replace view fatalities_view AS
select
people.id as person_id,
crashes.id as crash_pk,
crashes.cris_crash_id,
crashes.record_locator,
units.id as unit_id,
CONCAT_WS(' ', people.prsn_first_name, people.prsn_mid_name, people.prsn_last_name) as victim_name,
TO_CHAR(crashes.crash_timestamp at time zone 'US/Central', 'yyyy') AS year,
CONCAT_WS(' ',
crashes.rpt_block_num,
crashes.rpt_street_pfx,
crashes.rpt_street_name,
'(',
crashes.rpt_sec_block_num,
crashes.rpt_sec_street_pfx,
crashes.rpt_sec_street_name,
')') AS location,
to_char(
public.crashes.crash_timestamp at time zone 'US/Central', 'YYYY-MM-DD'
) as crash_date_ct,
to_char(
public.crashes.crash_timestamp at time zone 'US/Central', 'HH24:MI:SS'
) as crash_time_ct,
-- get ytd fatality, partition by year and sort by date timestamp
ROW_NUMBER() OVER (
PARTITION BY EXTRACT(year FROM crashes.crash_timestamp)
ORDER BY crashes.crash_timestamp ASC)
AS ytd_fatality,
-- get ytd fatal crash, partition by year and sort by date timestamp.
-- records with the same crash.id will get "tie" rankings thus making
-- this column count each crash rather than each fatality
DENSE_RANK() OVER (
PARTITION BY EXTRACT(year FROM crashes.crash_timestamp)
ORDER BY crashes.crash_timestamp ASC, crashes.id)
AS ytd_fatal_crash,
crashes.case_id,
crashes.law_enforcement_ytd_fatality_num,
crashes.engineering_area
from
people
left join units on people.unit_id = units.id
left join crashes on units.crash_pk = crashes.id
where crashes.in_austin_full_purpose = true AND people.prsn_injry_sev_id = 4 AND crashes.private_dr_fl = false AND crashes.is_deleted = false;

update _column_metadata SET column_name = 'engineering_area' WHERE id = 60;
Original file line number Diff line number Diff line change
@@ -0,0 +1,136 @@
alter table "public"."crashes" rename column "engineering_area" to "engineering_area_id";

-- update column engineering_area to engineering_area_id
create or replace function public.crashes_set_spatial_attributes()
returns trigger
language plpgsql
as $$
begin
if (new.latitude is not null and new.longitude is not null) then
-- save lat/lon into geometry col
new.position = st_setsrid(st_makepoint(new.longitude, new.latitude), 4326);
--
-- get location polygon id
--
if (new.rpt_road_part_id != 2 and upper(ltrim(new.rpt_hwy_num)) in ('35', '183','183A','1','290','71','360','620','45','130')) then
-- use level 5 polygon
new.location_id = (
select
location_id
from
public.atd_txdot_locations
where
location_group = 2 -- level 5
and st_contains(geometry, new.position)
limit 1);
else
-- use the other polygons
new.location_id = (
select
location_id
from
public.atd_txdot_locations
where
location_group = 1 -- not level 5
and st_contains(geometry, new.position)
limit 1);
end if;

raise debug 'found location: % compared to previous location: %', new.location_id, old.location_id;
--
-- check if in austin full purpose jurisdiction
--
new.in_austin_full_purpose = st_contains((select geometry from atd_jurisdictions where id = 5), new.position);
raise debug 'in austin full purpose: % compared to previous: %', new.in_austin_full_purpose, old.in_austin_full_purpose;
--
-- get council district
--
new.council_district = (
select
council_district
from
public.council_districts
where
st_contains(geometry, new.position)
limit 1);
raise debug 'council_district: % compared to previous: %', new.council_district, old.council_district;
--
-- get engineering area
--
new.engineering_area_id = (
select
area_id
from
public.engineering_areas
where
st_contains(geometry, new.position)
limit 1);
raise debug 'engineering_area_id: % compared to previous: %', new.engineering_area_id, old.engineering_area_id;
else
raise debug 'setting location id and council district to null';
-- nullify position column
new.position = null;
-- reset location id
new.location_id = null;
-- use city id to determine full purpose jurisdiction
new.in_austin_full_purpose = coalesce(new.rpt_city_id = 22, false);
raise debug 'setting in_austin_full_purpose based on city id: %', new.in_austin_full_purpose;
-- reset council district
new.council_district = null;
-- reset engineering area
new.engineering_area_id = null;
end if;
return new;
end;
$$;

drop view if exists fatalities_view cascade;

-- fixing a timezone bug in the ytd_fatality and ytd_fatal_crash counts
-- and updating engineering_area to engineering_area_id
create or replace view fatalities_view AS
select
people.id as person_id,
crashes.id as crash_pk,
crashes.cris_crash_id,
crashes.record_locator,
units.id as unit_id,
CONCAT_WS(' ', people.prsn_first_name, people.prsn_mid_name, people.prsn_last_name) as victim_name,
TO_CHAR(crashes.crash_timestamp at time zone 'US/Central', 'yyyy') AS year,
CONCAT_WS(' ',
crashes.rpt_block_num,
crashes.rpt_street_pfx,
crashes.rpt_street_name,
'(',
crashes.rpt_sec_block_num,
crashes.rpt_sec_street_pfx,
crashes.rpt_sec_street_name,
')') AS location,
to_char(
public.crashes.crash_timestamp at time zone 'US/Central', 'YYYY-MM-DD'
) as crash_date_ct,
to_char(
public.crashes.crash_timestamp at time zone 'US/Central', 'HH24:MI:SS'
) as crash_time_ct,
-- get ytd fatality, partition by year and sort by date timestamp
ROW_NUMBER() OVER (
PARTITION BY EXTRACT(year FROM crashes.crash_timestamp at time zone 'US/Central')
ORDER BY crashes.crash_timestamp at time zone 'US/Central' ASC)
AS ytd_fatality,
-- get ytd fatal crash, partition by year and sort by date timestamp.
-- records with the same crash.id will get "tie" rankings thus making
-- this column count each crash rather than each fatality
DENSE_RANK() OVER (
PARTITION BY EXTRACT(year FROM crashes.crash_timestamp at time zone 'US/Central')
ORDER BY crashes.crash_timestamp at time zone 'US/Central' ASC, crashes.id)
AS ytd_fatal_crash,
crashes.case_id,
crashes.law_enforcement_ytd_fatality_num,
crashes.engineering_area_id
from
people
left join units on people.unit_id = units.id
left join crashes on units.crash_pk = crashes.id
where crashes.in_austin_full_purpose = true AND people.prsn_injry_sev_id = 4 AND crashes.private_dr_fl = false AND crashes.is_deleted = false;

update _column_metadata SET column_name = 'engineering_area_id' WHERE id = 60;
Original file line number Diff line number Diff line change
Expand Up @@ -70,7 +70,7 @@ export const fatalityGridTableColumns = {
label_table: "FRB Recommendation",
type: "String",
},
engineering_area: {
"engineering_area { label }": {
searchable: true,
sortable: true,
label_table: "Current Engineering Area",
Expand Down

0 comments on commit b7ddbbb

Please sign in to comment.