From: miker Date: Fri, 24 Oct 2008 16:53:15 +0000 (+0000) Subject: adding vandelay; reordering some commands; conditional index dropping X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=b16315a5368d44fea78c92b1012bb0b4fa79b308;p=Evergreen.git adding vandelay; reordering some commands; conditional index dropping git-svn-id: svn://svn.open-ils.org/ILS/branches/rel_1_4@10898 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- diff --git a/Open-ILS/src/sql/Pg/1.2.3-1.4-upgrade-db.sql b/Open-ILS/src/sql/Pg/1.2.3-1.4-upgrade-db.sql index 78ff99f5c7..89b990de8d 100644 --- a/Open-ILS/src/sql/Pg/1.2.3-1.4-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/1.2.3-1.4-upgrade-db.sql @@ -19,6 +19,9 @@ BEGIN; +-- To avoid any updates while we're doin' our thing... +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; + CREATE TABLE config.upgrade_log ( version TEXT PRIMARY KEY, install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() @@ -41,6 +44,11 @@ CREATE TABLE config.i18n_locale ( name TEXT UNIQUE NOT NULL, description TEXT ); +INSERT INTO config.i18n_locale (code,marc_code,name,description) VALUES ('en-US', 'eng', 'English (US)', 'American English'); +INSERT INTO config.i18n_locale (code,marc_code,name,description) VALUES ('en-CA', 'eng', 'English (Canada)', 'Canadian English'); +INSERT INTO config.i18n_locale (code,marc_code,name,description) VALUES ('fr-CA', 'fre', 'French (Canada)', 'Canadian French'); +INSERT INTO config.i18n_locale (code,marc_code,name,description) VALUES ('hy-AM', 'arm', 'Armenian', 'Armenian'); + CREATE TABLE config.i18n_core ( id BIGSERIAL PRIMARY KEY, @@ -137,6 +145,11 @@ CREATE TABLE config.z3950_source ( transmission_format TEXT NOT NULL DEFAULT 'usmarc', auth BOOL NOT NULL DEFAULT TRUE ); +INSERT INTO config.z3950_source (name, label, host, port, db, auth) + VALUES ('loc', oils_i18n_gettext('loc', 'Library of Congress', 'czs', 'label'), 'z3950.loc.gov', 7090, 'Voyager', FALSE); +INSERT INTO config.z3950_source (name, label, host, port, db, auth) + VALUES ('oclc', oils_i18n_gettext('loc', 'OCLC', 'czs', 'label'), 'zcat.oclc.org', 210, 'OLUCWorldCat', TRUE); + CREATE TABLE config.z3950_attr ( id SERIAL PRIMARY KEY, @@ -148,6 +161,45 @@ CREATE TABLE config.z3950_attr ( truncation INT NOT NULL DEFAULT 0, CONSTRAINT z_code_format_once_per_source UNIQUE (code,format,source) ); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (1, 'loc','tcn', oils_i18n_gettext(1, 'Title Control Number', 'cza', 'label'), 12, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (2, 'loc', 'isbn', oils_i18n_gettext(2, 'ISBN', 'cza', 'label'), 7, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (3, 'loc', 'lccn', oils_i18n_gettext(3, 'LCCN', 'cza', 'label'), 9, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (4, 'loc', 'author', oils_i18n_gettext(4, 'Author', 'cza', 'label'), 1003, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (5, 'loc', 'title', oils_i18n_gettext(5, 'Title', 'cza', 'label'), 4, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (6, 'loc', 'issn', oils_i18n_gettext(6, 'ISSN', 'cza', 'label'), 8, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (7, 'loc', 'publisher', oils_i18n_gettext(7, 'Publisher', 'cza', 'label'), 1018, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (8, 'loc', 'pubdate', oils_i18n_gettext(8, 'Publication Date', 'cza', 'label'), 31, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (9, 'loc', 'item_type', oils_i18n_gettext(9, 'Item Type', 'cza', 'label'), 1001, 1); + +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (10, 'oclc', 'tcn', oils_i18n_gettext(10, 'Title Control Number', 'cza', 'label'), 12, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (11, 'oclc', 'isbn', oils_i18n_gettext(11, 'ISBN', 'cza', 'label'), 7, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (12, 'oclc', 'lccn', oils_i18n_gettext(12, 'LCCN', 'cza', 'label'), 9, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (13, 'oclc', 'author', oils_i18n_gettext(13, 'Author', 'cza', 'label'), 1003, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (14, 'oclc', 'title', oils_i18n_gettext(14, 'Title', 'cza', 'label'), 4, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (15, 'oclc', 'issn', oils_i18n_gettext(15, 'ISSN', 'cza', 'label'), 8, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (16, 'oclc', 'publisher', oils_i18n_gettext(16, 'Publisher', 'cza', 'label'), 1018, 6); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (17, 'oclc', 'pubdate', oils_i18n_gettext(17, 'Publication Date', 'cza', 'label'), 31, 1); +INSERT INTO config.z3950_attr (id, source, name, label, code, format) + VALUES (18, 'oclc', 'item_type', oils_i18n_gettext(18, 'Item Type', 'cza', 'label'), 1001, 1); +SELECT SETVAL('config.z3950_attr_id_seq'::TEXT, 100); + CREATE TABLE actor.org_lasso ( @@ -173,11 +225,9 @@ CREATE TABLE permission.usr_object_perm_map ( grantable BOOL NOT NULL DEFAULT FALSE, CONSTRAINT perm_usr_obj_once UNIQUE (usr,perm,object_type,object_id) ); - CREATE INDEX uopm_usr_idx ON permission.usr_object_perm_map (usr); - CREATE OR REPLACE FUNCTION permission.grp_ancestors ( INT ) RETURNS SETOF permission.grp_tree AS $$ SELECT a.* FROM connectby('permission.grp_tree'::text,'parent'::text,'id'::text,'name'::text,$1::text,100,'.'::text) @@ -1032,11 +1082,8 @@ BEGIN END; $func$ LANGUAGE PLPGSQL; --- To avoid any updates while we're doin' our thing... -SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; - -- This index, right here, is the reason for this change. -DROP INDEX metabib.metabib_full_rec_value_idx; +DROP INDEX IF EXISTS metabib.metabib_full_rec_value_idx; -- So, on to it. -- Move the table out of the way ... @@ -1183,6 +1230,7 @@ CREATE TABLE config.circ_matrix_matchpoint ( usr_age_upper_bound INTERVAL, CONSTRAINT ep_once_per_grp_loc_mod_marc UNIQUE (grp, org_unit, circ_modifier, marc_type, marc_form, marc_vr_format, ref_flag, usr_age_lower_bound, usr_age_upper_bound, is_renewal) ); +INSERT INTO config.circ_matrix_matchpoint (org_unit,grp) VALUES (1,1); -- Tests to determine if circ can occur for this item at this location for this patron @@ -1212,6 +1260,7 @@ CREATE TABLE config.circ_matrix_ruleset ( recurring_fine_rule INT NOT NULL REFERENCES config.rule_recuring_fine (id) DEFERRABLE INITIALLY DEFERRED, max_fine_rule INT NOT NULL REFERENCES config.rule_max_fine (id) DEFERRABLE INITIALLY DEFERRED ); +INSERT INTO config.circ_matrix_ruleset (matchpoint,duration_rule,recurring_fine_rule,max_fine_rule) VALUES (1,11,1,1); CREATE OR REPLACE FUNCTION action.find_circ_matrix_matchpoint( context_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS INT AS $func$ DECLARE @@ -1319,7 +1368,7 @@ BEGIN -- Fail if the user is BARRED SELECT INTO user_object * FROM actor.usr WHERE id = match_user; - -- Fail if we couldn't find a set of tests + -- Fail if we couldn't find a user IF user_object.id IS NULL THEN result.fail_part := 'no_user'; result.success := FALSE; @@ -1501,6 +1550,8 @@ CREATE TABLE config.hold_matrix_matchpoint ( ref_flag BOOL, CONSTRAINT hous_once_per_grp_loc_mod_marc UNIQUE (user_home_ou, request_ou, pickup_ou, item_owning_ou, item_circ_ou, requestor_grp, usr_grp, circ_modifier, marc_type, marc_form, marc_vr_format) ); +INSERT INTO config.hold_matrix_matchpoint (requestor_grp) VALUES (1); + -- Tests to determine if hold against a specific copy is possible for a user at (and from) a location CREATE TABLE config.hold_matrix_test ( @@ -1764,9 +1815,709 @@ BEGIN END; $func$ LANGUAGE plpgsql; -INSERT INTO config.circ_matrix_matchpoint (org_unit,grp) VALUES (1,1); -INSERT INTO config.circ_matrix_ruleset (matchpoint,duration_rule,recurring_fine_rule,max_fine_rule) VALUES (1,11,1,1); -INSERT INTO config.hold_matrix_matchpoint (requestor_grp) VALUES (1); +CREATE SCHEMA vandelay; + +CREATE TABLE vandelay.queue ( + id BIGSERIAL PRIMARY KEY, + owner INT NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED, + name TEXT NOT NULL, + complete BOOL NOT NULL DEFAULT FALSE, + queue_type TEXT NOT NULL DEFAULT 'bib' CHECK (queue_type IN ('bib','authority')), + CONSTRAINT vand_queue_name_once_per_owner_const UNIQUE (owner,name,queue_type) +); + +CREATE TABLE vandelay.queued_record ( + id BIGSERIAL PRIMARY KEY, + create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + import_time TIMESTAMP WITH TIME ZONE, + purpose TEXT NOT NULL DEFAULT 'import' CHECK (purpose IN ('import','overlay')), + marc TEXT NOT NULL +); + + + +/* Bib stuff at the top */ +---------------------------------------------------- + +CREATE TABLE vandelay.bib_attr_definition ( + id SERIAL PRIMARY KEY, + code TEXT UNIQUE NOT NULL, + description TEXT, + xpath TEXT NOT NULL, + remove TEXT NOT NULL DEFAULT '', + ident BOOL NOT NULL DEFAULT FALSE +); + +-- Each TEXT field (other than 'name') should hold an XPath predicate for pulling the data needed +-- DROP TABLE vandelay.import_item_attr_definition CASCADE; +CREATE TABLE vandelay.import_item_attr_definition ( + id BIGSERIAL PRIMARY KEY, + owner INT NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + name TEXT NOT NULL, + tag TEXT NOT NULL, + keep BOOL NOT NULL DEFAULT FALSE, + owning_lib TEXT, + circ_lib TEXT, + call_number TEXT, + copy_number TEXT, + status TEXT, + location TEXT, + circulate TEXT, + deposit TEXT, + deposit_amount TEXT, + ref TEXT, + holdable TEXT, + price TEXT, + barcode TEXT, + circ_modifier TEXT, + circ_as_type TEXT, + alert_message TEXT, + opac_visible TEXT, + pub_note_title TEXT, + pub_note TEXT, + priv_note_title TEXT, + priv_note TEXT, + CONSTRAINT vand_import_item_attr_def_idx UNIQUE (owner,name) +); + +CREATE TABLE vandelay.bib_queue ( + queue_type TEXT NOT NULL DEFAULT 'bib' CHECK (queue_type = 'bib'), + item_attr_def TEXT REFERENCES vandelay.import_item_attr_definition (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, + CONSTRAINT vand_bib_queue_name_once_per_owner_const UNIQUE (owner,name,queue_type) +) INHERITS (vandelay.queue); +ALTER TABLE vandelay.bib_queue ADD PRIMARY KEY (id); + +CREATE TABLE vandelay.queued_bib_record ( + queue INT NOT NULL REFERENCES vandelay.bib_queue (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + bib_source INT REFERENCES config.bib_source (id) DEFERRABLE INITIALLY DEFERRED, + imported_as INT REFERENCES biblio.record_entry (id) DEFERRABLE INITIALLY DEFERRED +) INHERITS (vandelay.queued_record); +ALTER TABLE vandelay.queued_bib_record ADD PRIMARY KEY (id); + +CREATE TABLE vandelay.queued_bib_record_attr ( + id BIGSERIAL PRIMARY KEY, + record BIGINT NOT NULL REFERENCES vandelay.queued_bib_record (id) DEFERRABLE INITIALLY DEFERRED, + field INT NOT NULL REFERENCES vandelay.bib_attr_definition (id) DEFERRABLE INITIALLY DEFERRED, + attr_value TEXT NOT NULL +); + +CREATE TABLE vandelay.bib_match ( + id BIGSERIAL PRIMARY KEY, + field_type TEXT NOT NULL CHECK (field_type in ('isbn','tcn_value','id')), + matched_attr INT REFERENCES vandelay.queued_bib_record_attr (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + queued_record BIGINT REFERENCES vandelay.queued_bib_record (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + eg_record BIGINT REFERENCES biblio.record_entry (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED +); + +-- DROP TABLE vandelay.import_item CASCADE; +CREATE TABLE vandelay.import_item ( + id BIGSERIAL PRIMARY KEY, + record BIGINT NOT NULL REFERENCES vandelay.queued_bib_record (id) ON DELETE CASCADE, + definition BIGINT NOT NULL REFERENCES vandelay.import_item_attr_definition (id) ON DELETE CASCADE, + owning_lib INT, + circ_lib INT, + call_number TEXT, + copy_number INT, + status INT, + location INT, + circulate BOOL, + deposit BOOL, + deposit_amount NUMERIC(8,2), + ref BOOL, + holdable BOOL, + price NUMERIC(8,2), + barcode TEXT, + circ_modifier TEXT, + circ_as_type TEXT, + alert_message TEXT, + pub_note TEXT, + priv_note TEXT, + opac_visible BOOL +); + +CREATE TABLE vandelay.import_bib_trash_fields ( + id BIGSERIAL PRIMARY KEY, + owner INT NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + field TEXT NOT NULL, + CONSTRAINT vand_import_bib_trash_fields_idx UNIQUE (owner,field) +); + +CREATE OR REPLACE FUNCTION vandelay.strip_field ( xml TEXT, field TEXT ) RETURNS TEXT AS $_$ + + use MARC::Record; + use MARC::File::XML; + + my $xml = shift; + my $field_spec = shift; + + my $r = MARC::Record->new_from_xml( $xml ); + $r->delete_field( $_ ) for ( $r->field( $field_spec ) ); + + $xml = $r->as_xml_record; + $xml =~ s/^<\?.+?\?>$//mo; + $xml =~ s/\n//sgo; + $xml =~ s/>\s+ '') THEN + INSERT INTO vandelay.queued_bib_record_attr (record, field, attr_value) VALUES (NEW.id, adef.id, value); + END IF; + + END LOOP; + + RETURN NULL; +END; +$$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION vandelay.ingest_bib_items ( ) RETURNS TRIGGER AS $func$ +DECLARE + queue_rec RECORD; + item_rule RECORD; + item_data vandelay.import_item%ROWTYPE; +BEGIN + + SELECT * INTO queue_rec FROM vandelay.bib_queue WHERE id = NEW.queue; + + FOR item_rule IN SELECT r.* FROM actor.org_unit_ancestors( queue_rec.owner ) o JOIN vandelay.import_item_attr_definition r ON ( r.owner = o.id ) LOOP + FOR item_data IN SELECT * FROM vandelay.ingest_items( NEW.id::BIGINT, item_rule.id::BIGINT ) LOOP + INSERT INTO vandelay.import_item ( + record, + definition, + owning_lib, + circ_lib, + call_number, + copy_number, + status, + location, + circulate, + deposit, + deposit_amount, + ref, + holdable, + price, + barcode, + circ_modifier, + circ_as_type, + alert_message, + pub_note, + priv_note, + opac_visible + ) VALUES ( + NEW.id, + item_data.definition, + item_data.owning_lib, + item_data.circ_lib, + item_data.call_number, + item_data.copy_number, + item_data.status, + item_data.location, + item_data.circulate, + item_data.deposit, + item_data.deposit_amount, + item_data.ref, + item_data.holdable, + item_data.price, + item_data.barcode, + item_data.circ_modifier, + item_data.circ_as_type, + item_data.alert_message, + item_data.pub_note, + item_data.priv_note, + item_data.opac_visible + ); + END LOOP; + END LOOP; + + RETURN NULL; +END; +$func$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION vandelay.match_bib_record ( ) RETURNS TRIGGER AS $func$ +DECLARE + attr RECORD; + eg_rec RECORD; +BEGIN + FOR attr IN SELECT a.* FROM vandelay.queued_bib_record_attr a JOIN vandelay.bib_attr_definition d ON (d.id = a.field) WHERE record = NEW.id AND d.ident IS TRUE LOOP + + -- All numbers? check for an id match + IF (attr.attr_value ~ $r$^\d+$$r$) THEN + FOR eg_rec IN SELECT * FROM biblio.record_entry WHERE id = attr.attr_value::BIGINT AND deleted IS FALSE LOOP + INSERT INTO vandelay.bib_match (field_type, matched_attr, queued_record, eg_record) VALUES ('id', attr.id, NEW.id, eg_rec.id); + END LOOP; + END IF; + + -- Looks like an ISBN? check for an isbn match + IF (attr.attr_value ~* $r$^[0-9x]+$$r$ AND character_length(attr.attr_value) IN (10,13)) THEN + FOR eg_rec IN EXECUTE $$SELECT * FROM metabib.full_rec fr WHERE fr.value LIKE LOWER('$$ || attr.attr_value || $$%') AND fr.tag = '020' AND fr.subfield = 'a'$$ LOOP + PERFORM id FROM biblio.record_entry WHERE id = eg_rec.record AND deleted IS FALSE; + IF FOUND THEN + INSERT INTO vandelay.bib_match (field_type, matched_attr, queued_record, eg_record) VALUES ('isbn', attr.id, NEW.id, eg_rec.record); + END IF; + END LOOP; + + -- subcheck for isbn-as-tcn + FOR eg_rec IN SELECT * FROM biblio.record_entry WHERE tcn_value = 'i' || attr.attr_value AND deleted IS FALSE LOOP + INSERT INTO vandelay.bib_match (field_type, matched_attr, queued_record, eg_record) VALUES ('tcn_value', attr.id, NEW.id, eg_rec.id); + END LOOP; + END IF; + + -- check for an OCLC tcn_value match + IF (attr.attr_value ~ $r$^o\d+$$r$) THEN + FOR eg_rec IN SELECT * FROM biblio.record_entry WHERE tcn_value = regexp_replace(attr.attr_value,'^o','ocm') AND deleted IS FALSE LOOP + INSERT INTO vandelay.bib_match (field_type, matched_attr, queued_record, eg_record) VALUES ('tcn_value', attr.id, NEW.id, eg_rec.id); + END LOOP; + END IF; + + -- check for a direct tcn_value match + FOR eg_rec IN SELECT * FROM biblio.record_entry WHERE tcn_value = attr.attr_value AND deleted IS FALSE LOOP + INSERT INTO vandelay.bib_match (field_type, matched_attr, queued_record, eg_record) VALUES ('tcn_value', attr.id, NEW.id, eg_rec.id); + END LOOP; + + END LOOP; + + RETURN NULL; +END; +$func$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION vandelay.cleanup_bib_marc ( ) RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM vandelay.queued_bib_record_attr WHERE record = OLD.id; + DELETE FROM vandelay.import_item WHERE record = OLD.id; + + IF TG_OP = 'UPDATE' THEN + RETURN NEW; + END IF; + RETURN OLD; +END; +$$ LANGUAGE PLPGSQL; + +CREATE TRIGGER cleanup_bib_trigger + BEFORE UPDATE OR DELETE ON vandelay.queued_bib_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.cleanup_bib_marc(); + +CREATE TRIGGER ingest_bib_trigger + AFTER INSERT OR UPDATE ON vandelay.queued_bib_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.ingest_bib_marc(); + +CREATE TRIGGER ingest_item_trigger + AFTER INSERT OR UPDATE ON vandelay.queued_bib_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.ingest_bib_items(); + +CREATE TRIGGER zz_match_bibs_trigger + AFTER INSERT OR UPDATE ON vandelay.queued_bib_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.match_bib_record(); + + +/* Authority stuff down here */ +--------------------------------------- +CREATE TABLE vandelay.authority_attr_definition ( + id SERIAL PRIMARY KEY, + code TEXT UNIQUE NOT NULL, + description TEXT, + xpath TEXT NOT NULL, + remove TEXT NOT NULL DEFAULT '', + ident BOOL NOT NULL DEFAULT FALSE +); + +CREATE TABLE vandelay.authority_queue ( + queue_type TEXT NOT NULL DEFAULT 'authority' CHECK (queue_type = 'authority'), + CONSTRAINT vand_authority_queue_name_once_per_owner_const UNIQUE (owner,name,queue_type) +) INHERITS (vandelay.queue); +ALTER TABLE vandelay.authority_queue ADD PRIMARY KEY (id); + +CREATE TABLE vandelay.queued_authority_record ( + queue INT NOT NULL REFERENCES vandelay.authority_queue (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + imported_as INT REFERENCES authority.record_entry (id) DEFERRABLE INITIALLY DEFERRED +) INHERITS (vandelay.queued_record); +ALTER TABLE vandelay.queued_authority_record ADD PRIMARY KEY (id); + +CREATE TABLE vandelay.queued_authority_record_attr ( + id BIGSERIAL PRIMARY KEY, + record BIGINT NOT NULL REFERENCES vandelay.queued_authority_record (id) DEFERRABLE INITIALLY DEFERRED, + field INT NOT NULL REFERENCES vandelay.authority_attr_definition (id) DEFERRABLE INITIALLY DEFERRED, + attr_value TEXT NOT NULL +); + +CREATE TABLE vandelay.authority_match ( + id BIGSERIAL PRIMARY KEY, + matched_attr INT REFERENCES vandelay.queued_authority_record_attr (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + queued_record BIGINT REFERENCES vandelay.queued_authority_record (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + eg_record BIGINT REFERENCES authority.record_entry (id) DEFERRABLE INITIALLY DEFERRED +); + +CREATE OR REPLACE FUNCTION vandelay.ingest_authority_marc ( ) RETURNS TRIGGER AS $$ +DECLARE + value TEXT; + atype TEXT; + adef RECORD; +BEGIN + FOR adef IN SELECT * FROM vandelay.authority_attr_definition LOOP + + SELECT extract_marc_field('vandelay.queued_authority_record', id, adef.xpath, adef.remove) INTO value FROM vandelay.queued_authority_record WHERE id = NEW.id; + IF (value IS NOT NULL AND value <> '') THEN + INSERT INTO vandelay.queued_authority_record_attr (record, field, attr_value) VALUES (NEW.id, adef.id, value); + END IF; + + END LOOP; + + RETURN NULL; +END; +$$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION vandelay.cleanup_authority_marc ( ) RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM vandelay.queued_authority_record_attr WHERE record = OLD.id; + IF TG_OP = 'UPDATE' THEN + RETURN NEW; + END IF; + RETURN OLD; +END; +$$ LANGUAGE PLPGSQL; + +CREATE TRIGGER cleanup_authority_trigger + BEFORE UPDATE OR DELETE ON vandelay.queued_authority_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.cleanup_authority_marc(); + +CREATE TRIGGER ingest_authority_trigger + AFTER INSERT OR UPDATE ON vandelay.queued_authority_record + FOR EACH ROW EXECUTE PROCEDURE vandelay.ingest_authority_marc(); + +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (1, 'title', oils_i18n_gettext(1, 'vqbrad', 'Title of work', 'description'),'//*[@tag="245"]/*[contains("abcmnopr",@code)]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (2, 'author', oils_i18n_gettext(1, 'vqbrad', 'Author of work', 'description'),'//*[@tag="100" or @tag="110" or @tag="113"]/*[contains("ad",@code)]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (3, 'language', oils_i18n_gettext(3, 'vqbrad', 'Language of work', 'description'),'//*[@tag="240"]/*[@code="l"][1]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (4, 'pagination', oils_i18n_gettext(4, 'vqbrad', 'Pagination', 'description'),'//*[@tag="300"]/*[@code="a"][1]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident, remove ) VALUES (5, 'isbn',oils_i18n_gettext(5, 'vqbrad', 'ISBN', 'description'),'//*[@tag="020"]/*[@code="a"]', TRUE, $r$(?:-|\s.+$)$r$); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident, remove ) VALUES (6, 'issn',oils_i18n_gettext(6, 'vqbrad', 'ISSN', 'description'),'//*[@tag="022"]/*[@code="a"]', TRUE, $r$(?:-|\s.+$)$r$); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (7, 'price',oils_i18n_gettext(7, 'vqbrad', 'Price', 'description'),'//*[@tag="020" or @tag="022"]/*[@code="c"][1]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident ) VALUES (8, 'rec_identifier',oils_i18n_gettext(8, 'vqbrad', 'Accession Number', 'description'),'//*[@tag="001"]', TRUE); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident ) VALUES (9, 'eg_tcn',oils_i18n_gettext(9, 'vqbrad', 'TCN Value', 'description'),'//*[@tag="901"]/*[@code="a"]', TRUE); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident ) VALUES (10, 'eg_tcn_source',oils_i18n_gettext(10, 'vqbrad', 'TCN Source', 'description'),'//*[@tag="901"]/*[@code="b"]', TRUE); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, ident ) VALUES (11, 'eg_identifier',oils_i18n_gettext(11, 'vqbrad', 'Internal ID', 'description'),'//*[@tag="901"]/*[@code="c"]', TRUE); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (12, 'publisher',oils_i18n_gettext(12, 'vqbrad', 'Publisher', 'description'),'//*[@tag="260"]/*[@code="b"][1]'); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath, remove ) VALUES (13, 'pubdate',oils_i18n_gettext(13, 'vqbrad', 'Publication Date', 'description'),'//*[@tag="260"]/*[@code="c"][1]',$r$\D$r$); +INSERT INTO vandelay.bib_attr_definition ( id, code, description, xpath ) VALUES (14, 'edition',oils_i18n_gettext(14, 'vqbrad', 'Edition', 'description'),'//*[@tag="250"]/*[@code="a"][1]'); + +INSERT INTO vandelay.import_item_attr_definition ( + owner, name, tag, owning_lib, circ_lib, location, + call_number, circ_modifier, barcode, price, copy_number, + circulate, ref, holdable, opac_visible, status +) VALUES ( + 1, + 'Evergreen 852 export format', + '852', + '[@code = "b"][1]', + '[@code = "b"][2]', + 'c', + 'j', + 'g', + 'p', + 'y', + 't', + '[@code = "x" and text() = "circulating"]', + '[@code = "x" and text() = "reference"]', + '[@code = "x" and text() = "holdable"]', + '[@code = "x" and text() = "visible"]', + 'z' +); + +INSERT INTO vandelay.import_item_attr_definition ( + owner, + name, + tag, + owning_lib, + location, + call_number, + circ_modifier, + barcode, + price, + status +) VALUES ( + 1, + 'Unicorn Import format -- 999', + '999', + 'm', + 'l', + 'a', + 't', + 'i', + 'p', + 'k' +); --- COMMIT; +INSERT INTO vandelay.authority_attr_definition ( code, description, xpath, ident ) VALUES ('rec_identifier','Identifier','//*[@tag="001"]', TRUE); +--COMMIT