diff --git a/sql/tms-template.sql b/sql/tms-template.sql index 5bed1105f..5ee34cbeb 100644 --- a/sql/tms-template.sql +++ b/sql/tms-template.sql @@ -173,116 +173,6 @@ BEGIN END; $update_version$ language plpgsql; --- --- Events --- -CREATE SEQUENCE event.event_id_seq; - -CREATE TABLE iris.event_config ( - name VARCHAR(32) PRIMARY KEY, - enable_store BOOLEAN NOT NULL, - enable_purge BOOLEAN NOT NULL, - purge_days INTEGER NOT NULL -); - -INSERT INTO iris.event_config (name, enable_store, enable_purge, purge_days) -VALUES - ('action_plan_event', true, true, 90), - ('alarm_event', true, false, 0), - ('beacon_event', true, false, 0), - ('brightness_sample', true, false, 0), - ('camera_switch_event', true, true, 30), - ('camera_video_event', true, true, 14), - ('cap_alert', true, true, 7), - ('client_event', true, false, 0), - ('comm_event', true, true, 14), - ('detector_event', true, true, 90), - ('gate_arm_event', true, false, 0), - ('incident', true, false, 0), - ('incident_update', true, false, 0), - ('meter_event', true, true, 14), - ('meter_lock_event', true, false, 0), - ('price_message_event', true, false, 0), - ('sign_event', true, false, 0), - ('tag_read_event', true, false, 0), - ('travel_time_event', true, true, 1), - ('weather_sensor_sample', true, true, 90), - ('weather_sensor_settings', true, false, 0); - -CREATE TRIGGER event_config_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.event_config - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE TABLE event.event_description ( - event_desc_id INTEGER PRIMARY KEY, - description text NOT NULL -); - -COPY event.event_description (event_desc_id, description) FROM stdin; -1 Alarm TRIGGERED -2 Alarm CLEARED -8 Comm ERROR -9 Comm RESTORED -10 Comm QUEUE DRAINED -11 Comm POLL TIMEOUT -12 Comm PARSING ERROR -13 Comm CHECKSUM ERROR -14 Comm CONTROLLER ERROR -15 Comm CONNECTION REFUSED -21 Incident CRASH -22 Incident STALL -23 Incident HAZARD -24 Incident ROADWORK -65 Comm FAILED -81 DMS MSG ERROR -82 DMS PIXEL ERROR -83 DMS MSG RESET -89 LCS DEPLOYED -90 LCS CLEARED -91 Sign DEPLOYED -92 Sign CLEARED -94 NO HITS -95 LOCKED ON -96 CHATTER -97 NO CHANGE -98 OCC SPIKE -101 Sign BRIGHTNESS LOW -102 Sign BRIGHTNESS GOOD -103 Sign BRIGHTNESS HIGH -201 Client CONNECT -202 Client AUTHENTICATE -203 Client FAIL AUTHENTICATION -204 Client DISCONNECT -205 Client CHANGE PASSWORD -206 Client FAIL PASSWORD -207 Client FAIL DOMAIN -208 Client FAIL DOMAIN XFF -209 Client UPDATE PASSWORD -301 Gate Arm UNKNOWN -302 Gate Arm FAULT -303 Gate Arm OPENING -304 Gate Arm OPEN -305 Gate Arm WARN CLOSE -306 Gate Arm CLOSING -307 Gate Arm CLOSED -401 Meter event -402 Meter LOCK -501 Beacon STATE -601 Tag Read -651 Price DEPLOYED -652 Price VERIFIED -701 TT Link too long -703 TT No destination data -704 TT No origin data -705 TT No route -801 Camera SWITCHED -811 Camera Video LOST -812 Camera Video RESTORED -900 Action Plan ACTIVATED -901 Action Plan DEACTIVATED -902 Action Plan Phase CHANGED -\. - -- -- Resources and Hashtags -- @@ -414,168 +304,147 @@ END; $hashtag_trig$ LANGUAGE plpgsql; -- --- Domains, Roles, Users, and Permissions +-- Events -- -CREATE TABLE iris.domain ( - name VARCHAR(15) PRIMARY KEY, - block CIDR NOT NULL, - enabled BOOLEAN NOT NULL -); - -CREATE TRIGGER domain_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.domain - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -COPY iris.domain (name, block, enabled) FROM stdin; -any_ipv4 0.0.0.0/0 t -any_ipv6 ::0/0 t -local_ipv6 ::1/128 t -\. +CREATE SEQUENCE event.event_id_seq; -CREATE TABLE iris.role ( - name VARCHAR(15) PRIMARY KEY, - enabled BOOLEAN NOT NULL +CREATE TABLE iris.event_config ( + name VARCHAR(32) PRIMARY KEY, + enable_store BOOLEAN NOT NULL, + enable_purge BOOLEAN NOT NULL, + purge_days INTEGER NOT NULL ); -COPY iris.role (name, enabled) FROM stdin; -administrator t -operator t -\. +INSERT INTO iris.event_config (name, enable_store, enable_purge, purge_days) +VALUES + ('action_plan_event', true, true, 90), + ('alarm_event', true, false, 0), + ('beacon_event', true, false, 0), + ('brightness_sample', true, false, 0), + ('camera_switch_event', true, true, 30), + ('camera_video_event', true, true, 14), + ('cap_alert', true, true, 7), + ('client_event', true, false, 0), + ('comm_event', true, true, 14), + ('detector_event', true, true, 90), + ('gate_arm_event', true, false, 0), + ('incident', true, false, 0), + ('incident_update', true, false, 0), + ('meter_event', true, true, 14), + ('meter_lock_event', true, false, 0), + ('price_message_event', true, false, 0), + ('sign_event', true, false, 0), + ('tag_read_event', true, false, 0), + ('travel_time_event', true, true, 1), + ('weather_sensor_sample', true, true, 90), + ('weather_sensor_settings', true, false, 0); -CREATE TRIGGER role_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.role +CREATE TRIGGER event_config_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.event_config FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE TABLE iris.role_domain ( - role VARCHAR(15) NOT NULL REFERENCES iris.role, - domain VARCHAR(15) NOT NULL REFERENCES iris.domain +CREATE TABLE event.event_description ( + event_desc_id INTEGER PRIMARY KEY, + description text NOT NULL ); -ALTER TABLE iris.role_domain ADD PRIMARY KEY (role, domain); - -CREATE FUNCTION iris.role_domain_notify() RETURNS TRIGGER AS - $role_domain_notify$ -BEGIN - IF (TG_OP = 'DELETE') THEN - PERFORM pg_notify('role', OLD.role); - ELSE - PERFORM pg_notify('role', NEW.role); - END IF; - RETURN NULL; -- AFTER trigger return is ignored -END; -$role_domain_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER role_domain_notify_trig - AFTER INSERT OR DELETE ON iris.role_domain - FOR EACH ROW EXECUTE FUNCTION iris.role_domain_notify(); -COPY iris.role_domain (role, domain) FROM stdin; -administrator any_ipv4 -administrator any_ipv6 +COPY event.event_description (event_desc_id, description) FROM stdin; +1 Alarm TRIGGERED +2 Alarm CLEARED +8 Comm ERROR +9 Comm RESTORED +10 Comm QUEUE DRAINED +11 Comm POLL TIMEOUT +12 Comm PARSING ERROR +13 Comm CHECKSUM ERROR +14 Comm CONTROLLER ERROR +15 Comm CONNECTION REFUSED +21 Incident CRASH +22 Incident STALL +23 Incident HAZARD +24 Incident ROADWORK +65 Comm FAILED +81 DMS MSG ERROR +82 DMS PIXEL ERROR +83 DMS MSG RESET +89 LCS DEPLOYED +90 LCS CLEARED +91 Sign DEPLOYED +92 Sign CLEARED +94 NO HITS +95 LOCKED ON +96 CHATTER +97 NO CHANGE +98 OCC SPIKE +101 Sign BRIGHTNESS LOW +102 Sign BRIGHTNESS GOOD +103 Sign BRIGHTNESS HIGH +201 Client CONNECT +202 Client AUTHENTICATE +203 Client FAIL AUTHENTICATION +204 Client DISCONNECT +205 Client CHANGE PASSWORD +206 Client FAIL PASSWORD +207 Client FAIL DOMAIN +208 Client FAIL DOMAIN XFF +209 Client UPDATE PASSWORD +301 Gate Arm UNKNOWN +302 Gate Arm FAULT +303 Gate Arm OPENING +304 Gate Arm OPEN +305 Gate Arm WARN CLOSE +306 Gate Arm CLOSING +307 Gate Arm CLOSED +401 Meter event +402 Meter LOCK +501 Beacon STATE +601 Tag Read +651 Price DEPLOYED +652 Price VERIFIED +701 TT Link too long +703 TT No destination data +704 TT No origin data +705 TT No route +801 Camera SWITCHED +811 Camera Video LOST +812 Camera Video RESTORED +900 Action Plan ACTIVATED +901 Action Plan DEACTIVATED +902 Action Plan Phase CHANGED \. -CREATE TABLE iris.user_id ( - name VARCHAR(15) PRIMARY KEY, - full_name VARCHAR(31) NOT NULL, - password VARCHAR(64) NOT NULL, - dn VARCHAR(128) NOT NULL, - role VARCHAR(15) REFERENCES iris.role, - enabled BOOLEAN NOT NULL -); - -INSERT INTO iris.user_id (name, full_name, password, dn, role, enabled) - VALUES ( - 'admin', 'IRIS Administrator', - '+vAwDtk/0KGx9k+kIoKFgWWbd3Ku8e/FOHoZoHB65PAuNEiN2muHVavP0fztOi4=', - '', 'administrator', true - ); - -CREATE TRIGGER user_id_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.user_id - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW user_id_view AS - SELECT name, full_name, dn, role, enabled - FROM iris.user_id; -GRANT SELECT ON user_id_view TO PUBLIC; - -CREATE TABLE iris.access_level ( - id INTEGER PRIMARY KEY, - description VARCHAR NOT NULL -); - -COPY iris.access_level (id, description) FROM stdin; -1 View -2 Operate -3 Manage -4 Configure -\. - -CREATE TABLE iris.permission ( - name VARCHAR(8) PRIMARY KEY, - role VARCHAR(15) NOT NULL REFERENCES iris.role ON DELETE CASCADE, - base_resource VARCHAR(16) NOT NULL REFERENCES iris.resource_type, - hashtag VARCHAR(16), - access_level INTEGER NOT NULL REFERENCES iris.access_level, - - CONSTRAINT hashtag_ck CHECK (hashtag ~ '^#[A-Za-z0-9]+$'), - -- hashtag cannot be applied to "View" access level - CONSTRAINT hashtag_access_ck CHECK (hashtag IS NULL OR access_level != 1) +-- +-- Lane Codes, Direction, Road, Map Extent, Geo Loc +-- +CREATE TABLE iris.lane_code ( + lcode VARCHAR(1) PRIMARY KEY, + description VARCHAR(12) NOT NULL ); -ALTER TABLE iris.permission - ADD CONSTRAINT base_resource_ck - CHECK (iris.resource_is_base(base_resource)) NOT VALID; - -CREATE UNIQUE INDEX permission_role_base_resource_hashtag_idx - ON iris.permission (role, base_resource, COALESCE(hashtag, '')); - -COPY iris.permission (name, role, base_resource, access_level) FROM stdin; -prm_1 administrator action_plan 4 -prm_2 administrator alert_config 4 -prm_3 administrator beacon 4 -prm_4 administrator camera 4 -prm_5 administrator controller 4 -prm_6 administrator detector 4 -prm_7 administrator dms 4 -prm_8 administrator gate_arm 4 -prm_9 administrator incident 4 -prm_10 administrator lcs 4 -prm_11 administrator parking_area 4 -prm_12 administrator permission 4 -prm_13 administrator ramp_meter 4 -prm_14 administrator system_attribute 4 -prm_15 administrator toll_zone 4 -prm_16 administrator video_monitor 4 -prm_17 administrator weather_sensor 4 +COPY iris.lane_code (lcode, description) FROM stdin; + Mainline +A Auxiliary +B Bypass +C CD Lane +D Shoulder +G Green +H HOV +K Parking +M Merge +O Omnibus +P Passage +Q Queue +R Reversible +T HOT +V Velocity +X Exit +Y Wrong Way \. -CREATE TRIGGER permission_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.permission - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW permission_view AS - SELECT name, role, base_resource, hashtag, description AS access_level - FROM iris.permission p - JOIN iris.access_level a ON a.id = p.access_level; -GRANT SELECT ON permission_view TO PUBLIC; - -CREATE TABLE event.client_event ( - id SERIAL PRIMARY KEY, - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc INTEGER NOT NULL REFERENCES event.event_description, - host_port VARCHAR(64) NOT NULL, - user_id VARCHAR(15) -); - -CREATE VIEW client_event_view AS - SELECT ev.id, event_date, ed.description, host_port, user_id - FROM event.client_event ev - JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; -GRANT SELECT ON client_event_view TO PUBLIC; +CREATE VIEW lane_code_view AS + SELECT lcode, description FROM iris.lane_code; +GRANT SELECT ON lane_code_view TO PUBLIC; --- --- Direction, Road, Geo Location, R_Node, Map Extent --- CREATE TABLE iris.direction ( id SMALLINT PRIMARY KEY, direction VARCHAR(4) NOT NULL, @@ -658,33 +527,13 @@ CREATE VIEW road_view AS LEFT JOIN iris.direction dir ON r.direction = dir.id; GRANT SELECT ON road_view TO PUBLIC; -CREATE TABLE iris.road_affix ( - name VARCHAR(12) PRIMARY KEY, - prefix BOOLEAN NOT NULL, - fixup VARCHAR(12), - allow_retain BOOLEAN NOT NULL +CREATE TABLE iris.map_extent ( + name VARCHAR(20) PRIMARY KEY, + lat real NOT NULL, + lon real NOT NULL, + zoom INTEGER NOT NULL ); -COPY iris.road_affix (name, prefix, fixup, allow_retain) FROM stdin; -C.S.A.H. t CTY f -CO RD t CTY f -I- t f -U.S. t HWY f -T.H. t HWY f -AVE f t -BLVD f f -CIR f f -DR f t -HWY f f -LN f f -PKWY f f -PL f f -RD f t -ST f t -TR f f -WAY f f -\. - CREATE TABLE iris.geo_loc ( name VARCHAR(20) PRIMARY KEY, resource_n VARCHAR(16) NOT NULL REFERENCES iris.resource_type, @@ -759,571 +608,1408 @@ CREATE VIEW geo_loc_view AS LEFT JOIN iris.direction c_dir ON l.cross_dir = c_dir.id; GRANT SELECT ON geo_loc_view TO PUBLIC; -CREATE TABLE iris.r_node_type ( - n_type INTEGER PRIMARY KEY, - name VARCHAR(12) NOT NULL +-- +-- Incidents, descriptors, locators, advice, road affix +-- +CREATE TABLE event.incident_detail ( + name VARCHAR(8) PRIMARY KEY, + description VARCHAR(32) NOT NULL ); -COPY iris.r_node_type (n_type, name) FROM stdin; -0 station -1 entrance -2 exit -3 intersection -4 access -5 interchange -\. +INSERT INTO event.incident_detail (name, description) +VALUES + ('animal', 'Animal on Road'), + ('debris', 'Debris'), + ('detour', 'Detour'), + ('emrg_veh', 'Emergency Vehicles'), + ('event', 'Event Congestion'), + ('flooding', 'Flash Flooding'), + ('gr_fire', 'Grass Fire'), + ('ice', 'Ice'), + ('jacknife', 'Jacknifed Trailer'), + ('pavement', 'Pavement Failure'), + ('ped', 'Pedestrian'), + ('rollover', 'Rollover'), + ('sgnl_out', 'Traffic Lights Out'), + ('snow_rmv', 'Snow Removal'), + ('spill', 'Spilled Load'), + ('spin_out', 'Vehicle Spin Out'), + ('test', 'Test Incident'), + ('veh_fire', 'Vehicle Fire'); -CREATE TABLE iris.r_node_transition ( - n_transition INTEGER PRIMARY KEY, - name VARCHAR(12) NOT NULL -); +CREATE TRIGGER incident_detail_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON event.incident_detail + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -COPY iris.r_node_transition (n_transition, name) FROM stdin; -0 none -1 loop -2 leg -3 slipramp -4 CD -5 HOV -6 common -7 flyover -\. +CREATE TABLE event.incident ( + id SERIAL PRIMARY KEY, + name VARCHAR(16) NOT NULL UNIQUE, + replaces VARCHAR(16) REFERENCES event.incident(name), + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc INTEGER NOT NULL REFERENCES event.event_description, + detail VARCHAR(8) REFERENCES event.incident_detail(name), + lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, + road VARCHAR(20) NOT NULL, + dir SMALLINT NOT NULL REFERENCES iris.direction(id), + lat double precision NOT NULL, + lon double precision NOT NULL, + camera VARCHAR(20), + impact VARCHAR(20) NOT NULL, + cleared BOOLEAN NOT NULL, + confirmed BOOLEAN NOT NULL, + user_id VARCHAR(15), -CREATE TABLE iris.r_node ( - name VARCHAR(10) PRIMARY KEY, - geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), - node_type INTEGER NOT NULL REFERENCES iris.r_node_type, - pickable BOOLEAN NOT NULL, - above BOOLEAN NOT NULL, - transition INTEGER NOT NULL REFERENCES iris.r_node_transition, - lanes INTEGER NOT NULL, - attach_side BOOLEAN NOT NULL, - shift INTEGER NOT NULL, - active BOOLEAN NOT NULL, - station_id VARCHAR(10), - speed_limit INTEGER NOT NULL, - notes VARCHAR(160) + CONSTRAINT impact_ck CHECK (impact ~ '^[!?\.]*$') ); -CREATE UNIQUE INDEX r_node_station_idx ON iris.r_node USING btree (station_id); +CREATE TRIGGER incident_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON event.incident + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE FUNCTION iris.r_node_notify() RETURNS TRIGGER AS - $r_node_notify$ +CREATE FUNCTION event.incident_blocked_lanes(TEXT) + RETURNS INTEGER AS $incident_blocked_lanes$ +DECLARE + impact ALIAS FOR $1; + imp TEXT; + lanes INTEGER; BEGIN - IF (TG_OP = 'DELETE') THEN - PERFORM pg_notify('r_node', OLD.name); + lanes = length(impact) - 2; + IF lanes > 0 THEN + imp = substring(impact FROM 2 FOR lanes); + RETURN lanes - length(replace(imp, '!', '')); ELSE - PERFORM pg_notify('r_node', NEW.name); + RETURN 0; END IF; - RETURN NULL; -- AFTER trigger return is ignored END; -$r_node_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER r_node_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.r_node - FOR EACH ROW EXECUTE FUNCTION iris.r_node_notify(); +$incident_blocked_lanes$ LANGUAGE plpgsql; -CREATE FUNCTION iris.r_node_left(INTEGER, INTEGER, BOOLEAN, INTEGER) - RETURNS INTEGER AS $r_node_left$ +CREATE FUNCTION event.incident_blocked_shoulders(TEXT) + RETURNS INTEGER AS $incident_blocked_shoulders$ DECLARE - node_type ALIAS FOR $1; - lanes ALIAS FOR $2; - attach_side ALIAS FOR $3; - shift ALIAS FOR $4; + impact ALIAS FOR $1; + len INTEGER; + imp TEXT; BEGIN - IF attach_side = TRUE THEN - RETURN shift; + len = length(impact); + IF len > 2 THEN + imp = substring(impact FROM 1 FOR 1) || + substring(impact FROM len FOR 1); + RETURN 2 - length(replace(imp, '!', '')); + ELSE + RETURN 0; END IF; - IF node_type = 0 THEN - RETURN shift - lanes; +END; +$incident_blocked_shoulders$ LANGUAGE plpgsql; + +CREATE VIEW incident_view AS + SELECT i.id, name, event_date, ed.description, road, d.direction, + impact, event.incident_blocked_lanes(impact) AS blocked_lanes, + event.incident_blocked_shoulders(impact) AS blocked_shoulders, + cleared, confirmed, user_id, camera, lc.description AS lane_type, + detail, replaces, lat, lon + FROM event.incident i + LEFT JOIN event.event_description ed ON i.event_desc = ed.event_desc_id + LEFT JOIN iris.direction d ON i.dir = d.id + LEFT JOIN iris.lane_code lc ON i.lane_code = lc.lcode; +GRANT SELECT ON incident_view TO PUBLIC; + +CREATE TABLE event.incident_update ( + id SERIAL PRIMARY KEY, + incident VARCHAR(16) NOT NULL REFERENCES event.incident(name), + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + impact VARCHAR(20) NOT NULL, + cleared BOOLEAN NOT NULL, + confirmed BOOLEAN NOT NULL, + user_id VARCHAR(15) +); + +CREATE FUNCTION event.incident_update_trig() RETURNS TRIGGER AS +$incident_update_trig$ +BEGIN + IF (NEW.impact IS DISTINCT FROM OLD.impact) OR + (NEW.cleared IS DISTINCT FROM OLD.cleared) + THEN + INSERT INTO event.incident_update ( + incident, event_date, impact, cleared, confirmed, user_id + ) VALUES ( + NEW.name, now(), NEW.impact, NEW.cleared, NEW.confirmed, NEW.user_id + ); END IF; - RETURN shift; + RETURN NEW; END; -$r_node_left$ LANGUAGE plpgsql; +$incident_update_trig$ LANGUAGE plpgsql; -CREATE FUNCTION iris.r_node_right(INTEGER, INTEGER, BOOLEAN, INTEGER) - RETURNS INTEGER AS $r_node_right$ -DECLARE - node_type ALIAS FOR $1; - lanes ALIAS FOR $2; - attach_side ALIAS FOR $3; - shift ALIAS FOR $4; +CREATE TRIGGER incident_update_trigger + AFTER INSERT OR UPDATE ON event.incident + FOR EACH ROW EXECUTE FUNCTION event.incident_update_trig(); + +CREATE VIEW incident_update_view AS + SELECT iu.id, name, iu.event_date, ed.description, road, + d.direction, iu.impact, iu.cleared, iu.confirmed, iu.user_id, + camera, lc.description AS lane_type, detail, replaces, lat, lon + FROM event.incident i + JOIN event.incident_update iu ON i.name = iu.incident + LEFT JOIN event.event_description ed ON i.event_desc = ed.event_desc_id + LEFT JOIN iris.direction d ON i.dir = d.id + LEFT JOIN iris.lane_code lc ON i.lane_code = lc.lcode; +GRANT SELECT ON incident_update_view TO PUBLIC; + +CREATE TABLE iris.inc_descriptor ( + name VARCHAR(10) PRIMARY KEY, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), + detail VARCHAR(8) REFERENCES event.incident_detail(name), + lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, + multi VARCHAR(64) NOT NULL +); + +CREATE FUNCTION iris.inc_descriptor_ck() RETURNS TRIGGER AS + $inc_descriptor_ck$ BEGIN - IF attach_side = FALSE THEN - RETURN shift; + -- Only incident event IDs are allowed + IF NEW.event_desc_id < 21 OR NEW.event_desc_id > 24 THEN + RAISE EXCEPTION 'invalid incident event_desc_id'; END IF; - IF node_type = 0 THEN - RETURN shift + lanes; + -- Only mainline, cd road, merge and exit lane types are allowed + IF NEW.lane_code != '' AND NEW.lane_code != 'C' AND + NEW.lane_code != 'M' AND NEW.lane_code != 'X' THEN + RAISE EXCEPTION 'invalid incident lane_code'; END IF; - RETURN shift; + RETURN NEW; END; -$r_node_right$ LANGUAGE plpgsql; +$inc_descriptor_ck$ LANGUAGE plpgsql; -ALTER TABLE iris.r_node ADD CONSTRAINT left_edge_ck - CHECK (iris.r_node_left(node_type, lanes, attach_side, shift) >= 1); -ALTER TABLE iris.r_node ADD CONSTRAINT right_edge_ck - CHECK (iris.r_node_right(node_type, lanes, attach_side, shift) <= 9); +CREATE TRIGGER inc_descriptor_ck_trig + BEFORE INSERT OR UPDATE ON iris.inc_descriptor + FOR EACH ROW EXECUTE FUNCTION iris.inc_descriptor_ck(); -CREATE VIEW r_node_view AS - SELECT n.name, n.geo_loc, - l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir, - l.landmark, l.lat, l.lon, l.corridor, l.location, - nt.name AS node_type, n.pickable, n.above, tr.name AS transition, - n.lanes, n.attach_side, n.shift, n.active, - n.station_id, n.speed_limit, n.notes - FROM iris.r_node n - JOIN geo_loc_view l ON n.geo_loc = l.name - JOIN iris.r_node_type nt ON n.node_type = nt.n_type - JOIN iris.r_node_transition tr ON n.transition = tr.n_transition; -GRANT SELECT ON r_node_view TO PUBLIC; +CREATE TRIGGER inc_descriptor_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.inc_descriptor + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE VIEW roadway_station_view AS - SELECT station_id, roadway, road_dir, cross_mod, cross_street, active, - speed_limit - FROM iris.r_node r, geo_loc_view l - WHERE r.geo_loc = l.name AND station_id IS NOT NULL; -GRANT SELECT ON roadway_station_view TO PUBLIC; +CREATE VIEW inc_descriptor_view AS + SELECT id.name, ed.description AS event_description, detail, + lc.description AS lane_type, multi + FROM iris.inc_descriptor id + JOIN event.event_description ed ON id.event_desc_id = ed.event_desc_id + LEFT JOIN iris.lane_code lc ON id.lane_code = lc.lcode; +GRANT SELECT ON inc_descriptor_view TO PUBLIC; -CREATE TABLE iris.map_extent ( - name VARCHAR(20) PRIMARY KEY, - lat real NOT NULL, - lon real NOT NULL, - zoom INTEGER NOT NULL -); +COPY iris.inc_descriptor (name, event_desc_id, detail, lane_code, multi) FROM stdin; +idsc_00001 21 \N CRASH +idsc_00002 21 \N X CRASH ON EXIT +idsc_00003 22 \N STALLED VEHICLE +idsc_00004 23 \N INCIDENT +idsc_00005 23 animal ANIMAL ON ROAD +idsc_00006 23 debris DEBRIS ON ROAD +idsc_00007 23 emrg_veh EMERGENCY VEHICLES +idsc_00008 23 event EVENT CONGESTION +idsc_00009 23 event X CONGESTION ON RAMP +idsc_00010 23 flooding FLASH FLOODING +idsc_00011 23 gr_fire GRASS FIRE +idsc_00012 23 ice ICE +idsc_00013 23 pavement PAVEMENT FAILURE +idsc_00014 23 ped PEDESTRIAN ON ROAD +idsc_00015 23 rollover CRASH +idsc_00016 23 snow_rmv SNOW REMOVAL +idsc_00017 23 spin_out CRASH +idsc_00018 23 spin_out X CRASH ON EXIT +idsc_00019 23 test TEST +idsc_00020 23 veh_fire VEHICLE FIRE +idsc_00021 24 \N ROAD WORK +idsc_00022 24 \N X ROAD WORK ON RAMP +\. --- --- Day Matchers, Day Plans, Plan Phases, Action Plans and Time Actions --- -CREATE TABLE iris.day_matcher ( - name VARCHAR(32) PRIMARY KEY, - holiday BOOLEAN NOT NULL, - month INTEGER NOT NULL, - day INTEGER NOT NULL, - week INTEGER NOT NULL, - weekday INTEGER NOT NULL, - shift INTEGER NOT NULL +CREATE TABLE iris.inc_impact ( + id INTEGER PRIMARY KEY, + description VARCHAR(24) NOT NULL ); -COPY iris.day_matcher (name, holiday, month, day, week, weekday, shift) FROM stdin; -Any Day f -1 0 0 0 0 -Sunday Holiday t -1 0 0 1 0 -Saturday Holiday t -1 0 0 7 0 -New Years Day t 0 1 0 0 0 -Memorial Day t 4 0 -1 2 0 -Independence Day t 6 4 0 0 0 -Labor Day t 8 0 1 2 0 -Thanksgiving Day t 10 0 4 5 0 -Black Friday t 10 0 4 5 1 -Christmas Eve t 11 24 0 0 0 -Christmas Day t 11 25 0 0 0 -New Years Eve t 11 31 0 0 0 +COPY iris.inc_impact (id, description) FROM stdin; +0 lanes blocked +1 left lanes blocked +2 right lanes blocked +3 center lanes blocked +4 lanes affected +5 left lanes affected +6 right lanes affected +7 center lanes affected +8 both shoulders blocked +9 left shoulder blocked +10 right shoulder blocked +11 both shoulders affected +12 left shoulder affected +13 right shoulder affected +14 free flowing \. -CREATE TABLE iris.day_plan ( - name VARCHAR(10) PRIMARY KEY +CREATE TABLE iris.inc_range ( + id INTEGER PRIMARY KEY, + description VARCHAR(10) NOT NULL ); -COPY iris.day_plan (name) FROM stdin; -EVERY_DAY -WEEKDAYS -WORK_DAYS +COPY iris.inc_range (id, description) FROM stdin; +0 ahead +1 near +2 middle +3 far \. -CREATE TABLE iris.day_plan_day_matcher ( - day_plan VARCHAR(10) NOT NULL REFERENCES iris.day_plan, - day_matcher VARCHAR(32) NOT NULL REFERENCES iris.day_matcher +CREATE TABLE iris.inc_locator ( + name VARCHAR(10) PRIMARY KEY, + range INTEGER NOT NULL REFERENCES iris.inc_range(id), + branched BOOLEAN NOT NULL, + picked BOOLEAN NOT NULL, + multi VARCHAR(64) NOT NULL ); -ALTER TABLE iris.day_plan_day_matcher ADD PRIMARY KEY (day_plan, day_matcher); -COPY iris.day_plan_day_matcher (day_plan, day_matcher) FROM stdin; -EVERY_DAY Any Day -WEEKDAYS Any Day -WEEKDAYS Sunday Holiday -WEEKDAYS Saturday Holiday -WORK_DAYS Any Day -WORK_DAYS Sunday Holiday -WORK_DAYS Saturday Holiday -WORK_DAYS New Years Day -WORK_DAYS Memorial Day -WORK_DAYS Independence Day -WORK_DAYS Labor Day -WORK_DAYS Thanksgiving Day -WORK_DAYS Black Friday -WORK_DAYS Christmas Eve -WORK_DAYS Christmas Day -WORK_DAYS New Years Eve +CREATE TRIGGER inc_locator_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.inc_locator + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW inc_locator_view AS + SELECT il.name, rng.description AS range, branched, picked, multi + FROM iris.inc_locator il + LEFT JOIN iris.inc_range rng ON il.range = rng.id; +GRANT SELECT ON inc_locator_view TO PUBLIC; + +COPY iris.inc_locator (name, range, branched, picked, multi) FROM stdin; +iloc_00001 0 f f AHEAD +iloc_00002 0 f t AHEAD +iloc_00003 0 t f AHEAD +iloc_00004 0 t t AHEAD +iloc_00005 1 f f [locmi] MILES AHEAD +iloc_00006 1 f t [locmd] [locxn] +iloc_00007 1 t f ON [locrn] [locrd] +iloc_00008 1 t t ON [locrn] [locrd] +iloc_00009 2 f f [locmi] MILES AHEAD +iloc_00010 2 f t [locmd] [locxn] +iloc_00011 2 t f ON [locrn] [locrd] +iloc_00012 2 t t ON [locrn] [locrd] [locmd] [locxn] +iloc_00013 3 f f [locmi] MILES AHEAD +iloc_00014 3 f t [locmd] [locxn] +iloc_00015 3 t f ON [locrn] [locrd] +iloc_00016 3 t t ON [locrn] [locrd] [locmd] [locxn] +\. + +CREATE TABLE iris.inc_advice ( + name VARCHAR(10) PRIMARY KEY, + impact INTEGER NOT NULL REFERENCES iris.inc_impact(id), + open_lanes INTEGER, + impacted_lanes INTEGER, + range INTEGER NOT NULL REFERENCES iris.inc_range(id), + lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, + multi VARCHAR(64) NOT NULL +); + +CREATE FUNCTION iris.inc_advice_ck() RETURNS TRIGGER AS + $inc_advice_ck$ +BEGIN + -- Only mainline, cd road, merge and exit lane codes are allowed + IF NEW.lane_code != '' AND NEW.lane_code != 'C' AND + NEW.lane_code != 'M' AND NEW.lane_code != 'X' THEN + RAISE EXCEPTION 'invalid incident lane_code'; + END IF; + RETURN NEW; +END; +$inc_advice_ck$ LANGUAGE plpgsql; + +CREATE TRIGGER inc_advice_ck_trig + BEFORE INSERT OR UPDATE ON iris.inc_advice + FOR EACH ROW EXECUTE FUNCTION iris.inc_advice_ck(); + +CREATE TRIGGER inc_advice_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.inc_advice + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW inc_advice_view AS + SELECT a.name, imp.description AS impact, lc.description AS lane_type, + rng.description AS range, open_lanes, impacted_lanes, multi + FROM iris.inc_advice a + LEFT JOIN iris.inc_impact imp ON a.impact = imp.id + LEFT JOIN iris.inc_range rng ON a.range = rng.id + LEFT JOIN iris.lane_code lc ON a.lane_code = lc.lcode; +GRANT SELECT ON inc_advice_view TO PUBLIC; + +COPY iris.inc_advice (name, impact, lane_code, range, open_lanes, impacted_lanes, multi) FROM stdin; +iadv_00001 0 0 0 \N ROAD CLOSED +iadv_00002 0 0 \N \N LANES CLOSED +iadv_00003 0 1 0 \N ROAD CLOSED +iadv_00004 0 1 \N \N LANES CLOSED +iadv_00005 0 2 \N 1 1 LANE CLOSED +iadv_00006 0 2 \N 2 2 LANES CLOSED +iadv_00007 0 2 \N 3 3 LANES CLOSED +iadv_00008 0 2 0 \N ROAD CLOSED +iadv_00009 0 2 1 \N SINGLE LANE +iadv_00010 0 2 \N \N LANES CLOSED +iadv_00011 0 3 \N 1 1 LANE CLOSED +iadv_00012 0 3 \N 2 2 LANES CLOSED +iadv_00013 0 3 \N 3 3 LANES CLOSED +iadv_00014 0 3 0 \N ROAD CLOSED +iadv_00015 0 3 1 \N SINGLE LANE +iadv_00016 0 3 \N \N LANES CLOSED +iadv_00017 1 0 \N 1 LEFT LANE CLOSED +iadv_00018 1 0 \N 2 LEFT 2 LANES CLOSED +iadv_00019 1 0 \N 3 LEFT 3 LANES CLOSED +iadv_00020 1 0 \N \N LEFT LANES CLOSED +iadv_00021 1 1 \N 1 LEFT LANE CLOSED +iadv_00022 1 1 \N 2 LEFT 2 LANES CLOSED +iadv_00023 1 1 \N 3 LEFT 3 LANES CLOSED +iadv_00024 1 1 \N \N LEFT LANES CLOSED +iadv_00025 1 2 \N 1 LANE CLOSED +iadv_00026 1 2 \N 2 2 LANES CLOSED +iadv_00027 1 2 \N 3 3 LANES CLOSED +iadv_00028 1 2 1 \N SINGLE LANE +iadv_00029 1 2 \N \N LANES CLOSED +iadv_00030 1 3 \N 1 LANE CLOSED +iadv_00031 1 3 \N 2 2 LANES CLOSED +iadv_00032 1 3 \N 3 3 LANES CLOSED +iadv_00033 1 3 1 \N SINGLE LANE +iadv_00034 1 3 \N \N LANES CLOSED +iadv_00035 2 0 \N 1 RIGHT LANE CLOSED +iadv_00036 2 0 \N 2 RIGHT 2 LANES CLOSED +iadv_00037 2 0 \N 3 RIGHT 3 LANES CLOSED +iadv_00038 2 0 \N \N RIGHT LANES CLOSED +iadv_00039 2 1 \N 1 RIGHT LANE CLOSED +iadv_00040 2 1 \N 2 RIGHT 2 LANES CLOSED +iadv_00041 2 1 \N 3 RIGHT 3 LANES CLOSED +iadv_00042 2 1 \N \N RIGHT LANES CLOSED +iadv_00043 2 2 \N 1 LANE CLOSED +iadv_00044 2 2 \N 2 2 LANES CLOSED +iadv_00045 2 2 \N 3 3 LANES CLOSED +iadv_00046 2 2 1 \N SINGLE LANE +iadv_00047 2 2 \N \N LANES CLOSED +iadv_00048 2 3 \N 1 LANE CLOSED +iadv_00049 2 3 \N 2 2 LANES CLOSED +iadv_00050 2 3 \N 3 3 LANES CLOSED +iadv_00051 2 3 1 \N SINGLE LANE +iadv_00052 2 3 \N \N LANES CLOSED +iadv_00053 3 0 \N 1 CENTER LANE CLOSED +iadv_00054 3 0 \N \N CENTER LANES CLOSED +iadv_00055 3 1 \N 1 CENTER LANE CLOSED +iadv_00056 3 1 \N \N CENTER LANES CLOSED +iadv_00057 3 2 \N 1 LANE CLOSED +iadv_00058 3 2 \N 2 2 LANES CLOSED +iadv_00059 3 2 \N 3 3 LANES CLOSED +iadv_00060 3 2 \N \N LANES CLOSED +iadv_00061 3 3 \N 1 LANE CLOSED +iadv_00062 3 3 \N 2 2 LANES CLOSED +iadv_00063 3 3 \N 3 3 LANES CLOSED +iadv_00064 3 3 \N \N LANES CLOSED +iadv_00065 4 0 0 1 IN LANE +iadv_00066 4 0 0 2 IN BOTH LANES +iadv_00067 4 0 0 \N IN ALL LANES +iadv_00068 4 1 0 1 IN LANE +iadv_00069 4 1 0 2 IN BOTH LANES +iadv_00070 4 1 0 \N IN ALL LANES +iadv_00071 5 0 \N 1 IN LEFT LANE +iadv_00072 5 0 \N 2 IN LEFT 2 LANES +iadv_00073 5 0 \N 3 IN LEFT 3 LANES +iadv_00074 5 0 \N 4 IN LEFT 4 LANES +iadv_00075 5 0 \N \N IN LEFT LANES +iadv_00076 5 1 \N 1 IN LEFT LANE +iadv_00077 5 1 \N 2 IN LEFT 2 LANES +iadv_00078 5 1 \N 3 IN LEFT 3 LANES +iadv_00079 5 1 \N 4 IN LEFT 4 LANES +iadv_00080 5 1 \N \N IN LEFT LANES +iadv_00081 6 0 \N 1 IN RIGHT LANE +iadv_00082 6 0 \N 2 IN RIGHT 2 LANES +iadv_00083 6 0 \N 3 IN RIGHT 3 LANES +iadv_00084 6 0 \N 4 IN RIGHT 4 LANES +iadv_00085 6 0 \N \N IN RIGHT LANES +iadv_00086 6 1 \N 1 IN RIGHT LANE +iadv_00087 6 1 \N 2 IN RIGHT 2 LANES +iadv_00088 6 1 \N 3 IN RIGHT 3 LANES +iadv_00089 6 1 \N 4 IN RIGHT 4 LANES +iadv_00090 6 1 \N \N IN RIGHT LANES +iadv_00091 7 0 \N 1 IN CENTER LANE +iadv_00092 7 0 \N \N IN CENTER LANES +iadv_00093 7 1 \N 1 IN CENTER LANE +iadv_00094 7 1 \N \N IN CENTER LANES +iadv_00095 8 0 \N \N ON BOTH SHOULDERS +iadv_00096 8 1 \N \N ON BOTH SHOULDERS +iadv_00097 9 0 \N \N ON LEFT SHOULDER +iadv_00098 9 1 \N \N ON LEFT SHOULDER +iadv_00099 10 0 \N \N ON RIGHT SHOULDER +iadv_00100 10 1 \N \N ON RIGHT SHOULDER +iadv_00101 11 0 \N \N IN BOTH SHOULDERS +iadv_00102 11 1 \N \N IN BOTH SHOULDERS +iadv_00103 12 0 \N \N IN LEFT SHOULDER +iadv_00104 12 1 \N \N IN LEFT SHOULDER +iadv_00105 13 0 \N \N IN RIGHT SHOULDER +iadv_00106 13 1 \N \N IN RIGHT SHOULDER +\. + +CREATE TABLE iris.road_affix ( + name VARCHAR(12) PRIMARY KEY, + prefix BOOLEAN NOT NULL, + fixup VARCHAR(12), + allow_retain BOOLEAN NOT NULL +); + +COPY iris.road_affix (name, prefix, fixup, allow_retain) FROM stdin; +C.S.A.H. t CTY f +CO RD t CTY f +I- t f +U.S. t HWY f +T.H. t HWY f +AVE f t +BLVD f f +CIR f f +DR f t +HWY f f +LN f f +PKWY f f +PL f f +RD f t +ST f t +TR f f +WAY f f +\. + +-- +-- Domains, Roles, Users, and Permissions +-- +CREATE TABLE iris.domain ( + name VARCHAR(15) PRIMARY KEY, + block CIDR NOT NULL, + enabled BOOLEAN NOT NULL +); + +CREATE TRIGGER domain_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.domain + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +COPY iris.domain (name, block, enabled) FROM stdin; +any_ipv4 0.0.0.0/0 t +any_ipv6 ::0/0 t +local_ipv6 ::1/128 t +\. + +CREATE TABLE iris.role ( + name VARCHAR(15) PRIMARY KEY, + enabled BOOLEAN NOT NULL +); + +COPY iris.role (name, enabled) FROM stdin; +administrator t +operator t +\. + +CREATE TRIGGER role_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.role + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE TABLE iris.role_domain ( + role VARCHAR(15) NOT NULL REFERENCES iris.role, + domain VARCHAR(15) NOT NULL REFERENCES iris.domain +); +ALTER TABLE iris.role_domain ADD PRIMARY KEY (role, domain); + +CREATE FUNCTION iris.role_domain_notify() RETURNS TRIGGER AS + $role_domain_notify$ +BEGIN + IF (TG_OP = 'DELETE') THEN + PERFORM pg_notify('role', OLD.role); + ELSE + PERFORM pg_notify('role', NEW.role); + END IF; + RETURN NULL; -- AFTER trigger return is ignored +END; +$role_domain_notify$ LANGUAGE plpgsql; + +CREATE TRIGGER role_domain_notify_trig + AFTER INSERT OR DELETE ON iris.role_domain + FOR EACH ROW EXECUTE FUNCTION iris.role_domain_notify(); + +COPY iris.role_domain (role, domain) FROM stdin; +administrator any_ipv4 +administrator any_ipv6 +\. + +CREATE TABLE iris.user_id ( + name VARCHAR(15) PRIMARY KEY, + full_name VARCHAR(31) NOT NULL, + password VARCHAR(64) NOT NULL, + dn VARCHAR(128) NOT NULL, + role VARCHAR(15) REFERENCES iris.role, + enabled BOOLEAN NOT NULL +); + +INSERT INTO iris.user_id (name, full_name, password, dn, role, enabled) + VALUES ( + 'admin', 'IRIS Administrator', + '+vAwDtk/0KGx9k+kIoKFgWWbd3Ku8e/FOHoZoHB65PAuNEiN2muHVavP0fztOi4=', + '', 'administrator', true + ); + +CREATE TRIGGER user_id_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.user_id + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW user_id_view AS + SELECT name, full_name, dn, role, enabled + FROM iris.user_id; +GRANT SELECT ON user_id_view TO PUBLIC; + +CREATE TABLE iris.access_level ( + id INTEGER PRIMARY KEY, + description VARCHAR NOT NULL +); + +COPY iris.access_level (id, description) FROM stdin; +1 View +2 Operate +3 Manage +4 Configure +\. + +CREATE TABLE iris.permission ( + name VARCHAR(8) PRIMARY KEY, + role VARCHAR(15) NOT NULL REFERENCES iris.role ON DELETE CASCADE, + base_resource VARCHAR(16) NOT NULL REFERENCES iris.resource_type, + hashtag VARCHAR(16), + access_level INTEGER NOT NULL REFERENCES iris.access_level, + + CONSTRAINT hashtag_ck CHECK (hashtag ~ '^#[A-Za-z0-9]+$'), + -- hashtag cannot be applied to "View" access level + CONSTRAINT hashtag_access_ck CHECK (hashtag IS NULL OR access_level != 1) +); + +ALTER TABLE iris.permission + ADD CONSTRAINT base_resource_ck + CHECK (iris.resource_is_base(base_resource)) NOT VALID; + +CREATE UNIQUE INDEX permission_role_base_resource_hashtag_idx + ON iris.permission (role, base_resource, COALESCE(hashtag, '')); + +COPY iris.permission (name, role, base_resource, access_level) FROM stdin; +prm_1 administrator action_plan 4 +prm_2 administrator alert_config 4 +prm_3 administrator beacon 4 +prm_4 administrator camera 4 +prm_5 administrator controller 4 +prm_6 administrator detector 4 +prm_7 administrator dms 4 +prm_8 administrator gate_arm 4 +prm_9 administrator incident 4 +prm_10 administrator lcs 4 +prm_11 administrator parking_area 4 +prm_12 administrator permission 4 +prm_13 administrator ramp_meter 4 +prm_14 administrator system_attribute 4 +prm_15 administrator toll_zone 4 +prm_16 administrator video_monitor 4 +prm_17 administrator weather_sensor 4 +\. + +CREATE TRIGGER permission_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.permission + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW permission_view AS + SELECT name, role, base_resource, hashtag, description AS access_level + FROM iris.permission p + JOIN iris.access_level a ON a.id = p.access_level; +GRANT SELECT ON permission_view TO PUBLIC; + +CREATE TABLE event.client_event ( + id SERIAL PRIMARY KEY, + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc INTEGER NOT NULL REFERENCES event.event_description, + host_port VARCHAR(64) NOT NULL, + user_id VARCHAR(15) +); + +CREATE VIEW client_event_view AS + SELECT ev.id, event_date, ed.description, host_port, user_id + FROM event.client_event ev + JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; +GRANT SELECT ON client_event_view TO PUBLIC; + +-- +-- Comm Protocols, Comm Links, Modems, Cabinets, Controllers +-- +CREATE TABLE iris.comm_protocol ( + id SMALLINT PRIMARY KEY, + description VARCHAR(20) NOT NULL +); + +COPY iris.comm_protocol (id, description) FROM stdin; +0 NTCIP Class B +1 MnDOT 170 (4-bit) +2 MnDOT 170 (5-bit) +3 SmartSensor 105 +4 Canoga +5 Pelco P +6 Pelco D PTZ +7 NTCIP Class C +8 Manchester PTZ +9 DMS XML +10 MSG_FEED +11 NTCIP Class A +12 Banner DXM +13 Vicon PTZ +14 SmartSensor 125 HD +15 OSi ORG-815 +16 Infinova D PTZ +17 RTMS G4 +18 RTMS G4 vlog +19 SmartSensor 125 vlog +20 Natch +21 PeMS +22 SSI +23 CHP Incidents +24 NDOT Beacon +25 DLI DIN Relay +26 Axis 292 +27 Axis PTZ +28 HySecurity STC +29 Cohu PTZ +30 DR-500 +31 ADDCO +32 TransCore E6 +33 CBW +34 Incident Feed +35 MonStream +36 Gate NDORv5 +37 GPS TAIP +38 SierraGX +39 GPS RedLion +40 Cohu Helios PTZ +41 Streambed +42 CAP Feed +43 ClearGuide +44 GPS Digi WR +45 ONVIF PTZ +\. + +CREATE TABLE iris.comm_config ( + name VARCHAR(10) PRIMARY KEY, + description VARCHAR(20) NOT NULL UNIQUE, + protocol SMALLINT NOT NULL REFERENCES iris.comm_protocol(id), + timeout_ms INTEGER NOT NULL, + retry_threshold INTEGER NOT NULL, + poll_period_sec INTEGER NOT NULL, + long_poll_period_sec INTEGER NOT NULL, + idle_disconnect_sec INTEGER NOT NULL, + no_response_disconnect_sec INTEGER NOT NULL +); + +ALTER TABLE iris.comm_config + ADD CONSTRAINT retry_threshold_ck + CHECK (retry_threshold >= 0 AND retry_threshold <= 8); + +ALTER TABLE iris.comm_config + ADD CONSTRAINT poll_period_ck + CHECK (poll_period_sec >= 5 AND long_poll_period_sec >= poll_period_sec); + +INSERT INTO iris.comm_config ( + name, description, protocol, timeout_ms, retry_threshold, poll_period_sec, + long_poll_period_sec, idle_disconnect_sec, no_response_disconnect_sec +) VALUES ( + 'cfg_0', 'NTCIP udp', 11, 1000, 3, 30, 300, 0, 0 +); + +CREATE TRIGGER comm_config_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.comm_config + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW comm_config_view AS + SELECT cc.name, cc.description, cp.description AS protocol, + timeout_ms, retry_threshold, poll_period_sec, long_poll_period_sec, + idle_disconnect_sec, no_response_disconnect_sec + FROM iris.comm_config cc + JOIN iris.comm_protocol cp ON cc.protocol = cp.id; +GRANT SELECT ON comm_config_view TO PUBLIC; + +CREATE TABLE iris.comm_link ( + name VARCHAR(20) PRIMARY KEY, + description VARCHAR(32) NOT NULL, + uri VARCHAR(256) NOT NULL, + poll_enabled BOOLEAN NOT NULL, + comm_config VARCHAR(10) NOT NULL REFERENCES iris.comm_config, + connected BOOLEAN NOT NULL +); + +CREATE FUNCTION iris.comm_link_notify() RETURNS TRIGGER AS + $comm_link_notify$ +BEGIN + -- all attributes are primary + NOTIFY comm_link; + RETURN NULL; -- AFTER trigger return is ignored +END; +$comm_link_notify$ LANGUAGE plpgsql; + +CREATE TRIGGER comm_link_notify_trig + AFTER UPDATE ON iris.comm_link + FOR EACH ROW EXECUTE FUNCTION iris.comm_link_notify(); + +CREATE TRIGGER comm_link_table_notify_trig + AFTER INSERT OR DELETE ON iris.comm_link + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW comm_link_view AS + SELECT cl.name, cl.description, uri, poll_enabled, + cp.description AS protocol, cc.description AS comm_config, + timeout_ms, poll_period_sec, connected + FROM iris.comm_link cl + JOIN iris.comm_config cc ON cl.comm_config = cc.name + JOIN iris.comm_protocol cp ON cc.protocol = cp.id; +GRANT SELECT ON comm_link_view TO PUBLIC; + +CREATE TABLE iris.modem ( + name VARCHAR(20) PRIMARY KEY, + uri VARCHAR(64) NOT NULL, + config VARCHAR(64) NOT NULL, + timeout_ms INTEGER NOT NULL, + enabled BOOLEAN NOT NULL +); + +CREATE TRIGGER modem_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.modem + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW modem_view AS + SELECT name, uri, config, timeout_ms, enabled + FROM iris.modem; +GRANT SELECT ON modem_view TO PUBLIC; + +CREATE TABLE iris.cabinet_style ( + name VARCHAR(20) PRIMARY KEY, + police_panel_pin_1 INTEGER, + police_panel_pin_2 INTEGER, + watchdog_reset_pin_1 INTEGER, + watchdog_reset_pin_2 INTEGER, + dip INTEGER +); + +CREATE TRIGGER cabinet_style_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.cabinet_style + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW cabinet_style_view AS + SELECT name, police_panel_pin_1, police_panel_pin_2, + watchdog_reset_pin_1, watchdog_reset_pin_2, dip + FROM iris.cabinet_style; +GRANT SELECT ON cabinet_style_view TO PUBLIC; + +CREATE TABLE iris.condition ( + id INTEGER PRIMARY KEY, + description VARCHAR(12) NOT NULL +); + +COPY iris.condition (id, description) FROM stdin; +0 Planned +1 Active +2 Construction +3 Removed +4 Testing +\. + +CREATE TABLE iris.controller ( + name VARCHAR(20) PRIMARY KEY, + drop_id SMALLINT NOT NULL, + comm_link VARCHAR(20) REFERENCES iris.comm_link(name), + cabinet_style VARCHAR(20) REFERENCES iris.cabinet_style(name), + geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), + condition INTEGER NOT NULL REFERENCES iris.condition, + notes VARCHAR CHECK (LENGTH(notes) < 256), + password VARCHAR(32), + setup JSONB, + fail_time TIMESTAMP WITH time zone +); + +CREATE UNIQUE INDEX ctrl_link_drop_idx ON iris.controller + USING btree (comm_link, drop_id); + +CREATE FUNCTION iris.controller_notify() RETURNS TRIGGER AS + $controller_notify$ +BEGIN + IF (NEW.drop_id IS DISTINCT FROM OLD.drop_id) OR + (NEW.comm_link IS DISTINCT FROM OLD.comm_link) OR + (NEW.cabinet_style IS DISTINCT FROM OLD.cabinet_style) OR + (NEW.condition IS DISTINCT FROM OLD.condition) OR + (NEW.notes IS DISTINCT FROM OLD.notes) OR + (NEW.setup IS DISTINCT FROM OLD.setup) OR + (NEW.fail_time IS DISTINCT FROM OLD.fail_time) + THEN + NOTIFY controller; + ELSE + PERFORM pg_notify('controller', NEW.name); + END IF; + RETURN NULL; -- AFTER trigger return is ignored +END; +$controller_notify$ LANGUAGE plpgsql; + +CREATE TRIGGER controller_notify_trig + AFTER UPDATE ON iris.controller + FOR EACH ROW EXECUTE FUNCTION iris.controller_notify(); + +CREATE TRIGGER controller_table_notify_trig + AFTER INSERT OR DELETE ON iris.controller + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); + +CREATE VIEW controller_view AS + SELECT c.name, drop_id, comm_link, cabinet_style, geo_loc, + cnd.description AS condition, notes, setup, fail_time + FROM iris.controller c + LEFT JOIN iris.condition cnd ON c.condition = cnd.id; +GRANT SELECT ON controller_view TO PUBLIC; + +CREATE VIEW controller_loc_view AS + SELECT c.name, drop_id, comm_link, cabinet_style, condition, c.notes, + l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir + FROM controller_view c + LEFT JOIN geo_loc_view l ON c.geo_loc = l.name; +GRANT SELECT ON controller_loc_view TO PUBLIC; + +CREATE TABLE event.comm_event ( + event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), + controller VARCHAR(20) NOT NULL REFERENCES iris.controller(name) + ON DELETE CASCADE, + device_id VARCHAR(20) +); + +-- DELETE of iris.controller *very* slow without this index +CREATE INDEX ON event.comm_event (controller); + +CREATE VIEW comm_event_view AS + SELECT e.event_id, e.event_date, ed.description, e.controller, + c.comm_link, c.drop_id + FROM event.comm_event e + JOIN event.event_description ed ON e.event_desc_id = ed.event_desc_id + LEFT JOIN iris.controller c ON e.controller = c.name; +GRANT SELECT ON comm_event_view TO PUBLIC; + +CREATE TABLE iris.controller_io ( + name VARCHAR(20) PRIMARY KEY, + resource_n VARCHAR(16) NOT NULL REFERENCES iris.resource_type, + controller VARCHAR(20) REFERENCES iris.controller, + pin INTEGER NOT NULL, + UNIQUE (controller, pin) +); + +CREATE FUNCTION iris.controller_io_notify() RETURNS TRIGGER AS + $controller_io_notify$ +BEGIN + -- controller is primary; pin is secondary + IF (NEW.controller IS DISTINCT FROM OLD.controller) THEN + PERFORM pg_notify(NEW.resource_n, ''); + ELSIF (NEW.pin IS DISTINCT FROM OLD.pin) THEN + PERFORM pg_notify(NEW.resource_n, NEW.name); + END IF; + RETURN NULL; -- AFTER trigger return is ignored +END; +$controller_io_notify$ LANGUAGE plpgsql; + +CREATE TRIGGER controller_io_notify_trig + AFTER UPDATE ON iris.controller_io + FOR EACH ROW EXECUTE FUNCTION iris.controller_io_notify(); + +CREATE FUNCTION iris.controller_io_delete() RETURNS TRIGGER AS + $controller_io_delete$ +BEGIN + DELETE FROM iris.device_preset WHERE name = OLD.name; + DELETE FROM iris.controller_io WHERE name = OLD.name; + IF FOUND THEN + RETURN OLD; + ELSE + RETURN NULL; + END IF; +END; +$controller_io_delete$ LANGUAGE plpgsql; + +CREATE VIEW controller_io_view AS + SELECT name, resource_n, controller, pin + FROM iris.controller_io; +GRANT SELECT ON controller_io_view TO PUBLIC; + +-- +-- R_Node, Detectors +-- +CREATE TABLE iris.r_node_type ( + n_type INTEGER PRIMARY KEY, + name VARCHAR(12) NOT NULL +); + +COPY iris.r_node_type (n_type, name) FROM stdin; +0 station +1 entrance +2 exit +3 intersection +4 access +5 interchange \. -CREATE TABLE iris.plan_phase ( - name VARCHAR(12) PRIMARY KEY, - hold_time INTEGER NOT NULL, - next_phase VARCHAR(12) REFERENCES iris.plan_phase +CREATE TABLE iris.r_node_transition ( + n_transition INTEGER PRIMARY KEY, + name VARCHAR(12) NOT NULL ); -COPY iris.plan_phase (name, hold_time, next_phase) FROM stdin; -deployed 0 \N -undeployed 0 \N -alert_before 0 \N -alert_during 0 \N -alert_after 0 \N -ga_open 0 \N -ga_closed 0 \N +COPY iris.r_node_transition (n_transition, name) FROM stdin; +0 none +1 loop +2 leg +3 slipramp +4 CD +5 HOV +6 common +7 flyover \. -CREATE TABLE iris.action_plan ( - name VARCHAR(16) PRIMARY KEY, - notes VARCHAR CHECK (LENGTH(notes) < 256), - sync_actions BOOLEAN NOT NULL, - sticky BOOLEAN NOT NULL, - ignore_auto_fail BOOLEAN NOT NULL, +CREATE TABLE iris.r_node ( + name VARCHAR(10) PRIMARY KEY, + geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), + node_type INTEGER NOT NULL REFERENCES iris.r_node_type, + pickable BOOLEAN NOT NULL, + above BOOLEAN NOT NULL, + transition INTEGER NOT NULL REFERENCES iris.r_node_transition, + lanes INTEGER NOT NULL, + attach_side BOOLEAN NOT NULL, + shift INTEGER NOT NULL, active BOOLEAN NOT NULL, - default_phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, - phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase + station_id VARCHAR(10), + speed_limit INTEGER NOT NULL, + notes VARCHAR(160) ); -CREATE TRIGGER action_plan_hashtag_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.action_plan - FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('action_plan'); +CREATE UNIQUE INDEX r_node_station_idx ON iris.r_node USING btree (station_id); -CREATE VIEW action_plan_view AS - SELECT name, notes, sync_actions, sticky, ignore_auto_fail, active, - default_phase, phase - FROM iris.action_plan; -GRANT SELECT ON action_plan_view TO PUBLIC; +CREATE FUNCTION iris.r_node_notify() RETURNS TRIGGER AS + $r_node_notify$ +BEGIN + IF (TG_OP = 'DELETE') THEN + PERFORM pg_notify('r_node', OLD.name); + ELSE + PERFORM pg_notify('r_node', NEW.name); + END IF; + RETURN NULL; -- AFTER trigger return is ignored +END; +$r_node_notify$ LANGUAGE plpgsql; -CREATE TABLE iris.time_action ( - name VARCHAR(30) PRIMARY KEY, - action_plan VARCHAR(16) NOT NULL REFERENCES iris.action_plan, - day_plan VARCHAR(10) REFERENCES iris.day_plan, - sched_date DATE, - time_of_day TIME WITHOUT TIME ZONE NOT NULL, - phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, - CONSTRAINT time_action_date CHECK ( - ((day_plan IS NULL) OR (sched_date IS NULL)) AND - ((day_plan IS NOT NULL) OR (sched_date IS NOT NULL)) - ) -); +CREATE TRIGGER r_node_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.r_node + FOR EACH ROW EXECUTE FUNCTION iris.r_node_notify(); + +CREATE FUNCTION iris.r_node_left(INTEGER, INTEGER, BOOLEAN, INTEGER) + RETURNS INTEGER AS $r_node_left$ +DECLARE + node_type ALIAS FOR $1; + lanes ALIAS FOR $2; + attach_side ALIAS FOR $3; + shift ALIAS FOR $4; +BEGIN + IF attach_side = TRUE THEN + RETURN shift; + END IF; + IF node_type = 0 THEN + RETURN shift - lanes; + END IF; + RETURN shift; +END; +$r_node_left$ LANGUAGE plpgsql; + +CREATE FUNCTION iris.r_node_right(INTEGER, INTEGER, BOOLEAN, INTEGER) + RETURNS INTEGER AS $r_node_right$ +DECLARE + node_type ALIAS FOR $1; + lanes ALIAS FOR $2; + attach_side ALIAS FOR $3; + shift ALIAS FOR $4; +BEGIN + IF attach_side = FALSE THEN + RETURN shift; + END IF; + IF node_type = 0 THEN + RETURN shift + lanes; + END IF; + RETURN shift; +END; +$r_node_right$ LANGUAGE plpgsql; + +ALTER TABLE iris.r_node ADD CONSTRAINT left_edge_ck + CHECK (iris.r_node_left(node_type, lanes, attach_side, shift) >= 1); +ALTER TABLE iris.r_node ADD CONSTRAINT right_edge_ck + CHECK (iris.r_node_right(node_type, lanes, attach_side, shift) <= 9); + +CREATE VIEW r_node_view AS + SELECT n.name, n.geo_loc, + l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir, + l.landmark, l.lat, l.lon, l.corridor, l.location, + nt.name AS node_type, n.pickable, n.above, tr.name AS transition, + n.lanes, n.attach_side, n.shift, n.active, + n.station_id, n.speed_limit, n.notes + FROM iris.r_node n + JOIN geo_loc_view l ON n.geo_loc = l.name + JOIN iris.r_node_type nt ON n.node_type = nt.n_type + JOIN iris.r_node_transition tr ON n.transition = tr.n_transition; +GRANT SELECT ON r_node_view TO PUBLIC; -CREATE VIEW time_action_view AS - SELECT name, action_plan, day_plan, sched_date, time_of_day, phase - FROM iris.time_action; -GRANT SELECT ON time_action_view TO PUBLIC; +CREATE VIEW roadway_station_view AS + SELECT station_id, roadway, road_dir, cross_mod, cross_street, active, + speed_limit + FROM iris.r_node r, geo_loc_view l + WHERE r.geo_loc = l.name AND station_id IS NOT NULL; +GRANT SELECT ON roadway_station_view TO PUBLIC; -CREATE TABLE event.action_plan_event ( - id SERIAL PRIMARY KEY, - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc INTEGER NOT NULL REFERENCES event.event_description, - action_plan VARCHAR(16) NOT NULL, - phase VARCHAR(12), - user_id VARCHAR(15) +CREATE TABLE iris._detector ( + name VARCHAR(20) PRIMARY KEY, + r_node VARCHAR(10) NOT NULL REFERENCES iris.r_node(name), + lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, + lane_number SMALLINT NOT NULL, + abandoned BOOLEAN NOT NULL, + force_fail BOOLEAN NOT NULL, + auto_fail BOOLEAN NOT NULL, + field_length REAL NOT NULL, + fake VARCHAR(32), + notes VARCHAR(32) ); -CREATE VIEW action_plan_event_view AS - SELECT ev.id, event_date, ed.description, action_plan, phase, user_id - FROM event.action_plan_event ev - JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; -GRANT SELECT ON action_plan_event_view TO PUBLIC; +ALTER TABLE iris._detector ADD CONSTRAINT _detector_fkey + FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; --- --- Comm Protocols, Comm Links, Modems, Cabinets, Controllers --- -CREATE TABLE iris.comm_protocol ( - id SMALLINT PRIMARY KEY, - description VARCHAR(20) NOT NULL -); +CREATE FUNCTION iris.detector_notify() RETURNS TRIGGER AS + $detector_notify$ +BEGIN + -- lane_code, lane_number and abandoned are secondary, but affect label + IF (NEW.notes IS DISTINCT FROM OLD.notes) OR + (NEW.lane_code IS DISTINCT FROM OLD.lane_code) OR + (NEW.lane_number IS DISTINCT FROM OLD.lane_number) OR + (NEW.abandoned IS DISTINCT FROM OLD.abandoned) + THEN + NOTIFY detector; + ELSE + PERFORM pg_notify('detector', NEW.name); + END IF; + RETURN NULL; -- AFTER trigger return is ignored +END; +$detector_notify$ LANGUAGE plpgsql; -COPY iris.comm_protocol (id, description) FROM stdin; -0 NTCIP Class B -1 MnDOT 170 (4-bit) -2 MnDOT 170 (5-bit) -3 SmartSensor 105 -4 Canoga -5 Pelco P -6 Pelco D PTZ -7 NTCIP Class C -8 Manchester PTZ -9 DMS XML -10 MSG_FEED -11 NTCIP Class A -12 Banner DXM -13 Vicon PTZ -14 SmartSensor 125 HD -15 OSi ORG-815 -16 Infinova D PTZ -17 RTMS G4 -18 RTMS G4 vlog -19 SmartSensor 125 vlog -20 Natch -21 PeMS -22 SSI -23 CHP Incidents -24 NDOT Beacon -25 DLI DIN Relay -26 Axis 292 -27 Axis PTZ -28 HySecurity STC -29 Cohu PTZ -30 DR-500 -31 ADDCO -32 TransCore E6 -33 CBW -34 Incident Feed -35 MonStream -36 Gate NDORv5 -37 GPS TAIP -38 SierraGX -39 GPS RedLion -40 Cohu Helios PTZ -41 Streambed -42 CAP Feed -43 ClearGuide -44 GPS Digi WR -45 ONVIF PTZ -\. +CREATE TRIGGER detector_notify_trig + AFTER UPDATE ON iris._detector + FOR EACH ROW EXECUTE FUNCTION iris.detector_notify(); -CREATE TABLE iris.comm_config ( - name VARCHAR(10) PRIMARY KEY, - description VARCHAR(20) NOT NULL UNIQUE, - protocol SMALLINT NOT NULL REFERENCES iris.comm_protocol(id), - timeout_ms INTEGER NOT NULL, - retry_threshold INTEGER NOT NULL, - poll_period_sec INTEGER NOT NULL, - long_poll_period_sec INTEGER NOT NULL, - idle_disconnect_sec INTEGER NOT NULL, - no_response_disconnect_sec INTEGER NOT NULL -); +CREATE TRIGGER detector_table_notify_trig + AFTER INSERT OR DELETE ON iris._detector + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -ALTER TABLE iris.comm_config - ADD CONSTRAINT retry_threshold_ck - CHECK (retry_threshold >= 0 AND retry_threshold <= 8); +CREATE VIEW iris.detector AS + SELECT d.name, controller, pin, r_node, lane_code, lane_number, + abandoned, force_fail, auto_fail, field_length, fake, notes + FROM iris._detector d + JOIN iris.controller_io cio ON d.name = cio.name; -ALTER TABLE iris.comm_config - ADD CONSTRAINT poll_period_ck - CHECK (poll_period_sec >= 5 AND long_poll_period_sec >= poll_period_sec); +CREATE FUNCTION iris.detector_insert() RETURNS TRIGGER AS + $detector_insert$ +BEGIN + INSERT INTO iris.controller_io (name, resource_n, controller, pin) + VALUES (NEW.name, 'detector', NEW.controller, NEW.pin); + INSERT INTO iris._detector ( + name, r_node, lane_code, lane_number, abandoned, force_fail, auto_fail, + field_length, fake, notes + ) VALUES ( + NEW.name, NEW.r_node, NEW.lane_code, NEW.lane_number, NEW.abandoned, + NEW.force_fail, NEW.auto_fail, NEW.field_length, NEW.fake, NEW.notes + ); + RETURN NEW; +END; +$detector_insert$ LANGUAGE plpgsql; -INSERT INTO iris.comm_config ( - name, description, protocol, timeout_ms, retry_threshold, poll_period_sec, - long_poll_period_sec, idle_disconnect_sec, no_response_disconnect_sec -) VALUES ( - 'cfg_0', 'NTCIP udp', 11, 1000, 3, 30, 300, 0, 0 -); +CREATE TRIGGER detector_insert_trig + INSTEAD OF INSERT ON iris.detector + FOR EACH ROW EXECUTE FUNCTION iris.detector_insert(); -CREATE TRIGGER comm_config_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.comm_config - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +CREATE FUNCTION iris.detector_update() RETURNS TRIGGER AS + $detector_update$ +BEGIN + UPDATE iris.controller_io + SET controller = NEW.controller, + pin = NEW.pin + WHERE name = OLD.name; + UPDATE iris._detector + SET r_node = NEW.r_node, + lane_code = NEW.lane_code, + lane_number = NEW.lane_number, + abandoned = NEW.abandoned, + force_fail = NEW.force_fail, + auto_fail = NEW.auto_fail, + field_length = NEW.field_length, + fake = NEW.fake, + notes = NEW.notes + WHERE name = OLD.name; + RETURN NEW; +END; +$detector_update$ LANGUAGE plpgsql; -CREATE VIEW comm_config_view AS - SELECT cc.name, cc.description, cp.description AS protocol, - timeout_ms, retry_threshold, poll_period_sec, long_poll_period_sec, - idle_disconnect_sec, no_response_disconnect_sec - FROM iris.comm_config cc - JOIN iris.comm_protocol cp ON cc.protocol = cp.id; -GRANT SELECT ON comm_config_view TO PUBLIC; +CREATE TRIGGER detector_update_trig + INSTEAD OF UPDATE ON iris.detector + FOR EACH ROW EXECUTE FUNCTION iris.detector_update(); -CREATE TABLE iris.comm_link ( - name VARCHAR(20) PRIMARY KEY, - description VARCHAR(32) NOT NULL, - uri VARCHAR(256) NOT NULL, - poll_enabled BOOLEAN NOT NULL, - comm_config VARCHAR(10) NOT NULL REFERENCES iris.comm_config, - connected BOOLEAN NOT NULL -); +CREATE TRIGGER detector_delete_trig + INSTEAD OF DELETE ON iris.detector + FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); -CREATE FUNCTION iris.comm_link_notify() RETURNS TRIGGER AS - $comm_link_notify$ +CREATE FUNCTION iris.landmark_abbrev(VARCHAR(24)) RETURNS TEXT + AS $landmark_abbrev$ +DECLARE + lmrk TEXT; + lmrk2 TEXT; +BEGIN + lmrk = initcap($1); + -- Replace common words + lmrk = replace(lmrk, 'Of ', ''); + lmrk = replace(lmrk, 'Miles', 'MI'); + lmrk = replace(lmrk, 'Mile', 'MI'); + -- Remove whitespace and non-printable characters + lmrk = regexp_replace(lmrk, '[^[:graph:]]', '', 'g'); + IF length(lmrk) > 6 THEN + -- Remove lower-case vowels + lmrk = regexp_replace(lmrk, '[aeiouy]', '', 'g'); + END IF; + IF length(lmrk) > 6 THEN + -- Remove all punctuation + lmrk = regexp_replace(lmrk, '[[:punct:]]', '', 'g'); + END IF; + lmrk2 = lmrk; + IF length(lmrk) > 6 THEN + -- Remove letters + lmrk = regexp_replace(lmrk, '[[:alpha:]]', '', 'g'); + END IF; + IF length(lmrk) > 0 THEN + RETURN left(lmrk, 6); + ELSE + RETURN left(lmrk2, 6); + END IF; +END; +$landmark_abbrev$ LANGUAGE plpgsql; + +CREATE FUNCTION iris.root_lbl(rd VARCHAR(6), rdir VARCHAR(4), xst VARCHAR(6), + xdir VARCHAR(4), xmod VARCHAR(2), lmark VARCHAR(24)) RETURNS TEXT AS +$$ + SELECT rd || '/' || COALESCE( + xdir || replace(xmod, '@', '') || xst, + iris.landmark_abbrev(lmark) + ) || rdir; +$$ LANGUAGE sql SECURITY DEFINER; + +ALTER FUNCTION iris.root_lbl(VARCHAR(6), VARCHAR(4), VARCHAR(6), VARCHAR(4), + VARCHAR(2), VARCHAR(24) +) + SET search_path = pg_catalog, pg_temp; + +CREATE FUNCTION iris.detector_label(TEXT, CHAR, SMALLINT, BOOLEAN) RETURNS TEXT + AS $detector_label$ +DECLARE + root ALIAS FOR $1; + lcode ALIAS FOR $2; + lane_number ALIAS FOR $3; + abandoned ALIAS FOR $4; + lnum VARCHAR(2); + suffix VARCHAR(5); BEGIN - -- all attributes are primary - NOTIFY comm_link; - RETURN NULL; -- AFTER trigger return is ignored + lnum = ''; + IF lane_number > 0 THEN + lnum = TO_CHAR(lane_number, 'FM9'); + END IF; + suffix = ''; + IF abandoned THEN + suffix = '-ABND'; + END IF; + RETURN COALESCE( + root || lcode || lnum || suffix, + 'FUTURE' + ); END; -$comm_link_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER comm_link_notify_trig - AFTER UPDATE ON iris.comm_link - FOR EACH ROW EXECUTE FUNCTION iris.comm_link_notify(); - -CREATE TRIGGER comm_link_table_notify_trig - AFTER INSERT OR DELETE ON iris.comm_link - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +$detector_label$ LANGUAGE plpgsql; -CREATE VIEW comm_link_view AS - SELECT cl.name, cl.description, uri, poll_enabled, - cp.description AS protocol, cc.description AS comm_config, - timeout_ms, poll_period_sec, connected - FROM iris.comm_link cl - JOIN iris.comm_config cc ON cl.comm_config = cc.name - JOIN iris.comm_protocol cp ON cc.protocol = cp.id; -GRANT SELECT ON comm_link_view TO PUBLIC; +CREATE VIEW detector_label_view AS + SELECT d.name AS det_id, + iris.detector_label( + iris.root_lbl(l.rd, l.rdir, l.xst, l.cross_dir, l.xmod, l.landmark), + d.lane_code, d.lane_number, d.abandoned + ) AS label, rnd.geo_loc + FROM iris._detector d + LEFT JOIN iris.r_node rnd ON d.r_node = rnd.name + LEFT JOIN geo_loc_view l ON rnd.geo_loc = l.name; +GRANT SELECT ON detector_label_view TO PUBLIC; -CREATE TABLE iris.modem ( - name VARCHAR(20) PRIMARY KEY, - uri VARCHAR(64) NOT NULL, - config VARCHAR(64) NOT NULL, - timeout_ms INTEGER NOT NULL, - enabled BOOLEAN NOT NULL +CREATE TABLE event.detector_event ( + event_id INTEGER DEFAULT nextval('event.event_id_seq') NOT NULL, + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), + device_id VARCHAR(20) REFERENCES iris._detector(name) ON DELETE CASCADE ); -CREATE TRIGGER modem_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.modem - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW modem_view AS - SELECT name, uri, config, timeout_ms, enabled - FROM iris.modem; -GRANT SELECT ON modem_view TO PUBLIC; - -CREATE TABLE iris.cabinet_style ( - name VARCHAR(20) PRIMARY KEY, - police_panel_pin_1 INTEGER, - police_panel_pin_2 INTEGER, - watchdog_reset_pin_1 INTEGER, - watchdog_reset_pin_2 INTEGER, - dip INTEGER -); +CREATE VIEW detector_view AS + SELECT d.name, d.r_node, c.comm_link, c.drop_id, cio.controller, cio.pin, + dl.label, dl.geo_loc, l.rd || '_' || l.road_dir AS cor_id, + l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir, + d.lane_number, d.field_length, lc.description AS lane_type, + d.lane_code, d.abandoned, d.force_fail, d.auto_fail, c.condition, + d.fake, d.notes + FROM iris.detector d + JOIN iris.controller_io cio ON d.name = cio.name + LEFT JOIN detector_label_view dl ON d.name = dl.det_id + LEFT JOIN geo_loc_view l ON dl.geo_loc = l.name + LEFT JOIN iris.lane_code lc ON d.lane_code = lc.lcode + LEFT JOIN controller_view c ON cio.controller = c.name; +GRANT SELECT ON detector_view TO PUBLIC; -CREATE TRIGGER cabinet_style_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.cabinet_style - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +CREATE VIEW detector_event_view AS + SELECT e.event_id, e.event_date, ed.description, e.device_id, dl.label + FROM event.detector_event e + JOIN event.event_description ed ON e.event_desc_id = ed.event_desc_id + JOIN detector_label_view dl ON e.device_id = dl.det_id; +GRANT SELECT ON detector_event_view TO PUBLIC; -CREATE VIEW cabinet_style_view AS - SELECT name, police_panel_pin_1, police_panel_pin_2, - watchdog_reset_pin_1, watchdog_reset_pin_2, dip - FROM iris.cabinet_style; -GRANT SELECT ON cabinet_style_view TO PUBLIC; +CREATE VIEW detector_auto_fail_view AS + WITH af AS (SELECT device_id, event_desc_id, count(*) AS event_count, + max(event_date) AS last_fail + FROM event.detector_event + GROUP BY device_id, event_desc_id) + SELECT device_id, label, ed.description, event_count, last_fail + FROM af + JOIN event.event_description ed ON af.event_desc_id = ed.event_desc_id + JOIN detector_label_view dl ON af.device_id = dl.det_id; +GRANT SELECT ON detector_auto_fail_view TO PUBLIC; -CREATE TABLE iris.condition ( - id INTEGER PRIMARY KEY, - description VARCHAR(12) NOT NULL +-- +-- Day Matchers, Day Plans, Plan Phases, Action Plans and Time Actions +-- +CREATE TABLE iris.day_matcher ( + name VARCHAR(32) PRIMARY KEY, + holiday BOOLEAN NOT NULL, + month INTEGER NOT NULL, + day INTEGER NOT NULL, + week INTEGER NOT NULL, + weekday INTEGER NOT NULL, + shift INTEGER NOT NULL ); -COPY iris.condition (id, description) FROM stdin; -0 Planned -1 Active -2 Construction -3 Removed -4 Testing +COPY iris.day_matcher (name, holiday, month, day, week, weekday, shift) FROM stdin; +Any Day f -1 0 0 0 0 +Sunday Holiday t -1 0 0 1 0 +Saturday Holiday t -1 0 0 7 0 +New Years Day t 0 1 0 0 0 +Memorial Day t 4 0 -1 2 0 +Independence Day t 6 4 0 0 0 +Labor Day t 8 0 1 2 0 +Thanksgiving Day t 10 0 4 5 0 +Black Friday t 10 0 4 5 1 +Christmas Eve t 11 24 0 0 0 +Christmas Day t 11 25 0 0 0 +New Years Eve t 11 31 0 0 0 \. -CREATE TABLE iris.controller ( - name VARCHAR(20) PRIMARY KEY, - drop_id SMALLINT NOT NULL, - comm_link VARCHAR(20) REFERENCES iris.comm_link(name), - cabinet_style VARCHAR(20) REFERENCES iris.cabinet_style(name), - geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), - condition INTEGER NOT NULL REFERENCES iris.condition, - notes VARCHAR CHECK (LENGTH(notes) < 256), - password VARCHAR(32), - setup JSONB, - fail_time TIMESTAMP WITH time zone +CREATE TABLE iris.day_plan ( + name VARCHAR(10) PRIMARY KEY ); -CREATE UNIQUE INDEX ctrl_link_drop_idx ON iris.controller - USING btree (comm_link, drop_id); - -CREATE FUNCTION iris.controller_notify() RETURNS TRIGGER AS - $controller_notify$ -BEGIN - IF (NEW.drop_id IS DISTINCT FROM OLD.drop_id) OR - (NEW.comm_link IS DISTINCT FROM OLD.comm_link) OR - (NEW.cabinet_style IS DISTINCT FROM OLD.cabinet_style) OR - (NEW.condition IS DISTINCT FROM OLD.condition) OR - (NEW.notes IS DISTINCT FROM OLD.notes) OR - (NEW.setup IS DISTINCT FROM OLD.setup) OR - (NEW.fail_time IS DISTINCT FROM OLD.fail_time) - THEN - NOTIFY controller; - ELSE - PERFORM pg_notify('controller', NEW.name); - END IF; - RETURN NULL; -- AFTER trigger return is ignored -END; -$controller_notify$ LANGUAGE plpgsql; +COPY iris.day_plan (name) FROM stdin; +EVERY_DAY +WEEKDAYS +WORK_DAYS +\. -CREATE TRIGGER controller_notify_trig - AFTER UPDATE ON iris.controller - FOR EACH ROW EXECUTE FUNCTION iris.controller_notify(); +CREATE TABLE iris.day_plan_day_matcher ( + day_plan VARCHAR(10) NOT NULL REFERENCES iris.day_plan, + day_matcher VARCHAR(32) NOT NULL REFERENCES iris.day_matcher +); +ALTER TABLE iris.day_plan_day_matcher ADD PRIMARY KEY (day_plan, day_matcher); -CREATE TRIGGER controller_table_notify_trig - AFTER INSERT OR DELETE ON iris.controller - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +COPY iris.day_plan_day_matcher (day_plan, day_matcher) FROM stdin; +EVERY_DAY Any Day +WEEKDAYS Any Day +WEEKDAYS Sunday Holiday +WEEKDAYS Saturday Holiday +WORK_DAYS Any Day +WORK_DAYS Sunday Holiday +WORK_DAYS Saturday Holiday +WORK_DAYS New Years Day +WORK_DAYS Memorial Day +WORK_DAYS Independence Day +WORK_DAYS Labor Day +WORK_DAYS Thanksgiving Day +WORK_DAYS Black Friday +WORK_DAYS Christmas Eve +WORK_DAYS Christmas Day +WORK_DAYS New Years Eve +\. -CREATE VIEW controller_view AS - SELECT c.name, drop_id, comm_link, cabinet_style, geo_loc, - cnd.description AS condition, notes, setup, fail_time - FROM iris.controller c - LEFT JOIN iris.condition cnd ON c.condition = cnd.id; -GRANT SELECT ON controller_view TO PUBLIC; +CREATE TABLE iris.plan_phase ( + name VARCHAR(12) PRIMARY KEY, + hold_time INTEGER NOT NULL, + next_phase VARCHAR(12) REFERENCES iris.plan_phase +); -CREATE VIEW controller_loc_view AS - SELECT c.name, drop_id, comm_link, cabinet_style, condition, c.notes, - l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir - FROM controller_view c - LEFT JOIN geo_loc_view l ON c.geo_loc = l.name; -GRANT SELECT ON controller_loc_view TO PUBLIC; +COPY iris.plan_phase (name, hold_time, next_phase) FROM stdin; +deployed 0 \N +undeployed 0 \N +alert_before 0 \N +alert_during 0 \N +alert_after 0 \N +ga_open 0 \N +ga_closed 0 \N +\. -CREATE TABLE event.comm_event ( - event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - controller VARCHAR(20) NOT NULL REFERENCES iris.controller(name) - ON DELETE CASCADE, - device_id VARCHAR(20) +CREATE TABLE iris.action_plan ( + name VARCHAR(16) PRIMARY KEY, + notes VARCHAR CHECK (LENGTH(notes) < 256), + sync_actions BOOLEAN NOT NULL, + sticky BOOLEAN NOT NULL, + ignore_auto_fail BOOLEAN NOT NULL, + active BOOLEAN NOT NULL, + default_phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, + phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase ); --- DELETE of iris.controller *very* slow without this index -CREATE INDEX ON event.comm_event (controller); +CREATE TRIGGER action_plan_hashtag_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.action_plan + FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('action_plan'); -CREATE VIEW comm_event_view AS - SELECT e.event_id, e.event_date, ed.description, e.controller, - c.comm_link, c.drop_id - FROM event.comm_event e - JOIN event.event_description ed ON e.event_desc_id = ed.event_desc_id - LEFT JOIN iris.controller c ON e.controller = c.name; -GRANT SELECT ON comm_event_view TO PUBLIC; +CREATE VIEW action_plan_view AS + SELECT name, notes, sync_actions, sticky, ignore_auto_fail, active, + default_phase, phase + FROM iris.action_plan; +GRANT SELECT ON action_plan_view TO PUBLIC; -CREATE TABLE iris.controller_io ( - name VARCHAR(20) PRIMARY KEY, - resource_n VARCHAR(16) NOT NULL REFERENCES iris.resource_type, - controller VARCHAR(20) REFERENCES iris.controller, - pin INTEGER NOT NULL, - UNIQUE (controller, pin) +CREATE TABLE iris.time_action ( + name VARCHAR(30) PRIMARY KEY, + action_plan VARCHAR(16) NOT NULL REFERENCES iris.action_plan, + day_plan VARCHAR(10) REFERENCES iris.day_plan, + sched_date DATE, + time_of_day TIME WITHOUT TIME ZONE NOT NULL, + phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, + CONSTRAINT time_action_date CHECK ( + ((day_plan IS NULL) OR (sched_date IS NULL)) AND + ((day_plan IS NOT NULL) OR (sched_date IS NOT NULL)) + ) ); -CREATE FUNCTION iris.controller_io_notify() RETURNS TRIGGER AS - $controller_io_notify$ -BEGIN - -- controller is primary; pin is secondary - IF (NEW.controller IS DISTINCT FROM OLD.controller) THEN - PERFORM pg_notify(NEW.resource_n, ''); - ELSIF (NEW.pin IS DISTINCT FROM OLD.pin) THEN - PERFORM pg_notify(NEW.resource_n, NEW.name); - END IF; - RETURN NULL; -- AFTER trigger return is ignored -END; -$controller_io_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER controller_io_notify_trig - AFTER UPDATE ON iris.controller_io - FOR EACH ROW EXECUTE FUNCTION iris.controller_io_notify(); +CREATE VIEW time_action_view AS + SELECT name, action_plan, day_plan, sched_date, time_of_day, phase + FROM iris.time_action; +GRANT SELECT ON time_action_view TO PUBLIC; -CREATE FUNCTION iris.controller_io_delete() RETURNS TRIGGER AS - $controller_io_delete$ -BEGIN - DELETE FROM iris.device_preset WHERE name = OLD.name; - DELETE FROM iris.controller_io WHERE name = OLD.name; - IF FOUND THEN - RETURN OLD; - ELSE - RETURN NULL; - END IF; -END; -$controller_io_delete$ LANGUAGE plpgsql; +CREATE TABLE event.action_plan_event ( + id SERIAL PRIMARY KEY, + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc INTEGER NOT NULL REFERENCES event.event_description, + action_plan VARCHAR(16) NOT NULL, + phase VARCHAR(12), + user_id VARCHAR(15) +); -CREATE VIEW controller_io_view AS - SELECT name, resource_n, controller, pin - FROM iris.controller_io; -GRANT SELECT ON controller_io_view TO PUBLIC; +CREATE VIEW action_plan_event_view AS + SELECT ev.id, event_date, ed.description, action_plan, phase, user_id + FROM event.action_plan_event ev + JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; +GRANT SELECT ON action_plan_event_view TO PUBLIC; -- -- Cameras, Encoders, Presets @@ -1722,385 +2408,131 @@ COPY iris.beacon_state (id, description) FROM stdin; 5 Fault: No Verify 6 Fault: Stuck On 7 Flashing: External -\. - -CREATE TABLE iris._beacon ( - name VARCHAR(20) PRIMARY KEY, - geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), - message VARCHAR(128) NOT NULL, - notes VARCHAR CHECK (LENGTH(notes) < 256), - verify_pin INTEGER, - ext_mode BOOLEAN NOT NULL, - state INTEGER NOT NULL REFERENCES iris.beacon_state -); - -ALTER TABLE iris._beacon ADD CONSTRAINT _beacon_fkey - FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; - -CREATE TRIGGER beacon_hashtag_trig - AFTER INSERT OR UPDATE OR DELETE ON iris._beacon - FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('beacon'); - -CREATE FUNCTION iris.beacon_notify() RETURNS TRIGGER AS - $beacon_notify$ -BEGIN - IF (NEW.message IS DISTINCT FROM OLD.message) OR - (NEW.notes IS DISTINCT FROM OLD.notes) OR - (NEW.state IS DISTINCT FROM OLD.state) - THEN - NOTIFY beacon; - ELSE - PERFORM pg_notify('beacon', NEW.name); - END IF; - RETURN NULL; -- AFTER trigger return is ignored -END; -$beacon_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER beacon_notify_trig - AFTER UPDATE ON iris._beacon - FOR EACH ROW EXECUTE FUNCTION iris.beacon_notify(); - -CREATE TRIGGER beacon_table_notify_trig - AFTER INSERT OR DELETE ON iris._beacon - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW iris.beacon AS - SELECT b.name, geo_loc, controller, pin, notes, message, verify_pin, - ext_mode, preset, state - FROM iris._beacon b - JOIN iris.controller_io cio ON b.name = cio.name - JOIN iris.device_preset p ON b.name = p.name; - -CREATE FUNCTION iris.beacon_insert() RETURNS TRIGGER AS - $beacon_insert$ -BEGIN - INSERT INTO iris.controller_io (name, resource_n, controller, pin) - VALUES (NEW.name, 'beacon', NEW.controller, NEW.pin); - INSERT INTO iris.device_preset (name, resource_n, preset) - VALUES (NEW.name, 'beacon', NEW.preset); - INSERT INTO iris._beacon (name, geo_loc, notes, message, verify_pin, - ext_mode, state) - VALUES (NEW.name, NEW.geo_loc, NEW.notes, NEW.message, - NEW.verify_pin, NEW.ext_mode, NEW.state); - RETURN NEW; -END; -$beacon_insert$ LANGUAGE plpgsql; - -CREATE TRIGGER beacon_insert_trig - INSTEAD OF INSERT ON iris.beacon - FOR EACH ROW EXECUTE FUNCTION iris.beacon_insert(); - -CREATE FUNCTION iris.beacon_update() RETURNS TRIGGER AS - $beacon_update$ -BEGIN - UPDATE iris.controller_io - SET controller = NEW.controller, - pin = NEW.pin - WHERE name = OLD.name; - UPDATE iris.device_preset - SET preset = NEW.preset - WHERE name = OLD.name; - UPDATE iris._beacon - SET notes = NEW.notes, - message = NEW.message, - verify_pin = NEW.verify_pin, - ext_mode = NEW.ext_mode, - state = NEW.state - WHERE name = OLD.name; - RETURN NEW; -END; -$beacon_update$ LANGUAGE plpgsql; - -CREATE TRIGGER beacon_update_trig - INSTEAD OF UPDATE ON iris.beacon - FOR EACH ROW EXECUTE FUNCTION iris.beacon_update(); - -CREATE TRIGGER beacon_delete_trig - INSTEAD OF DELETE ON iris.beacon - FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); - -CREATE VIEW beacon_view AS - SELECT b.name, b.notes, b.message, cp.camera, cp.preset_num, b.geo_loc, - l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir, - l.landmark, l.lat, l.lon, l.corridor, l.location, - cio.controller, cio.pin, b.verify_pin, b.ext_mode, - ctr.comm_link, ctr.drop_id, ctr.condition, bs.description AS state - FROM iris._beacon b - JOIN iris.beacon_state bs ON b.state = bs.id - JOIN iris.controller_io cio ON b.name = cio.name - LEFT JOIN iris.device_preset p ON b.name = p.name - LEFT JOIN iris.camera_preset cp ON cp.name = p.preset - LEFT JOIN geo_loc_view l ON b.geo_loc = l.name - LEFT JOIN controller_view ctr ON cio.controller = ctr.name; -GRANT SELECT ON beacon_view TO PUBLIC; - -CREATE TABLE event.beacon_event ( - id SERIAL PRIMARY KEY, - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - beacon VARCHAR(20) NOT NULL REFERENCES iris._beacon ON DELETE CASCADE, - state INTEGER NOT NULL REFERENCES iris.beacon_state, - user_id VARCHAR(15) -); - -CREATE VIEW beacon_event_view AS - SELECT be.id, event_date, beacon, bs.description AS state, user_id - FROM event.beacon_event be - JOIN iris.beacon_state bs ON be.state = bs.id; -GRANT SELECT ON beacon_event_view TO PUBLIC; - --- --- Lane Codes, Detectors --- -CREATE TABLE iris.lane_code ( - lcode VARCHAR(1) PRIMARY KEY, - description VARCHAR(12) NOT NULL -); - -COPY iris.lane_code (lcode, description) FROM stdin; - Mainline -A Auxiliary -B Bypass -C CD Lane -D Shoulder -G Green -H HOV -K Parking -M Merge -O Omnibus -P Passage -Q Queue -R Reversible -T HOT -V Velocity -X Exit -Y Wrong Way -\. - -CREATE VIEW lane_code_view AS - SELECT lcode, description FROM iris.lane_code; -GRANT SELECT ON lane_code_view TO PUBLIC; - -CREATE TABLE iris._detector ( - name VARCHAR(20) PRIMARY KEY, - r_node VARCHAR(10) NOT NULL REFERENCES iris.r_node(name), - lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, - lane_number SMALLINT NOT NULL, - abandoned BOOLEAN NOT NULL, - force_fail BOOLEAN NOT NULL, - auto_fail BOOLEAN NOT NULL, - field_length REAL NOT NULL, - fake VARCHAR(32), - notes VARCHAR(32) +\. + +CREATE TABLE iris._beacon ( + name VARCHAR(20) PRIMARY KEY, + geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc(name), + message VARCHAR(128) NOT NULL, + notes VARCHAR CHECK (LENGTH(notes) < 256), + verify_pin INTEGER, + ext_mode BOOLEAN NOT NULL, + state INTEGER NOT NULL REFERENCES iris.beacon_state ); -ALTER TABLE iris._detector ADD CONSTRAINT _detector_fkey +ALTER TABLE iris._beacon ADD CONSTRAINT _beacon_fkey FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; -CREATE FUNCTION iris.detector_notify() RETURNS TRIGGER AS - $detector_notify$ +CREATE TRIGGER beacon_hashtag_trig + AFTER INSERT OR UPDATE OR DELETE ON iris._beacon + FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('beacon'); + +CREATE FUNCTION iris.beacon_notify() RETURNS TRIGGER AS + $beacon_notify$ BEGIN - -- lane_code, lane_number and abandoned are secondary, but affect label - IF (NEW.notes IS DISTINCT FROM OLD.notes) OR - (NEW.lane_code IS DISTINCT FROM OLD.lane_code) OR - (NEW.lane_number IS DISTINCT FROM OLD.lane_number) OR - (NEW.abandoned IS DISTINCT FROM OLD.abandoned) + IF (NEW.message IS DISTINCT FROM OLD.message) OR + (NEW.notes IS DISTINCT FROM OLD.notes) OR + (NEW.state IS DISTINCT FROM OLD.state) THEN - NOTIFY detector; + NOTIFY beacon; ELSE - PERFORM pg_notify('detector', NEW.name); + PERFORM pg_notify('beacon', NEW.name); END IF; RETURN NULL; -- AFTER trigger return is ignored END; -$detector_notify$ LANGUAGE plpgsql; +$beacon_notify$ LANGUAGE plpgsql; -CREATE TRIGGER detector_notify_trig - AFTER UPDATE ON iris._detector - FOR EACH ROW EXECUTE FUNCTION iris.detector_notify(); +CREATE TRIGGER beacon_notify_trig + AFTER UPDATE ON iris._beacon + FOR EACH ROW EXECUTE FUNCTION iris.beacon_notify(); -CREATE TRIGGER detector_table_notify_trig - AFTER INSERT OR DELETE ON iris._detector +CREATE TRIGGER beacon_table_notify_trig + AFTER INSERT OR DELETE ON iris._beacon FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE VIEW iris.detector AS - SELECT d.name, controller, pin, r_node, lane_code, lane_number, - abandoned, force_fail, auto_fail, field_length, fake, notes - FROM iris._detector d - JOIN iris.controller_io cio ON d.name = cio.name; +CREATE VIEW iris.beacon AS + SELECT b.name, geo_loc, controller, pin, notes, message, verify_pin, + ext_mode, preset, state + FROM iris._beacon b + JOIN iris.controller_io cio ON b.name = cio.name + JOIN iris.device_preset p ON b.name = p.name; -CREATE FUNCTION iris.detector_insert() RETURNS TRIGGER AS - $detector_insert$ +CREATE FUNCTION iris.beacon_insert() RETURNS TRIGGER AS + $beacon_insert$ BEGIN INSERT INTO iris.controller_io (name, resource_n, controller, pin) - VALUES (NEW.name, 'detector', NEW.controller, NEW.pin); - INSERT INTO iris._detector ( - name, r_node, lane_code, lane_number, abandoned, force_fail, auto_fail, - field_length, fake, notes - ) VALUES ( - NEW.name, NEW.r_node, NEW.lane_code, NEW.lane_number, NEW.abandoned, - NEW.force_fail, NEW.auto_fail, NEW.field_length, NEW.fake, NEW.notes - ); + VALUES (NEW.name, 'beacon', NEW.controller, NEW.pin); + INSERT INTO iris.device_preset (name, resource_n, preset) + VALUES (NEW.name, 'beacon', NEW.preset); + INSERT INTO iris._beacon (name, geo_loc, notes, message, verify_pin, + ext_mode, state) + VALUES (NEW.name, NEW.geo_loc, NEW.notes, NEW.message, + NEW.verify_pin, NEW.ext_mode, NEW.state); RETURN NEW; END; -$detector_insert$ LANGUAGE plpgsql; +$beacon_insert$ LANGUAGE plpgsql; -CREATE TRIGGER detector_insert_trig - INSTEAD OF INSERT ON iris.detector - FOR EACH ROW EXECUTE FUNCTION iris.detector_insert(); +CREATE TRIGGER beacon_insert_trig + INSTEAD OF INSERT ON iris.beacon + FOR EACH ROW EXECUTE FUNCTION iris.beacon_insert(); -CREATE FUNCTION iris.detector_update() RETURNS TRIGGER AS - $detector_update$ +CREATE FUNCTION iris.beacon_update() RETURNS TRIGGER AS + $beacon_update$ BEGIN UPDATE iris.controller_io SET controller = NEW.controller, pin = NEW.pin WHERE name = OLD.name; - UPDATE iris._detector - SET r_node = NEW.r_node, - lane_code = NEW.lane_code, - lane_number = NEW.lane_number, - abandoned = NEW.abandoned, - force_fail = NEW.force_fail, - auto_fail = NEW.auto_fail, - field_length = NEW.field_length, - fake = NEW.fake, - notes = NEW.notes + UPDATE iris.device_preset + SET preset = NEW.preset + WHERE name = OLD.name; + UPDATE iris._beacon + SET notes = NEW.notes, + message = NEW.message, + verify_pin = NEW.verify_pin, + ext_mode = NEW.ext_mode, + state = NEW.state WHERE name = OLD.name; RETURN NEW; END; -$detector_update$ LANGUAGE plpgsql; +$beacon_update$ LANGUAGE plpgsql; -CREATE TRIGGER detector_update_trig - INSTEAD OF UPDATE ON iris.detector - FOR EACH ROW EXECUTE FUNCTION iris.detector_update(); +CREATE TRIGGER beacon_update_trig + INSTEAD OF UPDATE ON iris.beacon + FOR EACH ROW EXECUTE FUNCTION iris.beacon_update(); -CREATE TRIGGER detector_delete_trig - INSTEAD OF DELETE ON iris.detector +CREATE TRIGGER beacon_delete_trig + INSTEAD OF DELETE ON iris.beacon FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); -CREATE FUNCTION iris.landmark_abbrev(VARCHAR(24)) RETURNS TEXT - AS $landmark_abbrev$ -DECLARE - lmrk TEXT; - lmrk2 TEXT; -BEGIN - lmrk = initcap($1); - -- Replace common words - lmrk = replace(lmrk, 'Of ', ''); - lmrk = replace(lmrk, 'Miles', 'MI'); - lmrk = replace(lmrk, 'Mile', 'MI'); - -- Remove whitespace and non-printable characters - lmrk = regexp_replace(lmrk, '[^[:graph:]]', '', 'g'); - IF length(lmrk) > 6 THEN - -- Remove lower-case vowels - lmrk = regexp_replace(lmrk, '[aeiouy]', '', 'g'); - END IF; - IF length(lmrk) > 6 THEN - -- Remove all punctuation - lmrk = regexp_replace(lmrk, '[[:punct:]]', '', 'g'); - END IF; - lmrk2 = lmrk; - IF length(lmrk) > 6 THEN - -- Remove letters - lmrk = regexp_replace(lmrk, '[[:alpha:]]', '', 'g'); - END IF; - IF length(lmrk) > 0 THEN - RETURN left(lmrk, 6); - ELSE - RETURN left(lmrk2, 6); - END IF; -END; -$landmark_abbrev$ LANGUAGE plpgsql; - -CREATE FUNCTION iris.root_lbl(rd VARCHAR(6), rdir VARCHAR(4), xst VARCHAR(6), - xdir VARCHAR(4), xmod VARCHAR(2), lmark VARCHAR(24)) RETURNS TEXT AS -$$ - SELECT rd || '/' || COALESCE( - xdir || replace(xmod, '@', '') || xst, - iris.landmark_abbrev(lmark) - ) || rdir; -$$ LANGUAGE sql SECURITY DEFINER; - -ALTER FUNCTION iris.root_lbl(VARCHAR(6), VARCHAR(4), VARCHAR(6), VARCHAR(4), - VARCHAR(2), VARCHAR(24) -) - SET search_path = pg_catalog, pg_temp; - -CREATE FUNCTION iris.detector_label(TEXT, CHAR, SMALLINT, BOOLEAN) RETURNS TEXT - AS $detector_label$ -DECLARE - root ALIAS FOR $1; - lcode ALIAS FOR $2; - lane_number ALIAS FOR $3; - abandoned ALIAS FOR $4; - lnum VARCHAR(2); - suffix VARCHAR(5); -BEGIN - lnum = ''; - IF lane_number > 0 THEN - lnum = TO_CHAR(lane_number, 'FM9'); - END IF; - suffix = ''; - IF abandoned THEN - suffix = '-ABND'; - END IF; - RETURN COALESCE( - root || lcode || lnum || suffix, - 'FUTURE' - ); -END; -$detector_label$ LANGUAGE plpgsql; - -CREATE VIEW detector_label_view AS - SELECT d.name AS det_id, - iris.detector_label( - iris.root_lbl(l.rd, l.rdir, l.xst, l.cross_dir, l.xmod, l.landmark), - d.lane_code, d.lane_number, d.abandoned - ) AS label, rnd.geo_loc - FROM iris._detector d - LEFT JOIN iris.r_node rnd ON d.r_node = rnd.name - LEFT JOIN geo_loc_view l ON rnd.geo_loc = l.name; -GRANT SELECT ON detector_label_view TO PUBLIC; - -CREATE TABLE event.detector_event ( - event_id INTEGER DEFAULT nextval('event.event_id_seq') NOT NULL, - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - device_id VARCHAR(20) REFERENCES iris._detector(name) ON DELETE CASCADE -); - -CREATE VIEW detector_view AS - SELECT d.name, d.r_node, c.comm_link, c.drop_id, cio.controller, cio.pin, - dl.label, dl.geo_loc, l.rd || '_' || l.road_dir AS cor_id, +CREATE VIEW beacon_view AS + SELECT b.name, b.notes, b.message, cp.camera, cp.preset_num, b.geo_loc, l.roadway, l.road_dir, l.cross_mod, l.cross_street, l.cross_dir, - d.lane_number, d.field_length, lc.description AS lane_type, - d.lane_code, d.abandoned, d.force_fail, d.auto_fail, c.condition, - d.fake, d.notes - FROM iris.detector d - JOIN iris.controller_io cio ON d.name = cio.name - LEFT JOIN detector_label_view dl ON d.name = dl.det_id - LEFT JOIN geo_loc_view l ON dl.geo_loc = l.name - LEFT JOIN iris.lane_code lc ON d.lane_code = lc.lcode - LEFT JOIN controller_view c ON cio.controller = c.name; -GRANT SELECT ON detector_view TO PUBLIC; - -CREATE VIEW detector_event_view AS - SELECT e.event_id, e.event_date, ed.description, e.device_id, dl.label - FROM event.detector_event e - JOIN event.event_description ed ON e.event_desc_id = ed.event_desc_id - JOIN detector_label_view dl ON e.device_id = dl.det_id; -GRANT SELECT ON detector_event_view TO PUBLIC; + l.landmark, l.lat, l.lon, l.corridor, l.location, + cio.controller, cio.pin, b.verify_pin, b.ext_mode, + ctr.comm_link, ctr.drop_id, ctr.condition, bs.description AS state + FROM iris._beacon b + JOIN iris.beacon_state bs ON b.state = bs.id + JOIN iris.controller_io cio ON b.name = cio.name + LEFT JOIN iris.device_preset p ON b.name = p.name + LEFT JOIN iris.camera_preset cp ON cp.name = p.preset + LEFT JOIN geo_loc_view l ON b.geo_loc = l.name + LEFT JOIN controller_view ctr ON cio.controller = ctr.name; +GRANT SELECT ON beacon_view TO PUBLIC; -CREATE VIEW detector_auto_fail_view AS - WITH af AS (SELECT device_id, event_desc_id, count(*) AS event_count, - max(event_date) AS last_fail - FROM event.detector_event - GROUP BY device_id, event_desc_id) - SELECT device_id, label, ed.description, event_count, last_fail - FROM af - JOIN event.event_description ed ON af.event_desc_id = ed.event_desc_id - JOIN detector_label_view dl ON af.device_id = dl.det_id; -GRANT SELECT ON detector_auto_fail_view TO PUBLIC; +CREATE TABLE event.beacon_event ( + id SERIAL PRIMARY KEY, + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + beacon VARCHAR(20) NOT NULL REFERENCES iris._beacon ON DELETE CASCADE, + state INTEGER NOT NULL REFERENCES iris.beacon_state, + user_id VARCHAR(15) +); + +CREATE VIEW beacon_event_view AS + SELECT be.id, event_date, beacon, bs.description AS state, user_id + FROM event.beacon_event be + JOIN iris.beacon_state bs ON be.state = bs.id; +GRANT SELECT ON beacon_event_view TO PUBLIC; -- -- GPS @@ -2781,796 +3213,364 @@ CREATE TRIGGER msg_pattern_notify_trig AFTER INSERT OR UPDATE OR DELETE ON iris.msg_pattern FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE VIEW msg_pattern_view AS - SELECT name, multi, flash_beacon, compose_hashtag - FROM iris.msg_pattern; -GRANT SELECT ON msg_pattern_view TO PUBLIC; - -CREATE TABLE iris.msg_line ( - name VARCHAR(10) PRIMARY KEY, - msg_pattern VARCHAR(20) NOT NULL REFERENCES iris.msg_pattern, - restrict_hashtag VARCHAR(16), - line SMALLINT NOT NULL, - multi VARCHAR(64) NOT NULL, - rank SMALLINT NOT NULL, - - CONSTRAINT hashtag_ck CHECK (restrict_hashtag ~ '^#[A-Za-z0-9]+$'), - CONSTRAINT msg_line_line CHECK ((line >= 1) AND (line <= 12)), - CONSTRAINT msg_line_rank CHECK ((rank >= 1) AND (rank <= 99)) -); - -CREATE TRIGGER msg_line_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.msg_line - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW msg_line_view AS - SELECT name, msg_pattern, restrict_hashtag, line, multi, rank - FROM iris.msg_line; -GRANT SELECT ON msg_line_view TO PUBLIC; - -CREATE TABLE iris.device_action ( - name VARCHAR(30) PRIMARY KEY, - action_plan VARCHAR(16) NOT NULL REFERENCES iris.action_plan, - phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, - hashtag VARCHAR(16) NOT NULL, - msg_pattern VARCHAR(20) REFERENCES iris.msg_pattern, - msg_priority INTEGER NOT NULL, - - CONSTRAINT hashtag_ck CHECK (hashtag ~ '^#[A-Za-z0-9]+$') -); - -CREATE VIEW device_action_view AS - SELECT name, action_plan, phase, hashtag, msg_pattern, msg_priority - FROM iris.device_action; -GRANT SELECT ON device_action_view TO PUBLIC; - -CREATE VIEW dms_action_view AS - SELECT h.name AS dms, action_plan, phase, h.hashtag, msg_pattern, - msg_priority - FROM iris.device_action da - JOIN iris.hashtag h ON h.hashtag = da.hashtag AND resource_n = 'dms'; -GRANT SELECT ON dms_action_view TO PUBLIC; - -CREATE TABLE event.sign_event ( - event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - device_id VARCHAR(20), - multi VARCHAR(1024), - msg_owner VARCHAR(127), - duration INTEGER -); -CREATE INDEX ON event.sign_event(event_date); - -CREATE FUNCTION event.multi_message(VARCHAR(1024)) - RETURNS TEXT AS $multi_message$ -DECLARE - multi ALIAS FOR $1; -BEGIN - RETURN regexp_replace( - replace( - replace(multi, '[nl]', E'\n'), - '[np]', E'\n' - ), - '\[.+?\]', ' ', 'g' - ); -END; -$multi_message$ LANGUAGE plpgsql; - -CREATE VIEW sign_event_view AS - SELECT event_id, event_date, description, device_id, - event.multi_message(multi) as message, multi, msg_owner, duration - FROM event.sign_event JOIN event.event_description - ON sign_event.event_desc_id = event_description.event_desc_id; -GRANT SELECT ON sign_event_view TO PUBLIC; - -CREATE VIEW recent_sign_event_view AS - SELECT event_id, event_date, description, device_id, message, multi, - msg_owner, duration - FROM sign_event_view - WHERE event_date > (CURRENT_TIMESTAMP - interval '90 days'); -GRANT SELECT ON recent_sign_event_view TO PUBLIC; - -CREATE TABLE event.travel_time_event ( - event_id SERIAL PRIMARY KEY, - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - device_id VARCHAR(20), - station_id VARCHAR(10) -); - -CREATE VIEW travel_time_event_view AS - SELECT event_id, event_date, event_description.description, device_id, - station_id - FROM event.travel_time_event - JOIN event.event_description - ON travel_time_event.event_desc_id = event_description.event_desc_id; -GRANT SELECT ON travel_time_event_view TO PUBLIC; - -CREATE TABLE event.brightness_sample ( - event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - dms VARCHAR(20) NOT NULL REFERENCES iris._dms(name) - ON DELETE CASCADE, - photocell INTEGER NOT NULL, - output INTEGER NOT NULL -); - --- --- Gate Arms --- -CREATE TABLE iris.gate_arm_state ( - id INTEGER PRIMARY KEY, - description VARCHAR(10) NOT NULL -); - -COPY iris.gate_arm_state(id, description) FROM stdin; -0 unknown -1 fault -2 opening -3 open -4 warn close -5 closing -6 closed -\. - -CREATE TABLE iris.gate_arm_interlock ( - id INTEGER PRIMARY KEY, - description VARCHAR(16) NOT NULL -); - -COPY iris.gate_arm_interlock(id, description) FROM stdin; -0 none -1 deny open -2 deny close -3 deny all -4 system disable -\. - -CREATE TABLE iris._gate_arm_array ( - name VARCHAR(20) PRIMARY KEY, - geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc, - notes VARCHAR CHECK (LENGTH(notes) < 256), - opposing BOOLEAN NOT NULL, - prereq VARCHAR(20) REFERENCES iris._gate_arm_array, - camera VARCHAR(20) REFERENCES iris._camera, - approach VARCHAR(20) REFERENCES iris._camera, - action_plan VARCHAR(16) UNIQUE REFERENCES iris.action_plan, - arm_state INTEGER NOT NULL REFERENCES iris.gate_arm_state, - interlock INTEGER NOT NULL REFERENCES iris.gate_arm_interlock -); - --- This constraint ensures that the name is unique among all devices --- Gate arm arrays are *not* associated with controllers or pins -ALTER TABLE iris._gate_arm_array ADD CONSTRAINT _gate_arm_array_fkey - FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; - -CREATE TRIGGER gate_arm_array_hashtag_trig - AFTER INSERT OR UPDATE OR DELETE ON iris._gate_arm_array - FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('gate_arm_array'); - -CREATE FUNCTION iris.gate_arm_array_notify() RETURNS TRIGGER AS - $gate_arm_array_notify$ -BEGIN - IF (NEW.notes IS DISTINCT FROM OLD.notes) OR - (NEW.arm_state IS DISTINCT FROM OLD.arm_state) OR - (NEW.interlock IS DISTINCT FROM OLD.interlock) - THEN - NOTIFY gate_arm_array; - ELSE - PERFORM pg_notify('gate_arm_array', NEW.name); - END IF; - RETURN NULL; -- AFTER trigger return is ignored -END; -$gate_arm_array_notify$ LANGUAGE plpgsql; - -CREATE TRIGGER gate_arm_array_notify_trig - AFTER UPDATE ON iris._gate_arm_array - FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_notify(); - -CREATE TRIGGER gate_arm_array_table_notify_trig - AFTER INSERT OR DELETE ON iris._gate_arm_array - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW iris.gate_arm_array AS - SELECT ga.name, geo_loc, controller, pin, notes, opposing, prereq, camera, - approach, action_plan, arm_state, interlock - FROM iris._gate_arm_array ga - JOIN iris.controller_io cio ON ga.name = cio.name; - -CREATE FUNCTION iris.gate_arm_array_insert() RETURNS TRIGGER AS - $gate_arm_array_insert$ -BEGIN - INSERT INTO iris.controller_io (name, resource_n, controller, pin) - VALUES (NEW.name, 'gate_arm_array', NEW.controller, NEW.pin); - INSERT INTO iris._gate_arm_array ( - name, geo_loc, notes, opposing, prereq, camera, approach, action_plan, - arm_state, interlock - ) VALUES ( - NEW.name, NEW.geo_loc, NEW.notes, NEW.opposing, NEW.prereq, NEW.camera, - NEW.approach, NEW.action_plan, NEW.arm_state, NEW.interlock - ); - RETURN NEW; -END; -$gate_arm_array_insert$ LANGUAGE plpgsql; - -CREATE TRIGGER gate_arm_array_insert_trig - INSTEAD OF INSERT ON iris.gate_arm_array - FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_insert(); - -CREATE FUNCTION iris.gate_arm_array_update() RETURNS TRIGGER AS - $gate_arm_array_update$ -BEGIN - UPDATE iris.controller_io SET controller = NEW.controller, pin = NEW.pin - WHERE name = OLD.name; - UPDATE iris._gate_arm_array - SET notes = NEW.notes, - opposing = NEW.opposing, - prereq = NEW.prereq, - camera = NEW.camera, - approach = NEW.approach, - action_plan = NEW.action_plan, - arm_state = NEW.arm_state, - interlock = NEW.interlock - WHERE name = OLD.name; - RETURN NEW; -END; -$gate_arm_array_update$ LANGUAGE plpgsql; - -CREATE TRIGGER gate_arm_array_update_trig - INSTEAD OF UPDATE ON iris.gate_arm_array - FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_update(); - -CREATE TRIGGER gate_arm_array_delete_trig - INSTEAD OF DELETE ON iris.gate_arm_array - FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); +CREATE VIEW msg_pattern_view AS + SELECT name, multi, flash_beacon, compose_hashtag + FROM iris.msg_pattern; +GRANT SELECT ON msg_pattern_view TO PUBLIC; -CREATE VIEW gate_arm_array_view AS - SELECT ga.name, ga.notes, ga.geo_loc, l.roadway, l.road_dir, l.cross_mod, - l.cross_street, l.cross_dir, l.landmark, l.lat, l.lon, l.corridor, - l.location, cio.controller, cio.pin, ctr.comm_link, ctr.drop_id, - ctr.condition, ga.opposing, ga.prereq, ga.camera, ga.approach, - ga.action_plan, gas.description AS arm_state, - gai.description AS interlock - FROM iris._gate_arm_array ga - JOIN iris.controller_io cio ON ga.name = cio.name - JOIN iris.gate_arm_state gas ON ga.arm_state = gas.id - JOIN iris.gate_arm_interlock gai ON ga.interlock = gai.id - LEFT JOIN geo_loc_view l ON ga.geo_loc = l.name - LEFT JOIN controller_view ctr ON cio.controller = ctr.name; -GRANT SELECT ON gate_arm_array_view TO PUBLIC; +CREATE TABLE iris.msg_line ( + name VARCHAR(10) PRIMARY KEY, + msg_pattern VARCHAR(20) NOT NULL REFERENCES iris.msg_pattern, + restrict_hashtag VARCHAR(16), + line SMALLINT NOT NULL, + multi VARCHAR(64) NOT NULL, + rank SMALLINT NOT NULL, -CREATE TABLE iris._gate_arm ( - name VARCHAR(20) PRIMARY KEY, - ga_array VARCHAR(20) NOT NULL REFERENCES iris._gate_arm_array, - idx INTEGER NOT NULL, - notes VARCHAR CHECK (LENGTH(notes) < 256), - arm_state INTEGER NOT NULL REFERENCES iris.gate_arm_state, - fault VARCHAR(32) + CONSTRAINT hashtag_ck CHECK (restrict_hashtag ~ '^#[A-Za-z0-9]+$'), + CONSTRAINT msg_line_line CHECK ((line >= 1) AND (line <= 12)), + CONSTRAINT msg_line_rank CHECK ((rank >= 1) AND (rank <= 99)) ); -ALTER TABLE iris._gate_arm ADD CONSTRAINT _gate_arm_fkey - FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; +CREATE TRIGGER msg_line_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris.msg_line + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE UNIQUE INDEX gate_arm_array_idx ON iris._gate_arm - USING btree (ga_array, idx); +CREATE VIEW msg_line_view AS + SELECT name, msg_pattern, restrict_hashtag, line, multi, rank + FROM iris.msg_line; +GRANT SELECT ON msg_line_view TO PUBLIC; -CREATE TRIGGER gate_arm_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris._gate_arm - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +CREATE TABLE iris.device_action ( + name VARCHAR(30) PRIMARY KEY, + action_plan VARCHAR(16) NOT NULL REFERENCES iris.action_plan, + phase VARCHAR(12) NOT NULL REFERENCES iris.plan_phase, + hashtag VARCHAR(16) NOT NULL, + msg_pattern VARCHAR(20) REFERENCES iris.msg_pattern, + msg_priority INTEGER NOT NULL, -CREATE VIEW iris.gate_arm AS - SELECT g.name, ga_array, idx, controller, pin, notes, arm_state, fault - FROM iris._gate_arm g - JOIN iris.controller_io cio ON g.name = cio.name; + CONSTRAINT hashtag_ck CHECK (hashtag ~ '^#[A-Za-z0-9]+$') +); -CREATE FUNCTION iris.gate_arm_insert() RETURNS TRIGGER AS - $gate_arm_insert$ -BEGIN - INSERT INTO iris.controller_io (name, resource_n, controller, pin) - VALUES (NEW.name, 'gate_arm', NEW.controller, NEW.pin); - INSERT INTO iris._gate_arm ( - name, ga_array, idx, notes, arm_state, fault - ) VALUES ( - NEW.name, NEW.ga_array, NEW.idx, NEW.notes, NEW.arm_state, NEW.fault - ); - RETURN NEW; -END; -$gate_arm_insert$ LANGUAGE plpgsql; +CREATE VIEW device_action_view AS + SELECT name, action_plan, phase, hashtag, msg_pattern, msg_priority + FROM iris.device_action; +GRANT SELECT ON device_action_view TO PUBLIC; -CREATE TRIGGER gate_arm_insert_trig - INSTEAD OF INSERT ON iris.gate_arm - FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_insert(); +CREATE VIEW dms_action_view AS + SELECT h.name AS dms, action_plan, phase, h.hashtag, msg_pattern, + msg_priority + FROM iris.device_action da + JOIN iris.hashtag h ON h.hashtag = da.hashtag AND resource_n = 'dms'; +GRANT SELECT ON dms_action_view TO PUBLIC; -CREATE FUNCTION iris.gate_arm_update() RETURNS TRIGGER AS - $gate_arm_update$ +CREATE TABLE event.sign_event ( + event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), + device_id VARCHAR(20), + multi VARCHAR(1024), + msg_owner VARCHAR(127), + duration INTEGER +); +CREATE INDEX ON event.sign_event(event_date); + +CREATE FUNCTION event.multi_message(VARCHAR(1024)) + RETURNS TEXT AS $multi_message$ +DECLARE + multi ALIAS FOR $1; BEGIN - UPDATE iris.controller_io - SET controller = NEW.controller, pin = NEW.pin - WHERE name = OLD.name; - UPDATE iris._gate_arm - SET ga_array = NEW.ga_array, - idx = NEW.idx, - notes = NEW.notes, - arm_state = NEW.arm_state, - fault = NEW.fault - WHERE name = OLD.name; - RETURN NEW; + RETURN regexp_replace( + replace( + replace(multi, '[nl]', E'\n'), + '[np]', E'\n' + ), + '\[.+?\]', ' ', 'g' + ); END; -$gate_arm_update$ LANGUAGE plpgsql; - -CREATE TRIGGER gate_arm_update_trig - INSTEAD OF UPDATE ON iris.gate_arm - FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_update(); +$multi_message$ LANGUAGE plpgsql; -CREATE TRIGGER gate_arm_delete_trig - INSTEAD OF DELETE ON iris.gate_arm - FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); +CREATE VIEW sign_event_view AS + SELECT event_id, event_date, description, device_id, + event.multi_message(multi) as message, multi, msg_owner, duration + FROM event.sign_event JOIN event.event_description + ON sign_event.event_desc_id = event_description.event_desc_id; +GRANT SELECT ON sign_event_view TO PUBLIC; -CREATE VIEW gate_arm_view AS - SELECT g.name, g.ga_array, g.notes, ga.geo_loc, l.roadway, l.road_dir, - l.cross_mod, l.cross_street, l.cross_dir, l.landmark, l.lat, l.lon, - l.corridor, l.location, cio.controller, cio.pin, ctr.comm_link, - ctr.drop_id, ctr.condition, ga.opposing, ga.prereq, ga.camera, - ga.approach, gas.description AS arm_state, fault - FROM iris._gate_arm g - JOIN iris.controller_io cio ON g.name = cio.name - JOIN iris.gate_arm_state gas ON g.arm_state = gas.id - JOIN iris._gate_arm_array ga ON g.ga_array = ga.name - LEFT JOIN geo_loc_view l ON ga.geo_loc = l.name - LEFT JOIN controller_view ctr ON cio.controller = ctr.name; -GRANT SELECT ON gate_arm_view TO PUBLIC; +CREATE VIEW recent_sign_event_view AS + SELECT event_id, event_date, description, device_id, message, multi, + msg_owner, duration + FROM sign_event_view + WHERE event_date > (CURRENT_TIMESTAMP - interval '90 days'); +GRANT SELECT ON recent_sign_event_view TO PUBLIC; -CREATE TABLE event.gate_arm_event ( - id SERIAL PRIMARY KEY, +CREATE TABLE event.travel_time_event ( + event_id SERIAL PRIMARY KEY, event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc INTEGER NOT NULL REFERENCES event.event_description, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), device_id VARCHAR(20), - user_id VARCHAR(15), - fault VARCHAR(32) + station_id VARCHAR(10) ); -CREATE VIEW gate_arm_event_view AS - SELECT ev.id, event_date, ed.description, device_id, user_id, fault - FROM event.gate_arm_event ev - JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; -GRANT SELECT ON gate_arm_event_view TO PUBLIC; +CREATE VIEW travel_time_event_view AS + SELECT event_id, event_date, event_description.description, device_id, + station_id + FROM event.travel_time_event + JOIN event.event_description + ON travel_time_event.event_desc_id = event_description.event_desc_id; +GRANT SELECT ON travel_time_event_view TO PUBLIC; + +CREATE TABLE event.brightness_sample ( + event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'), + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc_id INTEGER NOT NULL + REFERENCES event.event_description(event_desc_id), + dms VARCHAR(20) NOT NULL REFERENCES iris._dms(name) + ON DELETE CASCADE, + photocell INTEGER NOT NULL, + output INTEGER NOT NULL +); -- --- Incidents +-- Gate Arms -- -CREATE TABLE event.incident_detail ( - name VARCHAR(8) PRIMARY KEY, - description VARCHAR(32) NOT NULL +CREATE TABLE iris.gate_arm_state ( + id INTEGER PRIMARY KEY, + description VARCHAR(10) NOT NULL ); -INSERT INTO event.incident_detail (name, description) -VALUES - ('animal', 'Animal on Road'), - ('debris', 'Debris'), - ('detour', 'Detour'), - ('emrg_veh', 'Emergency Vehicles'), - ('event', 'Event Congestion'), - ('flooding', 'Flash Flooding'), - ('gr_fire', 'Grass Fire'), - ('ice', 'Ice'), - ('jacknife', 'Jacknifed Trailer'), - ('pavement', 'Pavement Failure'), - ('ped', 'Pedestrian'), - ('rollover', 'Rollover'), - ('sgnl_out', 'Traffic Lights Out'), - ('snow_rmv', 'Snow Removal'), - ('spill', 'Spilled Load'), - ('spin_out', 'Vehicle Spin Out'), - ('test', 'Test Incident'), - ('veh_fire', 'Vehicle Fire'); +COPY iris.gate_arm_state(id, description) FROM stdin; +0 unknown +1 fault +2 opening +3 open +4 warn close +5 closing +6 closed +\. -CREATE TRIGGER incident_detail_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON event.incident_detail - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +CREATE TABLE iris.gate_arm_interlock ( + id INTEGER PRIMARY KEY, + description VARCHAR(16) NOT NULL +); -CREATE TABLE event.incident ( - id SERIAL PRIMARY KEY, - name VARCHAR(16) NOT NULL UNIQUE, - replaces VARCHAR(16) REFERENCES event.incident(name), - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - event_desc INTEGER NOT NULL REFERENCES event.event_description, - detail VARCHAR(8) REFERENCES event.incident_detail(name), - lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, - road VARCHAR(20) NOT NULL, - dir SMALLINT NOT NULL REFERENCES iris.direction(id), - lat double precision NOT NULL, - lon double precision NOT NULL, - camera VARCHAR(20), - impact VARCHAR(20) NOT NULL, - cleared BOOLEAN NOT NULL, - confirmed BOOLEAN NOT NULL, - user_id VARCHAR(15), +COPY iris.gate_arm_interlock(id, description) FROM stdin; +0 none +1 deny open +2 deny close +3 deny all +4 system disable +\. - CONSTRAINT impact_ck CHECK (impact ~ '^[!?\.]*$') +CREATE TABLE iris._gate_arm_array ( + name VARCHAR(20) PRIMARY KEY, + geo_loc VARCHAR(20) NOT NULL REFERENCES iris.geo_loc, + notes VARCHAR CHECK (LENGTH(notes) < 256), + opposing BOOLEAN NOT NULL, + prereq VARCHAR(20) REFERENCES iris._gate_arm_array, + camera VARCHAR(20) REFERENCES iris._camera, + approach VARCHAR(20) REFERENCES iris._camera, + action_plan VARCHAR(16) UNIQUE REFERENCES iris.action_plan, + arm_state INTEGER NOT NULL REFERENCES iris.gate_arm_state, + interlock INTEGER NOT NULL REFERENCES iris.gate_arm_interlock ); -CREATE TRIGGER incident_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON event.incident - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +-- This constraint ensures that the name is unique among all devices +-- Gate arm arrays are *not* associated with controllers or pins +ALTER TABLE iris._gate_arm_array ADD CONSTRAINT _gate_arm_array_fkey + FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; -CREATE FUNCTION event.incident_blocked_lanes(TEXT) - RETURNS INTEGER AS $incident_blocked_lanes$ -DECLARE - impact ALIAS FOR $1; - imp TEXT; - lanes INTEGER; -BEGIN - lanes = length(impact) - 2; - IF lanes > 0 THEN - imp = substring(impact FROM 2 FOR lanes); - RETURN lanes - length(replace(imp, '!', '')); - ELSE - RETURN 0; - END IF; -END; -$incident_blocked_lanes$ LANGUAGE plpgsql; +CREATE TRIGGER gate_arm_array_hashtag_trig + AFTER INSERT OR UPDATE OR DELETE ON iris._gate_arm_array + FOR EACH ROW EXECUTE FUNCTION iris.hashtag_trig('gate_arm_array'); -CREATE FUNCTION event.incident_blocked_shoulders(TEXT) - RETURNS INTEGER AS $incident_blocked_shoulders$ -DECLARE - impact ALIAS FOR $1; - len INTEGER; - imp TEXT; +CREATE FUNCTION iris.gate_arm_array_notify() RETURNS TRIGGER AS + $gate_arm_array_notify$ BEGIN - len = length(impact); - IF len > 2 THEN - imp = substring(impact FROM 1 FOR 1) || - substring(impact FROM len FOR 1); - RETURN 2 - length(replace(imp, '!', '')); + IF (NEW.notes IS DISTINCT FROM OLD.notes) OR + (NEW.arm_state IS DISTINCT FROM OLD.arm_state) OR + (NEW.interlock IS DISTINCT FROM OLD.interlock) + THEN + NOTIFY gate_arm_array; ELSE - RETURN 0; + PERFORM pg_notify('gate_arm_array', NEW.name); END IF; + RETURN NULL; -- AFTER trigger return is ignored END; -$incident_blocked_shoulders$ LANGUAGE plpgsql; +$gate_arm_array_notify$ LANGUAGE plpgsql; -CREATE VIEW incident_view AS - SELECT i.id, name, event_date, ed.description, road, d.direction, - impact, event.incident_blocked_lanes(impact) AS blocked_lanes, - event.incident_blocked_shoulders(impact) AS blocked_shoulders, - cleared, confirmed, user_id, camera, lc.description AS lane_type, - detail, replaces, lat, lon - FROM event.incident i - LEFT JOIN event.event_description ed ON i.event_desc = ed.event_desc_id - LEFT JOIN iris.direction d ON i.dir = d.id - LEFT JOIN iris.lane_code lc ON i.lane_code = lc.lcode; -GRANT SELECT ON incident_view TO PUBLIC; +CREATE TRIGGER gate_arm_array_notify_trig + AFTER UPDATE ON iris._gate_arm_array + FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_notify(); -CREATE TABLE event.incident_update ( - id SERIAL PRIMARY KEY, - incident VARCHAR(16) NOT NULL REFERENCES event.incident(name), - event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, - impact VARCHAR(20) NOT NULL, - cleared BOOLEAN NOT NULL, - confirmed BOOLEAN NOT NULL, - user_id VARCHAR(15) -); +CREATE TRIGGER gate_arm_array_table_notify_trig + AFTER INSERT OR DELETE ON iris._gate_arm_array + FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE FUNCTION event.incident_update_trig() RETURNS TRIGGER AS -$incident_update_trig$ +CREATE VIEW iris.gate_arm_array AS + SELECT ga.name, geo_loc, controller, pin, notes, opposing, prereq, camera, + approach, action_plan, arm_state, interlock + FROM iris._gate_arm_array ga + JOIN iris.controller_io cio ON ga.name = cio.name; + +CREATE FUNCTION iris.gate_arm_array_insert() RETURNS TRIGGER AS + $gate_arm_array_insert$ BEGIN - IF (NEW.impact IS DISTINCT FROM OLD.impact) OR - (NEW.cleared IS DISTINCT FROM OLD.cleared) - THEN - INSERT INTO event.incident_update ( - incident, event_date, impact, cleared, confirmed, user_id - ) VALUES ( - NEW.name, now(), NEW.impact, NEW.cleared, NEW.confirmed, NEW.user_id - ); - END IF; + INSERT INTO iris.controller_io (name, resource_n, controller, pin) + VALUES (NEW.name, 'gate_arm_array', NEW.controller, NEW.pin); + INSERT INTO iris._gate_arm_array ( + name, geo_loc, notes, opposing, prereq, camera, approach, action_plan, + arm_state, interlock + ) VALUES ( + NEW.name, NEW.geo_loc, NEW.notes, NEW.opposing, NEW.prereq, NEW.camera, + NEW.approach, NEW.action_plan, NEW.arm_state, NEW.interlock + ); RETURN NEW; END; -$incident_update_trig$ LANGUAGE plpgsql; - -CREATE TRIGGER incident_update_trigger - AFTER INSERT OR UPDATE ON event.incident - FOR EACH ROW EXECUTE FUNCTION event.incident_update_trig(); - -CREATE VIEW incident_update_view AS - SELECT iu.id, name, iu.event_date, ed.description, road, - d.direction, iu.impact, iu.cleared, iu.confirmed, iu.user_id, - camera, lc.description AS lane_type, detail, replaces, lat, lon - FROM event.incident i - JOIN event.incident_update iu ON i.name = iu.incident - LEFT JOIN event.event_description ed ON i.event_desc = ed.event_desc_id - LEFT JOIN iris.direction d ON i.dir = d.id - LEFT JOIN iris.lane_code lc ON i.lane_code = lc.lcode; -GRANT SELECT ON incident_update_view TO PUBLIC; +$gate_arm_array_insert$ LANGUAGE plpgsql; -CREATE TABLE iris.inc_descriptor ( - name VARCHAR(10) PRIMARY KEY, - event_desc_id INTEGER NOT NULL - REFERENCES event.event_description(event_desc_id), - detail VARCHAR(8) REFERENCES event.incident_detail(name), - lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, - multi VARCHAR(64) NOT NULL -); +CREATE TRIGGER gate_arm_array_insert_trig + INSTEAD OF INSERT ON iris.gate_arm_array + FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_insert(); -CREATE FUNCTION iris.inc_descriptor_ck() RETURNS TRIGGER AS - $inc_descriptor_ck$ +CREATE FUNCTION iris.gate_arm_array_update() RETURNS TRIGGER AS + $gate_arm_array_update$ BEGIN - -- Only incident event IDs are allowed - IF NEW.event_desc_id < 21 OR NEW.event_desc_id > 24 THEN - RAISE EXCEPTION 'invalid incident event_desc_id'; - END IF; - -- Only mainline, cd road, merge and exit lane types are allowed - IF NEW.lane_code != '' AND NEW.lane_code != 'C' AND - NEW.lane_code != 'M' AND NEW.lane_code != 'X' THEN - RAISE EXCEPTION 'invalid incident lane_code'; - END IF; + UPDATE iris.controller_io SET controller = NEW.controller, pin = NEW.pin + WHERE name = OLD.name; + UPDATE iris._gate_arm_array + SET notes = NEW.notes, + opposing = NEW.opposing, + prereq = NEW.prereq, + camera = NEW.camera, + approach = NEW.approach, + action_plan = NEW.action_plan, + arm_state = NEW.arm_state, + interlock = NEW.interlock + WHERE name = OLD.name; RETURN NEW; END; -$inc_descriptor_ck$ LANGUAGE plpgsql; - -CREATE TRIGGER inc_descriptor_ck_trig - BEFORE INSERT OR UPDATE ON iris.inc_descriptor - FOR EACH ROW EXECUTE FUNCTION iris.inc_descriptor_ck(); - -CREATE TRIGGER inc_descriptor_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.inc_descriptor - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); - -CREATE VIEW inc_descriptor_view AS - SELECT id.name, ed.description AS event_description, detail, - lc.description AS lane_type, multi - FROM iris.inc_descriptor id - JOIN event.event_description ed ON id.event_desc_id = ed.event_desc_id - LEFT JOIN iris.lane_code lc ON id.lane_code = lc.lcode; -GRANT SELECT ON inc_descriptor_view TO PUBLIC; +$gate_arm_array_update$ LANGUAGE plpgsql; -COPY iris.inc_descriptor (name, event_desc_id, detail, lane_code, multi) FROM stdin; -idsc_00001 21 \N CRASH -idsc_00002 21 \N X CRASH ON EXIT -idsc_00003 22 \N STALLED VEHICLE -idsc_00004 23 \N INCIDENT -idsc_00005 23 animal ANIMAL ON ROAD -idsc_00006 23 debris DEBRIS ON ROAD -idsc_00007 23 emrg_veh EMERGENCY VEHICLES -idsc_00008 23 event EVENT CONGESTION -idsc_00009 23 event X CONGESTION ON RAMP -idsc_00010 23 flooding FLASH FLOODING -idsc_00011 23 gr_fire GRASS FIRE -idsc_00012 23 ice ICE -idsc_00013 23 pavement PAVEMENT FAILURE -idsc_00014 23 ped PEDESTRIAN ON ROAD -idsc_00015 23 rollover CRASH -idsc_00016 23 snow_rmv SNOW REMOVAL -idsc_00017 23 spin_out CRASH -idsc_00018 23 spin_out X CRASH ON EXIT -idsc_00019 23 test TEST -idsc_00020 23 veh_fire VEHICLE FIRE -idsc_00021 24 \N ROAD WORK -idsc_00022 24 \N X ROAD WORK ON RAMP -\. +CREATE TRIGGER gate_arm_array_update_trig + INSTEAD OF UPDATE ON iris.gate_arm_array + FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_array_update(); -CREATE TABLE iris.inc_impact ( - id INTEGER PRIMARY KEY, - description VARCHAR(24) NOT NULL -); +CREATE TRIGGER gate_arm_array_delete_trig + INSTEAD OF DELETE ON iris.gate_arm_array + FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); -COPY iris.inc_impact (id, description) FROM stdin; -0 lanes blocked -1 left lanes blocked -2 right lanes blocked -3 center lanes blocked -4 lanes affected -5 left lanes affected -6 right lanes affected -7 center lanes affected -8 both shoulders blocked -9 left shoulder blocked -10 right shoulder blocked -11 both shoulders affected -12 left shoulder affected -13 right shoulder affected -14 free flowing -\. +CREATE VIEW gate_arm_array_view AS + SELECT ga.name, ga.notes, ga.geo_loc, l.roadway, l.road_dir, l.cross_mod, + l.cross_street, l.cross_dir, l.landmark, l.lat, l.lon, l.corridor, + l.location, cio.controller, cio.pin, ctr.comm_link, ctr.drop_id, + ctr.condition, ga.opposing, ga.prereq, ga.camera, ga.approach, + ga.action_plan, gas.description AS arm_state, + gai.description AS interlock + FROM iris._gate_arm_array ga + JOIN iris.controller_io cio ON ga.name = cio.name + JOIN iris.gate_arm_state gas ON ga.arm_state = gas.id + JOIN iris.gate_arm_interlock gai ON ga.interlock = gai.id + LEFT JOIN geo_loc_view l ON ga.geo_loc = l.name + LEFT JOIN controller_view ctr ON cio.controller = ctr.name; +GRANT SELECT ON gate_arm_array_view TO PUBLIC; -CREATE TABLE iris.inc_range ( - id INTEGER PRIMARY KEY, - description VARCHAR(10) NOT NULL +CREATE TABLE iris._gate_arm ( + name VARCHAR(20) PRIMARY KEY, + ga_array VARCHAR(20) NOT NULL REFERENCES iris._gate_arm_array, + idx INTEGER NOT NULL, + notes VARCHAR CHECK (LENGTH(notes) < 256), + arm_state INTEGER NOT NULL REFERENCES iris.gate_arm_state, + fault VARCHAR(32) ); -COPY iris.inc_range (id, description) FROM stdin; -0 ahead -1 near -2 middle -3 far -\. +ALTER TABLE iris._gate_arm ADD CONSTRAINT _gate_arm_fkey + FOREIGN KEY (name) REFERENCES iris.controller_io ON DELETE CASCADE; -CREATE TABLE iris.inc_locator ( - name VARCHAR(10) PRIMARY KEY, - range INTEGER NOT NULL REFERENCES iris.inc_range(id), - branched BOOLEAN NOT NULL, - picked BOOLEAN NOT NULL, - multi VARCHAR(64) NOT NULL -); +CREATE UNIQUE INDEX gate_arm_array_idx ON iris._gate_arm + USING btree (ga_array, idx); -CREATE TRIGGER inc_locator_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.inc_locator +CREATE TRIGGER gate_arm_notify_trig + AFTER INSERT OR UPDATE OR DELETE ON iris._gate_arm FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); -CREATE VIEW inc_locator_view AS - SELECT il.name, rng.description AS range, branched, picked, multi - FROM iris.inc_locator il - LEFT JOIN iris.inc_range rng ON il.range = rng.id; -GRANT SELECT ON inc_locator_view TO PUBLIC; +CREATE VIEW iris.gate_arm AS + SELECT g.name, ga_array, idx, controller, pin, notes, arm_state, fault + FROM iris._gate_arm g + JOIN iris.controller_io cio ON g.name = cio.name; -COPY iris.inc_locator (name, range, branched, picked, multi) FROM stdin; -iloc_00001 0 f f AHEAD -iloc_00002 0 f t AHEAD -iloc_00003 0 t f AHEAD -iloc_00004 0 t t AHEAD -iloc_00005 1 f f [locmi] MILES AHEAD -iloc_00006 1 f t [locmd] [locxn] -iloc_00007 1 t f ON [locrn] [locrd] -iloc_00008 1 t t ON [locrn] [locrd] -iloc_00009 2 f f [locmi] MILES AHEAD -iloc_00010 2 f t [locmd] [locxn] -iloc_00011 2 t f ON [locrn] [locrd] -iloc_00012 2 t t ON [locrn] [locrd] [locmd] [locxn] -iloc_00013 3 f f [locmi] MILES AHEAD -iloc_00014 3 f t [locmd] [locxn] -iloc_00015 3 t f ON [locrn] [locrd] -iloc_00016 3 t t ON [locrn] [locrd] [locmd] [locxn] -\. +CREATE FUNCTION iris.gate_arm_insert() RETURNS TRIGGER AS + $gate_arm_insert$ +BEGIN + INSERT INTO iris.controller_io (name, resource_n, controller, pin) + VALUES (NEW.name, 'gate_arm', NEW.controller, NEW.pin); + INSERT INTO iris._gate_arm ( + name, ga_array, idx, notes, arm_state, fault + ) VALUES ( + NEW.name, NEW.ga_array, NEW.idx, NEW.notes, NEW.arm_state, NEW.fault + ); + RETURN NEW; +END; +$gate_arm_insert$ LANGUAGE plpgsql; -CREATE TABLE iris.inc_advice ( - name VARCHAR(10) PRIMARY KEY, - impact INTEGER NOT NULL REFERENCES iris.inc_impact(id), - open_lanes INTEGER, - impacted_lanes INTEGER, - range INTEGER NOT NULL REFERENCES iris.inc_range(id), - lane_code VARCHAR(1) NOT NULL REFERENCES iris.lane_code, - multi VARCHAR(64) NOT NULL -); +CREATE TRIGGER gate_arm_insert_trig + INSTEAD OF INSERT ON iris.gate_arm + FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_insert(); -CREATE FUNCTION iris.inc_advice_ck() RETURNS TRIGGER AS - $inc_advice_ck$ +CREATE FUNCTION iris.gate_arm_update() RETURNS TRIGGER AS + $gate_arm_update$ BEGIN - -- Only mainline, cd road, merge and exit lane codes are allowed - IF NEW.lane_code != '' AND NEW.lane_code != 'C' AND - NEW.lane_code != 'M' AND NEW.lane_code != 'X' THEN - RAISE EXCEPTION 'invalid incident lane_code'; - END IF; + UPDATE iris.controller_io + SET controller = NEW.controller, pin = NEW.pin + WHERE name = OLD.name; + UPDATE iris._gate_arm + SET ga_array = NEW.ga_array, + idx = NEW.idx, + notes = NEW.notes, + arm_state = NEW.arm_state, + fault = NEW.fault + WHERE name = OLD.name; RETURN NEW; END; -$inc_advice_ck$ LANGUAGE plpgsql; +$gate_arm_update$ LANGUAGE plpgsql; -CREATE TRIGGER inc_advice_ck_trig - BEFORE INSERT OR UPDATE ON iris.inc_advice - FOR EACH ROW EXECUTE FUNCTION iris.inc_advice_ck(); +CREATE TRIGGER gate_arm_update_trig + INSTEAD OF UPDATE ON iris.gate_arm + FOR EACH ROW EXECUTE FUNCTION iris.gate_arm_update(); -CREATE TRIGGER inc_advice_notify_trig - AFTER INSERT OR UPDATE OR DELETE ON iris.inc_advice - FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify(); +CREATE TRIGGER gate_arm_delete_trig + INSTEAD OF DELETE ON iris.gate_arm + FOR EACH ROW EXECUTE FUNCTION iris.controller_io_delete(); -CREATE VIEW inc_advice_view AS - SELECT a.name, imp.description AS impact, lc.description AS lane_type, - rng.description AS range, open_lanes, impacted_lanes, multi - FROM iris.inc_advice a - LEFT JOIN iris.inc_impact imp ON a.impact = imp.id - LEFT JOIN iris.inc_range rng ON a.range = rng.id - LEFT JOIN iris.lane_code lc ON a.lane_code = lc.lcode; -GRANT SELECT ON inc_advice_view TO PUBLIC; +CREATE VIEW gate_arm_view AS + SELECT g.name, g.ga_array, g.notes, ga.geo_loc, l.roadway, l.road_dir, + l.cross_mod, l.cross_street, l.cross_dir, l.landmark, l.lat, l.lon, + l.corridor, l.location, cio.controller, cio.pin, ctr.comm_link, + ctr.drop_id, ctr.condition, ga.opposing, ga.prereq, ga.camera, + ga.approach, gas.description AS arm_state, fault + FROM iris._gate_arm g + JOIN iris.controller_io cio ON g.name = cio.name + JOIN iris.gate_arm_state gas ON g.arm_state = gas.id + JOIN iris._gate_arm_array ga ON g.ga_array = ga.name + LEFT JOIN geo_loc_view l ON ga.geo_loc = l.name + LEFT JOIN controller_view ctr ON cio.controller = ctr.name; +GRANT SELECT ON gate_arm_view TO PUBLIC; -COPY iris.inc_advice (name, impact, lane_code, range, open_lanes, impacted_lanes, multi) FROM stdin; -iadv_00001 0 0 0 \N ROAD CLOSED -iadv_00002 0 0 \N \N LANES CLOSED -iadv_00003 0 1 0 \N ROAD CLOSED -iadv_00004 0 1 \N \N LANES CLOSED -iadv_00005 0 2 \N 1 1 LANE CLOSED -iadv_00006 0 2 \N 2 2 LANES CLOSED -iadv_00007 0 2 \N 3 3 LANES CLOSED -iadv_00008 0 2 0 \N ROAD CLOSED -iadv_00009 0 2 1 \N SINGLE LANE -iadv_00010 0 2 \N \N LANES CLOSED -iadv_00011 0 3 \N 1 1 LANE CLOSED -iadv_00012 0 3 \N 2 2 LANES CLOSED -iadv_00013 0 3 \N 3 3 LANES CLOSED -iadv_00014 0 3 0 \N ROAD CLOSED -iadv_00015 0 3 1 \N SINGLE LANE -iadv_00016 0 3 \N \N LANES CLOSED -iadv_00017 1 0 \N 1 LEFT LANE CLOSED -iadv_00018 1 0 \N 2 LEFT 2 LANES CLOSED -iadv_00019 1 0 \N 3 LEFT 3 LANES CLOSED -iadv_00020 1 0 \N \N LEFT LANES CLOSED -iadv_00021 1 1 \N 1 LEFT LANE CLOSED -iadv_00022 1 1 \N 2 LEFT 2 LANES CLOSED -iadv_00023 1 1 \N 3 LEFT 3 LANES CLOSED -iadv_00024 1 1 \N \N LEFT LANES CLOSED -iadv_00025 1 2 \N 1 LANE CLOSED -iadv_00026 1 2 \N 2 2 LANES CLOSED -iadv_00027 1 2 \N 3 3 LANES CLOSED -iadv_00028 1 2 1 \N SINGLE LANE -iadv_00029 1 2 \N \N LANES CLOSED -iadv_00030 1 3 \N 1 LANE CLOSED -iadv_00031 1 3 \N 2 2 LANES CLOSED -iadv_00032 1 3 \N 3 3 LANES CLOSED -iadv_00033 1 3 1 \N SINGLE LANE -iadv_00034 1 3 \N \N LANES CLOSED -iadv_00035 2 0 \N 1 RIGHT LANE CLOSED -iadv_00036 2 0 \N 2 RIGHT 2 LANES CLOSED -iadv_00037 2 0 \N 3 RIGHT 3 LANES CLOSED -iadv_00038 2 0 \N \N RIGHT LANES CLOSED -iadv_00039 2 1 \N 1 RIGHT LANE CLOSED -iadv_00040 2 1 \N 2 RIGHT 2 LANES CLOSED -iadv_00041 2 1 \N 3 RIGHT 3 LANES CLOSED -iadv_00042 2 1 \N \N RIGHT LANES CLOSED -iadv_00043 2 2 \N 1 LANE CLOSED -iadv_00044 2 2 \N 2 2 LANES CLOSED -iadv_00045 2 2 \N 3 3 LANES CLOSED -iadv_00046 2 2 1 \N SINGLE LANE -iadv_00047 2 2 \N \N LANES CLOSED -iadv_00048 2 3 \N 1 LANE CLOSED -iadv_00049 2 3 \N 2 2 LANES CLOSED -iadv_00050 2 3 \N 3 3 LANES CLOSED -iadv_00051 2 3 1 \N SINGLE LANE -iadv_00052 2 3 \N \N LANES CLOSED -iadv_00053 3 0 \N 1 CENTER LANE CLOSED -iadv_00054 3 0 \N \N CENTER LANES CLOSED -iadv_00055 3 1 \N 1 CENTER LANE CLOSED -iadv_00056 3 1 \N \N CENTER LANES CLOSED -iadv_00057 3 2 \N 1 LANE CLOSED -iadv_00058 3 2 \N 2 2 LANES CLOSED -iadv_00059 3 2 \N 3 3 LANES CLOSED -iadv_00060 3 2 \N \N LANES CLOSED -iadv_00061 3 3 \N 1 LANE CLOSED -iadv_00062 3 3 \N 2 2 LANES CLOSED -iadv_00063 3 3 \N 3 3 LANES CLOSED -iadv_00064 3 3 \N \N LANES CLOSED -iadv_00065 4 0 0 1 IN LANE -iadv_00066 4 0 0 2 IN BOTH LANES -iadv_00067 4 0 0 \N IN ALL LANES -iadv_00068 4 1 0 1 IN LANE -iadv_00069 4 1 0 2 IN BOTH LANES -iadv_00070 4 1 0 \N IN ALL LANES -iadv_00071 5 0 \N 1 IN LEFT LANE -iadv_00072 5 0 \N 2 IN LEFT 2 LANES -iadv_00073 5 0 \N 3 IN LEFT 3 LANES -iadv_00074 5 0 \N 4 IN LEFT 4 LANES -iadv_00075 5 0 \N \N IN LEFT LANES -iadv_00076 5 1 \N 1 IN LEFT LANE -iadv_00077 5 1 \N 2 IN LEFT 2 LANES -iadv_00078 5 1 \N 3 IN LEFT 3 LANES -iadv_00079 5 1 \N 4 IN LEFT 4 LANES -iadv_00080 5 1 \N \N IN LEFT LANES -iadv_00081 6 0 \N 1 IN RIGHT LANE -iadv_00082 6 0 \N 2 IN RIGHT 2 LANES -iadv_00083 6 0 \N 3 IN RIGHT 3 LANES -iadv_00084 6 0 \N 4 IN RIGHT 4 LANES -iadv_00085 6 0 \N \N IN RIGHT LANES -iadv_00086 6 1 \N 1 IN RIGHT LANE -iadv_00087 6 1 \N 2 IN RIGHT 2 LANES -iadv_00088 6 1 \N 3 IN RIGHT 3 LANES -iadv_00089 6 1 \N 4 IN RIGHT 4 LANES -iadv_00090 6 1 \N \N IN RIGHT LANES -iadv_00091 7 0 \N 1 IN CENTER LANE -iadv_00092 7 0 \N \N IN CENTER LANES -iadv_00093 7 1 \N 1 IN CENTER LANE -iadv_00094 7 1 \N \N IN CENTER LANES -iadv_00095 8 0 \N \N ON BOTH SHOULDERS -iadv_00096 8 1 \N \N ON BOTH SHOULDERS -iadv_00097 9 0 \N \N ON LEFT SHOULDER -iadv_00098 9 1 \N \N ON LEFT SHOULDER -iadv_00099 10 0 \N \N ON RIGHT SHOULDER -iadv_00100 10 1 \N \N ON RIGHT SHOULDER -iadv_00101 11 0 \N \N IN BOTH SHOULDERS -iadv_00102 11 1 \N \N IN BOTH SHOULDERS -iadv_00103 12 0 \N \N IN LEFT SHOULDER -iadv_00104 12 1 \N \N IN LEFT SHOULDER -iadv_00105 13 0 \N \N IN RIGHT SHOULDER -iadv_00106 13 1 \N \N IN RIGHT SHOULDER -\. +CREATE TABLE event.gate_arm_event ( + id SERIAL PRIMARY KEY, + event_date TIMESTAMP WITH time zone DEFAULT NOW() NOT NULL, + event_desc INTEGER NOT NULL REFERENCES event.event_description, + device_id VARCHAR(20), + user_id VARCHAR(15), + fault VARCHAR(32) +); + +CREATE VIEW gate_arm_event_view AS + SELECT ev.id, event_date, ed.description, device_id, user_id, fault + FROM event.gate_arm_event ev + JOIN event.event_description ed ON ev.event_desc = ed.event_desc_id; +GRANT SELECT ON gate_arm_event_view TO PUBLIC; -- -- Alerts