stop_date TIMESTAMP WITH TIME ZONE,
editor BIGINT REFERENCES actor.usr (id),
edit_date TIMESTAMP WITH TIME ZONE
-
);
CREATE INDEX aum_usr ON actor.usr_message (usr);
+ALTER TABLE actor.usr_standing_penalty ALTER COLUMN id SET DEFAULT nextval('actor.usr_message_id_seq'::regclass);
ALTER TABLE actor.usr_standing_penalty ADD COLUMN usr_message BIGINT REFERENCES actor.usr_message(id);
+CREATE INDEX usr_standing_penalty_usr_message_idx ON actor.usr_standing_penalty (usr_message);
CREATE RULE protect_usr_message_delete AS
ON DELETE TO actor.usr_message DO INSTEAD (
-- combined view of actor.usr_standing_penalty and actor.usr_message for populating
-- staff Notes (formerly Messages) interface
-CREATE VIEW actor.usr_message_penalty
-AS SELECT
- COALESCE(ausp.id::TEXT,'') || ':' || COALESCE(aum.id::TEXT,'') AS "id",
+CREATE VIEW actor.usr_message_penalty AS
+SELECT -- ausp with or without messages
+ ausp.id AS "id",
ausp.id AS "ausp_id",
aum.id AS "aum_id",
- COALESCE(ausp.org_unit,aum.sending_lib) AS "org_unit",
+ ausp.org_unit AS "org_unit",
ausp.org_unit AS "ausp_org_unit",
aum.sending_lib AS "aum_sending_lib",
- COALESCE(ausp.usr,aum.usr) AS "usr",
+ ausp.usr AS "usr",
ausp.usr as "ausp_usr",
aum.usr as "aum_usr",
ausp.standing_penalty AS "standing_penalty",
ausp.staff AS "staff",
- LEAST(ausp.set_date,aum.create_date) AS "create_date",
+ ausp.set_date AS "create_date",
ausp.set_date AS "ausp_set_date",
aum.create_date AS "aum_create_date",
- LEAST(ausp.stop_date,aum.stop_date) AS "stop_date",
+ ausp.stop_date AS "stop_date",
ausp.stop_date AS "ausp_stop_date",
aum.stop_date AS "aum_stop_date",
ausp.usr_message AS "ausp_usr_message",
aum.edit_date AS "edit_date"
FROM
actor.usr_standing_penalty ausp
-FULL OUTER JOIN
+ LEFT JOIN actor.usr_message aum ON (ausp.usr_message = aum.id)
+ UNION ALL
+SELECT -- aum without penalties
+ aum.id AS "id",
+ NULL::INT AS "ausp_id",
+ aum.id AS "aum_id",
+ aum.sending_lib AS "org_unit",
+ NULL::INT AS "ausp_org_unit",
+ aum.sending_lib AS "aum_sending_lib",
+ aum.usr AS "usr",
+ NULL::INT as "ausp_usr",
+ aum.usr as "aum_usr",
+ NULL::INT AS "standing_penalty",
+ NULL::INT AS "staff",
+ aum.create_date AS "create_date",
+ NULL::TIMESTAMPTZ AS "ausp_set_date",
+ aum.create_date AS "aum_create_date",
+ aum.stop_date AS "stop_date",
+ NULL::TIMESTAMPTZ AS "ausp_stop_date",
+ aum.stop_date AS "aum_stop_date",
+ NULL::INT AS "ausp_usr_message",
+ aum.title AS "title",
+ aum.message AS "message",
+ aum.deleted AS "deleted",
+ aum.read_date AS "read_date",
+ aum.pub AS "pub",
+ aum.editor AS "editor",
+ aum.edit_date AS "edit_date"
+FROM
actor.usr_message aum
-ON (
- ausp.usr_message = aum.id
-)
-WHERE
- NOT (ausp.id IS NULL AND aum.deleted);
+ LEFT JOIN actor.usr_standing_penalty ausp ON (ausp.usr_message = aum.id)
+WHERE NOT aum.deleted AND ausp.id IS NULL
;
CREATE TABLE actor.passwd_type (
UPDATE
actor.usr_message
SET
- title = 'Penalty Note'
+ title = message
WHERE
id IN (SELECT id FROM actor.XXXX_usr_message_for_penalty_notes)
;
aum.edit_date AS "edit_date"
FROM
actor.usr_standing_penalty ausp
- LEFT JOIN actor.usr_message aum ON (ausp.usr_message = aum.id AND NOT aum.deleted)
+ LEFT JOIN actor.usr_message aum ON (ausp.usr_message = aum.id)
UNION ALL
SELECT -- aum without penalties
aum.id AS "id",
CREATE TABLE actor.XXXX_usr_message_for_private_notes (
LIKE actor.usr_message INCLUDING DEFAULTS
);
+ALTER TABLE actor.XXXX_usr_message_for_private_notes ADD COLUMN orig_id BIGINT;
+CREATE INDEX ON actor.XXXX_usr_message_for_private_notes (orig_id);
INSERT INTO actor.XXXX_usr_message_for_private_notes (
+ orig_id,
usr,
title,
message,
sending_lib,
pub
) SELECT
+ id,
usr,
title,
value,
CREATE TABLE actor.XXXX_usr_message_for_unmatched_public_notes (
LIKE actor.usr_message INCLUDING DEFAULTS
);
+ALTER TABLE actor.XXXX_usr_message_for_unmatched_public_notes ADD COLUMN orig_id BIGINT;
+CREATE INDEX ON actor.XXXX_usr_message_for_unmatched_public_notes (orig_id);
INSERT INTO actor.XXXX_usr_message_for_unmatched_public_notes (
+ orig_id,
usr,
title,
message,
create_date,
- stop_date,
+ deleted,
sending_lib,
pub
) SELECT
+ id,
usr,
title,
value,
create_date,
- NOW(), -- we want these "archived" since the patron probably already saw a corresponding usr_message
+ TRUE, -- the patron has likely already seen and deleted the corresponding usr_message
(select home_ou from actor.usr where id = creator), -- best we can do
FALSE
FROM
actor.usr_note n,
actor.XXXX_usr_message_for_private_notes m
WHERE
- n.usr = m.usr AND n.create_date = m.create_date AND NOT n.pub AND NOT m.pub
+ n.usr = m.usr AND n.id = m.orig_id AND NOT n.pub AND NOT m.pub
;
-- 2) actor.XXXX_usr_message_for_unmatched_public_notes and associated usr_note entries, but archive these
actor.usr_note n,
actor.XXXX_usr_message_for_unmatched_public_notes m
WHERE
- n.usr = m.usr AND n.create_date = m.create_date AND n.pub AND m.pub
+ n.usr = m.usr AND n.id = m.orig_id AND n.pub AND m.pub
;
-- 3) usr_note and usr_message entries that can be matched
m.id
FROM
actor.usr_note n
- JOIN actor.usr_message m ON (n.usr = m.usr AND n.create_date = m.create_date)
+ JOIN actor.usr_message m ON (n.usr = m.usr AND n.id = m.id)
WHERE
NOT EXISTS ( SELECT 1 FROM actor.XXXX_usr_message_for_private_notes WHERE id = m.id )
AND NOT EXISTS ( SELECT 1 FROM actor.XXXX_usr_message_for_unmatched_public_notes WHERE id = m.id )
-- so far so good, let's push these into production
INSERT INTO actor.usr_message
- SELECT * FROM actor.XXXX_usr_message_for_private_notes
- UNION SELECT * FROM actor.XXXX_usr_message_for_unmatched_public_notes;
+ SELECT id, usr, title, message, create_date, deleted, read_date, sending_lib, pub, stop_date, editor, edit_date FROM actor.XXXX_usr_message_for_private_notes
+ UNION SELECT id, usr, title, message, create_date, deleted, read_date, sending_lib, pub, stop_date, editor, edit_date FROM actor.XXXX_usr_message_for_unmatched_public_notes;
INSERT INTO actor.usr_standing_penalty
SELECT * FROM actor.XXXX_usr_standing_penalties_for_notes;