--- /dev/null
+BEGIN;
+
+/*
+using unapi.bre_output_layout for now.
+Do we need separate output config for mmr?
+*/
+
+CREATE OR REPLACE FUNCTION unapi.mmr (
+ mmr_id BIGINT,
+ format TEXT,
+ ename TEXT,
+ includes TEXT[],
+ org TEXT,
+ depth INT DEFAULT NULL,
+ slimit HSTORE DEFAULT NULL,
+ soffset HSTORE DEFAULT NULL,
+ include_xmlns BOOL DEFAULT TRUE,
+ pref_lib INT DEFAULT NULL
+)
+RETURNS XML AS $F$
+DECLARE
+ mmrec metabib.metarecord%ROWTYPE;
+ leadrec biblio.record_entry%ROWTYPE;
+ subrec biblio.record_entry%ROWTYPE;
+ layout unapi.bre_output_layout%ROWTYPE;
+ xfrm config.xml_transform%ROWTYPE;
+ ouid INT;
+ xml_buf TEXT; -- growing XML document
+ tmp_xml TEXT; -- single-use XML string
+ xml_frag TEXT; -- single-use XML fragment
+ top_el TEXT;
+ output XML;
+ hxml XML;
+ axml XML;
+ subxml XML; -- subordinate records elements
+ sub_xpath TEXT;
+BEGIN
+
+ -- xpath for extracting bre.marc values from subordinate records
+ -- so they may be appended to the MARC of the master record prior
+ -- to XSLT processing.
+ -- subjects, isbn, issn, upc -- anything else?
+ sub_xpath :=
+ '//*[starts-with(@tag, "6") or @tag="020" or @tag="022" or @tag="024"]';
+
+ IF org = '-' OR org IS NULL THEN
+ SELECT shortname INTO org FROM evergreen.org_top();
+ END IF;
+
+ SELECT id INTO ouid FROM actor.org_unit WHERE shortname = org;
+
+ IF ouid IS NULL THEN
+ RETURN NULL::XML;
+ END IF;
+
+ SELECT INTO mmrec * FROM metabib.metarecord WHERE id = mmr_id;
+ IF NOT FOUND THEN
+ RETURN NULL::XML;
+ END IF;
+
+ /*
+ -- TODO: aggregate holdings from constituent records
+ IF format = 'holdings_xml' THEN -- the special case
+ output := unapi.holdings_xml(
+ mmr_id, ouid, org, depth, includes, slimit, soffset, include_xmlns);
+ RETURN output;
+ END IF;
+ */
+
+ SELECT * INTO layout FROM unapi.bre_output_layout WHERE name = format;
+
+ IF layout.name IS NULL THEN
+ RETURN NULL::XML;
+ END IF;
+
+ SELECT * INTO xfrm FROM config.xml_transform WHERE name = layout.transform;
+
+ SELECT INTO leadrec * FROM biblio.record_entry WHERE id = mmrec.master_record;
+
+ -- Grab bulk SVF for the lead record if requested
+ -- TODO: additional SVF values from constituent records for formats, etc.
+ IF ('mra' = ANY (includes)) THEN
+ axml := unapi.mra(leadrec.id,NULL,NULL,NULL,NULL);
+ ELSE
+ axml := NULL::XML;
+ END IF;
+
+ xml_buf = leadrec.marc;
+
+ hxml := NULL::XML;
+ subxml := NULL::XML;
+ FOR subrec IN SELECT bre.* FROM biblio.record_entry bre
+ JOIN metabib.metarecord_source_map mmsm ON (mmsm.source = bre.id)
+ JOIN metabib.metarecord mmr ON (mmr.id = mmsm.metarecord)
+ WHERE mmr.id = mmr_id
+ ORDER BY CASE WHEN bre.id = mmr.master_record THEN 0 ELSE bre.id END
+ LIMIT COALESCE((slimit->'bre')::INT, 5) LOOP
+
+ -- collect holdings for all added records
+ IF ('holdings_xml' = ANY (includes)) THEN
+ hxml := XMLCONCAT(hxml, unapi.holdings_xml(
+ subrec.id, ouid, org, depth,
+ evergreen.array_remove_item_by_value(includes,'holdings_xml'),
+ slimit, soffset, include_xmlns, pref_lib));
+ END IF;
+
+ IF subrec.id = leadrec.id THEN CONTINUE; END IF;
+ -- Append choice data from the the non-lead records to the
+ -- the lead record document
+
+ FOREACH xml_frag IN ARRAY
+ (SELECT * FROM xpath(sub_xpath, subrec.marc::XML)) LOOP
+ subxml := XMLCONCAT(subxml, xml_frag::XML);
+ END LOOP;
+ END LOOP;
+
+ -- append data from the subordinate records to the
+ -- main record document before applying the XSLT
+
+ IF subxml IS NOT NULL THEN
+ xml_buf := REGEXP_REPLACE(xml_buf,
+ '</record>(.*?)$', subxml || '</record>' || E'\\1');
+ END IF;
+
+ IF format = 'marcxml' THEN
+ -- If we're not using the prefixed namespace in
+ -- this record, then remove all declarations of it
+ IF xml_buf !~ E'<marc:' THEN
+ xml_buf := REGEXP_REPLACE(xml_buf,
+ ' xmlns:marc="http://www.loc.gov/MARC21/slim"', '', 'g');
+ END IF;
+ ELSE
+ xml_buf := oils_xslt_process(xml_buf, xfrm.xslt)::XML;
+ END IF;
+
+ -- update top_el to reflect the change in xml_buf, which may
+ -- now be a different type of document (e.g. record -> mods)
+ top_el := REGEXP_REPLACE(xml_buf, E'^.*?<((?:\\S+:)?' ||
+ layout.holdings_element || ').*$', E'\\1');
+
+ IF axml IS NOT NULL THEN
+ xml_buf := REGEXP_REPLACE(xml_buf,
+ '</' || top_el || '>(.*?)$', axml || '</' || top_el || E'>\\1');
+ END IF;
+
+ IF hxml IS NOT NULL THEN
+ xml_buf := REGEXP_REPLACE(xml_buf,
+ '</' || top_el || '>(.*?)$', hxml || '</' || top_el || E'>\\1');
+ END IF;
+
+ IF ('mmr.unapi' = ANY (includes)) THEN
+ output := REGEXP_REPLACE(
+ xml_buf,
+ '</' || top_el || '>(.*?)',
+ XMLELEMENT(
+ name abbr,
+ XMLATTRIBUTES(
+ 'http://www.w3.org/1999/xhtml' AS xmlns,
+ 'unapi-id' AS class,
+ 'tag:open-ils.org:U2@mmr/' || mmr_id || '/' || org AS title
+ )
+ )::TEXT || '</' || top_el || E'>\\1'
+ );
+ ELSE
+ output := xml_buf;
+ END IF;
+
+ -- remove ignorable whitesace
+ output := REGEXP_REPLACE(output::TEXT,E'>\\s+<','><','gs')::XML;
+ RETURN output;
+END;
+$F$ LANGUAGE PLPGSQL STABLE;
+
+
+-- SEED DATA ---------------------------------------------------------------
+
+-- by default, use the same format record attribute as that used for icons
+-- TODO: verify attr name still matches
+INSERT INTO config.global_flag (name, label, value, enabled) VALUES (
+ 'opac.metarecord.holds.format_attr',
+ 'OPAC Metarecord Hold Formats Attribute',
+ 'local_format',
+ TRUE
+);
+
+CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
+ bibid BIGINT[],
+ ouid INT,
+ depth INT DEFAULT NULL,
+ slimit HSTORE DEFAULT NULL,
+ soffset HSTORE DEFAULT NULL,
+ pref_lib INT DEFAULT NULL,
+ includes TEXT[] DEFAULT NULL::TEXT[]
+) RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+ SELECT ua.id, ua.name, ua.label_sortkey, MIN(ua.rank) AS rank FROM (
+ SELECT acn.id, aou.name, acn.label_sortkey,
+ evergreen.rank_ou(aou.id, $2, $6), evergreen.rank_cp_status(acp.status),
+ RANK() OVER w
+ FROM asset.call_number acn
+ JOIN asset.copy acp ON (acn.id = acp.call_number)
+ JOIN actor.org_unit_descendants( $2, COALESCE(
+ $3, (
+ SELECT depth
+ FROM actor.org_unit_type aout
+ INNER JOIN actor.org_unit ou ON ou_type = aout.id
+ WHERE ou.id = $2
+ ), $6)
+ ) AS aou ON (acp.circ_lib = aou.id)
+ WHERE acn.record = ANY ($1)
+ AND acn.deleted IS FALSE
+ AND acp.deleted IS FALSE
+ AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN
+ EXISTS (
+ SELECT 1
+ FROM asset.opac_visible_copies
+ WHERE copy_id = acp.id AND record = acn.record
+ ) ELSE TRUE END
+ GROUP BY acn.id, acp.status, aou.name, acn.label_sortkey, aou.id
+ WINDOW w AS (
+ ORDER BY evergreen.rank_ou(aou.id, $2, $6), evergreen.rank_cp_status(acp.status)
+ )
+ ) AS ua
+ GROUP BY ua.id, ua.name, ua.label_sortkey
+ ORDER BY rank, ua.name, ua.label_sortkey
+ LIMIT ($4 -> 'acn')::INT
+ OFFSET ($5 -> 'acn')::INT;
+$$
+LANGUAGE SQL STABLE;
+
+CREATE OR REPLACE FUNCTION evergreen.ranked_volumes
+ ( bibid BIGINT, ouid INT, depth INT DEFAULT NULL, slimit HSTORE DEFAULT NULL, soffset HSTORE DEFAULT NULL, pref_lib INT DEFAULT NULL, includes TEXT[] DEFAULT NULL::TEXT[] )
+ RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT)
+ AS $$ SELECT * FROM evergreen.ranked_volumes(ARRAY[$1],$2,$3,$4,$5,$6,$7) $$ LANGUAGE SQL STABLE;
+
+
+CREATE OR REPLACE FUNCTION evergreen.located_uris (
+ bibid BIGINT[],
+ ouid INT,
+ pref_lib INT DEFAULT NULL
+) RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank INT) AS $$
+ SELECT acn.id, aou.name, acn.label_sortkey, evergreen.rank_ou(aou.id, $2, $3) AS pref_ou
+ FROM asset.call_number acn
+ INNER JOIN asset.uri_call_number_map auricnm ON acn.id = auricnm.call_number
+ INNER JOIN asset.uri auri ON auri.id = auricnm.uri
+ INNER JOIN actor.org_unit_ancestors( COALESCE($3, $2) ) aou ON (acn.owning_lib = aou.id)
+ WHERE acn.record = ANY ($1)
+ AND acn.deleted IS FALSE
+ AND auri.active IS TRUE
+ UNION
+ SELECT acn.id, aou.name, acn.label_sortkey, evergreen.rank_ou(aou.id, $2, $3) AS pref_ou
+ FROM asset.call_number acn
+ INNER JOIN asset.uri_call_number_map auricnm ON acn.id = auricnm.call_number
+ INNER JOIN asset.uri auri ON auri.id = auricnm.uri
+ INNER JOIN actor.org_unit_ancestors( $2 ) aou ON (acn.owning_lib = aou.id)
+ WHERE acn.record = ANY ($1)
+ AND acn.deleted IS FALSE
+ AND auri.active IS TRUE;
+$$
+LANGUAGE SQL STABLE;
+
+CREATE OR REPLACE FUNCTION evergreen.located_uris ( bibid BIGINT, ouid INT, pref_lib INT DEFAULT NULL)
+ RETURNS TABLE (id BIGINT, name TEXT, label_sortkey TEXT, rank INT)
+ AS $$ SELECT * FROM evergreen.located_uris(ARRAY[$1],$2,$3) $$ LANGUAGE SQL STABLE;
+
+COMMIT;