Unwrapped upgrade script user/tsbere@mvlc.org/native-array-functions
authorThomas Berezansky <tsbere@mvlc.org>
Sun, 29 May 2011 13:01:39 +0000 (09:01 -0400)
committerThomas Berezansky <tsbere@mvlc.org>
Sun, 29 May 2011 13:01:39 +0000 (09:01 -0400)
Signed-off-by: Thomas Berezansky <tsbere@mvlc.org>
Open-ILS/src/sql/Pg/upgrade/XXXX.native_func.sql [new file with mode: 0644]

diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.native_func.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.native_func.sql
new file mode 100644 (file)
index 0000000..2fc0970
--- /dev/null
@@ -0,0 +1,1742 @@
+CREATE OR REPLACE FUNCTION oils_xpath_table ( key TEXT, document_field TEXT, relation_name TEXT, xpaths TEXT, criteria TEXT ) RETURNS SETOF RECORD AS $func$
+DECLARE
+    xpath_list  TEXT[];
+    select_list TEXT[];
+    where_list  TEXT[];
+    q           TEXT;
+    out_record  RECORD;
+    empty_test  RECORD;
+BEGIN
+    xpath_list := STRING_TO_ARRAY( xpaths, '|' );
+
+    select_list := ARRAY_APPEND( select_list, key || '::INT AS key' );
+
+    FOR i IN 1 .. ARRAY_UPPER(xpath_list,1) LOOP
+        IF xpath_list[i] = 'null()' THEN
+            select_list := ARRAY_APPEND( select_list, 'NULL::TEXT AS c_' || i );
+        ELSE
+            select_list := ARRAY_APPEND(
+                select_list,
+                $sel$
+                unnest(
+                    COALESCE(
+                        NULLIF(
+                            oils_xpath(
+                                $sel$ ||
+                                    quote_literal(
+                                        CASE
+                                            WHEN xpath_list[i] ~ $re$/[^/[]*@[^/]+$$re$ OR xpath_list[i] ~ $re$text\(\)$$re$ THEN xpath_list[i]
+                                            ELSE xpath_list[i] || '//text()'
+                                        END
+                                    ) ||
+                                $sel$,
+                                $sel$ || document_field || $sel$
+                            ),
+                           '{}'::TEXT[]
+                        ),
+                        '{NULL}'::TEXT[]
+                    )
+                ) AS c_$sel$ || i
+            );
+            where_list := ARRAY_APPEND(
+                where_list,
+                'c_' || i || ' IS NOT NULL'
+            );
+        END IF;
+    END LOOP;
+
+    q := $q$
+SELECT * FROM (
+    SELECT $q$ || ARRAY_TO_STRING( select_list, ', ' ) || $q$ FROM $q$ || relation_name || $q$ WHERE ($q$ || criteria || $q$)
+)x WHERE $q$ || ARRAY_TO_STRING( where_list, ' OR ' );
+    -- RAISE NOTICE 'query: %', q;
+
+    FOR out_record IN EXECUTE q LOOP
+        RETURN NEXT out_record;
+    END LOOP;
+
+    RETURN;
+END;
+$func$ LANGUAGE PLPGSQL IMMUTABLE;
+
+CREATE OR REPLACE FUNCTION biblio.extract_metabib_field_entry ( rid BIGINT, default_joiner TEXT ) RETURNS SETOF metabib.field_entry_template AS $func$
+DECLARE
+    bib     biblio.record_entry%ROWTYPE;
+    idx     config.metabib_field%ROWTYPE;
+    xfrm        config.xml_transform%ROWTYPE;
+    prev_xfrm   TEXT;
+    transformed_xml TEXT;
+    xml_node    TEXT;
+    xml_node_list   TEXT[];
+    facet_text  TEXT;
+    raw_text    TEXT;
+    curr_text   TEXT;
+    joiner      TEXT := default_joiner; -- XXX will index defs supply a joiner?
+    output_row  metabib.field_entry_template%ROWTYPE;
+BEGIN
+
+    -- Get the record
+    SELECT INTO bib * FROM biblio.record_entry WHERE id = rid;
+
+    -- Loop over the indexing entries
+    FOR idx IN SELECT * FROM config.metabib_field ORDER BY format LOOP
+
+        SELECT INTO xfrm * from config.xml_transform WHERE name = idx.format;
+
+        -- See if we can skip the XSLT ... it's expensive
+        IF prev_xfrm IS NULL OR prev_xfrm <> xfrm.name THEN
+            -- Can't skip the transform
+            IF xfrm.xslt <> '---' THEN
+                transformed_xml := oils_xslt_process(bib.marc,xfrm.xslt);
+            ELSE
+                transformed_xml := bib.marc;
+            END IF;
+
+            prev_xfrm := xfrm.name;
+        END IF;
+
+        xml_node_list := oils_xpath( idx.xpath, transformed_xml, ARRAY[ARRAY[xfrm.prefix, xfrm.namespace_uri]] );
+
+        raw_text := NULL;
+        FOR xml_node IN SELECT x FROM unnest(xml_node_list) AS x LOOP
+            CONTINUE WHEN xml_node !~ E'^\\s*<';
+
+            curr_text := ARRAY_TO_STRING(
+                oils_xpath( '//text()',
+                    REGEXP_REPLACE( -- This escapes all &s not followed by "amp;".  Data ise returned from oils_xpath (above) in UTF-8, not entity encoded
+                        REGEXP_REPLACE( -- This escapes embeded <s
+                            xml_node,
+                            $re$(>[^<]+)(<)([^>]+<)$re$,
+                            E'\\1&lt;\\3',
+                            'g'
+                        ),
+                        '&(?!amp;)',
+                        '&amp;',
+                        'g'
+                    )
+                ),
+                ' '
+            );
+
+            CONTINUE WHEN curr_text IS NULL OR curr_text = '';
+
+            IF raw_text IS NOT NULL THEN
+                raw_text := raw_text || joiner;
+            END IF;
+
+            raw_text := COALESCE(raw_text,'') || curr_text;
+
+            -- insert raw node text for faceting
+            IF idx.facet_field THEN
+
+                IF idx.facet_xpath IS NOT NULL AND idx.facet_xpath <> '' THEN
+                    facet_text := oils_xpath_string( idx.facet_xpath, xml_node, joiner, ARRAY[ARRAY[xfrm.prefix, xfrm.namespace_uri]] );
+                ELSE
+                    facet_text := curr_text;
+                END IF;
+
+                output_row.field_class = idx.field_class;
+                output_row.field = -1 * idx.id;
+                output_row.source = rid;
+                output_row.value = BTRIM(REGEXP_REPLACE(facet_text, E'\\s+', ' ', 'g'));
+
+                RETURN NEXT output_row;
+            END IF;
+
+        END LOOP;
+
+        CONTINUE WHEN raw_text IS NULL OR raw_text = '';
+
+        -- insert combined node text for searching
+        IF idx.search_field THEN
+            output_row.field_class = idx.field_class;
+            output_row.field = idx.id;
+            output_row.source = rid;
+            output_row.value = BTRIM(REGEXP_REPLACE(raw_text, E'\\s+', ' ', 'g'));
+
+            RETURN NEXT output_row;
+        END IF;
+
+    END LOOP;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION biblio.extract_located_uris( bib_id BIGINT, marcxml TEXT, editor_id INT ) RETURNS VOID AS $func$
+DECLARE
+    uris            TEXT[];
+    uri_xml         TEXT;
+    uri_label       TEXT;
+    uri_href        TEXT;
+    uri_use         TEXT;
+    uri_owner_list  TEXT[];
+    uri_owner       TEXT;
+    uri_owner_id    INT;
+    uri_id          INT;
+    uri_cn_id       INT;
+    uri_map_id      INT;
+BEGIN
+
+    -- Clear any URI mappings and call numbers for this bib.
+    -- This leads to acn / auricnm inflation, but also enables
+    -- old acn/auricnm's to go away and for bibs to be deleted.
+    FOR uri_cn_id IN SELECT id FROM asset.call_number WHERE record = bib_id AND label = '##URI##' AND NOT deleted LOOP
+        DELETE FROM asset.uri_call_number_map WHERE call_number = uri_cn_id;
+        DELETE FROM asset.call_number WHERE id = uri_cn_id;
+    END LOOP;
+
+    uris := oils_xpath('//*[@tag="856" and (@ind1="4" or @ind1="1") and (@ind2="0" or @ind2="1")]',marcxml);
+    IF ARRAY_UPPER(uris,1) > 0 THEN
+        FOR i IN 1 .. ARRAY_UPPER(uris, 1) LOOP
+            -- First we pull info out of the 856
+            uri_xml     := uris[i];
+
+            uri_href    := (oils_xpath('//*[@code="u"]/text()',uri_xml))[1];
+            uri_label   := (oils_xpath('//*[@code="y"]/text()|//*[@code="3"]/text()|//*[@code="u"]/text()',uri_xml))[1];
+            uri_use     := (oils_xpath('//*[@code="z"]/text()|//*[@code="2"]/text()|//*[@code="n"]/text()',uri_xml))[1];
+            CONTINUE WHEN uri_href IS NULL OR uri_label IS NULL;
+
+            -- Get the distinct list of libraries wanting to use 
+            SELECT  array_agg(
+                        DISTINCT REGEXP_REPLACE(
+                            x,
+                            $re$^.*?\((\w+)\).*$$re$,
+                            E'\\1'
+                        )
+                    ) INTO uri_owner_list
+              FROM  UNNEST(
+                        oils_xpath(
+                            '//*[@code="9"]/text()|//*[@code="w"]/text()|//*[@code="n"]/text()',
+                            uri_xml
+                        )
+                    )x;
+
+            IF ARRAY_UPPER(uri_owner_list,1) > 0 THEN
+
+                -- look for a matching uri
+                SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+                IF NOT FOUND THEN -- create one
+                    INSERT INTO asset.uri (label, href, use_restriction) VALUES (uri_label, uri_href, uri_use);
+                    IF uri_use IS NULL THEN
+                        SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction IS NULL AND active;
+                    ELSE
+                        SELECT id INTO uri_id FROM asset.uri WHERE label = uri_label AND href = uri_href AND use_restriction = uri_use AND active;
+                    END IF;
+                END IF;
+
+                FOR j IN 1 .. ARRAY_UPPER(uri_owner_list, 1) LOOP
+                    uri_owner := uri_owner_list[j];
+
+                    SELECT id INTO uri_owner_id FROM actor.org_unit WHERE shortname = uri_owner;
+                    CONTINUE WHEN NOT FOUND;
+
+                    -- we need a call number to link through
+                    SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+                    IF NOT FOUND THEN
+                        INSERT INTO asset.call_number (owning_lib, record, create_date, edit_date, creator, editor, label)
+                            VALUES (uri_owner_id, bib_id, 'now', 'now', editor_id, editor_id, '##URI##');
+                        SELECT id INTO uri_cn_id FROM asset.call_number WHERE owning_lib = uri_owner_id AND record = bib_id AND label = '##URI##' AND NOT deleted;
+                    END IF;
+
+                    -- now, link them if they're not already
+                    SELECT id INTO uri_map_id FROM asset.uri_call_number_map WHERE call_number = uri_cn_id AND uri = uri_id;
+                    IF NOT FOUND THEN
+                        INSERT INTO asset.uri_call_number_map (call_number, uri) VALUES (uri_cn_id, uri_id);
+                    END IF;
+
+                END LOOP;
+
+            END IF;
+
+        END LOOP;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION metabib.remap_metarecord_for_bib( bib_id BIGINT, fp TEXT ) RETURNS BIGINT AS $func$
+DECLARE
+    source_count    INT;
+    old_mr          BIGINT;
+    tmp_mr          metabib.metarecord%ROWTYPE;
+    deleted_mrs     BIGINT[];
+BEGIN
+
+    DELETE FROM metabib.metarecord_source_map WHERE source = bib_id; -- Rid ourselves of the search-estimate-killing linkage
+
+    FOR tmp_mr IN SELECT  m.* FROM  metabib.metarecord m JOIN metabib.metarecord_source_map s ON (s.metarecord = m.id) WHERE s.source = bib_id LOOP
+
+        IF old_mr IS NULL AND fp = tmp_mr.fingerprint THEN -- Find the first fingerprint-matching
+            old_mr := tmp_mr.id;
+        ELSE
+            SELECT COUNT(*) INTO source_count FROM metabib.metarecord_source_map WHERE metarecord = tmp_mr.id;
+            IF source_count = 0 THEN -- No other records
+                deleted_mrs := ARRAY_APPEND(deleted_mrs, tmp_mr.id);
+                DELETE FROM metabib.metarecord WHERE id = tmp_mr.id;
+            END IF;
+        END IF;
+
+    END LOOP;
+
+    IF old_mr IS NULL THEN -- we found no suitable, preexisting MR based on old source maps
+        SELECT id INTO old_mr FROM metabib.metarecord WHERE fingerprint = fp; -- is there one for our current fingerprint?
+        IF old_mr IS NULL THEN -- nope, create one and grab its id
+            INSERT INTO metabib.metarecord ( fingerprint, master_record ) VALUES ( fp, bib_id );
+            SELECT id INTO old_mr FROM metabib.metarecord WHERE fingerprint = fp;
+        ELSE -- indeed there is. update it with a null cache and recalcualated master record
+            UPDATE  metabib.metarecord
+              SET   mods = NULL,
+                    master_record = ( SELECT id FROM biblio.record_entry WHERE fingerprint = fp ORDER BY quality DESC LIMIT 1)
+              WHERE id = old_mr;
+        END IF;
+    ELSE -- there was one we already attached to, update its mods cache and master_record
+        UPDATE  metabib.metarecord
+          SET   mods = NULL,
+                master_record = ( SELECT id FROM biblio.record_entry WHERE fingerprint = fp ORDER BY quality DESC LIMIT 1)
+          WHERE id = old_mr;
+    END IF;
+
+    INSERT INTO metabib.metarecord_source_map (metarecord, source) VALUES (old_mr, bib_id); -- new source mapping
+
+    IF ARRAY_UPPER(deleted_mrs,1) > 0 THEN
+        UPDATE action.hold_request SET target = old_mr WHERE target IN ( SELECT unnest(deleted_mrs) ) AND hold_type = 'M'; -- if we had to delete any MRs above, make sure their holds are moved
+    END IF;
+
+    RETURN old_mr;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION biblio.map_authority_linking (bibid BIGINT, marc TEXT) RETURNS BIGINT AS $func$
+    DELETE FROM authority.bib_linking WHERE bib = $1;
+    INSERT INTO authority.bib_linking (bib, authority)
+        SELECT  y.bib,
+                y.authority
+          FROM (    SELECT  DISTINCT $1 AS bib,
+                            BTRIM(remove_paren_substring(txt))::BIGINT AS authority
+                      FROM  unnest(oils_xpath('//*[@code="0"]/text()',$2)) x(txt)
+                      WHERE BTRIM(remove_paren_substring(txt)) ~ $re$^\d+$$re$
+                ) y JOIN authority.record_entry r ON r.id = y.authority;
+    SELECT $1;
+$func$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION biblio.indexing_ingest_or_delete () RETURNS TRIGGER AS $func$
+DECLARE
+    transformed_xml TEXT;
+    prev_xfrm       TEXT;
+    normalizer      RECORD;
+    xfrm            config.xml_transform%ROWTYPE;
+    attr_value      TEXT;
+    new_attrs       HSTORE := ''::HSTORE;
+    attr_def        config.record_attr_definition%ROWTYPE;
+BEGIN
+
+    IF NEW.deleted IS TRUE THEN -- If this bib is deleted
+        DELETE FROM metabib.metarecord_source_map WHERE source = NEW.id; -- Rid ourselves of the search-estimate-killing linkage
+        DELETE FROM metabib.record_attr WHERE id = NEW.id; -- Kill the attrs hash, useless on deleted records
+        DELETE FROM authority.bib_linking WHERE bib = NEW.id; -- Avoid updating fields in bibs that are no longer visible
+        DELETE FROM biblio.peer_bib_copy_map WHERE peer_record = NEW.id; -- Separate any multi-homed items
+        RETURN NEW; -- and we're done
+    END IF;
+
+    IF TG_OP = 'UPDATE' THEN -- re-ingest?
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.reingest.force_on_same_marc' AND enabled;
+
+        IF NOT FOUND AND OLD.marc = NEW.marc THEN -- don't do anything if the MARC didn't change
+            RETURN NEW;
+        END IF;
+    END IF;
+
+    -- Record authority linking
+    PERFORM * FROM config.internal_flag WHERE name = 'ingest.disable_authority_linking' AND enabled;
+    IF NOT FOUND THEN
+        PERFORM biblio.map_authority_linking( NEW.id, NEW.marc );
+    END IF;
+
+    -- Flatten and insert the mfr data
+    PERFORM * FROM config.internal_flag WHERE name = 'ingest.disable_metabib_full_rec' AND enabled;
+    IF NOT FOUND THEN
+        PERFORM metabib.reingest_metabib_full_rec(NEW.id);
+
+        -- Now we pull out attribute data, which is dependent on the mfr for all but XPath-based fields
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.disable_metabib_rec_descriptor' AND enabled;
+        IF NOT FOUND THEN
+            FOR attr_def IN SELECT * FROM config.record_attr_definition ORDER BY format LOOP
+
+                IF attr_def.tag IS NOT NULL THEN -- tag (and optional subfield list) selection
+                    SELECT  ARRAY_TO_STRING(array_agg(value), COALESCE(attr_def.joiner,' ')) INTO attr_value
+                      FROM  (SELECT * FROM metabib.full_rec ORDER BY tag, subfield) AS x
+                      WHERE record = NEW.id
+                            AND tag LIKE attr_def.tag
+                            AND CASE
+                                WHEN attr_def.sf_list IS NOT NULL 
+                                    THEN POSITION(subfield IN attr_def.sf_list) > 0
+                                ELSE TRUE
+                                END
+                      GROUP BY tag
+                      ORDER BY tag
+                      LIMIT 1;
+
+                ELSIF attr_def.fixed_field IS NOT NULL THEN -- a named fixed field, see config.marc21_ff_pos_map.fixed_field
+                    attr_value := biblio.marc21_extract_fixed_field(NEW.id, attr_def.fixed_field);
+
+                ELSIF attr_def.xpath IS NOT NULL THEN -- and xpath expression
+
+                    SELECT INTO xfrm * FROM config.xml_transform WHERE name = attr_def.format;
+            
+                    -- See if we can skip the XSLT ... it's expensive
+                    IF prev_xfrm IS NULL OR prev_xfrm <> xfrm.name THEN
+                        -- Can't skip the transform
+                        IF xfrm.xslt <> '---' THEN
+                            transformed_xml := oils_xslt_process(NEW.marc,xfrm.xslt);
+                        ELSE
+                            transformed_xml := NEW.marc;
+                        END IF;
+            
+                        prev_xfrm := xfrm.name;
+                    END IF;
+
+                    IF xfrm.name IS NULL THEN
+                        -- just grab the marcxml (empty) transform
+                        SELECT INTO xfrm * FROM config.xml_transform WHERE xslt = '---' LIMIT 1;
+                        prev_xfrm := xfrm.name;
+                    END IF;
+
+                    attr_value := oils_xpath_string(attr_def.xpath, transformed_xml, COALESCE(attr_def.joiner,' '), ARRAY[ARRAY[xfrm.prefix, xfrm.namespace_uri]]);
+
+                ELSIF attr_def.phys_char_sf IS NOT NULL THEN -- a named Physical Characteristic, see config.marc21_physical_characteristic_*_map
+                    SELECT  m.value INTO attr_value
+                      FROM  biblio.marc21_physical_characteristics(NEW.id) v
+                            JOIN config.marc21_physical_characteristic_value_map m ON (m.id = v.value)
+                      WHERE v.subfield = attr_def.phys_char_sf
+                      LIMIT 1; -- Just in case ...
+
+                END IF;
+
+                -- apply index normalizers to attr_value
+                FOR normalizer IN
+                    SELECT  n.func AS func,
+                            n.param_count AS param_count,
+                            m.params AS params
+                      FROM  config.index_normalizer n
+                            JOIN config.record_attr_index_norm_map m ON (m.norm = n.id)
+                      WHERE attr = attr_def.name
+                      ORDER BY m.pos LOOP
+                        EXECUTE 'SELECT ' || normalizer.func || '(' ||
+                            quote_literal( attr_value ) ||
+                            CASE
+                                WHEN normalizer.param_count > 0
+                                    THEN ',' || REPLACE(REPLACE(BTRIM(normalizer.params,'[]'),E'\'',E'\\\''),E'"',E'\'')
+                                    ELSE ''
+                                END ||
+                            ')' INTO attr_value;
+        
+                END LOOP;
+
+                -- Add the new value to the hstore
+                new_attrs := new_attrs || hstore( attr_def.name, attr_value );
+
+            END LOOP;
+
+            IF TG_OP = 'INSERT' OR OLD.deleted THEN -- initial insert OR revivication
+                INSERT INTO metabib.record_attr (id, attrs) VALUES (NEW.id, new_attrs);
+            ELSE
+                UPDATE metabib.record_attr SET attrs = attrs || new_attrs WHERE id = NEW.id;
+            END IF;
+
+        END IF;
+    END IF;
+
+    -- Gather and insert the field entry data
+    PERFORM metabib.reingest_metabib_field_entries(NEW.id);
+
+    -- Located URI magic
+    IF TG_OP = 'INSERT' THEN
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.disable_located_uri' AND enabled;
+        IF NOT FOUND THEN
+            PERFORM biblio.extract_located_uris( NEW.id, NEW.marc, NEW.editor );
+        END IF;
+    ELSE
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.disable_located_uri' AND enabled;
+        IF NOT FOUND THEN
+            PERFORM biblio.extract_located_uris( NEW.id, NEW.marc, NEW.editor );
+        END IF;
+    END IF;
+
+    -- (re)map metarecord-bib linking
+    IF TG_OP = 'INSERT' THEN -- if not deleted and performing an insert, check for the flag
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.metarecord_mapping.skip_on_insert' AND enabled;
+        IF NOT FOUND THEN
+            PERFORM metabib.remap_metarecord_for_bib( NEW.id, NEW.fingerprint );
+        END IF;
+    ELSE -- we're doing an update, and we're not deleted, remap
+        PERFORM * FROM config.internal_flag WHERE name = 'ingest.metarecord_mapping.skip_on_update' AND enabled;
+        IF NOT FOUND THEN
+            PERFORM metabib.remap_metarecord_for_bib( NEW.id, NEW.fingerprint );
+        END IF;
+    END IF;
+
+    RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION action.item_user_circ_test( circ_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS SETOF action.circ_matrix_test_result AS $func$
+DECLARE
+    user_object             actor.usr%ROWTYPE;
+    standing_penalty        config.standing_penalty%ROWTYPE;
+    item_object             asset.copy%ROWTYPE;
+    item_status_object      config.copy_status%ROWTYPE;
+    item_location_object    asset.copy_location%ROWTYPE;
+    result                  action.circ_matrix_test_result;
+    circ_test               action.found_circ_matrix_matchpoint;
+    circ_matchpoint         config.circ_matrix_matchpoint%ROWTYPE;
+    out_by_circ_mod         config.circ_matrix_circ_mod_test%ROWTYPE;
+    circ_mod_map            config.circ_matrix_circ_mod_test_map%ROWTYPE;
+    hold_ratio              action.hold_stats%ROWTYPE;
+    penalty_type            TEXT;
+    items_out               INT;
+    context_org_list        INT[];
+    done                    BOOL := FALSE;
+BEGIN
+    -- Assume success unless we hit a failure condition
+    result.success := TRUE;
+
+    -- Fail if the user is BARRED
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+    -- Fail if we couldn't find the user 
+    IF user_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+    -- Fail if we couldn't find the item 
+    IF item_object.id IS NULL THEN
+        result.fail_part := 'no_item';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    IF user_object.barred IS TRUE THEN
+        result.fail_part := 'actor.usr.barred';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate
+    IF item_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item isn't in a circulateable status on a non-renewal
+    IF NOT renewal AND item_object.status NOT IN ( 0, 7, 8 ) THEN 
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    ELSIF renewal AND item_object.status <> 1 THEN
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate because of the shelving location
+    SELECT INTO item_location_object * FROM asset.copy_location WHERE id = item_object.location;
+    IF item_location_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy_location.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    SELECT INTO circ_test * FROM action.find_circ_matrix_matchpoint(circ_ou, item_object, user_object, renewal);
+
+    circ_matchpoint             := circ_test.matchpoint;
+    result.matchpoint           := circ_matchpoint.id;
+    result.circulate            := circ_matchpoint.circulate;
+    result.duration_rule        := circ_matchpoint.duration_rule;
+    result.recurring_fine_rule  := circ_matchpoint.recurring_fine_rule;
+    result.max_fine_rule        := circ_matchpoint.max_fine_rule;
+    result.hard_due_date        := circ_matchpoint.hard_due_date;
+    result.renewals             := circ_matchpoint.renewals;
+    result.grace_period         := circ_matchpoint.grace_period;
+    result.buildrows            := circ_test.buildrows;
+
+    -- Fail if we couldn't find a matchpoint
+    IF circ_test.success = false THEN
+        result.fail_part := 'no_matchpoint';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN; -- All tests after this point require a matchpoint. No sense in running on an incomplete or missing one.
+    END IF;
+
+    -- Apparently....use the circ matchpoint org unit to determine what org units are valid.
+    SELECT INTO context_org_list array_agg(id) FROM actor.org_unit_full_path( circ_matchpoint.org_unit );
+
+    IF renewal THEN
+        penalty_type = '%RENEW%';
+    ELSE
+        penalty_type = '%CIRC%';
+    END IF;
+
+    FOR standing_penalty IN
+        SELECT  DISTINCT csp.*
+          FROM  actor.usr_standing_penalty usp
+                JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+          WHERE usr = match_user
+                AND usp.org_unit IN ( SELECT * FROM unnest(context_org_list) )
+                AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                AND csp.block_list LIKE penalty_type LOOP
+
+        result.fail_part := standing_penalty.name;
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END LOOP;
+
+    -- Fail if the test is set to hard non-circulating
+    IF circ_matchpoint.circulate IS FALSE THEN
+        result.fail_part := 'config.circ_matrix_test.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the total copy-hold ratio is too low
+    IF circ_matchpoint.total_copy_hold_ratio IS NOT NULL THEN
+        SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item);
+        IF hold_ratio.total_copy_ratio IS NOT NULL AND hold_ratio.total_copy_ratio < circ_matchpoint.total_copy_hold_ratio THEN
+            result.fail_part := 'config.circ_matrix_test.total_copy_hold_ratio';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    -- Fail if the available copy-hold ratio is too low
+    IF circ_matchpoint.available_copy_hold_ratio IS NOT NULL THEN
+        IF hold_ratio.hold_count IS NULL THEN
+            SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item);
+        END IF;
+        IF hold_ratio.available_copy_ratio IS NOT NULL AND hold_ratio.available_copy_ratio < circ_matchpoint.available_copy_hold_ratio THEN
+            result.fail_part := 'config.circ_matrix_test.available_copy_hold_ratio';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    -- Fail if the user has too many items with specific circ_modifiers checked out
+    FOR out_by_circ_mod IN SELECT * FROM config.circ_matrix_circ_mod_test WHERE matchpoint = circ_matchpoint.id LOOP
+        SELECT  INTO items_out COUNT(*)
+          FROM  action.circulation circ
+            JOIN asset.copy cp ON (cp.id = circ.target_copy)
+          WHERE circ.usr = match_user
+               AND circ.circ_lib IN ( SELECT * FROM unnest(context_org_list) )
+            AND circ.checkin_time IS NULL
+            AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL)
+            AND cp.circ_modifier IN (SELECT circ_mod FROM config.circ_matrix_circ_mod_test_map WHERE circ_mod_test = out_by_circ_mod.id);
+        IF items_out >= out_by_circ_mod.items_out THEN
+            result.fail_part := 'config.circ_matrix_circ_mod_test';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END LOOP;
+
+    -- If we passed everything, return the successful matchpoint id
+    IF NOT done THEN
+        RETURN NEXT result;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION actor.calculate_system_penalties( match_user INT, context_org INT ) RETURNS SETOF actor.usr_standing_penalty AS $func$
+DECLARE
+    user_object         actor.usr%ROWTYPE;
+    new_sp_row          actor.usr_standing_penalty%ROWTYPE;
+    existing_sp_row     actor.usr_standing_penalty%ROWTYPE;
+    collections_fines   permission.grp_penalty_threshold%ROWTYPE;
+    max_fines           permission.grp_penalty_threshold%ROWTYPE;
+    max_overdue         permission.grp_penalty_threshold%ROWTYPE;
+    max_items_out       permission.grp_penalty_threshold%ROWTYPE;
+    tmp_grp             INT;
+    items_overdue       INT;
+    items_out           INT;
+    context_org_list    INT[];
+    current_fines        NUMERIC(8,2) := 0.0;
+    tmp_fines            NUMERIC(8,2);
+    tmp_groc            RECORD;
+    tmp_circ            RECORD;
+    tmp_org             actor.org_unit%ROWTYPE;
+    tmp_penalty         config.standing_penalty%ROWTYPE;
+    tmp_depth           INTEGER;
+BEGIN
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+    -- Max fines
+    SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+    -- Fail if the user has a high fine balance
+    LOOP
+        tmp_grp := user_object.profile;
+        LOOP
+            SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 1 AND org_unit = tmp_org.id;
+
+            IF max_fines.threshold IS NULL THEN
+                SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+            ELSE
+                EXIT;
+            END IF;
+
+            IF tmp_grp IS NULL THEN
+                EXIT;
+            END IF;
+        END LOOP;
+
+        IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+            EXIT;
+        END IF;
+
+        SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+    END LOOP;
+
+    IF max_fines.threshold IS NOT NULL THEN
+
+        RETURN QUERY
+            SELECT  *
+              FROM  actor.usr_standing_penalty
+              WHERE usr = match_user
+                    AND org_unit = max_fines.org_unit
+                    AND (stop_date IS NULL or stop_date > NOW())
+                    AND standing_penalty = 1;
+
+        SELECT INTO context_org_list array_agg(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+        SELECT  SUM(f.balance_owed) INTO current_fines
+          FROM  money.materialized_billable_xact_summary f
+                JOIN (
+                    SELECT  r.id
+                      FROM  booking.reservation r
+                      WHERE r.usr = match_user
+                            AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  g.id
+                      FROM  money.grocery g
+                      WHERE g.usr = match_user
+                            AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  circ.id
+                      FROM  action.circulation circ
+                      WHERE circ.usr = match_user
+                            AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND xact_finish IS NULL ) l USING (id);
+
+        IF current_fines >= max_fines.threshold THEN
+            new_sp_row.usr := match_user;
+            new_sp_row.org_unit := max_fines.org_unit;
+            new_sp_row.standing_penalty := 1;
+            RETURN NEXT new_sp_row;
+        END IF;
+    END IF;
+
+    -- Start over for max overdue
+    SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+    -- Fail if the user has too many overdue items
+    LOOP
+        tmp_grp := user_object.profile;
+        LOOP
+
+            SELECT * INTO max_overdue FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 2 AND org_unit = tmp_org.id;
+
+            IF max_overdue.threshold IS NULL THEN
+                SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+            ELSE
+                EXIT;
+            END IF;
+
+            IF tmp_grp IS NULL THEN
+                EXIT;
+            END IF;
+        END LOOP;
+
+        IF max_overdue.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+            EXIT;
+        END IF;
+
+        SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+    END LOOP;
+
+    IF max_overdue.threshold IS NOT NULL THEN
+
+        RETURN QUERY
+            SELECT  *
+              FROM  actor.usr_standing_penalty
+              WHERE usr = match_user
+                    AND org_unit = max_overdue.org_unit
+                    AND (stop_date IS NULL or stop_date > NOW())
+                    AND standing_penalty = 2;
+
+        SELECT  INTO items_overdue COUNT(*)
+          FROM  action.circulation circ
+                JOIN  actor.org_unit_full_path( max_overdue.org_unit ) fp ON (circ.circ_lib = fp.id)
+          WHERE circ.usr = match_user
+            AND circ.checkin_time IS NULL
+            AND circ.due_date < NOW()
+            AND (circ.stop_fines = 'MAXFINES' OR circ.stop_fines IS NULL);
+
+        IF items_overdue >= max_overdue.threshold::INT THEN
+            new_sp_row.usr := match_user;
+            new_sp_row.org_unit := max_overdue.org_unit;
+            new_sp_row.standing_penalty := 2;
+            RETURN NEXT new_sp_row;
+        END IF;
+    END IF;
+
+    -- Start over for max out
+    SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+    -- Fail if the user has too many checked out items
+    LOOP
+        tmp_grp := user_object.profile;
+        LOOP
+            SELECT * INTO max_items_out FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 3 AND org_unit = tmp_org.id;
+
+            IF max_items_out.threshold IS NULL THEN
+                SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+            ELSE
+                EXIT;
+            END IF;
+
+            IF tmp_grp IS NULL THEN
+                EXIT;
+            END IF;
+        END LOOP;
+
+        IF max_items_out.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+            EXIT;
+        END IF;
+
+        SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+    END LOOP;
+
+
+    -- Fail if the user has too many items checked out
+    IF max_items_out.threshold IS NOT NULL THEN
+
+        RETURN QUERY
+            SELECT  *
+              FROM  actor.usr_standing_penalty
+              WHERE usr = match_user
+                    AND org_unit = max_items_out.org_unit
+                    AND (stop_date IS NULL or stop_date > NOW())
+                    AND standing_penalty = 3;
+
+        SELECT  INTO items_out COUNT(*)
+          FROM  action.circulation circ
+                JOIN  actor.org_unit_full_path( max_items_out.org_unit ) fp ON (circ.circ_lib = fp.id)
+          WHERE circ.usr = match_user
+                AND circ.checkin_time IS NULL
+                AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL);
+
+           IF items_out >= max_items_out.threshold::INT THEN
+            new_sp_row.usr := match_user;
+            new_sp_row.org_unit := max_items_out.org_unit;
+            new_sp_row.standing_penalty := 3;
+            RETURN NEXT new_sp_row;
+           END IF;
+    END IF;
+
+    -- Start over for collections warning
+    SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+    -- Fail if the user has a collections-level fine balance
+    LOOP
+        tmp_grp := user_object.profile;
+        LOOP
+            SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 4 AND org_unit = tmp_org.id;
+
+            IF max_fines.threshold IS NULL THEN
+                SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+            ELSE
+                EXIT;
+            END IF;
+
+            IF tmp_grp IS NULL THEN
+                EXIT;
+            END IF;
+        END LOOP;
+
+        IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+            EXIT;
+        END IF;
+
+        SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+    END LOOP;
+
+    IF max_fines.threshold IS NOT NULL THEN
+
+        RETURN QUERY
+            SELECT  *
+              FROM  actor.usr_standing_penalty
+              WHERE usr = match_user
+                    AND org_unit = max_fines.org_unit
+                    AND (stop_date IS NULL or stop_date > NOW())
+                    AND standing_penalty = 4;
+
+        SELECT INTO context_org_list array_agg(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+        SELECT  SUM(f.balance_owed) INTO current_fines
+          FROM  money.materialized_billable_xact_summary f
+                JOIN (
+                    SELECT  r.id
+                      FROM  booking.reservation r
+                      WHERE r.usr = match_user
+                            AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND r.xact_finish IS NULL
+                                UNION ALL
+                    SELECT  g.id
+                      FROM  money.grocery g
+                      WHERE g.usr = match_user
+                            AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+                            AND g.xact_finish IS NULL
+                                UNION ALL
+                    SELECT  circ.id
+                      FROM  action.circulation circ
+                      WHERE circ.usr = match_user
+                            AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND circ.xact_finish IS NULL ) l USING (id);
+
+        IF current_fines >= max_fines.threshold THEN
+            new_sp_row.usr := match_user;
+            new_sp_row.org_unit := max_fines.org_unit;
+            new_sp_row.standing_penalty := 4;
+            RETURN NEXT new_sp_row;
+        END IF;
+    END IF;
+
+    -- Start over for in collections
+    SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+    -- Remove the in-collections penalty if the user has paid down enough
+    -- This penalty is different, because this code is not responsible for creating 
+    -- new in-collections penalties, only for removing them
+    LOOP
+        tmp_grp := user_object.profile;
+        LOOP
+            SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 30 AND org_unit = tmp_org.id;
+
+            IF max_fines.threshold IS NULL THEN
+                SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+            ELSE
+                EXIT;
+            END IF;
+
+            IF tmp_grp IS NULL THEN
+                EXIT;
+            END IF;
+        END LOOP;
+
+        IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+            EXIT;
+        END IF;
+
+        SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+    END LOOP;
+
+    IF max_fines.threshold IS NOT NULL THEN
+
+        SELECT INTO context_org_list array_agg(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+        -- first, see if the user had paid down to the threshold
+        SELECT  SUM(f.balance_owed) INTO current_fines
+          FROM  money.materialized_billable_xact_summary f
+                JOIN (
+                    SELECT  r.id
+                      FROM  booking.reservation r
+                      WHERE r.usr = match_user
+                            AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND r.xact_finish IS NULL
+                                UNION ALL
+                    SELECT  g.id
+                      FROM  money.grocery g
+                      WHERE g.usr = match_user
+                            AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+                            AND g.xact_finish IS NULL
+                                UNION ALL
+                    SELECT  circ.id
+                      FROM  action.circulation circ
+                      WHERE circ.usr = match_user
+                            AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+                            AND circ.xact_finish IS NULL ) l USING (id);
+
+        IF current_fines IS NULL OR current_fines <= max_fines.threshold THEN
+            -- patron has paid down enough
+
+            SELECT INTO tmp_penalty * FROM config.standing_penalty WHERE id = 30;
+
+            IF tmp_penalty.org_depth IS NOT NULL THEN
+
+                -- since this code is not responsible for applying the penalty, it can't 
+                -- guarantee the current context org will match the org at which the penalty 
+                --- was applied.  search up the org tree until we hit the configured penalty depth
+                SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+                SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+
+                WHILE tmp_depth >= tmp_penalty.org_depth LOOP
+
+                    RETURN QUERY
+                        SELECT  *
+                          FROM  actor.usr_standing_penalty
+                          WHERE usr = match_user
+                                AND org_unit = tmp_org.id
+                                AND (stop_date IS NULL or stop_date > NOW())
+                                AND standing_penalty = 30;
+
+                    IF tmp_org.parent_ou IS NULL THEN
+                        EXIT;
+                    END IF;
+
+                    SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+                    SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+                END LOOP;
+
+            ELSE
+
+                -- no penalty depth is defined, look for exact matches
+
+                RETURN QUERY
+                    SELECT  *
+                      FROM  actor.usr_standing_penalty
+                      WHERE usr = match_user
+                            AND org_unit = max_fines.org_unit
+                            AND (stop_date IS NULL or stop_date > NOW())
+                            AND standing_penalty = 30;
+            END IF;
+    
+        END IF;
+
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION action.hold_request_permit_test( pickup_ou INT, request_ou INT, match_item BIGINT, match_user INT, match_requestor INT, retargetting BOOL ) RETURNS SETOF action.matrix_test_result AS $func$
+DECLARE
+    matchpoint_id        INT;
+    user_object        actor.usr%ROWTYPE;
+    age_protect_object    config.rule_age_hold_protect%ROWTYPE;
+    standing_penalty    config.standing_penalty%ROWTYPE;
+    transit_range_ou_type    actor.org_unit_type%ROWTYPE;
+    transit_source        actor.org_unit%ROWTYPE;
+    item_object        asset.copy%ROWTYPE;
+    item_cn_object     asset.call_number%ROWTYPE;
+    ou_skip              actor.org_unit_setting%ROWTYPE;
+    result            action.matrix_test_result;
+    hold_test        config.hold_matrix_matchpoint%ROWTYPE;
+    hold_count        INT;
+    hold_transit_prox    INT;
+    frozen_hold_count    INT;
+    context_org_list    INT[];
+    done            BOOL := FALSE;
+BEGIN
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+    SELECT INTO context_org_list array_agg(id) FROM actor.org_unit_full_path( pickup_ou );
+
+    result.success := TRUE;
+
+    -- Fail if we couldn't find a user
+    IF user_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+    -- Fail if we couldn't find a copy
+    IF item_object.id IS NULL THEN
+        result.fail_part := 'no_item';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO matchpoint_id action.find_hold_matrix_matchpoint(pickup_ou, request_ou, match_item, match_user, match_requestor);
+    result.matchpoint := matchpoint_id;
+
+    SELECT INTO ou_skip * FROM actor.org_unit_setting WHERE name = 'circ.holds.target_skip_me' AND org_unit = item_object.circ_lib;
+
+    -- Fail if the circ_lib for the item has circ.holds.target_skip_me set to true
+    IF ou_skip.id IS NOT NULL AND ou_skip.value = 'true' THEN
+        result.fail_part := 'circ.holds.target_skip_me';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    -- Fail if user is barred
+    IF user_object.barred IS TRUE THEN
+        result.fail_part := 'actor.usr.barred';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    -- Fail if we couldn't find any matchpoint (requires a default)
+    IF matchpoint_id IS NULL THEN
+        result.fail_part := 'no_matchpoint';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO hold_test * FROM config.hold_matrix_matchpoint WHERE id = matchpoint_id;
+
+    IF hold_test.holdable IS FALSE THEN
+        result.fail_part := 'config.hold_matrix_test.holdable';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    IF hold_test.transit_range IS NOT NULL THEN
+        SELECT INTO transit_range_ou_type * FROM actor.org_unit_type WHERE id = hold_test.transit_range;
+        IF hold_test.distance_is_from_owner THEN
+            SELECT INTO transit_source ou.* FROM actor.org_unit ou JOIN asset.call_number cn ON (cn.owning_lib = ou.id) WHERE cn.id = item_object.call_number;
+        ELSE
+            SELECT INTO transit_source * FROM actor.org_unit WHERE id = item_object.circ_lib;
+        END IF;
+
+        PERFORM * FROM actor.org_unit_descendants( transit_source.id, transit_range_ou_type.depth ) WHERE id = pickup_ou;
+
+        IF NOT FOUND THEN
+            result.fail_part := 'transit_range';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+    FOR standing_penalty IN
+        SELECT  DISTINCT csp.*
+          FROM  actor.usr_standing_penalty usp
+                JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+          WHERE usr = match_user
+                AND usp.org_unit IN ( SELECT * FROM unnest(context_org_list) )
+                AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                AND csp.block_list LIKE '%HOLD%' LOOP
+
+        result.fail_part := standing_penalty.name;
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END LOOP;
+
+    IF hold_test.stop_blocked_user IS TRUE THEN
+        FOR standing_penalty IN
+            SELECT  DISTINCT csp.*
+              FROM  actor.usr_standing_penalty usp
+                    JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+              WHERE usr = match_user
+                    AND usp.org_unit IN ( SELECT * FROM unnest(context_org_list) )
+                    AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                    AND csp.block_list LIKE '%CIRC%' LOOP
+    
+            result.fail_part := standing_penalty.name;
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END LOOP;
+    END IF;
+
+    IF hold_test.max_holds IS NOT NULL AND NOT retargetting THEN
+        SELECT    INTO hold_count COUNT(*)
+          FROM    action.hold_request
+          WHERE    usr = match_user
+            AND fulfillment_time IS NULL
+            AND cancel_time IS NULL
+            AND CASE WHEN hold_test.include_frozen_holds THEN TRUE ELSE frozen IS FALSE END;
+
+        IF hold_count >= hold_test.max_holds THEN
+            result.fail_part := 'config.hold_matrix_test.max_holds';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    IF item_object.age_protect IS NOT NULL THEN
+        SELECT INTO age_protect_object * FROM config.rule_age_hold_protect WHERE id = item_object.age_protect;
+
+        IF item_object.create_date + age_protect_object.age > NOW() THEN
+            IF hold_test.distance_is_from_owner THEN
+                SELECT INTO item_cn_object * FROM asset.call_number WHERE id = item_object.call_number;
+                SELECT INTO hold_transit_prox prox FROM actor.org_unit_proximity WHERE from_org = item_cn_object.owning_lib AND to_org = pickup_ou;
+            ELSE
+                SELECT INTO hold_transit_prox prox FROM actor.org_unit_proximity WHERE from_org = item_object.circ_lib AND to_org = pickup_ou;
+            END IF;
+
+            IF hold_transit_prox > age_protect_object.prox THEN
+                result.fail_part := 'config.rule_age_hold_protect.prox';
+                result.success := FALSE;
+                done := TRUE;
+                RETURN NEXT result;
+            END IF;
+        END IF;
+    END IF;
+
+    IF NOT done THEN
+        RETURN NEXT result;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION asset.merge_record_assets( target_record BIGINT, source_record BIGINT ) RETURNS INT AS $func$
+DECLARE
+    moved_objects INT := 0;
+    source_cn     asset.call_number%ROWTYPE;
+    target_cn     asset.call_number%ROWTYPE;
+    metarec       metabib.metarecord%ROWTYPE;
+    hold          action.hold_request%ROWTYPE;
+    ser_rec       serial.record_entry%ROWTYPE;
+    uri_count     INT := 0;
+    counter       INT := 0;
+    uri_datafield TEXT;
+    uri_text      TEXT := '';
+BEGIN
+
+    -- move any 856 entries on records that have at least one MARC-mapped URI entry
+    SELECT  INTO uri_count COUNT(*)
+      FROM  asset.uri_call_number_map m
+            JOIN asset.call_number cn ON (m.call_number = cn.id)
+      WHERE cn.record = source_record;
+
+    IF uri_count > 0 THEN
+        
+        SELECT  COUNT(*) INTO counter
+          FROM  oils_xpath_table(
+                    'id',
+                    'marc',
+                    'biblio.record_entry',
+                    '//*[@tag="856"]',
+                    'id=' || source_record
+                ) as t(i int,c text);
+    
+        FOR i IN 1 .. counter LOOP
+            SELECT  '<datafield xmlns="http://www.loc.gov/MARC21/slim"' || 
+                       ' tag="856"' ||
+                       ' ind1="' || FIRST(ind1) || '"'  ||
+                       ' ind2="' || FIRST(ind2) || '">' ||
+                        array_to_string(
+                            array_agg(
+                                '<subfield code="' || subfield || '">' ||
+                                regexp_replace(
+                                    regexp_replace(
+                                        regexp_replace(data,'&','&amp;','g'),
+                                        '>', '&gt;', 'g'
+                                    ),
+                                    '<', '&lt;', 'g'
+                                ) || '</subfield>'
+                            ), ''
+                        ) || '</datafield>' INTO uri_datafield
+              FROM  oils_xpath_table(
+                        'id',
+                        'marc',
+                        'biblio.record_entry',
+                        '//*[@tag="856"][position()=' || i || ']/@ind1|' ||
+                        '//*[@tag="856"][position()=' || i || ']/@ind2|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*/@code|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*[@code]',
+                        'id=' || source_record
+                    ) as t(id int,ind1 text, ind2 text,subfield text,data text);
+
+            uri_text := uri_text || uri_datafield;
+        END LOOP;
+
+        IF uri_text <> '' THEN
+            UPDATE  biblio.record_entry
+              SET   marc = regexp_replace(marc,'(</[^>]*record>)', uri_text || E'\\1')
+              WHERE id = target_record;
+        END IF;
+
+    END IF;
+
+       -- Find and move metarecords to the target record
+       SELECT  INTO metarec *
+         FROM  metabib.metarecord
+         WHERE master_record = source_record;
+
+       IF FOUND THEN
+               UPDATE  metabib.metarecord
+                 SET   master_record = target_record,
+                       mods = NULL
+                 WHERE id = metarec.id;
+
+               moved_objects := moved_objects + 1;
+       END IF;
+
+       -- Find call numbers attached to the source ...
+       FOR source_cn IN SELECT * FROM asset.call_number WHERE record = source_record LOOP
+
+               SELECT  INTO target_cn *
+                 FROM  asset.call_number
+                 WHERE label = source_cn.label
+                       AND owning_lib = source_cn.owning_lib
+                       AND record = target_record;
+
+               -- ... and if there's a conflicting one on the target ...
+               IF FOUND THEN
+
+                       -- ... move the copies to that, and ...
+                       UPDATE  asset.copy
+                         SET   call_number = target_cn.id
+                         WHERE call_number = source_cn.id;
+
+                       -- ... move V holds to the move-target call number
+                       FOR hold IN SELECT * FROM action.hold_request WHERE target = source_cn.id AND hold_type = 'V' LOOP
+               
+                               UPDATE  action.hold_request
+                                 SET   target = target_cn.id
+                                 WHERE id = hold.id;
+               
+                               moved_objects := moved_objects + 1;
+                       END LOOP;
+
+               -- ... if not ...
+               ELSE
+                       -- ... just move the call number to the target record
+                       UPDATE  asset.call_number
+                         SET   record = target_record
+                         WHERE id = source_cn.id;
+               END IF;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find T holds targeting the source record ...
+       FOR hold IN SELECT * FROM action.hold_request WHERE target = source_record AND hold_type = 'T' LOOP
+
+               -- ... and move them to the target record
+               UPDATE  action.hold_request
+                 SET   target = target_record
+                 WHERE id = hold.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find serial records targeting the source record ...
+       FOR ser_rec IN SELECT * FROM serial.record_entry WHERE record = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  serial.record_entry
+                 SET   record = target_record
+                 WHERE id = ser_rec.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+    -- Finally, "delete" the source record
+    DELETE FROM biblio.record_entry WHERE id = source_record;
+
+       -- That's all, folks!
+       RETURN moved_objects;
+END;
+$func$ LANGUAGE plpgsql;
+
+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_agg( DISTINCT REPLACE(SUBSTRING(isbn.value FROM $$^\S+$$), '-', '') ) AS isbn,
+       array_agg( 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_agg( DISTINCT publisher.value), ', ') AS publisher,
+    ARRAY_TO_STRING(array_agg( DISTINCT SUBSTRING(pubdate.value FROM $$\d+$$) ), ', ') AS pubdate,
+    array_agg( DISTINCT REPLACE(SUBSTRING(isbn.value FROM $$^\S+$$), '-', '') ) AS isbn,
+    array_agg( 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;
+
+CREATE OR REPLACE FUNCTION search.query_parser_fts (
+
+    param_search_ou INT,
+    param_depth     INT,
+    param_query     TEXT,
+    param_statuses  INT[],
+    param_locations INT[],
+    param_offset    INT,
+    param_check     INT,
+    param_limit     INT,
+    metarecord      BOOL,
+    staff           BOOL
+) RETURNS SETOF search.search_result AS $func$
+DECLARE
+
+    current_res         search.search_result%ROWTYPE;
+    search_org_list     INT[];
+
+    check_limit         INT;
+    core_limit          INT;
+    core_offset         INT;
+    tmp_int             INT;
+
+    core_result         RECORD;
+    core_cursor         REFCURSOR;
+    core_rel_query      TEXT;
+
+    total_count         INT := 0;
+    check_count         INT := 0;
+    deleted_count       INT := 0;
+    visible_count       INT := 0;
+    excluded_count      INT := 0;
+
+BEGIN
+
+    check_limit := COALESCE( param_check, 1000 );
+    core_limit  := COALESCE( param_limit, 25000 );
+    core_offset := COALESCE( param_offset, 0 );
+
+    -- core_skip_chk := COALESCE( param_skip_chk, 1 );
+
+    IF param_search_ou > 0 THEN
+        IF param_depth IS NOT NULL THEN
+            SELECT array_agg(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou, param_depth );
+        ELSE
+            SELECT array_agg(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou );
+        END IF;
+    ELSIF param_search_ou < 0 THEN
+        SELECT array_agg(distinct org_unit) INTO search_org_list FROM actor.org_lasso_map WHERE lasso = -param_search_ou;
+    ELSIF param_search_ou = 0 THEN
+        -- reserved for user lassos (ou_buckets/type='lasso') with ID passed in depth ... hack? sure.
+    END IF;
+
+    OPEN core_cursor FOR EXECUTE param_query;
+
+    LOOP
+
+        FETCH core_cursor INTO core_result;
+        EXIT WHEN NOT FOUND;
+        EXIT WHEN total_count >= core_limit;
+
+        total_count := total_count + 1;
+
+        CONTINUE WHEN total_count NOT BETWEEN  core_offset + 1 AND check_limit + core_offset;
+
+        check_count := check_count + 1;
+
+        PERFORM 1 FROM biblio.record_entry b WHERE NOT b.deleted AND b.id IN ( SELECT * FROM unnest( core_result.records ) );
+        IF NOT FOUND THEN
+            -- RAISE NOTICE ' % were all deleted ... ', core_result.records;
+            deleted_count := deleted_count + 1;
+            CONTINUE;
+        END IF;
+
+        PERFORM 1
+          FROM  biblio.record_entry b
+                JOIN config.bib_source s ON (b.source = s.id)
+          WHERE s.transcendant
+                AND b.id IN ( SELECT * FROM unnest( core_result.records ) );
+
+        IF FOUND THEN
+            -- RAISE NOTICE ' % were all transcendant ... ', core_result.records;
+            visible_count := visible_count + 1;
+
+            current_res.id = core_result.id;
+            current_res.rel = core_result.rel;
+
+            tmp_int := 1;
+            IF metarecord THEN
+                SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+            END IF;
+
+            IF tmp_int = 1 THEN
+                current_res.record = core_result.records[1];
+            ELSE
+                current_res.record = NULL;
+            END IF;
+
+            RETURN NEXT current_res;
+
+            CONTINUE;
+        END IF;
+
+        PERFORM 1
+          FROM  asset.call_number cn
+                JOIN asset.uri_call_number_map map ON (map.call_number = cn.id)
+                JOIN asset.uri uri ON (map.uri = uri.id)
+          WHERE NOT cn.deleted
+                AND cn.label = '##URI##'
+                AND uri.active
+                AND ( param_locations IS NULL OR array_upper(param_locations, 1) IS NULL )
+                AND cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+                AND cn.owning_lib IN ( SELECT * FROM unnest( search_org_list ) )
+          LIMIT 1;
+
+        IF FOUND THEN
+            -- RAISE NOTICE ' % have at least one URI ... ', core_result.records;
+            visible_count := visible_count + 1;
+
+            current_res.id = core_result.id;
+            current_res.rel = core_result.rel;
+
+            tmp_int := 1;
+            IF metarecord THEN
+                SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+            END IF;
+
+            IF tmp_int = 1 THEN
+                current_res.record = core_result.records[1];
+            ELSE
+                current_res.record = NULL;
+            END IF;
+
+            RETURN NEXT current_res;
+
+            CONTINUE;
+        END IF;
+
+        IF param_statuses IS NOT NULL AND array_upper(param_statuses, 1) > 0 THEN
+
+            PERFORM 1
+              FROM  asset.call_number cn
+                    JOIN asset.copy cp ON (cp.call_number = cn.id)
+              WHERE NOT cn.deleted
+                    AND NOT cp.deleted
+                    AND cp.status IN ( SELECT * FROM unnest( param_statuses ) )
+                    AND cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+                    AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+              LIMIT 1;
+
+            IF NOT FOUND THEN
+                PERFORM 1
+                  FROM  biblio.peer_bib_copy_map pr
+                        JOIN asset.copy cp ON (cp.id = pr.target_copy)
+                  WHERE NOT cp.deleted
+                        AND cp.status IN ( SELECT * FROM unnest( param_statuses ) )
+                        AND pr.peer_record IN ( SELECT * FROM unnest( core_result.records ) )
+                        AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                  LIMIT 1;
+
+                IF NOT FOUND THEN
+                -- RAISE NOTICE ' % and multi-home linked records were all status-excluded ... ', core_result.records;
+                    excluded_count := excluded_count + 1;
+                    CONTINUE;
+                END IF;
+            END IF;
+
+        END IF;
+
+        IF param_locations IS NOT NULL AND array_upper(param_locations, 1) > 0 THEN
+
+            PERFORM 1
+              FROM  asset.call_number cn
+                    JOIN asset.copy cp ON (cp.call_number = cn.id)
+              WHERE NOT cn.deleted
+                    AND NOT cp.deleted
+                    AND cp.location IN ( SELECT * FROM unnest( param_locations ) )
+                    AND cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+                    AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+              LIMIT 1;
+
+            IF NOT FOUND THEN
+                PERFORM 1
+                  FROM  biblio.peer_bib_copy_map pr
+                        JOIN asset.copy cp ON (cp.id = pr.target_copy)
+                  WHERE NOT cp.deleted
+                        AND cp.location IN ( SELECT * FROM unnest( param_locations ) )
+                        AND pr.peer_record IN ( SELECT * FROM unnest( core_result.records ) )
+                        AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                  LIMIT 1;
+
+                IF NOT FOUND THEN
+                    -- RAISE NOTICE ' % and multi-home linked records were all copy_location-excluded ... ', core_result.records;
+                    excluded_count := excluded_count + 1;
+                    CONTINUE;
+                END IF;
+            END IF;
+
+        END IF;
+
+        IF staff IS NULL OR NOT staff THEN
+
+            PERFORM 1
+              FROM  asset.opac_visible_copies
+              WHERE circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                    AND record IN ( SELECT * FROM unnest( core_result.records ) )
+              LIMIT 1;
+
+            IF NOT FOUND THEN
+                PERFORM 1
+                  FROM  biblio.peer_bib_copy_map pr
+                        JOIN asset.opac_visible_copies cp ON (cp.copy_id = pr.target_copy)
+                  WHERE cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                        AND pr.peer_record IN ( SELECT * FROM unnest( core_result.records ) )
+                  LIMIT 1;
+
+                IF NOT FOUND THEN
+
+                    -- RAISE NOTICE ' % and multi-home linked records were all visibility-excluded ... ', core_result.records;
+                    excluded_count := excluded_count + 1;
+                    CONTINUE;
+                END IF;
+            END IF;
+
+        ELSE
+
+            PERFORM 1
+              FROM  asset.call_number cn
+                    JOIN asset.copy cp ON (cp.call_number = cn.id)
+              WHERE NOT cn.deleted
+                    AND NOT cp.deleted
+                    AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                    AND cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+              LIMIT 1;
+
+            IF NOT FOUND THEN
+
+                PERFORM 1
+                  FROM  biblio.peer_bib_copy_map pr
+                        JOIN asset.copy cp ON (cp.id = pr.target_copy)
+                  WHERE NOT cp.deleted
+                        AND cp.circ_lib IN ( SELECT * FROM unnest( search_org_list ) )
+                        AND pr.peer_record IN ( SELECT * FROM unnest( core_result.records ) )
+                  LIMIT 1;
+
+                IF NOT FOUND THEN
+
+                    PERFORM 1
+                      FROM  asset.call_number cn
+                      WHERE cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+                      LIMIT 1;
+
+                    IF FOUND THEN
+                        -- RAISE NOTICE ' % and multi-home linked records were all visibility-excluded ... ', core_result.records;
+                        excluded_count := excluded_count + 1;
+                        CONTINUE;
+                    END IF;
+                END IF;
+
+            END IF;
+
+        END IF;
+
+        visible_count := visible_count + 1;
+
+        current_res.id = core_result.id;
+        current_res.rel = core_result.rel;
+
+        tmp_int := 1;
+        IF metarecord THEN
+            SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+        END IF;
+
+        IF tmp_int = 1 THEN
+            current_res.record = core_result.records[1];
+        ELSE
+            current_res.record = NULL;
+        END IF;
+
+        RETURN NEXT current_res;
+
+        IF visible_count % 1000 = 0 THEN
+            -- RAISE NOTICE ' % visible so far ... ', visible_count;
+        END IF;
+
+    END LOOP;
+
+    current_res.id = NULL;
+    current_res.rel = NULL;
+    current_res.record = NULL;
+    current_res.total = total_count;
+    current_res.checked = check_count;
+    current_res.deleted = deleted_count;
+    current_res.visible = visible_count;
+    current_res.excluded = excluded_count;
+
+    CLOSE core_cursor;
+
+    RETURN NEXT current_res;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION evergreen.array_remove_item_by_value(inp ANYARRAY, el ANYELEMENT) RETURNS anyarray AS $$ SELECT array_agg(x.e) FROM UNNEST( $1 ) x(e) WHERE x.e <> $2; $$ LANGUAGE SQL;