item BIGINT;
authority_code ALIAS FOR $1;
org_unit_id ALIAS for $2;
- lms_bib_id TEXT;
+ lms_bib_id BIGINT;
library_code TEXT;
bar_code TEXT;
last_use_date TEXT;
BEGIN
FOR item IN
- EXECUTE ('SELECT id FROM asset.copy WHERE NOT deleted AND circ_lib IN (SELECT id FROM actor.org_unit_descendants(' || org_unit_id || ')) ORDER BY id;')
+ SELECT id FROM asset.copy WHERE NOT deleted AND circ_lib IN (SELECT id FROM actor.org_unit_descendants(org_unit_id)) ORDER BY id
LOOP
- EXECUTE ('SELECT cn.record FROM asset.call_number cn, asset.copy c WHERE c.call_number = cn.id AND c.id = ' || item || ';') INTO lms_bib_id;
- EXECUTE (E'SELECT isbn[1] FROM reporter.materialized_simple_record r WHERE r.id = ' || lms_bib_id || ';') INTO isbn;
- EXECUTE ('SELECT collectionHQ.attempt_price(price::TEXT) FROM asset.copy WHERE id = ' || item || ';') INTO price;
+ SELECT cn.record, cn.label
+ INTO lms_bib_id, filter_level_1
+ FROM asset.call_number cn, asset.copy c
+ WHERE c.call_number = cn.id AND c.id = item;
+ SELECT r.isbn[1] INTO isbn
+ FROM reporter.materialized_simple_record r
+ WHERE id = lms_bib_id;
+ SELECT collectionHQ.attempt_price(ac.price::TEXT), barcode, ac.status,
+ REPLACE(create_date::DATE::TEXT, '-', ''),
+ CASE floating WHEN TRUE THEN 'Y' ELSE NULL END
+ INTO price, bar_code, status, date_added, rotating_stock
+ FROM asset.copy ac
+ WHERE id = item;
IF price IS NULL OR price = '' THEN
- EXECUTE (E'SELECT collectionHQ.attempt_price(value) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'020\' AND subfield = \'c\' LIMIT 1;') INTO price;
+ SELECT collectionHQ.attempt_price((XPATH('//marc:datafield[@tag="020"][1]/marc:subfield[@code="c"]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT)
+ INTO price
+ WHERE id = lms_bib_id;
END IF;
- EXECUTE (E'SELECT REPLACE(NOW()::DATE::TEXT, \'-\', \'\');') INTO extract_date;
- EXECUTE ('SELECT ou.shortname FROM actor.org_unit ou, asset.copy c WHERE ou.id = c.circ_lib AND c.id = ' || item || ';') INTO library_code;
- EXECUTE ('SELECT barcode FROM asset.copy WHERE id = ' || item || ';') INTO bar_code;
- EXECUTE (E'SELECT REPLACE(xact_start::DATE::TEXT, \'-\', \'\') FROM action.circulation WHERE target_copy = ' || item || ' ORDER BY xact_start DESC LIMIT 1;') INTO last_use_date;
- EXECUTE (E'SELECT circ_count FROM extend_reporter.full_circ_count WHERE id = ' || item || ';') INTO cumulative_use_total;
+ SELECT REPLACE(NOW()::DATE::TEXT, '-', '') INTO extract_date;
+ SELECT ou.shortname INTO library_code FROM actor.org_unit ou, asset.copy c WHERE ou.id = c.circ_lib AND c.id = item;
+ SELECT REPLACE(xact_start::DATE::TEXT, '-', '') INTO last_use_date FROM action.circulation WHERE target_copy = item ORDER BY xact_start DESC LIMIT 1;
+ SELECT circ_count INTO cumulative_use_total FROM extend_reporter.full_circ_count WHERE id = item;
IF cumulative_use_total IS NULL THEN
cumulative_use_total := '0';
END IF;
- EXECUTE ('SELECT h.audit_time FROM asset.copy c, auditor.asset_copy_history h WHERE c.id = h.id AND c.circ_lib <> h.circ_lib AND c.id = ' || item || 'ORDER BY h.audit_time DESC LIMIT 1;') INTO arrived;
+ SELECT MAX(dest_recv_time) INTO arrived
+ FROM action.transit_copy atc
+ JOIN asset.copy ac ON (ac.id = atc.target_copy AND ac.circ_lib = atc.dest)
+ WHERE ac.id = item;
IF arrived IS NOT NULL THEN
- EXECUTE('SELECT COUNT(*) FROM action.circulation WHERE target_copy = ' || item || ' AND xact_start > ' || quote_literal(arrived) || '::TIMESTAMPTZ;') INTO cumulative_use_current;
+ SELECT COUNT(*) INTO cumulative_use_current FROM action.circulation WHERE target_copy = item AND xact_start > arrived;
ELSE
cumulative_use_current := '0';
END IF;
- EXECUTE ('SELECT status FROM asset.copy WHERE id = ' || item || ';') INTO status;
- EXECUTE (E'SELECT REPLACE(create_date::DATE::TEXT, \'-\', \'\') FROM asset.copy WHERE id = ' || item || ';') INTO date_added;
- EXECUTE (E'SELECT CASE floating WHEN TRUE THEN \'Y\' ELSE NULL END FROM asset.copy WHERE id = ' || item || ';') INTO rotating_stock;
- EXECUTE ('SELECT SUBSTRING(value FROM 1 FOR 100) FROM asset.copy_note WHERE owning_copy = ' || item || E' AND title ILIKE \'%collectionHQ%\' ORDER BY id LIMIT 1;') INTO notes; -- FIXME or we could compile and concatenate in another function
- EXECUTE ('SELECT l.name FROM asset.copy c, asset.copy_location l WHERE c.location = l.id AND c.id = ' || item || ';') INTO collection_code;
- EXECUTE ('SELECT v.label FROM asset.call_number v, asset.copy c WHERE v.id = c.call_number AND c.id = ' || item || ';') INTO filter_level_1;
+ SELECT SUBSTRING(value FROM 1 FOR 100) INTO notes FROM asset.copy_note WHERE owning_copy = item AND title ILIKE '%collectionHQ%' ORDER BY id LIMIT 1;
+ SELECT l.name INTO collection_code FROM asset.copy c, asset.copy_location l WHERE c.location = l.id AND c.id = item;
purchase_code := ''; -- FIXME do we want something else here?
lib_supsel_tag := ''; -- FIXME do we want something else here?
RAISE INFO '%', output;
num_rows := num_rows + 1;
- IF (num_rows::numeric % 10000.0 = 0.0) THEN RAISE INFO '% rows written', num_rows; END IF;
+ IF (num_rows::numeric % 1000.0 = 0.0) THEN RAISE INFO '% rows written', num_rows; END IF;
END LOOP;
BEGIN
FOR lms_bib_id IN
- EXECUTE ('SELECT DISTINCT bre.id FROM biblio.record_entry bre JOIN asset.call_number acn ON (acn.record = bre.id) WHERE acn.owning_lib IN (SELECT id FROM actor.org_unit_descendants(' || org_unit_id || ')) AND NOT acn.deleted AND NOT bre.deleted;')
+ SELECT DISTINCT bre.id FROM biblio.record_entry bre JOIN asset.call_number acn ON (acn.record = bre.id) WHERE acn.owning_lib IN (SELECT id FROM actor.org_unit_descendants(org_unit_id)) AND NOT acn.deleted AND NOT bre.deleted
LOOP
- EXECUTE (E'SELECT isbn[1] FROM reporter.materialized_simple_record r WHERE r.id = ' || lms_bib_id || ';') INTO isbn;
- EXECUTE ('SELECT SUBSTRING(title FROM 1 FOR 100) FROM reporter.materialized_simple_record r WHERE r.id = ' || lms_bib_id || ';') INTO title;
- EXECUTE ('SELECT SUBSTRING(author FROM 1 FOR 50) FROM reporter.materialized_simple_record r WHERE r.id = ' || lms_bib_id || ';') INTO author;
- EXECUTE (E'SELECT SUBSTRING(value FROM 1 FOR 20) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'250\' AND subfield = \'a\' LIMIT 1;') INTO edition_num;
- EXECUTE (E'SELECT collectionHQ.attempt_year(value) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'260\' AND subfield = \'c\' LIMIT 1;') INTO publication_date;
- EXECUTE (E'SELECT SUBSTRING(value FROM 1 FOR 100) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'260\' AND subfield = \'b\' LIMIT 1;') INTO publisher;
- EXECUTE (E'SELECT collectionHQ.attempt_price(value) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'020\' AND subfield = \'c\' LIMIT 1;') INTO price;
- EXECUTE ('SELECT circ_modifier FROM asset.copy c, asset.call_number cn WHERE cn.record = ' || lms_bib_id || ' AND cn.id = c.call_number AND NOT cn.deleted AND NOT c.deleted LIMIT 1;') INTO lms_item_type;
- EXECUTE ('SELECT SUBSTRING(value FROM 1 FOR 20) FROM metabib.real_full_rec WHERE record = ' || lms_bib_id || E' AND tag = \'082\' AND subfield = \'a\' LIMIT 1;') INTO class_num;
- EXECUTE (E'SELECT REPLACE(NOW()::DATE::TEXT, \'-\', \'\');') INTO extract_date;
+ SELECT r.isbn[1],
+ SUBSTRING(r.title FROM 1 FOR 100),
+ SUBSTRING(r.author FROM 1 FOR 50)
+ INTO isbn, title, author
+ FROM reporter.materialized_simple_record r
+ WHERE id = lms_bib_id;
+ SELECT
+ SUBSTRING(naco_normalize((XPATH('//marc:datafield[@tag="250"][1]/marc:subfield[@code="a"]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT, 'a') FROM 1 FOR 20),
+ collectionHQ.attempt_year((XPATH('//marc:datafield[@tag="260"][1]/marc:subfield[@code="c"]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT),
+ SUBSTRING(naco_normalize((XPATH('//marc:datafield[@tag="260"][1]/marc:subfield[@code="b"]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT, 'b') FROM 1 FOR 100),
+ collectionHQ.attempt_price((XPATH('//marc:datafield[@tag="020"][1]/marc:subfield[@code="c"]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT),
+ SUBSTRING(naco_normalize((XPATH('//marc:datafield[@tag="082"][1]/marc:subfield[@code="a"][1]/text()', marc::XML, ARRAY[ARRAY['marc', 'http://www.loc.gov/MARC21/slim']]))[1]::TEXT, 'a') FROM 1 FOR 20)
+ INTO edition_num, publication_date, publisher, price, class_num
+ FROM biblio.record_entry
+ WHERE id = lms_bib_id;
+
+ SELECT circ_modifier INTO lms_item_type FROM asset.copy c, asset.call_number cn WHERE cn.record = lms_bib_id AND cn.id = c.call_number AND NOT cn.deleted AND NOT c.deleted LIMIT 1;
+ SELECT REPLACE(NOW()::DATE::TEXT, '-', '') INTO extract_date;
output :=
'##BIB##,'
RAISE INFO '%', output;
num_rows := num_rows + 1;
- IF (num_rows::numeric % 10000.0 = 0.0) THEN RAISE INFO '% rows written', num_rows; END IF;
+ IF (num_rows::numeric % 1000.0 = 0.0) THEN RAISE INFO '% rows written', num_rows; END IF;
END LOOP;