]> git.evergreen-ils.org Git - working/Evergreen.git/blob - Open-ILS/src/sql/Pg/090.schema.action.sql
teaching record merge function how to copy over 856 tags when there is a MARC-mapped...
[working/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 TRIGGER mat_summary_create_tgr AFTER INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_create ();
130 CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
131 CREATE TRIGGER mat_summary_remove_tgr AFTER DELETE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_delete ();
132
133
134 CREATE TABLE action.aged_circulation (
135         usr_post_code           TEXT,
136         usr_home_ou             INT     NOT NULL,
137         usr_profile             INT     NOT NULL,
138         usr_birth_year          INT,
139         copy_call_number        INT     NOT NULL,
140         copy_location           INT     NOT NULL,
141         copy_owning_lib         INT     NOT NULL,
142         copy_circ_lib           INT     NOT NULL,
143         copy_bib_record         BIGINT  NOT NULL,
144         LIKE action.circulation
145
146 );
147 ALTER TABLE action.aged_circulation ADD PRIMARY KEY (id);
148 ALTER TABLE action.aged_circulation DROP COLUMN usr;
149 CREATE INDEX aged_circ_circ_lib_idx ON "action".aged_circulation (circ_lib);
150 CREATE INDEX aged_circ_start_idx ON "action".aged_circulation (xact_start);
151 CREATE INDEX aged_circ_copy_circ_lib_idx ON "action".aged_circulation (copy_circ_lib);
152 CREATE INDEX aged_circ_copy_owning_lib_idx ON "action".aged_circulation (copy_owning_lib);
153 CREATE INDEX aged_circ_copy_location_idx ON "action".aged_circulation (copy_location);
154
155 CREATE OR REPLACE VIEW action.all_circulation AS
156         SELECT  id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
157                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
158                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
159                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
160                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
161                 max_fine_rule, stop_fines
162           FROM  action.aged_circulation
163                         UNION ALL
164         SELECT  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,
165                 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,
166                 cn.record AS copy_bib_record, circ.xact_start, circ.xact_finish, circ.target_copy, circ.circ_lib, circ.circ_staff, circ.checkin_staff,
167                 circ.checkin_lib, circ.renewal_remaining, circ.due_date, circ.stop_fines_time, circ.checkin_time, circ.create_time, circ.duration,
168                 circ.fine_interval, circ.recuring_fine, circ.max_fine, circ.phone_renewal, circ.desk_renewal, circ.opac_renewal, circ.duration_rule,
169                 circ.recuring_fine_rule, circ.max_fine_rule, circ.stop_fines
170           FROM  action.circulation circ
171                 JOIN asset.copy cp ON (circ.target_copy = cp.id)
172                 JOIN asset.call_number cn ON (cp.call_number = cn.id)
173                 JOIN actor.usr p ON (circ.usr = p.id)
174                 LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
175                 LEFT JOIN actor.usr_address b ON (p.billing_address = a.id);
176
177 CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$
178 BEGIN
179         INSERT INTO action.aged_circulation
180                 (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
181                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
182                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
183                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
184                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
185                 max_fine_rule, stop_fines)
186           SELECT
187                 id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
188                 copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
189                 circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, due_date,
190                 stop_fines_time, checkin_time, create_time, duration, fine_interval, recuring_fine,
191                 max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recuring_fine_rule,
192                 max_fine_rule, stop_fines
193             FROM action.all_circulation WHERE id = OLD.id;
194
195         RETURN OLD;
196 END;
197 $$ LANGUAGE 'plpgsql';
198
199 CREATE TRIGGER action_circulation_aging_tgr
200         BEFORE DELETE ON action.circulation
201         FOR EACH ROW
202         EXECUTE PROCEDURE action.age_circ_on_delete ();
203
204
205 CREATE OR REPLACE VIEW action.open_circulation AS
206         SELECT  *
207           FROM  action.circulation
208           WHERE checkin_time IS NULL
209           ORDER BY due_date;
210                 
211
212 CREATE OR REPLACE VIEW action.billable_circulations AS
213         SELECT  *
214           FROM  action.circulation
215           WHERE xact_finish IS NULL;
216
217 CREATE VIEW stats.fleshed_circulation AS
218         SELECT  c.*,
219                 CAST(c.xact_start AS DATE) AS start_date_day,
220                 CAST(c.xact_finish AS DATE) AS finish_date_day,
221                 DATE_TRUNC('hour', c.xact_start) AS start_date_hour,
222                 DATE_TRUNC('hour', c.xact_finish) AS finish_date_hour,
223                 cp.call_number_label,
224                 cp.owning_lib,
225                 cp.item_lang,
226                 cp.item_type,
227                 cp.item_form
228         FROM    "action".circulation c
229                 JOIN stats.fleshed_copy cp ON (cp.id = c.target_copy);
230
231
232 CREATE OR REPLACE FUNCTION action.circulation_claims_returned () RETURNS TRIGGER AS $$
233 BEGIN
234         IF OLD.stop_fines IS NULL OR OLD.stop_fines <> NEW.stop_fines THEN
235                 IF NEW.stop_fines = 'CLAIMSRETURNED' THEN
236                         UPDATE actor.usr SET claims_returned_count = claims_returned_count + 1 WHERE id = NEW.usr;
237                 END IF;
238                 IF NEW.stop_fines = 'LOST' THEN
239                         UPDATE asset.copy SET status = 3 WHERE id = NEW.target_copy;
240                 END IF;
241         END IF;
242         RETURN NEW;
243 END;
244 $$ LANGUAGE 'plpgsql';
245 CREATE TRIGGER action_circulation_stop_fines_tgr
246         BEFORE UPDATE ON action.circulation
247         FOR EACH ROW
248         EXECUTE PROCEDURE action.circulation_claims_returned ();
249
250 CREATE TABLE action.hold_request_cancel_cause (
251     id      SERIAL  PRIMARY KEY,
252     label   TEXT    UNIQUE
253 );
254 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (1,'Untargeted expiration');
255 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (2,'Hold Shelf expiration');
256 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (3,'Patron via phone');
257 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (4,'Patron in person');
258 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (5,'Staff forced');
259 INSERT INTO action.hold_request_cancel_cause (id,label) VALUES (6,'Patron via OPAC');
260 SELECT SETVAL('action.hold_request_cancel_cause_id_seq', 100);
261
262 CREATE TABLE action.hold_request (
263         id                      SERIAL                          PRIMARY KEY,
264         request_time            TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
265         capture_time            TIMESTAMP WITH TIME ZONE,
266         fulfillment_time        TIMESTAMP WITH TIME ZONE,
267         checkin_time            TIMESTAMP WITH TIME ZONE,
268         return_time             TIMESTAMP WITH TIME ZONE,
269         prev_check_time         TIMESTAMP WITH TIME ZONE,
270         expire_time             TIMESTAMP WITH TIME ZONE,
271         cancel_time             TIMESTAMP WITH TIME ZONE,
272         cancel_cause    INT REFERENCES action.hold_request_cancel_cause (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
273         cancel_note             TEXT,
274         target                  BIGINT                          NOT NULL, -- see hold_type
275         current_copy            BIGINT                          REFERENCES asset.copy (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
276         fulfillment_staff       INT                             REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
277         fulfillment_lib         INT                             REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
278         request_lib             INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
279         requestor               INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
280         usr                     INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
281         selection_ou            INT                             NOT NULL,
282         selection_depth         INT                             NOT NULL DEFAULT 0,
283         pickup_lib              INT                             NOT NULL REFERENCES actor.org_unit DEFERRABLE INITIALLY DEFERRED,
284         hold_type               TEXT                            NOT NULL CHECK (hold_type IN ('M','T','V','C')),
285         holdable_formats        TEXT,
286         phone_notify            TEXT,
287         email_notify            BOOL                            NOT NULL DEFAULT TRUE,
288         frozen                  BOOL                            NOT NULL DEFAULT FALSE,
289         thaw_date               TIMESTAMP WITH TIME ZONE
290 );
291
292 CREATE INDEX hold_request_target_idx ON action.hold_request (target);
293 CREATE INDEX hold_request_usr_idx ON action.hold_request (usr);
294 CREATE INDEX hold_request_pickup_lib_idx ON action.hold_request (pickup_lib);
295 CREATE INDEX hold_request_current_copy_idx ON action.hold_request (current_copy);
296 CREATE INDEX hold_request_prev_check_time_idx ON action.hold_request (prev_check_time);
297
298
299 CREATE TABLE action.hold_notification (
300         id              SERIAL                          PRIMARY KEY,
301         hold            INT                             NOT NULL REFERENCES action.hold_request (id) DEFERRABLE INITIALLY DEFERRED,
302         notify_staff    INT                             REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
303         notify_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
304         method          TEXT                            NOT NULL, -- email address or phone number
305         note            TEXT
306 );
307 CREATE INDEX ahn_hold_idx ON action.hold_notification (hold);
308
309 CREATE TABLE action.hold_copy_map (
310         id              SERIAL  PRIMARY KEY,
311         hold            INT     NOT NULL REFERENCES action.hold_request (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
312         target_copy     BIGINT  NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
313         CONSTRAINT copy_once_per_hold UNIQUE (hold,target_copy)
314 );
315 -- CREATE INDEX acm_hold_idx ON action.hold_copy_map (hold);
316 CREATE INDEX acm_copy_idx ON action.hold_copy_map (target_copy);
317
318 CREATE TABLE action.transit_copy (
319         id                      SERIAL                          PRIMARY KEY,
320         source_send_time        TIMESTAMP WITH TIME ZONE,
321         dest_recv_time          TIMESTAMP WITH TIME ZONE,
322         target_copy             BIGINT                          NOT NULL REFERENCES asset.copy (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
323         source                  INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
324         dest                    INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
325         prev_hop                INT                             REFERENCES action.transit_copy (id) DEFERRABLE INITIALLY DEFERRED,
326         copy_status             INT                             NOT NULL REFERENCES config.copy_status (id) DEFERRABLE INITIALLY DEFERRED,
327         persistant_transfer     BOOL                            NOT NULL DEFAULT FALSE
328 );
329 CREATE INDEX active_transit_dest_idx ON "action".transit_copy (dest); 
330 CREATE INDEX active_transit_source_idx ON "action".transit_copy (source);
331 CREATE INDEX active_transit_cp_idx ON "action".transit_copy (target_copy);
332
333
334 CREATE TABLE action.hold_transit_copy (
335         hold    INT     REFERENCES action.hold_request (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
336 ) INHERITS (action.transit_copy);
337 ALTER TABLE action.hold_transit_copy ADD PRIMARY KEY (id);
338 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;
339 CREATE INDEX active_hold_transit_dest_idx ON "action".hold_transit_copy (dest);
340 CREATE INDEX active_hold_transit_source_idx ON "action".hold_transit_copy (source);
341 CREATE INDEX active_hold_transit_cp_idx ON "action".hold_transit_copy (target_copy);
342
343
344 CREATE TABLE action.unfulfilled_hold_list (
345         id              BIGSERIAL                       PRIMARY KEY,
346         current_copy    BIGINT                          NOT NULL,
347         hold            INT                             NOT NULL,
348         circ_lib        INT                             NOT NULL,
349         fail_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW()
350 );
351
352 CREATE OR REPLACE FUNCTION asset.merge_record_assets( target_record BIGINT, source_record BIGINT ) RETURNS INT AS $func$
353 DECLARE
354         moved_objects INT := 0;
355         source_cn     asset.call_number%ROWTYPE;
356         target_cn     asset.call_number%ROWTYPE;
357         metarec       metabib.metarecord%ROWTYPE;
358         hold          action.hold_request%ROWTYPE;
359     uri_count     INT := 0;
360     counter       INT := 0;
361     uri_datafield TEXT;
362     uri_text      TEXT := '';
363 BEGIN
364
365     -- move any 856 entries on records that have at least one MARC-mapped URI entry
366     SELECT  INTO uri_count COUNT(*)
367       FROM  asset.uri_call_number_map m
368             JOIN asset.call_number cn ON (m.call_number = cn.id)
369       WHERE cn.record = source_record;
370
371     IF uri_count > 0 THEN
372         
373         SELECT  COUNT(*) INTO counter
374           FROM  xpath_table(
375                     'id',
376                     'marc',
377                     'acq.lineitem',
378                     '//*[@tag="856"]',
379                     'id=' || lineitem
380                 ) as t(i int,c text);
381     
382         FOR i IN 1 .. counter LOOP
383             SELECT  '<datafield xmlns="http://www.loc.gov/MARC21/slim" tag="856">' ||
384                         array_to_string(
385                             array_accum(
386                                 '<subfield code="' || subfield || '">' ||
387                                 regexp_replace(
388                                     regexp_replace(
389                                         regexp_replace(data,'&','&amp;','g'),
390                                         '>', '&gt;', 'g'
391                                     ),
392                                     '<', '&lt;', 'g'
393                                 ) || '</subfield>'
394                             ), ''
395                         ) || '</datafield>' INTO uri_datafield
396               FROM  xpath_table(
397                         'id',
398                         'marc',
399                         'biblio.record_entry',
400                         '//*[@tag="856"][position()=' || i || ']/*/@code|' ||
401                         '//*[@tag="856"][position()=' || i || ']/*[@code]',
402                         'id=' || source_record
403                     ) as t(id int,subfield text,data text);
404
405             uri_text := uri_text || uri_datafield;
406         END LOOP;
407
408         IF uri_text <> '' THEN
409             UPDATE  biblio.record_entry
410               SET   marc = regexp_replace(marc,'(</[^>]*record>)', uri_text || E'\\1')
411               WHERE id = target_record;
412         END IF;
413
414     END IF;
415
416         -- Find and move metarecords to the target record
417         SELECT  INTO metarec *
418           FROM  metabib.metarecord
419           WHERE master_record = source_record;
420
421         IF FOUND THEN
422                 UPDATE  metabib.metarecord
423                   SET   master_record = target_record,
424                         mods = NULL
425                   WHERE id = metarec.id;
426
427                 moved_objects := moved_objects + 1;
428         END IF;
429
430         -- Find call numbers attached to the source ...
431         FOR source_cn IN SELECT * FROM asset.call_number WHERE record = source_record LOOP
432
433                 SELECT  INTO target_cn *
434                   FROM  asset.call_number
435                   WHERE label = source_cn.label
436                         AND owning_lib = source_cn.owning_lib
437                         AND record = target_record;
438
439                 -- ... and if there's a conflicting one on the target ...
440                 IF FOUND THEN
441
442                         -- ... move the copies to that, and ...
443                         UPDATE  asset.copy
444                           SET   call_number = target_cn.id
445                           WHERE call_number = source_cn.id;
446
447                         -- ... move V holds to the move-target call number
448                         FOR hold IN SELECT * FROM action.hold_request WHERE target = source_cn.id AND hold_type = 'V' LOOP
449                 
450                                 UPDATE  action.hold_request
451                                   SET   target = target_cn.id
452                                   WHERE id = hold.id;
453                 
454                                 moved_objects := moved_objects + 1;
455                         END LOOP;
456
457                 -- ... if not ...
458                 ELSE
459                         -- ... just move the call number to the target record
460                         UPDATE  asset.call_number
461                           SET   record = target_record
462                           WHERE id = source_cn.id;
463                 END IF;
464
465                 moved_objects := moved_objects + 1;
466         END LOOP;
467
468         -- Find T holds targeting the source record ...
469         FOR hold IN SELECT * FROM action.hold_request WHERE target = source_record AND hold_type = 'T' LOOP
470
471                 -- ... and move them to the target record
472                 UPDATE  action.hold_request
473                   SET   target = target_record
474                   WHERE id = hold.id;
475
476                 moved_objects := moved_objects + 1;
477         END LOOP;
478
479         -- That's all, folks!
480         RETURN moved_objects;
481 END;
482 $func$ LANGUAGE plpgsql;
483
484 COMMIT;
485