]> git.evergreen-ils.org Git - Evergreen.git/blob - Open-ILS/src/sql/Pg/090.schema.action.sql
8cfe279c08b27ae61d53f71161777ef22c429c21
[Evergreen.git] / Open-ILS / src / sql / Pg / 090.schema.action.sql
1 /*
2  * Copyright (C) 2004-2008  Georgia Public Library Service
3  * Copyright (C) 2007-2008  Equinox Software, Inc.
4  * Mike Rylander <miker@esilibrary.com> 
5  *
6  * This program is free software; you can redistribute it and/or
7  * modify it under the terms of the GNU General Public License
8  * as published by the Free Software Foundation; either version 2
9  * of the License, or (at your option) any later version.
10  *
11  * This program is distributed in the hope that it will be useful,
12  * but WITHOUT ANY WARRANTY; without even the implied warranty of
13  * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
14  * GNU General Public License for more details.
15  *
16  */
17
18 DROP SCHEMA action CASCADE;
19
20 BEGIN;
21
22 CREATE SCHEMA action;
23
24 CREATE TABLE action.in_house_use (
25         id              SERIAL                          PRIMARY KEY,
26         item            BIGINT                          NOT NULL REFERENCES asset.copy (id) DEFERRABLE INITIALLY DEFERRED,
27         staff           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
28         org_unit        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
29         use_time        TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
30 );
31
32 CREATE TABLE action.non_cataloged_circulation (
33         id              SERIAL                          PRIMARY KEY,
34         patron          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
35         staff           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
36         circ_lib        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
37         item_type       INT                             NOT NULL REFERENCES config.non_cataloged_type (id) DEFERRABLE INITIALLY DEFERRED,
38         circ_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
39 );
40
41 CREATE TABLE action.non_cat_in_house_use (
42         id              SERIAL                          PRIMARY KEY,
43         item_type       BIGINT                          NOT NULL REFERENCES config.non_cataloged_type(id) DEFERRABLE INITIALLY DEFERRED,
44         staff           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
45         org_unit        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
46         use_time        TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
47 );
48
49 CREATE TABLE action.survey (
50         id              SERIAL                          PRIMARY KEY,
51         owner           INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
52         start_date      TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
53         end_date        TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW() + '10 years'::INTERVAL,
54         usr_summary     BOOL                            NOT NULL DEFAULT FALSE,
55         opac            BOOL                            NOT NULL DEFAULT FALSE,
56         poll            BOOL                            NOT NULL DEFAULT FALSE,
57         required        BOOL                            NOT NULL DEFAULT FALSE,
58         name            TEXT                            NOT NULL,
59         description     TEXT                            NOT NULL
60 );
61 CREATE UNIQUE INDEX asv_once_per_owner_idx ON action.survey (owner,name);
62
63 CREATE TABLE action.survey_question (
64         id              SERIAL  PRIMARY KEY,
65         survey          INT     NOT NULL REFERENCES action.survey DEFERRABLE INITIALLY DEFERRED,
66         question        TEXT    NOT NULL
67 );
68
69 CREATE TABLE action.survey_answer (
70         id              SERIAL  PRIMARY KEY,
71         question        INT     NOT NULL REFERENCES action.survey_question DEFERRABLE INITIALLY DEFERRED,
72         answer          TEXT    NOT NULL
73 );
74
75 CREATE SEQUENCE action.survey_response_group_id_seq;
76
77 CREATE TABLE action.survey_response (
78         id                      BIGSERIAL                       PRIMARY KEY,
79         response_group_id       INT,
80         usr                     INT, -- REFERENCES actor.usr
81         survey                  INT                             NOT NULL REFERENCES action.survey DEFERRABLE INITIALLY DEFERRED,
82         question                INT                             NOT NULL REFERENCES action.survey_question DEFERRABLE INITIALLY DEFERRED,
83         answer                  INT                             NOT NULL REFERENCES action.survey_answer DEFERRABLE INITIALLY DEFERRED,
84         answer_date             TIMESTAMP WITH TIME ZONE,
85         effective_date          TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
86 );
87 CREATE OR REPLACE FUNCTION action.survey_response_answer_date_fixup () RETURNS TRIGGER AS '
88 BEGIN
89         NEW.answer_date := NOW();
90         RETURN NEW;
91 END;
92 ' LANGUAGE 'plpgsql';
93 CREATE TRIGGER action_survey_response_answer_date_fixup_tgr
94         BEFORE INSERT ON action.survey_response
95         FOR EACH ROW
96         EXECUTE PROCEDURE action.survey_response_answer_date_fixup ();
97
98
99 CREATE TABLE action.circulation (
100         target_copy             BIGINT                          NOT NULL, -- asset.copy.id
101         circ_lib                INT                             NOT NULL, -- actor.org_unit.id
102         circ_staff              INT                             NOT NULL, -- actor.usr.id
103         checkin_staff           INT,                                      -- actor.usr.id
104         checkin_lib             INT,                                      -- actor.org_unit.id
105         renewal_remaining       INT                             NOT NULL, -- derived from "circ duration" rule
106         due_date                TIMESTAMP WITH TIME ZONE,
107         stop_fines_time         TIMESTAMP WITH TIME ZONE,
108         checkin_time            TIMESTAMP WITH TIME ZONE,
109         create_time             TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
110         duration                INTERVAL,                                 -- derived from "circ duration" rule
111         fine_interval           INTERVAL                        NOT NULL DEFAULT '1 day'::INTERVAL, -- derived from "circ fine" rule
112         recuring_fine           NUMERIC(6,2),                             -- derived from "circ fine" rule
113         max_fine                NUMERIC(6,2),                             -- derived from "max fine" rule
114         phone_renewal           BOOL                            NOT NULL DEFAULT FALSE,
115         desk_renewal            BOOL                            NOT NULL DEFAULT FALSE,
116         opac_renewal            BOOL                            NOT NULL DEFAULT FALSE,
117         duration_rule           TEXT                            NOT NULL, -- name of "circ duration" rule
118         recuring_fine_rule      TEXT                            NOT NULL, -- name of "circ fine" rule
119         max_fine_rule           TEXT                            NOT NULL, -- name of "max fine" rule
120         stop_fines              TEXT                            CHECK (stop_fines IN ('CHECKIN','CLAIMSRETURNED','LOST','MAXFINES','RENEW','LONGOVERDUE'))
121 ) INHERITS (money.billable_xact);
122 ALTER TABLE action.circulation ADD PRIMARY KEY (id);
123 CREATE INDEX circ_open_xacts_idx ON action.circulation (usr) WHERE xact_finish IS NULL;
124 CREATE INDEX circ_outstanding_idx ON action.circulation (usr) WHERE checkin_time IS NULL;
125 CREATE INDEX circ_checkin_time ON "action".circulation (checkin_time) WHERE checkin_time IS NOT NULL;
126 CREATE INDEX circ_circ_lib_idx ON "action".circulation (circ_lib);
127 CREATE INDEX circ_open_date_idx ON "action".circulation (xact_start) WHERE xact_finish IS NULL;
128
129 CREATE TABLE action.aged_circulation (
130         usr_post_code           TEXT,
131         usr_home_ou             INT     NOT NULL,
132         usr_profile             INT     NOT NULL,
133         usr_birth_year          INT,
134         copy_call_number        INT     NOT NULL,
135         copy_location           INT     NOT NULL,
136         copy_owning_lib         INT     NOT NULL,
137         copy_circ_lib           INT     NOT NULL,
138         copy_bib_record         BIGINT  NOT NULL,
139         LIKE action.circulation
140
141 );
142 ALTER TABLE action.aged_circulation ADD PRIMARY KEY (id);
143 ALTER TABLE action.aged_circulation DROP COLUMN usr;
144 CREATE INDEX aged_circ_circ_lib_idx ON "action".aged_circulation (circ_lib);
145 CREATE INDEX aged_circ_start_idx ON "action".aged_circulation (xact_start);
146 CREATE INDEX aged_circ_copy_circ_lib_idx ON "action".aged_circulation (copy_circ_lib);
147 CREATE INDEX aged_circ_copy_owning_lib_idx ON "action".aged_circulation (copy_owning_lib);
148 CREATE INDEX aged_circ_copy_location_idx ON "action".aged_circulation (copy_location);
149
150 CREATE OR REPLACE VIEW action.all_circulation AS
151         SELECT  usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
152                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
153                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
154                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
155                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
156                 max_fine_rule, stop_fines
157           FROM  action.aged_circulation
158                         UNION ALL
159         SELECT  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,
160                 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,
161                 cn.record AS copy_bib_record, circ.xact_start, circ.xact_finish, circ.target_copy, circ.circ_lib, circ.circ_staff, circ.checkin_staff,
162                 circ.checkin_lib, circ.renewal_remaining, circ.due_date, circ.stop_fines_time, circ.checkin_time, circ.create_time, circ.duration,
163                 circ.fine_interval, circ.recuring_fine, circ.max_fine, circ.phone_renewal, circ.desk_renewal, circ.opac_renewal, circ.duration_rule,
164                 circ.recuring_fine_rule, circ.max_fine_rule, circ.stop_fines
165           FROM  action.circulation circ
166                 JOIN asset.copy cp ON (circ.target_copy = cp.id)
167                 JOIN asset.call_number cn ON (cp.call_number = cn.id)
168                 JOIN actor.usr p ON (circ.usr = p.id)
169                 LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
170                 LEFT JOIN actor.usr_address b ON (p.billing_address = a.id);
171
172 CREATE OR REPLACE VIEW action.open_circulation AS
173         SELECT  *
174           FROM  action.circulation
175           WHERE checkin_time IS NULL
176           ORDER BY due_date;
177                 
178
179 CREATE OR REPLACE VIEW action.billable_cirulations AS
180         SELECT  *
181           FROM  action.circulation
182           WHERE xact_finish IS NULL;
183
184 CREATE VIEW stats.fleshed_circulation AS
185         SELECT  c.*,
186                 CAST(c.xact_start AS DATE) AS start_date_day,
187                 CAST(c.xact_finish AS DATE) AS finish_date_day,
188                 DATE_TRUNC('hour', c.xact_start) AS start_date_hour,
189                 DATE_TRUNC('hour', c.xact_finish) AS finish_date_hour,
190                 cp.call_number_label,
191                 cp.owning_lib,
192                 cp.item_lang,
193                 cp.item_type,
194                 cp.item_form
195         FROM    "action".circulation c
196                 JOIN stats.fleshed_copy cp ON (cp.id = c.target_copy);
197
198
199 CREATE OR REPLACE FUNCTION action.circulation_claims_returned () RETURNS TRIGGER AS $$
200 BEGIN
201         IF OLD.stop_fines IS NULL OR OLD.stop_fines <> NEW.stop_fines THEN
202                 IF NEW.stop_fines = 'CLAIMSRETURNED' THEN
203                         UPDATE actor.usr SET claims_returned_count = claims_returned_count + 1 WHERE id = NEW.usr;
204                 END IF;
205                 IF NEW.stop_fines = 'LOST' THEN
206                         UPDATE asset.copy SET status = 3 WHERE id = NEW.target_copy;
207                 END IF;
208         END IF;
209         RETURN NEW;
210 END;
211 $$ LANGUAGE 'plpgsql';
212 CREATE TRIGGER action_circulation_stop_fines_tgr
213         BEFORE UPDATE ON action.circulation
214         FOR EACH ROW
215         EXECUTE PROCEDURE action.circulation_claims_returned ();
216
217
218 CREATE TABLE action.hold_request (
219         id                      SERIAL                          PRIMARY KEY,
220         request_time            TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
221         capture_time            TIMESTAMP WITH TIME ZONE,
222         fulfillment_time        TIMESTAMP WITH TIME ZONE,
223         checkin_time            TIMESTAMP WITH TIME ZONE,
224         return_time             TIMESTAMP WITH TIME ZONE,
225         prev_check_time         TIMESTAMP WITH TIME ZONE,
226         expire_time             TIMESTAMP WITH TIME ZONE,
227         cancel_time             TIMESTAMP WITH TIME ZONE,
228         target                  BIGINT                          NOT NULL, -- see hold_type
229         current_copy            BIGINT                          REFERENCES asset.copy (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
230         fulfillment_staff       INT                             REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
231         fulfillment_lib         INT                             REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
232         request_lib             INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
233         requestor               INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
234         usr                     INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
235         selection_ou            INT                             NOT NULL,
236         selection_depth         INT                             NOT NULL DEFAULT 0,
237         pickup_lib              INT                             NOT NULL REFERENCES actor.org_unit DEFERRABLE INITIALLY DEFERRED,
238         hold_type               TEXT                            NOT NULL CHECK (hold_type IN ('M','T','V','C')),
239         holdable_formats        TEXT,
240         phone_notify            TEXT,
241         email_notify            BOOL                            NOT NULL DEFAULT TRUE,
242         frozen                  BOOL                            NOT NULL DEFAULT FALSE,
243         thaw_date               TIMESTAMP WITH TIME ZONE
244 );
245
246 CREATE INDEX hold_request_target_idx ON action.hold_request (target);
247 CREATE INDEX hold_request_usr_idx ON action.hold_request (usr);
248 CREATE INDEX hold_request_pickup_lib_idx ON action.hold_request (pickup_lib);
249 CREATE INDEX hold_request_current_copy_idx ON action.hold_request (current_copy);
250 CREATE INDEX hold_request_prev_check_time_idx ON action.hold_request (prev_check_time);
251
252
253 CREATE TABLE action.hold_notification (
254         id              SERIAL                          PRIMARY KEY,
255         hold            INT                             NOT NULL REFERENCES action.hold_request (id) DEFERRABLE INITIALLY DEFERRED,
256         notify_staff    INT                             REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
257         notify_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
258         method          TEXT                            NOT NULL, -- email address or phone number
259         note            TEXT
260 );
261 CREATE INDEX ahn_hold_idx ON action.hold_notification (hold);
262
263 CREATE TABLE action.hold_copy_map (
264         id              SERIAL  PRIMARY KEY,
265         hold            INT     NOT NULL REFERENCES action.hold_request (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
266         target_copy     BIGINT  NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
267         CONSTRAINT copy_once_per_hold UNIQUE (hold,target_copy)
268 );
269 -- CREATE INDEX acm_hold_idx ON action.hold_copy_map (hold);
270 CREATE INDEX acm_copy_idx ON action.hold_copy_map (target_copy);
271
272 CREATE TABLE action.transit_copy (
273         id                      SERIAL                          PRIMARY KEY,
274         source_send_time        TIMESTAMP WITH TIME ZONE,
275         dest_recv_time          TIMESTAMP WITH TIME ZONE,
276         target_copy             BIGINT                          NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
277         source                  INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
278         dest                    INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
279         prev_hop                INT                             REFERENCES action.transit_copy (id) DEFERRABLE INITIALLY DEFERRED,
280         copy_status             INT                             NOT NULL REFERENCES config.copy_status (id) DEFERRABLE INITIALLY DEFERRED,
281         persistant_transfer     BOOL                            NOT NULL DEFAULT FALSE
282 );
283 CREATE INDEX active_transit_dest_idx ON "action".transit_copy (dest); 
284 CREATE INDEX active_transit_source_idx ON "action".transit_copy (source);
285 CREATE INDEX active_transit_cp_idx ON "action".transit_copy (target_copy);
286
287
288 CREATE TABLE action.hold_transit_copy (
289         hold    INT     REFERENCES action.hold_request (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
290 ) INHERITS (action.transit_copy);
291 ALTER TABLE action.hold_transit_copy ADD PRIMARY KEY (id);
292 ALTER TABLE action.hold_transit_copy ADD CONSTRAINT ahtc_tc_fkey FOREIGN KEY (target_copy) REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
293 CREATE INDEX active_hold_transit_dest_idx ON "action".hold_transit_copy (dest);
294 CREATE INDEX active_hold_transit_source_idx ON "action".hold_transit_copy (source);
295 CREATE INDEX active_hold_transit_cp_idx ON "action".hold_transit_copy (target_copy);
296
297
298 CREATE TABLE action.unfulfilled_hold_list (
299         id              BIGSERIAL                       PRIMARY KEY,
300         current_copy    BIGINT                          NOT NULL,
301         hold            INT                             NOT NULL,
302         circ_lib        INT                             NOT NULL,
303         fail_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
304 );
305
306 COMMIT;
307