Stamping upgrade for STRING_AGG fix for metabib.staged_browse()
authorBen Shum <bshum@biblio.org>
Thu, 13 Feb 2014 05:05:38 +0000 (00:05 -0500)
committerBen Shum <bshum@biblio.org>
Thu, 13 Feb 2014 05:07:41 +0000 (00:07 -0500)
Signed-off-by: Ben Shum <bshum@biblio.org>
Open-ILS/src/sql/Pg/002.schema.config.sql
Open-ILS/src/sql/Pg/upgrade/0856.schema.metabib_staged_browse.sql [new file with mode: 0644]
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.metabib_staged_browse.sql [deleted file]

index dceeb6e..fb3c0f8 100644 (file)
@@ -91,7 +91,7 @@ CREATE TRIGGER no_overlapping_deps
     BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
     FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
 
-INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0855', :eg_version); -- bshum/dbs
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0856', :eg_version); -- dbs/bshum
 
 CREATE TABLE config.bib_source (
        id              SERIAL  PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/upgrade/0856.schema.metabib_staged_browse.sql b/Open-ILS/src/sql/Pg/upgrade/0856.schema.metabib_staged_browse.sql
new file mode 100644 (file)
index 0000000..f597c93
--- /dev/null
@@ -0,0 +1,212 @@
+BEGIN;
+
+SELECT evergreen.upgrade_deps_block_check('0856', :eg_version);
+
+CREATE OR REPLACE FUNCTION metabib.staged_browse(
+    query                   TEXT,
+    fields                  INT[],
+    context_org             INT,
+    context_locations       INT[],
+    staff                   BOOL,
+    browse_superpage_size   INT,
+    count_up_from_zero      BOOL,   -- if false, count down from -1
+    result_limit            INT,
+    next_pivot_pos          INT
+) RETURNS SETOF metabib.flat_browse_entry_appearance AS $p$
+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;
+BEGIN
+    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;
+
+
+        -- 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
+                STRING_AGG(DISTINCT aal.source::TEXT, $$,$$), -- authority record ids
+                ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
+
+          FROM  metabib.browse_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),
+                STRING_AGG(DISTINCT authority::TEXT, $$,$$),
+                ARRAY_AGG(DISTINCT def)
+          FROM  metabib.browse_entry_def_map
+          WHERE entry = rec.id
+                AND def = ANY(fields);
+
+        SELECT INTO result_row.fields STRING_AGG(DISTINCT x::TEXT, $$,$$) 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;
+$p$ LANGUAGE PLPGSQL;
+
+COMMIT;
+
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.metabib_staged_browse.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.metabib_staged_browse.sql
deleted file mode 100644 (file)
index e255c46..0000000
+++ /dev/null
@@ -1,207 +0,0 @@
-CREATE OR REPLACE FUNCTION metabib.staged_browse(
-    query                   TEXT,
-    fields                  INT[],
-    context_org             INT,
-    context_locations       INT[],
-    staff                   BOOL,
-    browse_superpage_size   INT,
-    count_up_from_zero      BOOL,   -- if false, count down from -1
-    result_limit            INT,
-    next_pivot_pos          INT
-) RETURNS SETOF metabib.flat_browse_entry_appearance AS $p$
-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;
-BEGIN
-    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;
-
-
-        -- 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
-                STRING_AGG(DISTINCT aal.source::TEXT, $$,$$), -- authority record ids
-                ARRAY_AGG(DISTINCT map.metabib_field) -- authority-tag-linked CMF rows
-
-          FROM  metabib.browse_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),
-                STRING_AGG(DISTINCT authority::TEXT, $$,$$),
-                ARRAY_AGG(DISTINCT def)
-          FROM  metabib.browse_entry_def_map
-          WHERE entry = rec.id
-                AND def = ANY(fields);
-
-        SELECT INTO result_row.fields STRING_AGG(DISTINCT x::TEXT, $$,$$) 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;
-$p$ LANGUAGE PLPGSQL;
-
-