From 11b262b3eca421b0aea33e6ca8c048723a64b747 Mon Sep 17 00:00:00 2001 From: rose Date: Tue, 10 Sep 2024 18:24:01 -0500 Subject: [PATCH 1/9] add migrations to fix timezone bug --- .../down.sql | 44 ++++++++++++++++++ .../up.sql | 45 +++++++++++++++++++ 2 files changed, 89 insertions(+) create mode 100644 atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql create mode 100644 atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql diff --git a/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql b/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql new file mode 100644 index 000000000..2de490d0d --- /dev/null +++ b/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql @@ -0,0 +1,44 @@ +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; diff --git a/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql b/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql new file mode 100644 index 000000000..13ebba831 --- /dev/null +++ b/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql @@ -0,0 +1,45 @@ +-- fixing a timezone bug in the ytd_fatality and ytd_fatal_crash counts +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 + 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; From 8441bea7209c571139cc8cffddf10b0423456657 Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:16:24 -0500 Subject: [PATCH 2/9] update column name engineering_area_id --- .../databases/default/tables/public_crashes.yaml | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/atd-vzd/metadata/databases/default/tables/public_crashes.yaml b/atd-vzd/metadata/databases/default/tables/public_crashes.yaml index d0fd5e0d1..d7af9ef16 100644 --- a/atd-vzd/metadata/databases/default/tables/public_crashes.yaml +++ b/atd-vzd/metadata/databases/default/tables/public_crashes.yaml @@ -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 @@ -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 @@ -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 @@ -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 @@ -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 From 9a580f1e262ad4fa0dd45ff87fe971c38298e3ea Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:16:49 -0500 Subject: [PATCH 3/9] add select permissions to engineering areas table --- .../tables/public_engineering_areas.yaml | 28 +++++++++++++++++++ 1 file changed, 28 insertions(+) diff --git a/atd-vzd/metadata/databases/default/tables/public_engineering_areas.yaml b/atd-vzd/metadata/databases/default/tables/public_engineering_areas.yaml index d2b4bcf90..543a440dc 100644 --- a/atd-vzd/metadata/databases/default/tables/public_engineering_areas.yaml +++ b/atd-vzd/metadata/databases/default/tables/public_engineering_areas.yaml @@ -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: "" From 5a7f51b9f6492027dad79ff107a2887398655c23 Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:17:46 -0500 Subject: [PATCH 4/9] rename column to engineering_area_id and create relationship to engineering table --- .../default/tables/public_fatalities_view.yaml | 15 ++++++++++++--- 1 file changed, 12 insertions(+), 3 deletions(-) diff --git a/atd-vzd/metadata/databases/default/tables/public_fatalities_view.yaml b/atd-vzd/metadata/databases/default/tables/public_fatalities_view.yaml index f65941208..8bed962e0 100644 --- a/atd-vzd/metadata/databases/default/tables/public_fatalities_view.yaml +++ b/atd-vzd/metadata/databases/default/tables/public_fatalities_view.yaml @@ -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: @@ -37,7 +46,7 @@ select_permissions: - ytd_fatality - crash_pk - cris_crash_id - - engineering_area + - engineering_area_id - person_id - unit_id - case_id @@ -58,7 +67,7 @@ select_permissions: - ytd_fatality - crash_pk - cris_crash_id - - engineering_area + - engineering_area_id - person_id - unit_id - case_id @@ -79,7 +88,7 @@ select_permissions: - ytd_fatality - crash_pk - cris_crash_id - - engineering_area + - engineering_area_id - person_id - unit_id - case_id From a840c52dda71fe9025303c8f4997057683a8d419 Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:19:19 -0500 Subject: [PATCH 5/9] get the label from relationship to engineering areas table --- atd-vze/src/views/Fatalities/fatalityGridTableParameters.js | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/atd-vze/src/views/Fatalities/fatalityGridTableParameters.js b/atd-vze/src/views/Fatalities/fatalityGridTableParameters.js index 38368002c..a1cf17678 100644 --- a/atd-vze/src/views/Fatalities/fatalityGridTableParameters.js +++ b/atd-vze/src/views/Fatalities/fatalityGridTableParameters.js @@ -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", From ca5c462c949fe1c5554d19715afa3e98f202aa20 Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:19:52 -0500 Subject: [PATCH 6/9] rename crashes column engineering_area to engineering_area_id --- .../down.sql | 1 + .../up.sql | 1 + 2 files changed, 2 insertions(+) create mode 100644 atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql create mode 100644 atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql diff --git a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql new file mode 100644 index 000000000..bd3b465ff --- /dev/null +++ b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql @@ -0,0 +1 @@ +alter table "public"."crashes" rename column "engineering_area_id" to "engineering_area"; diff --git a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql new file mode 100644 index 000000000..a6ffd3f56 --- /dev/null +++ b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql @@ -0,0 +1 @@ +alter table "public"."crashes" rename column "engineering_area" to "engineering_area_id"; From a84eb43eb3e46ef120b3035eafe21f38dab2953f Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:20:38 -0500 Subject: [PATCH 7/9] update engineering area to engineering_area_id --- .../down.sql | 82 ++++++++++++++++++ .../up.sql | 83 +++++++++++++++++++ .../down.sql | 0 .../up.sql | 5 +- 4 files changed, 169 insertions(+), 1 deletion(-) create mode 100644 atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql create mode 100644 atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql rename atd-vzd/migrations/default/{1726000511912_fix_timezone_fatalities_view => 1726084839740_fix_timezone_fatalities_view}/down.sql (100%) rename atd-vzd/migrations/default/{1726000511912_fix_timezone_fatalities_view => 1726084839740_fix_timezone_fatalities_view}/up.sql (93%) diff --git a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql b/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql new file mode 100644 index 000000000..f3773a288 --- /dev/null +++ b/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql @@ -0,0 +1,82 @@ +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; +$$; diff --git a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql b/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql new file mode 100644 index 000000000..6fcf1e18e --- /dev/null +++ b/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql @@ -0,0 +1,83 @@ +-- 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; +$$; diff --git a/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql b/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql similarity index 100% rename from atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/down.sql rename to atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql diff --git a/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql b/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql similarity index 93% rename from atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql rename to atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql index 13ebba831..1997e8f53 100644 --- a/atd-vzd/migrations/default/1726000511912_fix_timezone_fatalities_view/up.sql +++ b/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql @@ -1,4 +1,7 @@ +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, @@ -37,7 +40,7 @@ DENSE_RANK() OVER ( AS ytd_fatal_crash, crashes.case_id, crashes.law_enforcement_ytd_fatality_num, -crashes.engineering_area +crashes.engineering_area_id from people left join units on people.unit_id = units.id From 08f71b6c9de9029e78beb4d99c7fac82100488fd Mon Sep 17 00:00:00 2001 From: rose Date: Wed, 11 Sep 2024 23:31:02 -0500 Subject: [PATCH 8/9] update column metadata name --- .../default/1726115426755_update_column_metadata_name/down.sql | 1 + .../default/1726115426755_update_column_metadata_name/up.sql | 1 + 2 files changed, 2 insertions(+) create mode 100644 atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql create mode 100644 atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql diff --git a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql new file mode 100644 index 000000000..d942ccb6a --- /dev/null +++ b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql @@ -0,0 +1 @@ +update _column_metadata SET column_name = 'engineering_area' WHERE id = 60; diff --git a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql new file mode 100644 index 000000000..dcabca947 --- /dev/null +++ b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql @@ -0,0 +1 @@ +update _column_metadata SET column_name = 'engineering_area_id' WHERE id = 60; From a384fb23a0b2b9ba3e67e1609f62894fd21d94f3 Mon Sep 17 00:00:00 2001 From: rose Date: Tue, 17 Sep 2024 11:47:16 -0500 Subject: [PATCH 9/9] fix migrations --- .../down.sql | 1 - .../up.sql | 1 - .../down.sql | 51 ++++++++++++++++++ .../up.sql | 53 +++++++++++++++++++ .../down.sql | 44 --------------- .../up.sql | 48 ----------------- .../down.sql | 1 - .../up.sql | 1 - 8 files changed, 104 insertions(+), 96 deletions(-) delete mode 100644 atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql delete mode 100644 atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql rename atd-vzd/migrations/default/{1726084839739_update_crashes_set_spatial_attributes => 1726084778340_update_col_eng_area_fix_timezone_bug}/down.sql (62%) rename atd-vzd/migrations/default/{1726084839739_update_crashes_set_spatial_attributes => 1726084778340_update_col_eng_area_fix_timezone_bug}/up.sql (60%) delete mode 100644 atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql delete mode 100644 atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql delete mode 100644 atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql delete mode 100644 atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql diff --git a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql deleted file mode 100644 index bd3b465ff..000000000 --- a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/down.sql +++ /dev/null @@ -1 +0,0 @@ -alter table "public"."crashes" rename column "engineering_area_id" to "engineering_area"; diff --git a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql b/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql deleted file mode 100644 index a6ffd3f56..000000000 --- a/atd-vzd/migrations/default/1726084778340_alter_table_public_crashes_alter_column_engineering_area/up.sql +++ /dev/null @@ -1 +0,0 @@ -alter table "public"."crashes" rename column "engineering_area" to "engineering_area_id"; diff --git a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql b/atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/down.sql similarity index 62% rename from atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql rename to atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/down.sql index f3773a288..c5af609cb 100644 --- a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/down.sql +++ b/atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/down.sql @@ -1,3 +1,5 @@ +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 @@ -80,3 +82,52 @@ begin 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; diff --git a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql b/atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/up.sql similarity index 60% rename from atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql rename to atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/up.sql index 6fcf1e18e..5d5b4cb6f 100644 --- a/atd-vzd/migrations/default/1726084839739_update_crashes_set_spatial_attributes/up.sql +++ b/atd-vzd/migrations/default/1726084778340_update_col_eng_area_fix_timezone_bug/up.sql @@ -1,3 +1,5 @@ +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 @@ -81,3 +83,54 @@ begin 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; diff --git a/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql b/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql deleted file mode 100644 index 2de490d0d..000000000 --- a/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/down.sql +++ /dev/null @@ -1,44 +0,0 @@ -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; diff --git a/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql b/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql deleted file mode 100644 index 1997e8f53..000000000 --- a/atd-vzd/migrations/default/1726084839740_fix_timezone_fatalities_view/up.sql +++ /dev/null @@ -1,48 +0,0 @@ -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; diff --git a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql deleted file mode 100644 index d942ccb6a..000000000 --- a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/down.sql +++ /dev/null @@ -1 +0,0 @@ -update _column_metadata SET column_name = 'engineering_area' WHERE id = 60; diff --git a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql b/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql deleted file mode 100644 index dcabca947..000000000 --- a/atd-vzd/migrations/default/1726115426755_update_column_metadata_name/up.sql +++ /dev/null @@ -1 +0,0 @@ -update _column_metadata SET column_name = 'engineering_area_id' WHERE id = 60;