--- /dev/null
+-- Deploy kcls-evergreen:browse-mattype-filter to pg
+-- requires: 2.9-to-2.10-upgrade
+
+BEGIN;
+
+CREATE OR REPLACE FUNCTION metabib.browse(
+ search_class text,
+ browse_term text,
+ context_org integer DEFAULT NULL::integer,
+ context_loc_group integer DEFAULT NULL::integer,
+ staff boolean DEFAULT false,
+ pivot_id bigint DEFAULT NULL::bigint,
+ result_limit integer DEFAULT 10,
+ item_type text DEFAULT NULL::text
+) RETURNS SETOF metabib.flat_browse_entry_appearance
+
+AS $FUNK$
+DECLARE
+ v_bound_lower TEXT;
+ v_bound_upper TEXT;
+ core_query TEXT;
+ back_query TEXT;
+ forward_query TEXT;
+ pivot_sort_value TEXT;
+ pivot_sort_fallback TEXT;
+ search_field INT[];
+ context_locations INT[];
+ browse_superpage_size INT;
+ results_skipped INT := 0;
+ back_limit INT;
+ back_to_pivot INT;
+ forward_limit INT;
+ forward_to_pivot INT;
+ mbedm_mattype_filter TEXT DEFAULT '';
+ mbeshm_mattype_filter TEXT DEFAULT '';
+BEGIN
+ --ver1.1 updated with kmain-806
+ -- Get search field int list with search_class
+ IF search_class = 'id|bibcn' THEN
+
+ SELECT INTO search_class 'call_number';
+
+ SELECT INTO search_field COALESCE(ARRAY_AGG(id), ARRAY[]::INT[])
+ FROM config.metabib_field WHERE field_class = 'identifier' AND name = 'bibcn';
+ IF pivot_id IS NULL THEN
+
+ pivot_id := metabib.browse_call_number_pivot(browse_term);
+
+ END IF;
+ ELSE
+
+ SELECT INTO search_field COALESCE(ARRAY_AGG(id), ARRAY[]::INT[])
+ FROM config.metabib_field WHERE field_class = search_class;
+
+ -- First, find the pivot if we were given a browse term but not a pivot.
+ IF pivot_id IS NULL THEN
+
+ CASE search_class
+ WHEN 'author' THEN pivot_id := metabib.browse_author_pivot(search_field, browse_term);
+ WHEN 'title' THEN pivot_id := metabib.browse_title_pivot(search_field, browse_term);
+ WHEN 'subject' THEN pivot_id := metabib.browse_subject_pivot(search_field, browse_term);
+ WHEN 'series' THEN pivot_id := metabib.browse_series_pivot(search_field, browse_term);
+
+ END CASE;
+ END IF;
+ END IF;
+
+ CASE search_class
+ WHEN 'author' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_author_entry WHERE id = pivot_id;
+ WHEN 'title' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_title_entry WHERE id = pivot_id;
+ WHEN 'subject' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_subject_entry WHERE id = pivot_id;
+ WHEN 'series' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_series_entry WHERE id = pivot_id;
+ WHEN 'call_number' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_call_number_entry WHERE id = pivot_id;
+
+ END CASE;
+
+ --<<
+
+ -- Bail if we couldn't find a pivot.
+ IF pivot_sort_value IS NULL THEN
+ RETURN;
+ END IF;
+
+ select bound_lower, bound_upper into v_bound_lower, v_bound_upper from metabib.browse_table_bounds(search_class,public.replace_ampersand(pivot_sort_value),result_limit);
+
+ -- Transform the context_loc_group argument (if any) (logc at the
+ -- TPAC layer) into a form we'll be able to use.
+ IF context_loc_group IS NOT NULL THEN
+ SELECT INTO context_locations ARRAY_AGG(location)
+ FROM asset.copy_location_group_map
+ WHERE lgroup = context_loc_group;
+ END IF;
+
+ -- Get the configured size of browse superpages.
+ SELECT INTO browse_superpage_size value -- NULL ok
+ FROM config.global_flag
+ WHERE enabled AND name = 'opac.browse.holdings_visibility_test_limit';
+
+ -- First we're going to search backward from the pivot, then we're going
+ -- to search forward. In each direction, we need two limits. At the
+ -- lesser of the two limits, we delineate the edge of the result set
+ -- we're going to return. At the greater of the two limits, we find the
+ -- pivot value that would represent an offset from the current pivot
+ -- at a distance of one "page" in either direction, where a "page" is a
+ -- result set of the size specified in the "result_limit" argument.
+ --
+ -- The two limits in each direction make four derived values in total,
+ -- and we calculate them now.
+ back_limit := CEIL(result_limit::FLOAT / 2);
+ back_to_pivot := result_limit;
+ forward_limit := result_limit / 2;
+ forward_to_pivot := result_limit - 1;
+
+ IF item_type IS NOT NULL THEN
+ mbedm_mattype_filter := $x$
+ AND mbedm.source IN (
+ SELECT id FROM metabib.record_attr
+ WHERE attrs-> 'mattype' = '$x$ || item_type || $x$'
+ )
+ $x$;
+
+ mbeshm_mattype_filter := $x$
+ AND mbeshm.entry IN (
+ SELECT id FROM metabib.record_attr
+ WHERE attrs-> 'mattype' = '$x$ || item_type || $x$'
+ )
+ $x$;
+
+ END IF;
+
+create temporary table tmp_metabib_browse
+(
+ id bigint,
+ value text,
+ sort_value text,
+ --truncated_sort_value_noamp text,
+ value_noamp text
+) on commit drop;
+
+ -- This is the meat of the SQL query that finds browse entries. We'll
+ -- pass this to a function which uses it with a cursor, so that individual
+ -- rows may be fetched in a loop until some condition is satisfied.
+ core_query := '
+insert into tmp_metabib_browse
+(
+ id,
+ value,
+ sort_value,
+ --truncated_sort_value_noamp,
+ value_noamp
+)
+SELECT mbe.id,
+ mbe.value,
+ public.replace_ampersand(mbe.sort_value),
+ --public.replace_ampersand(mbe.truncated_sort_value), --this column is identical to sort_value
+ public.replace_ampersand(mbe.value)
+ FROM metabib.browse_' || search_class || '_entry mbe
+ WHERE (
+ EXISTS ( -- are there any bibs using this mbe via the requested fields?
+ SELECT 1
+ FROM metabib.browse_' || search_class || '_entry_def_map mbedm
+ WHERE mbedm.entry = mbe.id AND mbedm.def = ANY(' || quote_literal(search_field) || ')
+ ' || mbedm_mattype_filter || '
+ LIMIT 1
+ )';
+ IF search_class != 'call_number' THEN
+
+ core_query := core_query || ' OR EXISTS ( -- are there any authorities using this mbe via the requested fields?
+ SELECT 1
+ FROM metabib.browse_' || search_class || '_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(' || quote_literal(search_field) || ')
+ )
+ WHERE mbeshm.entry = mbe.id ' || mbeshm_mattype_filter || '
+ )';
+
+ END IF;
+ core_query := core_query || $$
+) AND public.replace_ampersand(mbe.sort_value) between $$ || quote_literal(public.replace_ampersand(v_bound_lower)) || ' and ' || quote_literal(public.replace_ampersand(v_bound_upper));
+ execute core_query;
+ -- This is the variant of the query for browsing backward.
+ back_query := $$select id, value, sort_value from tmp_metabib_browse
+where sort_value <= $$ || quote_literal(public.replace_ampersand(pivot_sort_value)) || $$
+order by sort_value desc, value_noamp desc$$;
+
+ -- This variant browses forward.
+ forward_query := $$select id, value, sort_value from tmp_metabib_browse
+where sort_value > $$ || quote_literal(public.replace_ampersand(pivot_sort_value)) || $$
+order by sort_value, value_noamp$$;
+ -- We now call the function which applies a cursor to the provided
+ -- queries, stopping at the appropriate limits and also giving us
+ -- the next page's pivot.
+ RETURN QUERY
+ SELECT * FROM metabib.staged_browse(
+ back_query, search_field, context_org, context_locations,
+ staff, browse_superpage_size, TRUE, back_limit, back_to_pivot,
+ search_class, item_type
+ ) UNION ALL
+ SELECT * FROM metabib.staged_browse(
+ forward_query, search_field, context_org, context_locations,
+ staff, browse_superpage_size, FALSE, forward_limit, forward_to_pivot,
+ search_class, item_type
+ ) ORDER BY row_number DESC;
+
+END;
+$FUNK$ LANGUAGE plpgsql ROWS 10;
+
+CREATE OR REPLACE FUNCTION metabib.staged_browse(
+ query text,
+ fields integer[],
+ context_org integer,
+ context_locations integer[],
+ staff boolean,
+ browse_superpage_size integer,
+ count_up_from_zero boolean,
+ result_limit integer,
+ next_pivot_pos integer,
+ search_class text,
+ item_type text DEFAULT NULL::text
+) RETURNS SETOF metabib.flat_browse_entry_appearance
+AS $FUNK$
+DECLARE
+ curs REFCURSOR;
+ rec RECORD;
+ qpfts_query TEXT;
+ aqpfts_query TEXT;
+ afields INT[];
+ bfields INT[];
+ result_row metabib.flat_browse_entry_appearance%ROWTYPE;
+ results_skipped INT := 0;
+ row_counter INT := 0;
+ row_number INT;
+ slice_start INT;
+ slice_end INT;
+ full_end INT;
+ all_records BIGINT[];
+ all_brecords BIGINT[];
+ all_arecords BIGINT[];
+ superpage_of_records BIGINT[];
+ superpage_size INT;
+ unauthorized_entry RECORD;
+BEGIN
+ --ver1.1 updated with kmain-806 - added support for the new metabib.browse_____entry_simple_heading_map tables.
+ IF count_up_from_zero THEN
+ row_number := 0;
+ ELSE
+ row_number := -1;
+ END IF;
+
+ OPEN curs FOR EXECUTE query;
+
+ LOOP
+ FETCH curs INTO rec;
+ IF NOT FOUND THEN
+ IF result_row.pivot_point IS NOT NULL THEN
+ RETURN NEXT result_row;
+ END IF;
+ RETURN;
+ END IF;
+
+ CASE search_class
+ WHEN 'author' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_author_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_author_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_author_entry_def_map map
+ WHERE entry = rec.id
+ AND (item_type IS NULL OR (
+ source IN (
+ SELECT id FROM metabib.record_attr rattr
+ /* The seemingly superfluous rattr.id = map.source
+ helps to ensure we're not filtering on every
+ record with the selected mattype -- i.e.
+ it makes this optional sub-filter faster */
+ WHERE rattr.id = map.source AND attrs->'mattype' = item_type
+ )
+ ))
+ AND def = ANY(fields);
+
+ WHEN 'title' THEN
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_title_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_title_entry_def_map map
+ WHERE entry = rec.id
+ AND (item_type IS NULL OR (
+ source IN (
+ SELECT id FROM metabib.record_attr rattr
+ WHERE rattr.id = map.source AND attrs->'mattype' = item_type
+ )
+ ))
+ AND def = ANY(fields);
+
+ WHEN 'subject' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_subject_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_subject_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_subject_entry_def_map map
+ WHERE entry = rec.id
+ AND (item_type IS NULL OR (
+ source IN (
+ SELECT id FROM metabib.record_attr rattr
+ WHERE rattr.id = map.source AND attrs->'mattype' = item_type
+ )
+ ))
+ AND def = ANY(fields);
+
+ WHEN 'series' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_series_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_series_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_series_entry_def_map map
+ WHERE entry = rec.id
+ AND (item_type IS NULL OR (
+ source IN (
+ SELECT id FROM metabib.record_attr rattr
+ WHERE rattr.id = map.source AND attrs->'mattype' = item_type
+ )
+ ))
+ AND def = ANY(fields);
+
+ WHEN 'call_number' THEN
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_call_number_entry_def_map
+ WHERE entry = rec.id
+ AND (item_type IS NULL OR (
+ source IN (
+ SELECT id FROM metabib.record_attr rattr
+ WHERE rattr.id = map.source AND attrs->'mattype' = item_type
+ )
+ ))
+ AND def = ANY(fields);
+
+ ELSE
+
+ END CASE;
+
+
+
+ SELECT INTO result_row.fields ARRAY_TO_STRING(ARRAY_AGG(DISTINCT x), $$,$$) FROM UNNEST(afields || bfields) x;
+
+ result_row.sources := 0;
+ result_row.asources := 0;
+
+ -- Bib-linked vis checking
+ IF ARRAY_UPPER(all_brecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_brecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.sources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_brecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, until we've
+ -- either exhausted that set of records or found at least 1
+ -- visible record.
+
+ SELECT INTO result_row.sources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+ -- Accurate? Well, probably.
+ result_row.accurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ -- Authority-linked vis checking
+ IF ARRAY_UPPER(all_arecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_arecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.asources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_arecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, via
+ -- authority until we've either exhausted that set of records
+ -- or found at least 1 visible record.
+
+ SELECT INTO result_row.asources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+
+ -- Accurate? Well, probably.
+ result_row.aaccurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ IF result_row.sources > 0 OR result_row.asources > 0 THEN
+
+ -- The function that calls this function needs row_number in order
+ -- to correctly order results from two different runs of this
+ -- functions.
+ result_row.row_number := row_number;
+
+ -- Now, if row_counter is still less than limit, return a row. If
+ -- not, but it is less than next_pivot_pos, continue on without
+ -- returning actual result rows until we find
+ -- that next pivot, and return it.
+
+ IF row_counter < result_limit THEN
+ result_row.browse_entry := rec.id;
+ result_row.value := rec.value;
+
+ RETURN NEXT result_row;
+ ELSE
+ result_row.browse_entry := NULL;
+ result_row.authorities := NULL;
+ result_row.fields := NULL;
+ result_row.value := NULL;
+ result_row.sources := NULL;
+ result_row.sees := NULL;
+ result_row.accurate := NULL;
+ result_row.aaccurate := NULL;
+ result_row.pivot_point := rec.id;
+
+ IF row_counter >= next_pivot_pos THEN
+ RETURN NEXT result_row;
+ RETURN;
+ END IF;
+ END IF;
+
+ IF count_up_from_zero THEN
+ row_number := row_number + 1;
+ ELSE
+ row_number := row_number - 1;
+ END IF;
+
+ -- row_counter is different from row_number.
+ -- It simply counts up from zero so that we know when
+ -- we've reached our limit.
+ row_counter := row_counter + 1;
+ END IF;
+ END LOOP;
+END;
+$FUNK$ LANGUAGE plpgsql ROWS 10;
+
+COMMIT;
+
--- /dev/null
+-- Revert kcls-evergreen:browse-mattype-filter from pg
+
+BEGIN;
+
+CREATE OR REPLACE FUNCTION metabib.browse(
+ search_class text,
+ browse_term text,
+ context_org integer DEFAULT NULL::integer,
+ context_loc_group integer DEFAULT NULL::integer,
+ staff boolean DEFAULT false,
+ pivot_id bigint DEFAULT NULL::bigint,
+ result_limit integer DEFAULT 10
+) RETURNS SETOF metabib.flat_browse_entry_appearance
+
+AS $FUNK$
+DECLARE
+ v_bound_lower TEXT;
+ v_bound_upper TEXT;
+ core_query TEXT;
+ back_query TEXT;
+ forward_query TEXT;
+ pivot_sort_value TEXT;
+ pivot_sort_fallback TEXT;
+ search_field INT[];
+ context_locations INT[];
+ browse_superpage_size INT;
+ results_skipped INT := 0;
+ back_limit INT;
+ back_to_pivot INT;
+ forward_limit INT;
+ forward_to_pivot INT;
+BEGIN
+ --ver1.1 updated with kmain-806
+ -- Get search field int list with search_class
+ IF search_class = 'id|bibcn' THEN
+
+ SELECT INTO search_class 'call_number';
+
+ SELECT INTO search_field COALESCE(ARRAY_AGG(id), ARRAY[]::INT[])
+ FROM config.metabib_field WHERE field_class = 'identifier' AND name = 'bibcn';
+ IF pivot_id IS NULL THEN
+
+ pivot_id := metabib.browse_call_number_pivot(browse_term);
+
+ END IF;
+ ELSE
+
+ SELECT INTO search_field COALESCE(ARRAY_AGG(id), ARRAY[]::INT[])
+ FROM config.metabib_field WHERE field_class = search_class;
+
+ -- First, find the pivot if we were given a browse term but not a pivot.
+ IF pivot_id IS NULL THEN
+
+ CASE search_class
+ WHEN 'author' THEN pivot_id := metabib.browse_author_pivot(search_field, browse_term);
+ WHEN 'title' THEN pivot_id := metabib.browse_title_pivot(search_field, browse_term);
+ WHEN 'subject' THEN pivot_id := metabib.browse_subject_pivot(search_field, browse_term);
+ WHEN 'series' THEN pivot_id := metabib.browse_series_pivot(search_field, browse_term);
+
+ END CASE;
+ END IF;
+ END IF;
+
+ CASE search_class
+ WHEN 'author' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_author_entry WHERE id = pivot_id;
+ WHEN 'title' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_title_entry WHERE id = pivot_id;
+ WHEN 'subject' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_subject_entry WHERE id = pivot_id;
+ WHEN 'series' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_series_entry WHERE id = pivot_id;
+ WHEN 'call_number' THEN
+ SELECT INTO pivot_sort_value, pivot_sort_fallback
+ truncated_sort_value, value
+ FROM metabib.browse_call_number_entry WHERE id = pivot_id;
+
+ END CASE;
+
+ --<<
+
+ -- Bail if we couldn't find a pivot.
+ IF pivot_sort_value IS NULL THEN
+ RETURN;
+ END IF;
+
+ select bound_lower, bound_upper into v_bound_lower, v_bound_upper from metabib.browse_table_bounds(search_class,public.replace_ampersand(pivot_sort_value),result_limit);
+
+ -- Transform the context_loc_group argument (if any) (logc at the
+ -- TPAC layer) into a form we'll be able to use.
+ IF context_loc_group IS NOT NULL THEN
+ SELECT INTO context_locations ARRAY_AGG(location)
+ FROM asset.copy_location_group_map
+ WHERE lgroup = context_loc_group;
+ END IF;
+
+ -- Get the configured size of browse superpages.
+ SELECT INTO browse_superpage_size value -- NULL ok
+ FROM config.global_flag
+ WHERE enabled AND name = 'opac.browse.holdings_visibility_test_limit';
+
+ -- First we're going to search backward from the pivot, then we're going
+ -- to search forward. In each direction, we need two limits. At the
+ -- lesser of the two limits, we delineate the edge of the result set
+ -- we're going to return. At the greater of the two limits, we find the
+ -- pivot value that would represent an offset from the current pivot
+ -- at a distance of one "page" in either direction, where a "page" is a
+ -- result set of the size specified in the "result_limit" argument.
+ --
+ -- The two limits in each direction make four derived values in total,
+ -- and we calculate them now.
+ back_limit := CEIL(result_limit::FLOAT / 2);
+ back_to_pivot := result_limit;
+ forward_limit := result_limit / 2;
+ forward_to_pivot := result_limit - 1;
+
+create temporary table tmp_metabib_browse
+(
+ id bigint,
+ value text,
+ sort_value text,
+ --truncated_sort_value_noamp text,
+ value_noamp text
+) on commit drop;
+
+ -- This is the meat of the SQL query that finds browse entries. We'll
+ -- pass this to a function which uses it with a cursor, so that individual
+ -- rows may be fetched in a loop until some condition is satisfied.
+ core_query := '
+insert into tmp_metabib_browse
+(
+ id,
+ value,
+ sort_value,
+ --truncated_sort_value_noamp,
+ value_noamp
+)
+SELECT mbe.id,
+ mbe.value,
+ public.replace_ampersand(mbe.sort_value),
+ --public.replace_ampersand(mbe.truncated_sort_value), --this column is identical to sort_value
+ public.replace_ampersand(mbe.value)
+ FROM metabib.browse_' || search_class || '_entry mbe
+ WHERE (
+ EXISTS ( -- are there any bibs using this mbe via the requested fields?
+ SELECT 1
+ FROM metabib.browse_' || search_class || '_entry_def_map mbedm
+ WHERE mbedm.entry = mbe.id AND mbedm.def = ANY(' || quote_literal(search_field) || ')
+ LIMIT 1
+ )';
+ IF search_class != 'call_number' THEN
+
+ core_query := core_query || ' OR EXISTS ( -- are there any authorities using this mbe via the requested fields?
+ SELECT 1
+ FROM metabib.browse_' || search_class || '_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(' || quote_literal(search_field) || ')
+ )
+ WHERE mbeshm.entry = mbe.id
+ )';
+
+ END IF;
+ core_query := core_query || $$
+) AND public.replace_ampersand(mbe.sort_value) between $$ || quote_literal(public.replace_ampersand(v_bound_lower)) || ' and ' || quote_literal(public.replace_ampersand(v_bound_upper));
+ execute core_query;
+ -- This is the variant of the query for browsing backward.
+ back_query := $$select id, value, sort_value from tmp_metabib_browse
+where sort_value <= $$ || quote_literal(public.replace_ampersand(pivot_sort_value)) || $$
+order by sort_value desc, value_noamp desc$$;
+
+ -- This variant browses forward.
+ forward_query := $$select id, value, sort_value from tmp_metabib_browse
+where sort_value > $$ || quote_literal(public.replace_ampersand(pivot_sort_value)) || $$
+order by sort_value, value_noamp$$;
+ -- We now call the function which applies a cursor to the provided
+ -- queries, stopping at the appropriate limits and also giving us
+ -- the next page's pivot.
+ RETURN QUERY
+ SELECT * FROM metabib.staged_browse(
+ back_query, search_field, context_org, context_locations,
+ staff, browse_superpage_size, TRUE, back_limit, back_to_pivot,
+ search_class
+ ) UNION ALL
+ SELECT * FROM metabib.staged_browse(
+ forward_query, search_field, context_org, context_locations,
+ staff, browse_superpage_size, FALSE, forward_limit, forward_to_pivot,
+ search_class
+ ) ORDER BY row_number DESC;
+
+END;
+$FUNK$ LANGUAGE plpgsql ROWS 10;
+
+CREATE OR REPLACE FUNCTION metabib.staged_browse(
+ query text,
+ fields integer[],
+ context_org integer,
+ context_locations integer[],
+ staff boolean,
+ browse_superpage_size integer,
+ count_up_from_zero boolean,
+ result_limit integer,
+ next_pivot_pos integer,
+ search_class text
+) RETURNS SETOF metabib.flat_browse_entry_appearance
+AS $FUNK$
+DECLARE
+ curs REFCURSOR;
+ rec RECORD;
+ qpfts_query TEXT;
+ aqpfts_query TEXT;
+ afields INT[];
+ bfields INT[];
+ result_row metabib.flat_browse_entry_appearance%ROWTYPE;
+ results_skipped INT := 0;
+ row_counter INT := 0;
+ row_number INT;
+ slice_start INT;
+ slice_end INT;
+ full_end INT;
+ all_records BIGINT[];
+ all_brecords BIGINT[];
+ all_arecords BIGINT[];
+ superpage_of_records BIGINT[];
+ superpage_size INT;
+ unauthorized_entry RECORD;
+BEGIN
+ --ver1.1 updated with kmain-806 - added support for the new metabib.browse_____entry_simple_heading_map tables.
+ IF count_up_from_zero THEN
+ row_number := 0;
+ ELSE
+ row_number := -1;
+ END IF;
+
+ OPEN curs FOR EXECUTE query;
+
+ LOOP
+ FETCH curs INTO rec;
+ IF NOT FOUND THEN
+ IF result_row.pivot_point IS NOT NULL THEN
+ RETURN NEXT result_row;
+ END IF;
+ RETURN;
+ END IF;
+
+ CASE search_class
+ WHEN 'author' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_author_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_author_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_author_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ WHEN 'title' THEN
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_title_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_title_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ WHEN 'subject' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_subject_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_subject_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_subject_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ WHEN 'series' THEN
+ --Is unauthorized, i.e., 4xx on an auth record?
+ SELECT INTO unauthorized_entry *
+ FROM metabib.browse_series_entry_simple_heading_map mbeshm
+ INNER JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ INNER JOIN authority.control_set_authority_field acsaf ON ( acsaf.id = ash.atag AND acsaf.tag like '4__')
+ WHERE mbeshm.entry = rec.id;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ -- Gather aggregate data based on the MBE row we're looking at now, authority axis
+ IF (unauthorized_entry.record IS NOT NULL) THEN
+ --Do unauthorized procedure, use the authorized term's auth record and it's bibs
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib),
+ STRING_AGG(DISTINCT abl.authority::TEXT, $$,$$),
+ ARRAY_AGG(DISTINCT map.metabib_field)
+ FROM authority.bib_linking abl
+ INNER JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ map.authority_field = unauthorized_entry.atag
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE abl.authority = unauthorized_entry.record;
+ ELSE
+ SELECT INTO all_arecords, result_row.sees, afields
+ ARRAY_AGG(DISTINCT abl.bib), -- bibs to check for visibility
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- authority record ids
+ ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+ FROM metabib.browse_series_entry_simple_heading_map mbeshm
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.authority_linking aal ON ( ash.record = aal.source )
+ JOIN authority.bib_linking abl ON ( aal.target = abl.authority )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY(fields)
+ )
+ WHERE mbeshm.entry = rec.id;
+ END IF;
+
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_series_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ WHEN 'call_number' THEN
+ -- Gather aggregate data based on the MBE row we're looking at now, bib axis
+ SELECT INTO all_brecords, result_row.authorities, bfields
+ ARRAY_AGG(DISTINCT source),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_call_number_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ ELSE
+
+ END CASE;
+
+
+
+ SELECT INTO result_row.fields ARRAY_TO_STRING(ARRAY_AGG(DISTINCT x), $$,$$) FROM UNNEST(afields || bfields) x;
+
+ result_row.sources := 0;
+ result_row.asources := 0;
+
+ -- Bib-linked vis checking
+ IF ARRAY_UPPER(all_brecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_brecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.sources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_brecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, until we've
+ -- either exhausted that set of records or found at least 1
+ -- visible record.
+
+ SELECT INTO result_row.sources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+ -- Accurate? Well, probably.
+ result_row.accurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ -- Authority-linked vis checking
+ IF ARRAY_UPPER(all_arecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_arecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.asources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_arecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, via
+ -- authority until we've either exhausted that set of records
+ -- or found at least 1 visible record.
+
+ SELECT INTO result_row.asources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+
+ -- Accurate? Well, probably.
+ result_row.aaccurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ IF result_row.sources > 0 OR result_row.asources > 0 THEN
+
+ -- The function that calls this function needs row_number in order
+ -- to correctly order results from two different runs of this
+ -- functions.
+ result_row.row_number := row_number;
+
+ -- Now, if row_counter is still less than limit, return a row. If
+ -- not, but it is less than next_pivot_pos, continue on without
+ -- returning actual result rows until we find
+ -- that next pivot, and return it.
+
+ IF row_counter < result_limit THEN
+ result_row.browse_entry := rec.id;
+ result_row.value := rec.value;
+
+ RETURN NEXT result_row;
+ ELSE
+ result_row.browse_entry := NULL;
+ result_row.authorities := NULL;
+ result_row.fields := NULL;
+ result_row.value := NULL;
+ result_row.sources := NULL;
+ result_row.sees := NULL;
+ result_row.accurate := NULL;
+ result_row.aaccurate := NULL;
+ result_row.pivot_point := rec.id;
+
+ IF row_counter >= next_pivot_pos THEN
+ RETURN NEXT result_row;
+ RETURN;
+ END IF;
+ END IF;
+
+ IF count_up_from_zero THEN
+ row_number := row_number + 1;
+ ELSE
+ row_number := row_number - 1;
+ END IF;
+
+ -- row_counter is different from row_number.
+ -- It simply counts up from zero so that we know when
+ -- we've reached our limit.
+ row_counter := row_counter + 1;
+ END IF;
+ END LOOP;
+END;
+$FUNK$ LANGUAGE plpgsql ROWS 10;
+
+COMMIT;
+