]> git.evergreen-ils.org Git - working/Evergreen.git/blob - Open-ILS/src/sql/Pg/upgrade/0021.schema.triggers-for-deleting-circs.sql
LP#1806968 Teach Vandelay to pass correct auth tracker type
[working/Evergreen.git] / Open-ILS / src / sql / Pg / upgrade / 0021.schema.triggers-for-deleting-circs.sql
1 BEGIN;
2
3 INSERT INTO config.upgrade_log (version) VALUES ('0021');
4
5 -- Must drop a dependent view temporarily:
6 DROP VIEW extend_reporter.full_circ_count;
7
8 -- Now drop and create the view we want to change:
9 DROP VIEW action.all_circulation;
10
11 CREATE OR REPLACE VIEW action.all_circulation AS
12     SELECT  id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
13         copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
14         circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
15         stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
16         max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
17         max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ
18       FROM  action.aged_circulation
19             UNION ALL
20     SELECT  DISTINCT circ.id,COALESCE(a.post_code,b.post_code) AS usr_post_code, p.home_ou AS usr_home_ou, p.profile AS usr_profile, EXTRACT(YEAR FROM p.dob)::INT AS usr_birth_year,
21         cp.call_number AS copy_call_number, cp.location AS copy_location, cn.owning_lib AS copy_owning_lib, cp.circ_lib AS copy_circ_lib,
22         cn.record AS copy_bib_record, circ.xact_start, circ.xact_finish, circ.target_copy, circ.circ_lib, circ.circ_staff, circ.checkin_staff,
23         circ.checkin_lib, circ.renewal_remaining, circ.due_date, circ.stop_fines_time, circ.checkin_time, circ.create_time, circ.duration,
24         circ.fine_interval, circ.recuring_fine, circ.max_fine, circ.phone_renewal, circ.desk_renewal, circ.opac_renewal, circ.duration_rule,
25         circ.recuring_fine_rule, circ.max_fine_rule, circ.stop_fines, circ.workstation, circ.checkin_workstation, circ.checkin_scan_time,
26         circ.parent_circ
27       FROM  action.circulation circ
28         JOIN asset.copy cp ON (circ.target_copy = cp.id)
29         JOIN asset.call_number cn ON (cp.call_number = cn.id)
30         JOIN actor.usr p ON (circ.usr = p.id)
31         LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
32         LEFT JOIN actor.usr_address b ON (p.billing_address = a.id);
33
34 -- Recreate the temporarily dropped view, with a revised view action.all_circulation:
35
36 CREATE OR REPLACE VIEW extend_reporter.full_circ_count AS
37  SELECT cp.id, COALESCE(sum(c.circ_count), 0::bigint) + COALESCE(count(circ.id), 0::bigint) + COALESCE(count(acirc.id), 0::bigint) AS circ_count
38    FROM asset."copy" cp
39    LEFT JOIN extend_reporter.legacy_circ_count c USING (id)
40    LEFT JOIN "action".circulation circ ON circ.target_copy = cp.id
41    LEFT JOIN "action".aged_circulation acirc ON acirc.target_copy = cp.id
42   GROUP BY cp.id;
43
44 -- Change the pre-delete trigger to copy the new columns
45
46 CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$
47 DECLARE
48 found char := 'N';
49 BEGIN
50
51     -- If there are any renewals for this circulation, don't archive or delete
52     -- it yet.   We'll do so later, when we archive and delete the renewals.
53
54     SELECT 'Y' INTO found
55     FROM action.circulation
56     WHERE parent_circ = OLD.id
57     LIMIT 1;
58
59     IF found = 'Y' THEN
60         RETURN NULL;  -- don't delete
61         END IF;
62
63     -- Archive a copy of the old row to action.aged_circulation
64
65     INSERT INTO action.aged_circulation
66         (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
67         copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
68         circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
69         stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
70         max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
71         max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ)
72       SELECT
73         id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
74         copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
75         circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
76         stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
77         max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
78         max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ
79         FROM action.all_circulation WHERE id = OLD.id;
80
81     RETURN OLD;
82 END;
83 $$ LANGUAGE 'plpgsql';
84
85 -- New post-delete trigger to propagate deletions to parent(s)
86
87 CREATE OR REPLACE FUNCTION action.age_parent_circ_on_delete () RETURNS TRIGGER AS $$
88 BEGIN
89
90     -- Having deleted a renewal, we can delete the original circulation (or a previous
91     -- renewal, if that's what parent_circ is pointing to).  That deletion will trigger
92     -- deletion of any prior parents, etc. recursively.
93
94     IF OLD.parent_circ IS NOT NULL THEN
95         DELETE FROM action.circulation
96         WHERE id = OLD.parent_circ;
97     END IF;
98
99     RETURN OLD;
100 END;
101 $$ LANGUAGE 'plpgsql';
102
103 CREATE TRIGGER age_parent_circ AFTER DELETE ON action.circulation
104 FOR EACH ROW EXECUTE PROCEDURE action.age_parent_circ_on_delete ();
105
106 COMMIT;