From 920e264e9853efe136024de64b429eaccf3864dd Mon Sep 17 00:00:00 2001 From: miker Date: Mon, 21 Feb 2011 18:45:38 +0000 Subject: [PATCH] 2.0.2 upgrade script git-svn-id: svn://svn.open-ils.org/ILS/branches/rel_2_0@19500 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- Open-ILS/src/sql/Pg/2.0.1-2.0.2-upgrade-db.sql | 445 +++++++++++++++++++++++++ 1 file changed, 445 insertions(+) create mode 100644 Open-ILS/src/sql/Pg/2.0.1-2.0.2-upgrade-db.sql diff --git a/Open-ILS/src/sql/Pg/2.0.1-2.0.2-upgrade-db.sql b/Open-ILS/src/sql/Pg/2.0.1-2.0.2-upgrade-db.sql new file mode 100644 index 0000000000..46c998a619 --- /dev/null +++ b/Open-ILS/src/sql/Pg/2.0.1-2.0.2-upgrade-db.sql @@ -0,0 +1,445 @@ +BEGIN; + +INSERT INTO config.upgrade_log (version) VALUES ('2.0.2'); +INSERT INTO config.upgrade_log (version) VALUES ('0484'); -- miker + +DROP FUNCTION asset.metarecord_copy_count ( INT, BIGINT, BOOL ); +DROP FUNCTION asset.record_copy_count ( INT, BIGINT, BOOL ); + +DROP FUNCTION asset.opac_ou_record_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.opac_ou_record_copy_count (org INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + SELECT ans.depth, + ans.id, + COUNT( av.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( av.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id) + JOIN asset.copy cp ON (cp.id = av.id) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.opac_lasso_record_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.opac_lasso_record_copy_count (i_lasso INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP + RETURN QUERY + SELECT -1, + ans.id, + COUNT( av.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( av.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id) + JOIN asset.copy cp ON (cp.id = av.id) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.staff_ou_record_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count (org INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + SELECT ans.depth, + ans.id, + COUNT( cp.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( cp.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id) + JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.staff_lasso_record_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.staff_lasso_record_copy_count (i_lasso INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP + RETURN QUERY + SELECT -1, + ans.id, + COUNT( cp.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( cp.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id) + JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION asset.record_copy_count ( place INT, rid BIGINT, staff BOOL) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +BEGIN + IF staff IS TRUE THEN + IF place > 0 THEN + RETURN QUERY SELECT * FROM asset.staff_ou_record_copy_count( place, rid ); + ELSE + RETURN QUERY SELECT * FROM asset.staff_lasso_record_copy_count( -place, rid ); + END IF; + ELSE + IF place > 0 THEN + RETURN QUERY SELECT * FROM asset.opac_ou_record_copy_count( place, rid ); + ELSE + RETURN QUERY SELECT * FROM asset.opac_lasso_record_copy_count( -place, rid ); + END IF; + END IF; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.opac_ou_metarecord_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.opac_ou_metarecord_copy_count (org INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + SELECT ans.depth, + ans.id, + COUNT( av.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( av.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id) + JOIN asset.copy cp ON (cp.id = av.id) + JOIN metabib.metarecord_source_map m ON (m.source = av.record) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.opac_lasso_metarecord_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.opac_lasso_metarecord_copy_count (i_lasso INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP + RETURN QUERY + SELECT -1, + ans.id, + COUNT( av.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( av.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id) + JOIN asset.copy cp ON (cp.id = av.id) + JOIN metabib.metarecord_source_map m ON (m.source = av.record) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.staff_ou_metarecord_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.staff_ou_metarecord_copy_count (org INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + SELECT ans.depth, + ans.id, + COUNT( cp.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( cp.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id) + JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number) + JOIN metabib.metarecord_source_map m ON (m.source = cn.record) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +DROP FUNCTION asset.staff_lasso_metarecord_copy_count (INT, BIGINT); +CREATE OR REPLACE FUNCTION asset.staff_lasso_metarecord_copy_count (i_lasso INT, rid BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP + RETURN QUERY + SELECT -1, + ans.id, + COUNT( cp.id ), + SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ), + COUNT( cp.id ), + trans + FROM + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id) + JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number) + JOIN metabib.metarecord_source_map m ON (m.source = cn.record) + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION asset.metarecord_copy_count ( place INT, rid BIGINT, staff BOOL) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$ +BEGIN + IF staff IS TRUE THEN + IF place > 0 THEN + RETURN QUERY SELECT * FROM asset.staff_ou_metarecord_copy_count( place, rid ); + ELSE + RETURN QUERY SELECT * FROM asset.staff_lasso_metarecord_copy_count( -place, rid ); + END IF; + ELSE + IF place > 0 THEN + RETURN QUERY SELECT * FROM asset.opac_ou_metarecord_copy_count( place, rid ); + ELSE + RETURN QUERY SELECT * FROM asset.opac_lasso_metarecord_copy_count( -place, rid ); + END IF; + END IF; + + RETURN; +END; +$f$ LANGUAGE PLPGSQL; + +INSERT INTO config.upgrade_log (version) VALUES ('0485'); -- dbs + +CREATE OR REPLACE VIEW reporter.simple_record AS +SELECT r.id, + s.metarecord, + r.fingerprint, + r.quality, + r.tcn_source, + r.tcn_value, + title.value AS title, + uniform_title.value AS uniform_title, + author.value AS author, + publisher.value AS publisher, + SUBSTRING(pubdate.value FROM $$\d+$$) AS pubdate, + series_title.value AS series_title, + series_statement.value AS series_statement, + summary.value AS summary, + ARRAY_ACCUM( DISTINCT REPLACE(SUBSTRING(isbn.value FROM $$^\S+$$), '-', '') ) AS isbn, + ARRAY_ACCUM( DISTINCT REGEXP_REPLACE(issn.value, E'^\\S*(\\d{4})[-\\s](\\d{3,4}x?)', E'\\1 \\2') ) AS issn, + ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '650' AND subfield = 'a' AND record = r.id)) AS topic_subject, + ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '651' AND subfield = 'a' AND record = r.id)) AS geographic_subject, + ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '655' AND subfield = 'a' AND record = r.id)) AS genre, + ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '600' AND subfield = 'a' AND record = r.id)) AS name_subject, + ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '610' AND subfield = 'a' AND record = r.id)) AS corporate_subject, + ARRAY((SELECT value FROM metabib.full_rec WHERE tag = '856' AND subfield IN ('3','y','u') AND record = r.id ORDER BY CASE WHEN subfield IN ('3','y') THEN 0 ELSE 1 END)) AS external_uri + FROM biblio.record_entry r + JOIN metabib.metarecord_source_map s ON (s.source = r.id) + LEFT JOIN metabib.full_rec uniform_title ON (r.id = uniform_title.record AND uniform_title.tag = '240' AND uniform_title.subfield = 'a') + LEFT JOIN metabib.full_rec title ON (r.id = title.record AND title.tag = '245' AND title.subfield = 'a') + LEFT JOIN metabib.full_rec author ON (r.id = author.record AND author.tag = '100' AND author.subfield = 'a') + LEFT JOIN metabib.full_rec publisher ON (r.id = publisher.record AND publisher.tag = '260' AND publisher.subfield = 'b') + LEFT JOIN metabib.full_rec pubdate ON (r.id = pubdate.record AND pubdate.tag = '260' AND pubdate.subfield = 'c') + LEFT JOIN metabib.full_rec isbn ON (r.id = isbn.record AND isbn.tag IN ('024', '020') AND isbn.subfield IN ('a','z')) + LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a') + LEFT JOIN metabib.full_rec series_title ON (r.id = series_title.record AND series_title.tag IN ('830','440') AND series_title.subfield = 'a') + LEFT JOIN metabib.full_rec series_statement ON (r.id = series_statement.record AND series_statement.tag = '490' AND series_statement.subfield = 'a') + LEFT JOIN metabib.full_rec summary ON (r.id = summary.record AND summary.tag = '520' AND summary.subfield = 'a') + GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14; + +CREATE OR REPLACE VIEW reporter.old_super_simple_record AS +SELECT r.id, + r.fingerprint, + r.quality, + r.tcn_source, + r.tcn_value, + FIRST(title.value) AS title, + FIRST(author.value) AS author, + ARRAY_TO_STRING(ARRAY_ACCUM( DISTINCT publisher.value), ', ') AS publisher, + ARRAY_TO_STRING(ARRAY_ACCUM( DISTINCT SUBSTRING(pubdate.value FROM $$\d+$$) ), ', ') AS pubdate, + ARRAY_ACCUM( DISTINCT REPLACE(SUBSTRING(isbn.value FROM $$^\S+$$), '-', '') ) AS isbn, + ARRAY_ACCUM( DISTINCT REGEXP_REPLACE(issn.value, E'^\\S*(\\d{4})[-\\s](\\d{3,4}x?)', E'\\1 \\2') ) AS issn + FROM biblio.record_entry r + LEFT JOIN metabib.full_rec title ON (r.id = title.record AND title.tag = '245' AND title.subfield = 'a') + LEFT JOIN metabib.full_rec author ON (r.id = author.record AND author.tag IN ('100','110','111') AND author.subfield = 'a') + LEFT JOIN metabib.full_rec publisher ON (r.id = publisher.record AND publisher.tag = '260' AND publisher.subfield = 'b') + LEFT JOIN metabib.full_rec pubdate ON (r.id = pubdate.record AND pubdate.tag = '260' AND pubdate.subfield = 'c') + LEFT JOIN metabib.full_rec isbn ON (r.id = isbn.record AND isbn.tag IN ('024', '020') AND isbn.subfield IN ('a','z')) + LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a') + GROUP BY 1,2,3,4,5; + +-- Update reporter.materialized_simple_record with normalized ISBN values +-- This might not get all of them, but most ISBNs will have more than one hyphen +DELETE FROM reporter.materialized_simple_record WHERE id IN ( + SELECT record FROM metabib.full_rec WHERE tag = '020' AND subfield IN ('a', 'z') AND value LIKE '%-%-%' +); + +INSERT INTO reporter.materialized_simple_record + SELECT DISTINCT rossr.* FROM reporter.old_super_simple_record rossr INNER JOIN metabib.full_rec mfr ON mfr.record = rossr.id + WHERE mfr.tag = '020' AND mfr.subfield IN ('a', 'z') AND mfr.value LIKE '%-%-%' +; + +INSERT INTO config.upgrade_log (version) VALUES ('0488'); -- dbs + +CREATE OR REPLACE FUNCTION maintain_901 () RETURNS TRIGGER AS $func$ +DECLARE + use_id_for_tcn BOOLEAN; +BEGIN + -- Remove any existing 901 fields before we insert the authoritative one + NEW.marc := REGEXP_REPLACE(NEW.marc, E']*?\s*tag="901".+?', '', 'g'); + + IF TG_TABLE_SCHEMA = 'biblio' THEN + -- Set TCN value to record ID? + SELECT enabled FROM config.global_flag INTO use_id_for_tcn + WHERE name = 'cat.bib.use_id_for_tcn'; + + IF use_id_for_tcn = 't' THEN + NEW.tcn_value := NEW.id; + END IF; + + NEW.marc := REGEXP_REPLACE( + NEW.marc, + E'()', + E'' || + '' || NEW.tcn_value || E'' || + '' || NEW.tcn_source || E'' || + '' || NEW.id || E'' || + '' || TG_TABLE_SCHEMA || E'' || + CASE WHEN NEW.owner IS NOT NULL THEN '' || NEW.owner || E'' ELSE '' END || + CASE WHEN NEW.share_depth IS NOT NULL THEN '' || NEW.share_depth || E'' ELSE '' END || + E'\\1' + ); + ELSIF TG_TABLE_SCHEMA = 'authority' THEN + NEW.marc := REGEXP_REPLACE( + NEW.marc, + E'()', + E'' || + '' || NEW.id || E'' || + '' || TG_TABLE_SCHEMA || E'' || + E'\\1' + ); + ELSIF TG_TABLE_SCHEMA = 'serial' THEN + NEW.marc := REGEXP_REPLACE( + NEW.marc, + E'()', + E'' || + '' || NEW.id || E'' || + '' || TG_TABLE_SCHEMA || E'' || + '' || NEW.owning_lib || E'' || + CASE WHEN NEW.record IS NOT NULL THEN '' || NEW.record || E'' ELSE '' END || + E'\\1' + ); + ELSE + NEW.marc := REGEXP_REPLACE( + NEW.marc, + E'()', + E'' || + '' || NEW.id || E'' || + '' || TG_TABLE_SCHEMA || E'' || + E'\\1' + ); + END IF; + + RETURN NEW; +END; +$func$ LANGUAGE PLPGSQL; + +COMMIT; -- 2.11.0