From: Lebbeous Fogle-Weekley Date: Wed, 1 May 2013 20:59:57 +0000 (-0400) Subject: Nearly done with the browse DB stuff X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=1aedaaa046007913602069db0e6a20530c766206;p=evergreen%2Fequinox.git Nearly done with the browse DB stuff Signed-off-by: Lebbeous Fogle-Weekley --- diff --git a/Open-ILS/src/sql/Pg/upgrade/YYYY.schema.bib-auth-browse.sql b/Open-ILS/src/sql/Pg/upgrade/YYYY.schema.bib-auth-browse.sql index d795e88481..a93d6ba905 100644 --- a/Open-ILS/src/sql/Pg/upgrade/YYYY.schema.bib-auth-browse.sql +++ b/Open-ILS/src/sql/Pg/upgrade/YYYY.schema.bib-auth-browse.sql @@ -6916,11 +6916,12 @@ CREATE INDEX CONCURRENTLY browse_entry_sort_value_idx -- ON metabib.browse_entry USING BTREE (sort_value DESC); CREATE TYPE metabib.flat_browse_entry_appearance AS ( - browse_entry BIGINT, - value TEXT, - fields TEXT, - authorities TEXT, - sources INT + browse_entry BIGINT, + value TEXT, + fields TEXT, + authorities TEXT, + sources INT, -- visible ones, that is + row_number INT -- internal use, sort of ); @@ -6940,23 +6941,84 @@ BEGIN END; $p$ LANGUAGE PLPGSQL; +CREATE OR REPLACE FUNCTION metabib.staged_browse( + core_query TEXT, + context_org INT, + context_locations INT[], + staff BOOL, + result_limit INT, + use_offset INT +) RETURNS SETOF metabib.flat_browse_entry_appearance AS $p$ +DECLARE + core_cursor REFCURSOR; + core_record RECORD; + qpfts_query TEXT; + result_row metabib.flat_browse_entry_appearance%ROWTYPE; + results_skipped INT := 0; + results_returned INT := 0; +BEGIN + OPEN core_cursor FOR EXECUTE core_query; + + LOOP + FETCH core_cursor INTO core_record; + EXIT WHEN NOT FOUND; + + qpfts_query := + 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, 1::INT AS rel ' || + 'FROM (SELECT UNNEST(' || + quote_literal(core_record.records) || '::BIGINT[]) AS r) rr'; + + -- We use search.query_parser_fts() for visibility testing. Yes there + -- is a reason we feed it the records for one mbe at a time instead of + -- the records for `result_limit` mbe's at a time. + 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; + + IF result_row.sources > 0 THEN + IF results_skipped < use_offset THEN + results_skipped := results_skipped + 1; + CONTINUE; + END IF; + + result_row.browse_entry := core_record.id; + result_row.authorities := core_record.authorities; + result_row.fields := core_record.fields; + result_row.value := core_record.value; + + -- This is needed so our caller can flip it and reverse it. + result_row.row_number := results_returned; + + RETURN NEXT result_row; + + results_returned := results_returned + 1; + + EXIT WHEN results_returned >= result_limit; + END IF; + END LOOP; +END; +$p$ LANGUAGE PLPGSQL; + +-- This is optimized to be fast for values of result_offset near zero. CREATE OR REPLACE FUNCTION metabib.browse( - search_field INT[], - browse_term TEXT, - context_org INT DEFAULT NULL, - context_loc_group INT DEFAULT NULL, - staff BOOL DEFAULT FALSE, - result_limit INT DEFAULT 10, - result_offset INT DEFAULT 0 -- Can be negative! + search_field INT[], + browse_term TEXT, + context_org INT DEFAULT NULL, + context_loc_group INT DEFAULT NULL, + staff BOOL DEFAULT FALSE, + result_limit INT DEFAULT 10, + result_offset INT DEFAULT 0 -- Can be negative! ) RETURNS SETOF metabib.flat_browse_entry_appearance AS $p$ DECLARE - inner_query TEXT; - whole_query TEXT; - loc_query_part TEXT; - pivot_sort_value TEXT; - f RECORD; - r metabib.flat_browse_entry_appearance%ROWTYPE; - use_offset INT; + core_query TEXT; + whole_query TEXT; + pivot_sort_value TEXT; + context_locations INT[]; + use_offset INT; + results_skipped INT := 0; BEGIN SELECT INTO pivot_sort_value * FROM metabib.browse_pivot(search_field, browse_term); @@ -6964,13 +7026,26 @@ BEGIN RETURN; END IF; - inner_query := ' + 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; + + core_query := ' SELECT - mbe.id AS id, + mbe.id, + mbe.value, + mbe.sort_value, (SELECT ARRAY_AGG(src) FROM ( SELECT DISTINCT UNNEST(ARRAY_AGG(mbedm.source)) AS src ) ss) AS records, - 1 AS rel + (SELECT ARRAY_TO_STRING(ARRAY_AGG(authority), $$,$$) FROM ( + SELECT DISTINCT UNNEST(ARRAY_AGG(mbedm.authority)) AS authority + ) au) AS authorities, + (SELECT ARRAY_TO_STRING(ARRAY_AGG(field), $$,$$) FROM ( + SELECT DISTINCT UNNEST(ARRAY_AGG(mbedm.def)) AS field + ) fi) AS fields FROM metabib.browse_entry mbe JOIN metabib.browse_entry_def_map mbedm ON ( mbedm.entry = mbe.id AND @@ -6981,14 +7056,20 @@ BEGIN -- PostgreSQL is not magic. We can't actually pass a negative offset. IF result_offset >= 0 THEN use_offset := result_offset; - inner_query := inner_query || + core_query := core_query || ' mbe.sort_value >= ' || quote_literal(pivot_sort_value) || - ' GROUP BY 1,3,mbe.sort_value ORDER BY mbe.sort_value '; + ' GROUP BY 1,2,3 ORDER BY mbe.sort_value '; + + RETURN QUERY SELECT * FROM metabib.staged_browse( + core_query, context_org, context_locations, + staff, result_limit, use_offset + ); ELSE - -- Step 1 of 2 to deliver what the user wants with a negative offset: - inner_query := inner_query || + -- Part 1 of 2 to deliver what the user wants with a negative offset: + + core_query := core_query || ' mbe.sort_value < ' || quote_literal(pivot_sort_value) || - ' GROUP BY 1,3,mbe.sort_value ORDER BY mbe.sort_value DESC '; + ' GROUP BY 1,2,3 ORDER BY mbe.sort_value DESC '; use_offset := ABS(result_offset) - result_limit; IF use_offset < 0 THEN @@ -7000,51 +7081,14 @@ BEGIN RAISE EXCEPTION 'Straddling the pivot point is not supported.'; END IF; - END IF; - --- XXX result_query := result_query || --- XXX ' LIMIT ' || result_limit || ' OFFSET ' || use_offset; --- XXX --- XXX IF result_offset < 0 THEN --- XXX -- Step 2 of 2 to deliver what the user wants with a negative offset: --- XXX result_query := 'SELECT * FROM (' || result_query || --- XXX ') x ORDER BY sort_value ASC'; -- Un-reverse the result set. --- XXX END IF; - - IF context_loc_group IS NULL THEN - loc_query_part := 'NULL, '; - ELSE - loc_query_part := - '(SELECT location FROM asset.copy_location_group_map WHERE - lgroup = ' || quote_literal(context_loc_group) || '), '; - END IF; - whole_query := 'SELECT * FROM search.query_parser_fts(' || - quote_literal(context_org) || - ', NULL, ' || - quote_literal(inner_query) || - ', NULL, ' || - loc_query_part || - use_offset || ',' || - result_limit || - ', 10000, - NULL, ' || - staff || - ', FALSE)'; - RAISE NOTICE 'query is { % }', whole_query; - - FOR f IN EXECUTE whole_query LOOP - IF f.id IS NULL THEN - CONTINUE; -- We don't need the summary row - END IF; - r.browse_entry := f.id; - r.value := NULL; -- XXX rest of these are TODO - r.fields := NULL; - r.authorities := NULL; - r.sources := NULL; + -- Part 2 of 2 to deliver what the user wants with a negative offset: + RETURN QUERY SELECT * FROM (SELECT * FROM metabib.staged_browse( + core_query, context_org, context_locations, + staff, result_limit, use_offset + )) sb ORDER BY row_number DESC; - RETURN NEXT r; - END LOOP; + END IF; END; $p$ LANGUAGE PLPGSQL;