diff --git a/atd-vzd/migrations/migration_atd_txdot_crashes_2023_07_14--1325.sql b/atd-vzd/migrations/migration_atd_txdot_crashes_2023_07_14--1325.sql new file mode 100644 index 000000000..75768df00 --- /dev/null +++ b/atd-vzd/migrations/migration_atd_txdot_crashes_2023_07_14--1325.sql @@ -0,0 +1,7 @@ +-- This trigger updates the city id of a crash to be in Austin if its currently +-- not in Austin and the position value is moved into any of the Austin jurisdictions +CREATE OR REPLACE TRIGGER crashes_position_update_city_id + BEFORE UPDATE ON atd_txdot_crashes + FOR EACH ROW + WHEN (OLD.position IS DISTINCT FROM NEW.position AND NEW.city_id != 22) + EXECUTE FUNCTION update_crash_city_id(); diff --git a/atd-vzd/triggers/update_crash_city_id.sql b/atd-vzd/triggers/update_crash_city_id.sql new file mode 100644 index 000000000..4827a6998 --- /dev/null +++ b/atd-vzd/triggers/update_crash_city_id.sql @@ -0,0 +1,27 @@ +-- This function updates the city id if a crashes position is moved into Austin +CREATE OR REPLACE FUNCTION update_crash_city_id() + RETURNS trigger + LANGUAGE plpgsql +AS $function$ +DECLARE +temprow RECORD; + BEGIN + -- loop through jurisdictions that contain the new position + -- if jurisdiction is in the list of valid jurisdictions then + -- update city id to be in Austin (22) + FOR temprow IN + ( + SELECT id + FROM atd_jurisdictions + WHERE (atd_jurisdictions.geometry && NEW.position) AND ST_Contains(atd_jurisdictions.geometry, NEW.position) + ) + LOOP + IF temprow.id IN (5, 3, 7, 8, 10) THEN + NEW.city_id = 22; + RETURN NEW; + END IF; + END LOOP; + RETURN NEW; + END +$function$ +;