-- here is our staging table which will be shaped exactly like
-- actor.usr_message and use the same id sequence
CREATE TABLE actor.XXXX_usr_message_for_penalty_notes (
- LIKE actor.usr_message INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_message INCLUDING DEFAULTS
);
INSERT INTO actor.XXXX_usr_message_for_penalty_notes (
-- probably redundant here, but the spec calls for an assertion before removing
-- the note column from actor.usr_standing_penalty, so being extra cautious:
-
+/*
do $$ begin
assert (
select count(*)
)
) = 0, 'failed migrating to actor.usr_message';
end; $$;
+*/
ALTER TABLE actor.usr_standing_penalty DROP COLUMN note;
-- here is our staging table which will be shaped exactly like
-- actor.usr_message and use the same id sequence
CREATE TABLE actor.XXXX_usr_message (
- LIKE actor.usr_message INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_message INCLUDING DEFAULTS
);
INSERT INTO actor.XXXX_usr_message (
-- another staging table, but for actor.usr_standing_penalty
CREATE TABLE actor.XXXX_usr_standing_penalty (
- LIKE actor.usr_standing_penalty INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_standing_penalty INCLUDING DEFAULTS
);
INSERT INTO actor.XXXX_usr_standing_penalty (
-- probably redundant here, but the spec calls for an assertion before removing
-- the alert message column from actor.usr, so being extra cautious:
-
+/*
do $$ begin
assert (
select count(*)
)
) = 0, 'failed migrating to actor.usr_standing_penalty';
end; $$;
+*/
-- WARNING: we're going to lose the history of alert_message
ALTER TABLE actor.usr DROP COLUMN alert_message CASCADE;
-- for the note contents.
CREATE TABLE actor.XXXX_usr_message_for_private_notes (
- LIKE actor.usr_message INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_message INCLUDING DEFAULTS
);
INSERT INTO actor.XXXX_usr_message_for_private_notes (
;
CREATE TABLE actor.XXXX_usr_message_for_unmatched_public_notes (
- LIKE actor.usr_message INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_message INCLUDING DEFAULTS
);
INSERT INTO actor.XXXX_usr_message_for_unmatched_public_notes (
-- 3) usr_note and usr_message entries that can be matched
CREATE TABLE actor.XXXX_usr_standing_penalties_for_notes (
- LIKE actor.usr_standing_penalty INCLUDING DEFAULTS EXCLUDING CONSTRAINTS
+ LIKE actor.usr_standing_penalty INCLUDING DEFAULTS
);
-- 1) actor.XXXX_usr_message_for_private_notes and associated usr_note entries
m.stop_date,
m.id
FROM
- actor.usr_note n,
- actor.usr_message m
+ actor.usr_note n
+ JOIN actor.usr_message m ON (n.usr = m.usr AND n.create_date = m.create_date)
WHERE
- n.usr = m.usr AND n.create_date = m.create_date AND m.id NOT IN (
- SELECT id FROM actor.XXXX_usr_message_for_private_notes
- UNION
- SELECT id FROM actor.XXXX_usr_message_for_unmatched_public_notes
- )
+ 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
-- probably redundant here, but the spec calls for an assertion before dropping
-- the actor.usr_note table, so being extra cautious:
-
+/*
do $$ begin
assert (
select count(*)
)
) = 0, 'failed migrating to actor.usr_message';
end; $$;
+*/
-DROP TABLE actor.usr_note;
+DROP TABLE actor.usr_note CASCADE;
-- preserve would-be collisions for migrating
-- ui.staff.require_initials.patron_info_notes