]> git.evergreen-ils.org Git - Evergreen.git/blob - Open-ILS/src/sql/Pg/090.schema.action.sql
moving the the upgrade SQL scripts to an unversioned "upgrade" directory instead...
[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 CREATE INDEX action_in_house_use_staff_idx      ON action.in_house_use ( staff );
32
33 CREATE TABLE action.non_cataloged_circulation (
34         id              SERIAL                          PRIMARY KEY,
35         patron          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
36         staff           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
37         circ_lib        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
38         item_type       INT                             NOT NULL REFERENCES config.non_cataloged_type (id) DEFERRABLE INITIALLY DEFERRED,
39         circ_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
40 );
41 CREATE INDEX action_non_cat_circ_patron_idx ON action.non_cataloged_circulation ( patron );
42 CREATE INDEX action_non_cat_circ_staff_idx  ON action.non_cataloged_circulation ( staff );
43
44 CREATE TABLE action.non_cat_in_house_use (
45         id              SERIAL                          PRIMARY KEY,
46         item_type       BIGINT                          NOT NULL REFERENCES config.non_cataloged_type(id) DEFERRABLE INITIALLY DEFERRED,
47         staff           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
48         org_unit        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
49         use_time        TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
50 );
51 CREATE INDEX non_cat_in_house_use_staff_idx ON action.non_cat_in_house_use ( staff );
52
53 CREATE TABLE action.survey (
54         id              SERIAL                          PRIMARY KEY,
55         owner           INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
56         start_date      TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
57         end_date        TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW() + '10 years'::INTERVAL,
58         usr_summary     BOOL                            NOT NULL DEFAULT FALSE,
59         opac            BOOL                            NOT NULL DEFAULT FALSE,
60         poll            BOOL                            NOT NULL DEFAULT FALSE,
61         required        BOOL                            NOT NULL DEFAULT FALSE,
62         name            TEXT                            NOT NULL,
63         description     TEXT                            NOT NULL
64 );
65 CREATE UNIQUE INDEX asv_once_per_owner_idx ON action.survey (owner,name);
66
67 CREATE TABLE action.survey_question (
68         id              SERIAL  PRIMARY KEY,
69         survey          INT     NOT NULL REFERENCES action.survey DEFERRABLE INITIALLY DEFERRED,
70         question        TEXT    NOT NULL
71 );
72
73 CREATE TABLE action.survey_answer (
74         id              SERIAL  PRIMARY KEY,
75         question        INT     NOT NULL REFERENCES action.survey_question DEFERRABLE INITIALLY DEFERRED,
76         answer          TEXT    NOT NULL
77 );
78
79 CREATE SEQUENCE action.survey_response_group_id_seq;
80
81 CREATE TABLE action.survey_response (
82         id                      BIGSERIAL                       PRIMARY KEY,
83         response_group_id       INT,
84         usr                     INT, -- REFERENCES actor.usr
85         survey                  INT                             NOT NULL REFERENCES action.survey DEFERRABLE INITIALLY DEFERRED,
86         question                INT                             NOT NULL REFERENCES action.survey_question DEFERRABLE INITIALLY DEFERRED,
87         answer                  INT                             NOT NULL REFERENCES action.survey_answer DEFERRABLE INITIALLY DEFERRED,
88         answer_date             TIMESTAMP WITH TIME ZONE,
89         effective_date          TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
90 );
91 CREATE INDEX action_survey_response_usr_idx ON action.survey_response ( usr );
92
93 CREATE OR REPLACE FUNCTION action.survey_response_answer_date_fixup () RETURNS TRIGGER AS '
94 BEGIN
95         NEW.answer_date := NOW();
96         RETURN NEW;
97 END;
98 ' LANGUAGE 'plpgsql';
99 CREATE TRIGGER action_survey_response_answer_date_fixup_tgr
100         BEFORE INSERT ON action.survey_response
101         FOR EACH ROW
102         EXECUTE PROCEDURE action.survey_response_answer_date_fixup ();
103
104
105 CREATE TABLE action.circulation (
106         target_copy             BIGINT                          NOT NULL, -- asset.copy.id
107         circ_lib                INT                             NOT NULL, -- actor.org_unit.id
108         circ_staff              INT                             NOT NULL, -- actor.usr.id
109         checkin_staff           INT,                                      -- actor.usr.id
110         checkin_lib             INT,                                      -- actor.org_unit.id
111         renewal_remaining       INT                             NOT NULL, -- derived from "circ duration" rule
112         due_date                TIMESTAMP WITH TIME ZONE,
113         stop_fines_time         TIMESTAMP WITH TIME ZONE,
114         checkin_time            TIMESTAMP WITH TIME ZONE,
115         create_time             TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
116         duration                INTERVAL,                                 -- derived from "circ duration" rule
117         fine_interval           INTERVAL                        NOT NULL DEFAULT '1 day'::INTERVAL, -- derived from "circ fine" rule
118         recuring_fine           NUMERIC(6,2),                             -- derived from "circ fine" rule
119         max_fine                NUMERIC(6,2),                             -- derived from "max fine" rule
120         phone_renewal           BOOL                            NOT NULL DEFAULT FALSE,
121         desk_renewal            BOOL                            NOT NULL DEFAULT FALSE,
122         opac_renewal            BOOL                            NOT NULL DEFAULT FALSE,
123         duration_rule           TEXT                            NOT NULL, -- name of "circ duration" rule
124         recuring_fine_rule      TEXT                            NOT NULL, -- name of "circ fine" rule
125         max_fine_rule           TEXT                            NOT NULL, -- name of "max fine" rule
126         stop_fines              TEXT                            CHECK (stop_fines IN ('CHECKIN','CLAIMSRETURNED','LOST','MAXFINES','RENEW','LONGOVERDUE')),
127         workstation         INT        REFERENCES actor.workstation(id)
128                                        ON DELETE SET NULL
129                                                                    DEFERRABLE INITIALLY DEFERRED,
130         checkin_workstation INT        REFERENCES actor.workstation(id)
131                                        ON DELETE SET NULL
132                                                                    DEFERRABLE INITIALLY DEFERRED
133 ) INHERITS (money.billable_xact);
134 ALTER TABLE action.circulation ADD PRIMARY KEY (id);
135 CREATE INDEX circ_open_xacts_idx ON action.circulation (usr) WHERE xact_finish IS NULL;
136 CREATE INDEX circ_outstanding_idx ON action.circulation (usr) WHERE checkin_time IS NULL;
137 CREATE INDEX circ_checkin_time ON "action".circulation (checkin_time) WHERE checkin_time IS NOT NULL;
138 CREATE INDEX circ_circ_lib_idx ON "action".circulation (circ_lib);
139 CREATE INDEX circ_open_date_idx ON "action".circulation (xact_start) WHERE xact_finish IS NULL;
140 CREATE INDEX circ_all_usr_idx       ON action.circulation ( usr );
141 CREATE INDEX circ_circ_staff_idx    ON action.circulation ( circ_staff );
142 CREATE INDEX circ_checkin_staff_idx ON action.circulation ( checkin_staff );
143
144 CREATE TRIGGER mat_summary_create_tgr AFTER INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_create ();
145 CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
146 CREATE TRIGGER mat_summary_remove_tgr AFTER DELETE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_delete ();
147
148
149 CREATE TABLE action.aged_circulation (
150         usr_post_code           TEXT,
151         usr_home_ou             INT     NOT NULL,
152         usr_profile             INT     NOT NULL,
153         usr_birth_year          INT,
154         copy_call_number        INT     NOT NULL,
155         copy_location           INT     NOT NULL,
156         copy_owning_lib         INT     NOT NULL,
157         copy_circ_lib           INT     NOT NULL,
158         copy_bib_record         BIGINT  NOT NULL,
159         LIKE action.circulation
160
161 );
162 ALTER TABLE action.aged_circulation ADD PRIMARY KEY (id);
163 ALTER TABLE action.aged_circulation DROP COLUMN usr;
164 CREATE INDEX aged_circ_circ_lib_idx ON "action".aged_circulation (circ_lib);
165 CREATE INDEX aged_circ_start_idx ON "action".aged_circulation (xact_start);
166 CREATE INDEX aged_circ_copy_circ_lib_idx ON "action".aged_circulation (copy_circ_lib);
167 CREATE INDEX aged_circ_copy_owning_lib_idx ON "action".aged_circulation (copy_owning_lib);
168 CREATE INDEX aged_circ_copy_location_idx ON "action".aged_circulation (copy_location);
169
170 CREATE OR REPLACE VIEW action.all_circulation AS
171         SELECT  id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
172                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
173                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
174                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
175                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
176                 max_fine_rule, stop_fines
177           FROM  action.aged_circulation
178                         UNION ALL
179         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,
180                 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,
181                 cn.record AS copy_bib_record, circ.xact_start, circ.xact_finish, circ.target_copy, circ.circ_lib, circ.circ_staff, circ.checkin_staff,
182                 circ.checkin_lib, circ.renewal_remaining, circ.due_date, circ.stop_fines_time, circ.checkin_time, circ.create_time, circ.duration,
183                 circ.fine_interval, circ.recuring_fine, circ.max_fine, circ.phone_renewal, circ.desk_renewal, circ.opac_renewal, circ.duration_rule,
184                 circ.recuring_fine_rule, circ.max_fine_rule, circ.stop_fines
185           FROM  action.circulation circ
186                 JOIN asset.copy cp ON (circ.target_copy = cp.id)
187                 JOIN asset.call_number cn ON (cp.call_number = cn.id)
188                 JOIN actor.usr p ON (circ.usr = p.id)
189                 LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
190                 LEFT JOIN actor.usr_address b ON (p.billing_address = a.id);
191
192 CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$
193 BEGIN
194         INSERT INTO action.aged_circulation
195                 (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
196                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
197                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
198                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
199                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
200                 max_fine_rule, stop_fines)
201           SELECT
202                 id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
203                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
204                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
205                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
206                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
207                 max_fine_rule, stop_fines
208             FROM action.all_circulation WHERE id = OLD.id;
209
210         RETURN OLD;
211 END;
212 $$ LANGUAGE 'plpgsql';
213
214 CREATE TRIGGER action_circulation_aging_tgr
215         BEFORE DELETE ON action.circulation
216         FOR EACH ROW
217         EXECUTE PROCEDURE action.age_circ_on_delete ();
218
219
220 CREATE OR REPLACE VIEW action.open_circulation AS
221         SELECT  *
222           FROM  action.circulation
223           WHERE checkin_time IS NULL
224           ORDER BY due_date;
225                 
226
227 CREATE OR REPLACE VIEW action.billable_circulations AS
228         SELECT  *
229           FROM  action.circulation
230           WHERE xact_finish IS NULL;
231
232 CREATE VIEW stats.fleshed_circulation AS
233         SELECT  c.*,
234                 CAST(c.xact_start AS DATE) AS start_date_day,
235                 CAST(c.xact_finish AS DATE) AS finish_date_day,
236                 DATE_TRUNC('hour', c.xact_start) AS start_date_hour,
237                 DATE_TRUNC('hour', c.xact_finish) AS finish_date_hour,
238                 cp.call_number_label,
239                 cp.owning_lib,
240                 cp.item_lang,
241                 cp.item_type,
242                 cp.item_form
243         FROM    "action".circulation c
244                 JOIN stats.fleshed_copy cp ON (cp.id = c.target_copy);
245
246
247 CREATE OR REPLACE FUNCTION action.circulation_claims_returned () RETURNS TRIGGER AS $$
248 BEGIN
249         IF OLD.stop_fines IS NULL OR OLD.stop_fines <> NEW.stop_fines THEN
250                 IF NEW.stop_fines = 'CLAIMSRETURNED' THEN
251                         UPDATE actor.usr SET claims_returned_count = claims_returned_count + 1 WHERE id = NEW.usr;
252                 END IF;
253                 IF NEW.stop_fines = 'LOST' THEN
254                         UPDATE asset.copy SET status = 3 WHERE id = NEW.target_copy;
255                 END IF;
256         END IF;
257         RETURN NEW;
258 END;
259 $$ LANGUAGE 'plpgsql';
260 CREATE TRIGGER action_circulation_stop_fines_tgr
261         BEFORE UPDATE ON action.circulation
262         FOR EACH ROW
263         EXECUTE PROCEDURE action.circulation_claims_returned ();
264
265 CREATE TABLE action.hold_request_cancel_cause (
266     id      SERIAL  PRIMARY KEY,
267     label   TEXT    UNIQUE
268 );
269 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (1,'Untargeted expiration');
270 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (2,'Hold Shelf expiration');
271 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (3,'Patron via phone');
272 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (4,'Patron in person');
273 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (5,'Staff forced');
274 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (6,'Patron via OPAC');
275 SELECT SETVAL('action.hold_request_cancel_cause_id_seq', 100);
276
277 CREATE TABLE action.hold_request (
278         id                      SERIAL                          PRIMARY KEY,
279         request_time            TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
280         capture_time            TIMESTAMP WITH TIME ZONE,
281         fulfillment_time        TIMESTAMP WITH TIME ZONE,
282         checkin_time            TIMESTAMP WITH TIME ZONE,
283         return_time             TIMESTAMP WITH TIME ZONE,
284         prev_check_time         TIMESTAMP WITH TIME ZONE,
285         expire_time             TIMESTAMP WITH TIME ZONE,
286         cancel_time             TIMESTAMP WITH TIME ZONE,
287         cancel_cause    INT REFERENCES action.hold_request_cancel_cause (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
288         cancel_note             TEXT,
289         target                  BIGINT                          NOT NULL, -- see hold_type
290         current_copy            BIGINT                          REFERENCES asset.copy (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
291         fulfillment_staff       INT                             REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
292         fulfillment_lib         INT                             REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
293         request_lib             INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
294         requestor               INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
295         usr                     INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
296         selection_ou            INT                             NOT NULL,
297         selection_depth         INT                             NOT NULL DEFAULT 0,
298         pickup_lib              INT                             NOT NULL REFERENCES actor.org_unit DEFERRABLE INITIALLY DEFERRED,
299         hold_type               TEXT                            NOT NULL CHECK (hold_type IN ('M','T','V','C')),
300         holdable_formats        TEXT,
301         phone_notify            TEXT,
302         email_notify            BOOL                            NOT NULL DEFAULT TRUE,
303         frozen                  BOOL                            NOT NULL DEFAULT FALSE,
304         thaw_date               TIMESTAMP WITH TIME ZONE,
305         shelf_time              TIMESTAMP WITH TIME ZONE
306 );
307
308 CREATE INDEX hold_request_target_idx ON action.hold_request (target);
309 CREATE INDEX hold_request_usr_idx ON action.hold_request (usr);
310 CREATE INDEX hold_request_pickup_lib_idx ON action.hold_request (pickup_lib);
311 CREATE INDEX hold_request_current_copy_idx ON action.hold_request (current_copy);
312 CREATE INDEX hold_request_prev_check_time_idx ON action.hold_request (prev_check_time);
313 CREATE INDEX hold_request_fulfillment_staff_idx ON action.hold_request ( fulfillment_staff );
314 CREATE INDEX hold_request_requestor_idx         ON action.hold_request ( requestor );
315
316
317 CREATE TABLE action.hold_request_note (
318
319     id     BIGSERIAL PRIMARY KEY,
320     hold   BIGINT    NOT NULL REFERENCES action.hold_request (id)
321                               ON DELETE CASCADE
322                               DEFERRABLE INITIALLY DEFERRED,
323     title  TEXT      NOT NULL,
324     body   TEXT      NOT NULL,
325     slip   BOOL      NOT NULL DEFAULT FALSE,
326     pub    BOOL      NOT NULL DEFAULT FALSE,
327     staff  BOOL      NOT NULL DEFAULT FALSE  -- created by staff
328
329 );
330 CREATE INDEX ahrn_hold_idx ON action.hold_request_note (hold);
331
332
333 CREATE TABLE action.hold_notification (
334         id              SERIAL                          PRIMARY KEY,
335         hold            INT                             NOT NULL REFERENCES action.hold_request (id)
336                                                                         ON DELETE CASCADE
337                                                                         DEFERRABLE INITIALLY DEFERRED,
338         notify_staff    INT                     REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
339         notify_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
340         method          TEXT                            NOT NULL, -- email address or phone number
341         note            TEXT
342 );
343 CREATE INDEX ahn_hold_idx ON action.hold_notification (hold);
344 CREATE INDEX ahn_notify_staff_idx ON action.hold_notification ( notify_staff );
345
346 CREATE TABLE action.hold_copy_map (
347         id              SERIAL  PRIMARY KEY,
348         hold            INT     NOT NULL REFERENCES action.hold_request (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
349         target_copy     BIGINT  NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
350         CONSTRAINT copy_once_per_hold UNIQUE (hold,target_copy)
351 );
352 -- CREATE INDEX acm_hold_idx ON action.hold_copy_map (hold);
353 CREATE INDEX acm_copy_idx ON action.hold_copy_map (target_copy);
354
355 CREATE TABLE action.transit_copy (
356         id                      SERIAL                          PRIMARY KEY,
357         source_send_time        TIMESTAMP WITH TIME ZONE,
358         dest_recv_time          TIMESTAMP WITH TIME ZONE,
359         target_copy             BIGINT                          NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
360         source                  INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
361         dest                    INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
362         prev_hop                INT                             REFERENCES action.transit_copy (id) DEFERRABLE INITIALLY DEFERRED,
363         copy_status             INT                             NOT NULL REFERENCES config.copy_status (id) DEFERRABLE INITIALLY DEFERRED,
364         persistant_transfer     BOOL                            NOT NULL DEFAULT FALSE
365 );
366 CREATE INDEX active_transit_dest_idx ON "action".transit_copy (dest); 
367 CREATE INDEX active_transit_source_idx ON "action".transit_copy (source);
368 CREATE INDEX active_transit_cp_idx ON "action".transit_copy (target_copy);
369
370
371 CREATE TABLE action.hold_transit_copy (
372         hold    INT     REFERENCES action.hold_request (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
373 ) INHERITS (action.transit_copy);
374 ALTER TABLE action.hold_transit_copy ADD PRIMARY KEY (id);
375 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;
376 CREATE INDEX active_hold_transit_dest_idx ON "action".hold_transit_copy (dest);
377 CREATE INDEX active_hold_transit_source_idx ON "action".hold_transit_copy (source);
378 CREATE INDEX active_hold_transit_cp_idx ON "action".hold_transit_copy (target_copy);
379
380
381 CREATE TABLE action.unfulfilled_hold_list (
382         id              BIGSERIAL                       PRIMARY KEY,
383         current_copy    BIGINT                          NOT NULL,
384         hold            INT                             NOT NULL,
385         circ_lib        INT                             NOT NULL,
386         fail_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
387 );
388 CREATE INDEX uhr_hold_idx ON action.unfulfilled_hold_list (hold);
389
390 CREATE OR REPLACE VIEW action.unfulfilled_hold_loops AS
391     SELECT  u.hold,
392             c.circ_lib,
393             count(*)
394       FROM  action.unfulfilled_hold_list u
395             JOIN asset.copy c ON (c.id = u.current_copy)
396       GROUP BY 1,2;
397
398 CREATE OR REPLACE VIEW action.unfulfilled_hold_min_loop AS
399     SELECT  hold,
400             min(count)
401       FROM  action.unfulfilled_hold_loops
402       GROUP BY 1;
403
404 CREATE OR REPLACE VIEW action.unfulfilled_hold_innermost_loop AS
405     SELECT  DISTINCT l.*
406       FROM  action.unfulfilled_hold_loops l
407             JOIN action.unfulfilled_hold_min_loop m USING (hold)
408       WHERE l.count = m.min;
409
410
411 COMMIT;
412