Skip to content

Commit

Permalink
Add user_id to incident / incident_update
Browse files Browse the repository at this point in the history
  • Loading branch information
DougLau committed Nov 5, 2024
1 parent 302aae7 commit 2315fdd
Show file tree
Hide file tree
Showing 5 changed files with 182 additions and 45 deletions.
119 changes: 115 additions & 4 deletions sql/migrate-5.62.sql
Original file line number Diff line number Diff line change
Expand Up @@ -34,10 +34,6 @@ CREATE TRIGGER camera_preset_notify_trig
AFTER INSERT OR UPDATE OR DELETE ON iris.camera_preset
FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify();

-- Add impact constraint to incident
ALTER TABLE event.incident ADD CONSTRAINT impact_ck
CHECK (impact ~ '^[!?\.]*$');

-- Rename iris_user to user_id in client_event
DROP VIEW client_event_view;

Expand Down Expand Up @@ -177,4 +173,119 @@ CREATE VIEW beacon_event_view AS
JOIN iris.beacon_state bs ON be.state = bs.id;
GRANT SELECT ON beacon_event_view TO PUBLIC;

-- Add user_id to incident / incident_update
DROP VIEW incident_update_view;
DROP VIEW incident_view;

ALTER TABLE event.incident_update DROP CONSTRAINT incident_update_incident_fkey;

ALTER TABLE event.incident DROP CONSTRAINT incident_pkey;
ALTER TABLE event.incident DROP CONSTRAINT incident_replaces_fkey;
ALTER TABLE event.incident DROP CONSTRAINT incident_name_key;
ALTER TABLE event.incident DROP CONSTRAINT incident_detail_fkey;
ALTER TABLE event.incident DROP CONSTRAINT incident_dir_fkey;
ALTER TABLE event.incident DROP CONSTRAINT incident_event_desc_id_fkey;
ALTER TABLE event.incident DROP CONSTRAINT incident_lane_code_fkey;

ALTER TABLE event.incident_update DROP CONSTRAINT incident_update_pkey;

ALTER TABLE event.incident RENAME TO old_incident;
ALTER TABLE event.incident_update RENAME TO old_incident_update;

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),

CONSTRAINT impact_ck CHECK (impact ~ '^[!?\.]*$')
);

INSERT INTO event.incident (
replaces, event_date, event_desc, detail, lane_code, road, dir, lat, lon,
camera, impact, cleared, confirmed
)
SELECT replaces, event_date, event_desc_id, detail, lane_code, road,
dir, lat, lon, camera, impact, cleared, confirmed
FROM event.old_incident;

DROP TABLE event.old_incident;

CREATE TRIGGER incident_notify_trig
AFTER INSERT OR UPDATE OR DELETE ON event.incident
FOR EACH STATEMENT EXECUTE FUNCTION iris.table_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)
);

INSERT INTO event.incident_update (
incident, event_date, impact, cleared, confirmed
)
SELECT incident, event_date, impact, cleared, confirmed
FROM event.old_incident_update;

DROP TABLE event.old_incident_update;

CREATE OR REPLACE 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 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_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 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;

COMMIT;
39 changes: 23 additions & 16 deletions sql/tms-template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3176,12 +3176,11 @@ CREATE TRIGGER incident_detail_notify_trig
FOR EACH STATEMENT EXECUTE FUNCTION iris.table_notify();

CREATE TABLE event.incident (
event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'),
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_id INTEGER NOT NULL
REFERENCES event.event_description(event_desc_id),
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,
Expand All @@ -3192,6 +3191,7 @@ CREATE TABLE event.incident (
impact VARCHAR(20) NOT NULL,
cleared BOOLEAN NOT NULL,
confirmed BOOLEAN NOT NULL,
user_id VARCHAR(15),

CONSTRAINT impact_ck CHECK (impact ~ '^[!?\.]*$')
);
Expand Down Expand Up @@ -3236,32 +3236,39 @@ END;
$incident_blocked_shoulders$ LANGUAGE plpgsql;

CREATE VIEW incident_view AS
SELECT event_id, name, event_date, ed.description, road, d.direction,
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, camera, lc.description AS lane_type, detail,
replaces, lat, lon
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_id = ed.event_desc_id
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 (
event_id INTEGER PRIMARY KEY DEFAULT nextval('event.event_id_seq'),
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
confirmed BOOLEAN NOT NULL,
user_id VARCHAR(15)
);

CREATE FUNCTION event.incident_update_trig() RETURNS TRIGGER AS
$incident_update_trig$
BEGIN
INSERT INTO event.incident_update
(incident, event_date, impact, cleared, confirmed)
VALUES (NEW.name, now(), NEW.impact, NEW.cleared, NEW.confirmed);
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 NEW;
END;
$incident_update_trig$ LANGUAGE plpgsql;
Expand All @@ -3271,12 +3278,12 @@ CREATE TRIGGER incident_update_trigger
FOR EACH ROW EXECUTE FUNCTION event.incident_update_trig();

CREATE VIEW incident_update_view AS
SELECT iu.event_id, name, iu.event_date, ed.description, road,
d.direction, iu.impact, iu.cleared, iu.confirmed, camera,
lc.description AS lane_type, detail, replaces, lat, lon
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_id = ed.event_desc_id
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;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -329,6 +329,7 @@ private void create(ClientIncident inc) {
attrs.put("camera", getSelectedCamera());
attrs.put("impact", impact_pnl.getImpact());
attrs.put("cleared", false);
attrs.put("user_id", session.getUser().getName());
cache.createObject(name, attrs);
Incident proxy = cache.lookupObjectWait(name);
if (proxy != null)
Expand Down
65 changes: 41 additions & 24 deletions src/us/mn/state/dot/tms/server/IncidentImpl.java
Original file line number Diff line number Diff line change
Expand Up @@ -57,25 +57,27 @@ static private void validateImpact(String imp)
static protected void loadAll() throws TMSException {
store.query("SELECT name, replaces, event_desc_id, " +
"event_date, detail, lane_code, road, dir, lat, " +
"lon, camera, impact, cleared, confirmed FROM event." +
SONAR_TYPE + " WHERE cleared = 'f';",new ResultFactory()
"lon, camera, impact, cleared, confirmed, user_id " +
"FROM event." + SONAR_TYPE + " WHERE cleared = 'f';",
new ResultFactory()
{
public void create(ResultSet row) throws Exception {
namespace.addObject(new IncidentImpl(namespace,
row.getString(1), // name
row.getString(2), // replaces
row.getInt(3), // event_desc_id
row.getTimestamp(4), // event_date
row.getString(5), // detail
row.getString(6), // lane_code
row.getString(7), // road
row.getShort(8), // dir
row.getDouble(9), // lat
row.getDouble(10), // lon
row.getString(11), // camera
row.getString(12), // impact
row.getBoolean(13), // cleared
row.getBoolean(14) // confirmed
namespace.addObject(new IncidentImpl(
row.getString(1), // name
row.getString(2), // replaces
row.getInt(3), // event_desc_id
row.getTimestamp(4), // event_date
row.getString(5), // detail
row.getString(6), // lane_code
row.getString(7), // road
row.getShort(8), // dir
row.getDouble(9), // lat
row.getDouble(10), // lon
row.getString(11), // camera
row.getString(12), // impact
row.getBoolean(13), // cleared
row.getBoolean(14), // confirmed
row.getString(15) // user_id
));
}
});
Expand All @@ -99,6 +101,7 @@ public Map<String, Object> getColumns() {
map.put("impact", impact);
map.put("cleared", cleared);
map.put("confirmed", confirmed);
map.put("user_id", user_id);
return map;
}

Expand All @@ -114,19 +117,20 @@ public IncidentImpl(String n) {
}

/** Create an incident */
protected IncidentImpl(Namespace ns, String n, String rpl, int et,
Date ed, String dtl, String lc, String r, short d, double lt,
double ln, String cam, String im, boolean clr, boolean cnf)
private IncidentImpl(String n, String rpl, int et, Date ed,
String dtl, String lc, String r, short d, double lt,
double ln, String cam, String im, boolean clr, boolean cnf,
String uid)
{
this(n, rpl, et, ed, (IncidentDetail)ns.lookupObject(
IncidentDetail.SONAR_TYPE, dtl), lc, lookupRoad(r), d, lt,
ln, lookupCamera(cam), im, clr, cnf);
this(n, rpl, et, ed, lookupIncDetail(dtl), lc, lookupRoad(r),
d, lt, ln, lookupCamera(cam), im, clr, cnf, uid);
}

/** Create an incident */
public IncidentImpl(String n, String rpl, int et, Date ed,
IncidentDetail dtl, String lc, Road r, short d, double lt,
double ln, Camera cam, String im, boolean clr, boolean cnf)
double ln, Camera cam, String im, boolean clr, boolean cnf,
String uid)
{
super(n);
replaces = rpl;
Expand All @@ -142,6 +146,7 @@ public IncidentImpl(String n, String rpl, int et, Date ed,
impact = im;
cleared = clr;
confirmed = cnf;
user_id = uid;
}

/** Destroy an object */
Expand Down Expand Up @@ -263,6 +268,7 @@ public void setImpact(String imp) {
public void doSetImpact(String imp) throws TMSException {
if (!imp.equals(impact)) {
validateImpact(imp);
setUserId();
setConfirmedNotify(true);
store.update(this, "impact", imp);
setImpact(imp);
Expand All @@ -288,6 +294,7 @@ public void setCleared(boolean c) {
/** Set the cleared status */
public void doSetCleared(boolean c) throws TMSException {
if (c != cleared) {
setUserId();
store.update(this, "cleared", c);
setCleared(c);
}
Expand Down Expand Up @@ -332,6 +339,16 @@ private void setConfirmedNotify(boolean c) throws TMSException {
}
}

/** User ID */
private String user_id = null;

/** Set the user ID */
private void setUserId() throws TMSException {
String uid = getProcUser();
store.update(this, "user_id", uid);
user_id = uid;
}

/** Write the incident as xml */
public void writeXml(Writer w) throws IOException {
String dtl = lookupDetail();
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -170,7 +170,8 @@ private boolean createIncidentNotify(String n, String orig,
IncidentImpl inc = new IncidentImpl(n, orig,
pi.inc_type.id, new Date(), pi.detail,
lc, loc.getRoadway(), loc.getRoadDir(),
pi.lat, pi.lon, pi.lookupCamera(), im, false, false);
pi.lat, pi.lon, pi.lookupCamera(), im,
false, false, null);
try {
inc.notifyCreate();
return true;
Expand Down

0 comments on commit 2315fdd

Please sign in to comment.