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 ('0982', :eg_version); -- dyrcona/bshum
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0984', :eg_version); -- miker/gmcharlt/kmlussier
CREATE TABLE config.bib_source (
id SERIAL PRIMARY KEY,
--- /dev/null
+
+BEGIN;
+
+SELECT evergreen.upgrade_deps_block_check('0983', :eg_version);
+
+-- Create these so that the queries in the UDFs will validate
+CREATE TEMP TABLE precalc_filter_bib_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_bib_filter_bib_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_src_filter_bib_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_copy_filter_bib_list (
+ id BIGINT,
+ copy BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_circ_mod_filter_bib_list (
+ id BIGINT,
+ copy BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_location_filter_bib_list (
+ id BIGINT,
+ copy BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_attr_filter_bib_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_bibs_by_copy_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_bibs_by_uri_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_bibs_by_copy_or_uri_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+CREATE TEMP TABLE precalc_bib_list (
+ id BIGINT
+) ON COMMIT DROP;
+
+-- rhrr needs to be a real table, so it can be fast. To that end, we use
+-- a materialized view updated via a trigger.
+
+DROP VIEW reporter.hold_request_record;
+
+CREATE TABLE reporter.hold_request_record AS
+SELECT id,
+ target,
+ hold_type,
+ CASE
+ WHEN hold_type = 'T'
+ THEN target
+ WHEN hold_type = 'I'
+ THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = ahr.target)
+ WHEN hold_type = 'V'
+ THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = ahr.target)
+ WHEN hold_type IN ('C','R','F')
+ THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = ahr.target)
+ WHEN hold_type = 'M'
+ THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = ahr.target)
+ WHEN hold_type = 'P'
+ THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = ahr.target)
+ END AS bib_record
+ FROM action.hold_request ahr;
+
+CREATE UNIQUE INDEX reporter_hold_request_record_pkey_idx ON reporter.hold_request_record (id);
+CREATE INDEX reporter_hold_request_record_bib_record_idx ON reporter.hold_request_record (bib_record);
+
+ALTER TABLE reporter.hold_request_record ADD PRIMARY KEY USING INDEX reporter_hold_request_record_pkey_idx;
+
+CREATE FUNCTION reporter.hold_request_record_mapper () RETURNS TRIGGER AS $$
+BEGIN
+ IF TG_OP = 'INSERT' THEN
+ INSERT INTO reporter.hold_request_record (id, target, hold_type, bib_record)
+ SELECT NEW.id,
+ NEW.target,
+ NEW.hold_type,
+ CASE
+ WHEN NEW.hold_type = 'T'
+ THEN NEW.target
+ WHEN NEW.hold_type = 'I'
+ THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = NEW.target)
+ WHEN NEW.hold_type = 'V'
+ THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = NEW.target)
+ WHEN NEW.hold_type IN ('C','R','F')
+ THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = NEW.target)
+ WHEN NEW.hold_type = 'M'
+ THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = NEW.target)
+ WHEN NEW.hold_type = 'P'
+ THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = NEW.target)
+ END AS bib_record;
+ ELSIF TG_OP = 'UPDATE' AND (OLD.target <> NEW.target OR OLD.hold_type <> NEW.hold_type) THEN
+ UPDATE reporter.hold_request_record
+ SET target = NEW.target,
+ hold_type = NEW.hold_type,
+ bib_record = CASE
+ WHEN NEW.hold_type = 'T'
+ THEN NEW.target
+ WHEN NEW.hold_type = 'I'
+ THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = NEW.target)
+ WHEN NEW.hold_type = 'V'
+ THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = NEW.target)
+ WHEN NEW.hold_type IN ('C','R','F')
+ THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = NEW.target)
+ WHEN NEW.hold_type = 'M'
+ THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = NEW.target)
+ WHEN NEW.hold_type = 'P'
+ THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = NEW.target)
+ END;
+ END IF;
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER reporter_hold_request_record_trigger AFTER INSERT OR UPDATE ON action.hold_request
+ FOR EACH ROW EXECUTE PROCEDURE reporter.hold_request_record_mapper();
+
+CREATE SCHEMA rating;
+
+INSERT INTO config.global_flag (name, label, value, enabled) VALUES (
+ 'opac.default_sort',
+ 'OPAC Default Sort (titlesort, authorsort, pubdate, popularity, poprel, or empty for relevance)',
+ '',
+ TRUE
+);
+
+INSERT INTO config.global_flag (name, label, value, enabled) VALUES (
+ 'search.max_popularity_importance_multiplier',
+ oils_i18n_gettext(
+ 'search.max_popularity_importance_multiplier',
+ 'Maximum popularity importance multiplier for popularity-adjusted relevance searches (decimal value between 1.0 and 2.0)',
+ 'cgf',
+ 'label'
+ ),
+ '1.1',
+ TRUE
+);
+
+CREATE TABLE rating.popularity_parameter (
+ id INT PRIMARY KEY,
+ name TEXT NOT NULL UNIQUE, -- i18n
+ description TEXT,
+ func TEXT,
+ require_horizon BOOL NOT NULL DEFAULT FALSE,
+ require_importance BOOL NOT NULL DEFAULT FALSE,
+ require_percentile BOOL NOT NULL DEFAULT FALSE
+);
+
+INSERT INTO rating.popularity_parameter (id,name,func,require_horizon,require_importance,require_percentile) VALUES
+ (1,'Holds Filled Over Time','rating.holds_filled_over_time',TRUE,FALSE,TRUE),
+ (2,'Holds Requested Over Time','rating.holds_placed_over_time',TRUE,FALSE,TRUE),
+ (3,'Current Hold Count','rating.current_hold_count',FALSE,FALSE,TRUE),
+ (4,'Circulations Over Time','rating.circs_over_time',TRUE,FALSE,TRUE),
+ (5,'Current Circulation Count','rating.current_circ_count',FALSE,FALSE,TRUE),
+ (6,'Out/Total Ratio','rating.checked_out_total_ratio',FALSE,FALSE,TRUE),
+ (7,'Holds/Total Ratio','rating.holds_total_ratio',FALSE,FALSE,TRUE),
+ (8,'Holds/Holdable Ratio','rating.holds_holdable_ratio',FALSE,FALSE,TRUE),
+ (9,'Percent of Time Circulating','rating.percent_time_circulating',FALSE,FALSE,TRUE),
+ (10,'Bibliographic Record Age (days, newer is better)','rating.bib_record_age',FALSE,FALSE,TRUE),
+ (11,'Publication Age (days, newer is better)','rating.bib_pub_age',FALSE,FALSE,TRUE),
+ (12,'On-line Bib has attributes','rating.generic_fixed_rating_by_uri',FALSE,FALSE,FALSE),
+ (13,'Bib has attributes and copies','rating.generic_fixed_rating_by_copy',FALSE,FALSE,FALSE),
+ (14,'Bib has attributes and copies or URIs','rating.generic_fixed_rating_by_copy_or_uri',FALSE,FALSE,FALSE),
+ (15,'Bib has attributes','rating.generic_fixed_rating_global',FALSE,FALSE,FALSE);
+
+CREATE TABLE rating.badge (
+ id SERIAL PRIMARY KEY,
+ name TEXT NOT NULL,
+ description TEXT,
+ scope INT NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ weight INT NOT NULL DEFAULT 1,
+ horizon_age INTERVAL,
+ importance_age INTERVAL,
+ importance_interval INTERVAL NOT NULL DEFAULT '1 day',
+ importance_scale NUMERIC CHECK (importance_scale IS NULL OR importance_scale > 0.0),
+ recalc_interval INTERVAL NOT NULL DEFAULT '1 month',
+ attr_filter TEXT,
+ src_filter INT REFERENCES config.bib_source (id) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
+ circ_mod_filter TEXT REFERENCES config.circ_modifier (code) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
+ loc_grp_filter INT REFERENCES asset.copy_location_group (id) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
+ popularity_parameter INT NOT NULL REFERENCES rating.popularity_parameter (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ fixed_rating INT CHECK (fixed_rating IS NULL OR fixed_rating BETWEEN -5 AND 5),
+ percentile NUMERIC CHECK (percentile IS NULL OR (percentile >= 50.0 AND percentile < 100.0)),
+ discard INT NOT NULL DEFAULT 0,
+ last_calc TIMESTAMPTZ,
+ CONSTRAINT unique_name_scope UNIQUE (name,scope)
+);
+
+CREATE TABLE rating.record_badge_score (
+ id BIGSERIAL PRIMARY KEY,
+ record BIGINT NOT NULL REFERENCES biblio.record_entry (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ badge INT NOT NULL REFERENCES rating.badge (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ score INT NOT NULL CHECK (score BETWEEN -5 AND 5),
+ CONSTRAINT unique_record_badge UNIQUE (record,badge)
+);
+CREATE INDEX record_badge_score_badge_idx ON rating.record_badge_score (badge);
+CREATE INDEX record_badge_score_record_idx ON rating.record_badge_score (record);
+
+CREATE OR REPLACE VIEW rating.badge_with_orgs AS
+ WITH org_scope AS (
+ SELECT id,
+ array_agg(tree) AS orgs
+ FROM (SELECT id,
+ (actor.org_unit_descendants(id)).id AS tree
+ FROM actor.org_unit
+ ) x
+ GROUP BY 1
+ )
+ SELECT b.*,
+ s.orgs
+ FROM rating.badge b
+ JOIN org_scope s ON (b.scope = s.id);
+
+CREATE OR REPLACE FUNCTION rating.precalc_src_filter(src INT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+BEGIN
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_src_filter_bib_list;
+ IF src IS NOT NULL THEN
+ CREATE TEMP TABLE precalc_src_filter_bib_list ON COMMIT DROP AS
+ SELECT id FROM biblio.record_entry
+ WHERE source = src AND NOT deleted;
+ ELSE
+ CREATE TEMP TABLE precalc_src_filter_bib_list ON COMMIT DROP AS
+ SELECT id FROM biblio.record_entry
+ WHERE id > 0 AND NOT deleted;
+ END IF;
+
+ SELECT count(*) INTO cnt FROM precalc_src_filter_bib_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.precalc_circ_mod_filter(cm TEXT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+BEGIN
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_circ_mod_filter_bib_list;
+ IF cm IS NOT NULL THEN
+ CREATE TEMP TABLE precalc_circ_mod_filter_bib_list ON COMMIT DROP AS
+ SELECT cn.record AS id,
+ cp.id AS copy
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cn.id = cp.call_number)
+ WHERE cp.circ_modifier = cm
+ AND NOT cp.deleted;
+ ELSE
+ CREATE TEMP TABLE precalc_circ_mod_filter_bib_list ON COMMIT DROP AS
+ SELECT cn.record AS id,
+ cp.id AS copy
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cn.id = cp.call_number)
+ WHERE NOT cp.deleted;
+ END IF;
+
+ SELECT count(*) INTO cnt FROM precalc_circ_mod_filter_bib_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.precalc_location_filter(loc INT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+BEGIN
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_location_filter_bib_list;
+ IF loc IS NOT NULL THEN
+ CREATE TEMP TABLE precalc_location_filter_bib_list ON COMMIT DROP AS
+ SELECT cn.record AS id,
+ cp.id AS copy
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cn.id = cp.call_number)
+ JOIN asset.copy_location_group_map lg ON (cp.location = lg.location)
+ WHERE lg.lgroup = loc
+ AND NOT cp.deleted;
+ ELSE
+ CREATE TEMP TABLE precalc_location_filter_bib_list ON COMMIT DROP AS
+ SELECT cn.record AS id,
+ cp.id AS copy
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cn.id = cp.call_number)
+ WHERE NOT cp.deleted;
+ END IF;
+
+ SELECT count(*) INTO cnt FROM precalc_location_filter_bib_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+-- all or limited...
+CREATE OR REPLACE FUNCTION rating.precalc_attr_filter(attr_filter TEXT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+ afilter TEXT;
+BEGIN
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_attr_filter_bib_list;
+ IF attr_filter IS NOT NULL THEN
+ afilter := metabib.compile_composite_attr(attr_filter);
+ CREATE TEMP TABLE precalc_attr_filter_bib_list ON COMMIT DROP AS
+ SELECT source AS id FROM metabib.record_attr_vector_list
+ WHERE vlist @@ metabib.compile_composite_attr(attr_filter);
+ ELSE
+ CREATE TEMP TABLE precalc_attr_filter_bib_list ON COMMIT DROP AS
+ SELECT source AS id FROM metabib.record_attr_vector_list;
+ END IF;
+
+ SELECT count(*) INTO cnt FROM precalc_attr_filter_bib_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_copy(badge_id INT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+ badge_row rating.badge_with_orgs%ROWTYPE;
+ base TEXT;
+ whr TEXT;
+BEGIN
+
+ SELECT * INTO badge_row FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bibs_by_copy_list;
+ CREATE TEMP TABLE precalc_bibs_by_copy_list ON COMMIT DROP AS
+ SELECT DISTINCT cn.record AS id
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id AND NOT cp.deleted)
+ JOIN precalc_copy_filter_bib_list f ON (cp.id = f.copy)
+ WHERE cn.owning_lib = ANY (badge_row.orgs)
+ AND NOT cn.deleted;
+
+ SELECT count(*) INTO cnt FROM precalc_bibs_by_copy_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_uri(badge_id INT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+ badge_row rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge_row FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bibs_by_uri_list;
+ CREATE TEMP TABLE precalc_bibs_by_uri_list ON COMMIT DROP AS
+ SELECT DISTINCT record AS id
+ FROM asset.call_number cn
+ JOIN asset.uri_call_number_map urim ON (urim.call_number = cn.id)
+ JOIN asset.uri uri ON (urim.uri = uri.id AND uri.active)
+ WHERE cn.owning_lib = ANY (badge_row.orgs)
+ AND cn.label = '##URI##'
+ AND NOT cn.deleted;
+
+ SELECT count(*) INTO cnt FROM precalc_bibs_by_uri_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_copy_or_uri(badge_id INT)
+ RETURNS INT AS $f$
+DECLARE
+ cnt INT := 0;
+BEGIN
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+ PERFORM rating.precalc_bibs_by_uri(badge_id);
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bibs_by_copy_or_uri_list;
+ CREATE TEMP TABLE precalc_bibs_by_copy_or_uri_list ON COMMIT DROP AS
+ SELECT id FROM precalc_bibs_by_copy_list
+ UNION
+ SELECT id FROM precalc_bibs_by_uri_list;
+
+ SELECT count(*) INTO cnt FROM precalc_bibs_by_copy_or_uri_list;
+ RETURN cnt;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION rating.recalculate_badge_score ( badge_id INT, setup_only BOOL DEFAULT FALSE ) RETURNS VOID AS $f$
+DECLARE
+ badge_row rating.badge%ROWTYPE;
+ param rating.popularity_parameter%ROWTYPE;
+BEGIN
+ SET LOCAL client_min_messages = error;
+
+ -- Find what we're doing
+ SELECT * INTO badge_row FROM rating.badge WHERE id = badge_id;
+ SELECT * INTO param FROM rating.popularity_parameter WHERE id = badge_row.popularity_parameter;
+
+ -- Calculate the filtered bib set, or all bibs if none
+ PERFORM rating.precalc_attr_filter(badge_row.attr_filter);
+ PERFORM rating.precalc_src_filter(badge_row.src_filter);
+ PERFORM rating.precalc_circ_mod_filter(badge_row.circ_mod_filter);
+ PERFORM rating.precalc_location_filter(badge_row.loc_grp_filter);
+
+ -- Bring the bib-level filter lists together
+ DROP TABLE IF EXISTS precalc_bib_filter_bib_list;
+ CREATE TEMP TABLE precalc_bib_filter_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_attr_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_src_filter_bib_list;
+
+ -- Bring the copy-level filter lists together. We're keeping this for bib_by_copy filtering later.
+ DROP TABLE IF EXISTS precalc_copy_filter_bib_list;
+ CREATE TEMP TABLE precalc_copy_filter_bib_list ON COMMIT DROP AS
+ SELECT id, copy FROM precalc_circ_mod_filter_bib_list
+ INTERSECT
+ SELECT id, copy FROM precalc_location_filter_bib_list;
+
+ -- Bring the collapsed filter lists together
+ DROP TABLE IF EXISTS precalc_filter_bib_list;
+ CREATE TEMP TABLE precalc_filter_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_bib_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_copy_filter_bib_list;
+
+ CREATE INDEX precalc_filter_bib_list_idx
+ ON precalc_filter_bib_list (id);
+
+ IF setup_only THEN
+ RETURN;
+ END IF;
+
+ -- If it's a fixed-rating badge, just do it ...
+ IF badge_row.fixed_rating IS NOT NULL THEN
+ DELETE FROM rating.record_badge_score WHERE badge = badge_id;
+ EXECUTE $e$
+ INSERT INTO rating.record_badge_score (record, badge, score)
+ SELECT record, $1, $2 FROM $e$ || param.func || $e$($1)$e$
+ USING badge_id, badge_row.fixed_rating;
+
+ UPDATE rating.badge SET last_calc = NOW() WHERE id = badge_id;
+
+ RETURN;
+ END IF;
+ -- else, calculate!
+
+ -- Make a session-local scratchpad for calculating scores
+ CREATE TEMP TABLE record_score_scratchpad (
+ bib BIGINT,
+ value NUMERIC
+ ) ON COMMIT DROP;
+
+ -- Gather raw values
+ EXECUTE $e$
+ INSERT INTO record_score_scratchpad (bib, value)
+ SELECT * FROM $e$ || param.func || $e$($1)$e$
+ USING badge_id;
+
+ IF badge_row.discard > 0 OR badge_row.percentile IS NOT NULL THEN
+ -- To speed up discard-common
+ CREATE INDEX record_score_scratchpad_score_idx ON record_score_scratchpad (value);
+ ANALYZE record_score_scratchpad;
+ END IF;
+
+ IF badge_row.discard > 0 THEN -- Remove common low values (trim the long tail)
+ DELETE FROM record_score_scratchpad WHERE value IN (
+ SELECT DISTINCT value FROM record_score_scratchpad ORDER BY value LIMIT badge_row.discard
+ );
+ END IF;
+
+ IF badge_row.percentile IS NOT NULL THEN -- Cut population down to exceptional records
+ DELETE FROM record_score_scratchpad WHERE value <= (
+ SELECT value FROM (
+ SELECT value,
+ CUME_DIST() OVER (ORDER BY value) AS p
+ FROM record_score_scratchpad
+ ) x WHERE p < badge_row.percentile / 100.0 ORDER BY p DESC LIMIT 1
+ );
+ END IF;
+
+
+ -- And, finally, push new data in
+ DELETE FROM rating.record_badge_score WHERE badge = badge_id;
+ INSERT INTO rating.record_badge_score (badge, record, score)
+ SELECT badge_id,
+ bib,
+ GREATEST(ROUND((CUME_DIST() OVER (ORDER BY value)) * 5), 1) AS value
+ FROM record_score_scratchpad;
+
+ DROP TABLE record_score_scratchpad;
+
+ -- Now, finally-finally, mark the badge as recalculated
+ UPDATE rating.badge SET last_calc = NOW() WHERE id = badge_id;
+
+ RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION rating.holds_filled_over_time(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+ iage INT := 1;
+ iint INT := NULL;
+ iscale NUMERIC := NULL;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ IF badge.horizon_age IS NULL THEN
+ RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
+ badge.name,
+ badge.id;
+ END IF;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bib_list;
+ CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list;
+
+ iint := EXTRACT(EPOCH FROM badge.importance_interval);
+ IF badge.importance_age IS NOT NULL THEN
+ iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
+ END IF;
+
+ -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
+ iscale := COALESCE(badge.importance_scale, 1.0);
+
+ RETURN QUERY
+ SELECT bib,
+ SUM( holds * GREATEST( iscale * (iage - hage), 1.0 ))
+ FROM (
+ SELECT f.id AS bib,
+ (1 + EXTRACT(EPOCH FROM AGE(h.fulfillment_time)) / iint)::INT AS hage,
+ COUNT(h.id)::INT AS holds
+ FROM action.hold_request h
+ JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN precalc_bib_list f ON (f.id = rhrr.bib_record)
+ WHERE h.fulfillment_time >= NOW() - badge.horizon_age
+ AND h.request_lib = ANY (badge.orgs)
+ GROUP BY 1, 2
+ ) x
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.holds_placed_over_time(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+ iage INT := 1;
+ iint INT := NULL;
+ iscale NUMERIC := NULL;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ IF badge.horizon_age IS NULL THEN
+ RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
+ badge.name,
+ badge.id;
+ END IF;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bib_list;
+ CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list;
+
+ iint := EXTRACT(EPOCH FROM badge.importance_interval);
+ IF badge.importance_age IS NOT NULL THEN
+ iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
+ END IF;
+
+ -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
+ iscale := COALESCE(badge.importance_scale, 1.0);
+
+ RETURN QUERY
+ SELECT bib,
+ SUM( holds * GREATEST( iscale * (iage - hage), 1.0 ))
+ FROM (
+ SELECT f.id AS bib,
+ (1 + EXTRACT(EPOCH FROM AGE(h.request_time)) / iint)::INT AS hage,
+ COUNT(h.id)::INT AS holds
+ FROM action.hold_request h
+ JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN precalc_bib_list f ON (f.id = rhrr.bib_record)
+ WHERE h.request_time >= NOW() - badge.horizon_age
+ AND h.request_lib = ANY (badge.orgs)
+ GROUP BY 1, 2
+ ) x
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.current_hold_count(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT rhrr.bib_record AS bib,
+ COUNT(DISTINCT h.id)::NUMERIC AS holds
+ FROM action.hold_request h
+ JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN action.hold_copy_map m ON (m.hold = h.id)
+ JOIN precalc_copy_filter_bib_list cf ON (rhrr.bib_record = cf.id AND m.target_copy = cf.copy)
+ WHERE h.fulfillment_time IS NULL
+ AND h.request_lib = ANY (badge.orgs)
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.circs_over_time(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+ iage INT := 1;
+ iint INT := NULL;
+ iscale NUMERIC := NULL;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ IF badge.horizon_age IS NULL THEN
+ RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
+ badge.name,
+ badge.id;
+ END IF;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ iint := EXTRACT(EPOCH FROM badge.importance_interval);
+ IF badge.importance_age IS NOT NULL THEN
+ iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
+ END IF;
+
+ -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
+ iscale := COALESCE(badge.importance_scale, 1.0);
+
+ RETURN QUERY
+ SELECT bib,
+ SUM( circs * GREATEST( iscale * (iage - cage), 1.0 ))
+ FROM (
+ SELECT cn.record AS bib,
+ (1 + EXTRACT(EPOCH FROM AGE(c.xact_start)) / iint)::INT AS cage,
+ COUNT(c.id)::INT AS circs
+ FROM action.circulation c
+ JOIN precalc_copy_filter_bib_list cf ON (c.target_copy = cf.copy)
+ JOIN asset.copy cp ON (cp.id = c.target_copy)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ WHERE c.xact_start >= NOW() - badge.horizon_age
+ AND cn.owning_lib = ANY (badge.orgs)
+ AND c.phone_renewal IS FALSE -- we don't count renewals
+ AND c.desk_renewal IS FALSE
+ AND c.opac_renewal IS FALSE
+ GROUP BY 1, 2
+ ) x
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.current_circ_count(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT cn.record AS bib,
+ COUNT(c.id)::NUMERIC AS circs
+ FROM action.circulation c
+ JOIN precalc_copy_filter_bib_list cf ON (c.target_copy = cf.copy)
+ JOIN asset.copy cp ON (cp.id = c.target_copy)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ WHERE c.checkin_time IS NULL
+ AND cn.owning_lib = ANY (badge.orgs)
+ GROUP BY 1;
+
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.checked_out_total_ratio(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT bib,
+ SUM(checked_out)::NUMERIC / SUM(total)::NUMERIC
+ FROM (SELECT cn.record AS bib,
+ (cp.status = 1)::INT AS checked_out,
+ 1 AS total
+ FROM asset.copy cp
+ JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ WHERE cn.owning_lib = ANY (badge.orgs)
+ ) x
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.holds_total_ratio(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT cn.record AS bib,
+ COUNT(DISTINCT m.hold)::NUMERIC / COUNT(DISTINCT cp.id)::NUMERIC
+ FROM asset.copy cp
+ JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
+ WHERE cn.owning_lib = ANY (badge.orgs)
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.holds_holdable_ratio(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT cn.record AS bib,
+ COUNT(DISTINCT m.hold)::NUMERIC / COUNT(DISTINCT cp.id)::NUMERIC
+ FROM asset.copy cp
+ JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
+ JOIN asset.copy_location cl ON (cl.id = cp.location)
+ JOIN config.copy_status cs ON (cs.id = cp.status)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
+ WHERE cn.owning_lib = ANY (badge.orgs)
+ AND cp.holdable IS TRUE
+ AND cl.holdable IS TRUE
+ AND cs.holdable IS TRUE
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.bib_record_age(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bib_list;
+ CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_or_uri_list;
+
+ RETURN QUERY
+ SELECT b.id,
+ 1.0 / EXTRACT(EPOCH FROM AGE(b.create_date))::NUMERIC + 1.0
+ FROM precalc_bib_list pop
+ JOIN biblio.record_entry b ON (b.id = pop.id);
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.bib_pub_age(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
+
+ SET LOCAL client_min_messages = error;
+ DROP TABLE IF EXISTS precalc_bib_list;
+ CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_or_uri_list;
+
+ RETURN QUERY
+ SELECT pop.id AS bib,
+ s.value::NUMERIC
+ FROM precalc_bib_list pop
+ JOIN metabib.record_sorter s ON (
+ s.source = pop.id
+ AND s.attr = 'pubdate'
+ AND s.value ~ '^\d+$'
+ )
+ WHERE s.value::INT <= EXTRACT(YEAR FROM NOW())::INT;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.percent_time_circulating(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+DECLARE
+ badge rating.badge_with_orgs%ROWTYPE;
+BEGIN
+
+ SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
+
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+
+ DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
+ SELECT id FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id FROM precalc_bibs_by_copy_list
+ );
+
+ ANALYZE precalc_copy_filter_bib_list;
+
+ RETURN QUERY
+ SELECT bib,
+ SUM(COALESCE(circ_time,0))::NUMERIC / SUM(age)::NUMERIC
+ FROM (SELECT cn.record AS bib,
+ cp.id,
+ EXTRACT( EPOCH FROM AGE(cp.active_date) ) + 1 AS age,
+ SUM( -- time copy spent circulating
+ EXTRACT(
+ EPOCH FROM
+ AGE(
+ COALESCE(circ.checkin_time, circ.stop_fines_time, NOW()),
+ circ.xact_start
+ )
+ )
+ )::NUMERIC AS circ_time
+ FROM asset.copy cp
+ JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
+ JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ LEFT JOIN action.all_circulation circ ON (
+ circ.target_copy = cp.id
+ AND stop_fines NOT IN (
+ 'LOST',
+ 'LONGOVERDUE',
+ 'CLAIMSRETURNED',
+ 'LONGOVERDUE'
+ )
+ AND NOT (
+ checkin_time IS NULL AND
+ stop_fines = 'MAXFINES'
+ )
+ )
+ WHERE cn.owning_lib = ANY (badge.orgs)
+ AND cp.active_date IS NOT NULL
+ -- Next line requires that copies with no circs (circ.id IS NULL) also not be deleted
+ AND ((circ.id IS NULL AND NOT cp.deleted) OR circ.id IS NOT NULL)
+ GROUP BY 1,2,3
+ ) x
+ GROUP BY 1;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_copy(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+BEGIN
+ PERFORM rating.precalc_bibs_by_copy(badge_id);
+ RETURN QUERY
+ SELECT id, 1.0 FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id, 1.0 FROM precalc_bibs_by_copy_list;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_uri(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+BEGIN
+ PERFORM rating.precalc_bibs_by_uri(badge_id);
+ RETURN QUERY
+ SELECT id, 1.0 FROM precalc_bib_filter_bib_list
+ INTERSECT
+ SELECT id, 1.0 FROM precalc_bibs_by_uri_list;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_copy_or_uri(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+BEGIN
+ PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
+ RETURN QUERY
+ (SELECT id, 1.0 FROM precalc_filter_bib_list
+ INTERSECT
+ SELECT id, 1.0 FROM precalc_bibs_by_copy_list)
+ UNION
+ (SELECT id, 1.0 FROM precalc_bib_filter_bib_list
+ INTERSECT
+ SELECT id, 1.0 FROM precalc_bibs_by_uri_list);
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_global(badge_id INT)
+ RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
+BEGIN
+ RETURN QUERY
+ SELECT id, 1.0 FROM precalc_bib_filter_bib_list;
+END;
+$f$ LANGUAGE PLPGSQL STRICT;
+
+CREATE INDEX hold_fulfillment_time_idx ON action.hold_request (fulfillment_time) WHERE fulfillment_time IS NOT NULL;
+CREATE INDEX hold_request_time_idx ON action.hold_request (request_time);
+
+COMMIT;
+
--- /dev/null
+/*
+ * Copyright (C) 2016 Equinox Software, Inc.
+ * Mike Rylander <miker@esilibrary.com>
+ *
+ * This program is free software; you can redistribute it and/or
+ * modify it under the terms of the GNU General Public License
+ * as published by the Free Software Foundation; either version 2
+ * of the License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
+ * GNU General Public License for more details.
+ *
+ */
+
+
+BEGIN;
+
+SELECT evergreen.upgrade_deps_block_check('0984', :eg_version);
+
+ALTER TYPE search.search_result ADD ATTRIBUTE badges TEXT, ADD ATTRIBUTE popularity NUMERIC;
+
+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,
+ deleted_search BOOL,
+ param_pref_ou INT DEFAULT NULL
+) RETURNS SETOF search.search_result AS $func$
+DECLARE
+
+ current_res search.search_result%ROWTYPE;
+ search_org_list INT[];
+ luri_org_list INT[];
+ tmp_int_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;
+
+ luri_as_copy BOOL;
+BEGIN
+
+ check_limit := COALESCE( param_check, 1000 );
+ core_limit := COALESCE( param_limit, 25000 );
+ core_offset := COALESCE( param_offset, 0 );
+
+ SELECT COALESCE( enabled, FALSE ) INTO luri_as_copy FROM config.global_flag WHERE name = 'opac.located_uri.act_as_copy';
+
+ -- 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;
+
+ IF luri_as_copy THEN
+ SELECT ARRAY_AGG(distinct id) INTO luri_org_list FROM actor.org_unit_full_path( param_search_ou );
+ ELSE
+ SELECT ARRAY_AGG(distinct id) INTO luri_org_list FROM actor.org_unit_ancestors( 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;
+
+ FOR tmp_int IN SELECT * FROM UNNEST(search_org_list) LOOP
+
+ IF luri_as_copy THEN
+ SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_full_path( tmp_int );
+ ELSE
+ SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors( tmp_int );
+ END IF;
+
+ luri_org_list := luri_org_list || tmp_int_list;
+ END LOOP;
+
+ SELECT ARRAY_AGG(DISTINCT x.id) INTO luri_org_list FROM UNNEST(luri_org_list) x(id);
+
+ ELSIF param_search_ou = 0 THEN
+ -- reserved for user lassos (ou_buckets/type='lasso') with ID passed in depth ... hack? sure.
+ END IF;
+
+ IF param_pref_ou IS NOT NULL THEN
+ IF luri_as_copy THEN
+ SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_full_path( param_pref_ou );
+ ELSE
+ SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors( param_pref_ou );
+ END IF;
+
+ luri_org_list := luri_org_list || tmp_int_list;
+ 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;
+
+ IF NOT deleted_search THEN
+
+ 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;
+ current_res.badges = core_result.badges;
+ current_res.popularity = core_result.popularity;
+
+ 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( luri_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;
+ current_res.badges = core_result.badges;
+ current_res.popularity = core_result.popularity;
+
+ 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
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ WHERE cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+ AND NOT cp.deleted
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- Recheck Located URI visibility in the case of no "foreign" copies
+ 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 cn.record IN ( SELECT * FROM unnest( core_result.records ) )
+ AND cn.owning_lib NOT IN ( SELECT * FROM unnest( luri_org_list ) )
+ LIMIT 1;
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % were excluded for foreign located URIs... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+ ELSE
+ -- 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;
+
+ END IF;
+
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+ current_res.badges = core_result.badges;
+ current_res.popularity = core_result.popularity;
+
+ 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.badges = NULL;
+ current_res.popularity = 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 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, ' ||
+ 'NULL AS badges, NULL::NUMERIC AS popularity, ' ||
+ '1::NUMERIC 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, ' ||
+ 'NULL AS badges, NULL::NUMERIC AS popularity, ' ||
+ '1::NUMERIC 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;
+
+++ /dev/null
-
-BEGIN;
-
--- Create these so that the queries in the UDFs will validate
-CREATE TEMP TABLE precalc_filter_bib_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_bib_filter_bib_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_src_filter_bib_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_copy_filter_bib_list (
- id BIGINT,
- copy BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_circ_mod_filter_bib_list (
- id BIGINT,
- copy BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_location_filter_bib_list (
- id BIGINT,
- copy BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_attr_filter_bib_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_bibs_by_copy_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_bibs_by_uri_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_bibs_by_copy_or_uri_list (
- id BIGINT
-) ON COMMIT DROP;
-
-CREATE TEMP TABLE precalc_bib_list (
- id BIGINT
-) ON COMMIT DROP;
-
--- rhrr needs to be a real table, so it can be fast. To that end, we use
--- a materialized view updated via a trigger.
-
-DROP VIEW reporter.hold_request_record;
-
-CREATE TABLE reporter.hold_request_record AS
-SELECT id,
- target,
- hold_type,
- CASE
- WHEN hold_type = 'T'
- THEN target
- WHEN hold_type = 'I'
- THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = ahr.target)
- WHEN hold_type = 'V'
- THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = ahr.target)
- WHEN hold_type IN ('C','R','F')
- THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = ahr.target)
- WHEN hold_type = 'M'
- THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = ahr.target)
- WHEN hold_type = 'P'
- THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = ahr.target)
- END AS bib_record
- FROM action.hold_request ahr;
-
-CREATE UNIQUE INDEX reporter_hold_request_record_pkey_idx ON reporter.hold_request_record (id);
-CREATE INDEX reporter_hold_request_record_bib_record_idx ON reporter.hold_request_record (bib_record);
-
-ALTER TABLE reporter.hold_request_record ADD PRIMARY KEY USING INDEX reporter_hold_request_record_pkey_idx;
-
-CREATE FUNCTION reporter.hold_request_record_mapper () RETURNS TRIGGER AS $$
-BEGIN
- IF TG_OP = 'INSERT' THEN
- INSERT INTO reporter.hold_request_record (id, target, hold_type, bib_record)
- SELECT NEW.id,
- NEW.target,
- NEW.hold_type,
- CASE
- WHEN NEW.hold_type = 'T'
- THEN NEW.target
- WHEN NEW.hold_type = 'I'
- THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = NEW.target)
- WHEN NEW.hold_type = 'V'
- THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = NEW.target)
- WHEN NEW.hold_type IN ('C','R','F')
- THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = NEW.target)
- WHEN NEW.hold_type = 'M'
- THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = NEW.target)
- WHEN NEW.hold_type = 'P'
- THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = NEW.target)
- END AS bib_record;
- ELSIF TG_OP = 'UPDATE' AND (OLD.target <> NEW.target OR OLD.hold_type <> NEW.hold_type) THEN
- UPDATE reporter.hold_request_record
- SET target = NEW.target,
- hold_type = NEW.hold_type,
- bib_record = CASE
- WHEN NEW.hold_type = 'T'
- THEN NEW.target
- WHEN NEW.hold_type = 'I'
- THEN (SELECT ssub.record_entry FROM serial.subscription ssub JOIN serial.issuance si ON (si.subscription = ssub.id) WHERE si.id = NEW.target)
- WHEN NEW.hold_type = 'V'
- THEN (SELECT cn.record FROM asset.call_number cn WHERE cn.id = NEW.target)
- WHEN NEW.hold_type IN ('C','R','F')
- THEN (SELECT cn.record FROM asset.call_number cn JOIN asset.copy cp ON (cn.id = cp.call_number) WHERE cp.id = NEW.target)
- WHEN NEW.hold_type = 'M'
- THEN (SELECT mr.master_record FROM metabib.metarecord mr WHERE mr.id = NEW.target)
- WHEN NEW.hold_type = 'P'
- THEN (SELECT bmp.record FROM biblio.monograph_part bmp WHERE bmp.id = NEW.target)
- END;
- END IF;
- RETURN NEW;
-END;
-$$ LANGUAGE PLPGSQL;
-
-CREATE TRIGGER reporter_hold_request_record_trigger AFTER INSERT OR UPDATE ON action.hold_request
- FOR EACH ROW EXECUTE PROCEDURE reporter.hold_request_record_mapper();
-
-CREATE SCHEMA rating;
-
-INSERT INTO config.global_flag (name, label, value, enabled) VALUES (
- 'opac.default_sort',
- 'OPAC Default Sort (titlesort, authorsort, pubdate, popularity, poprel, or empty for relevance)',
- '',
- TRUE
-);
-
-INSERT INTO config.global_flag (name, label, value, enabled) VALUES (
- 'search.max_popularity_importance_multiplier',
- oils_i18n_gettext(
- 'search.max_popularity_importance_multiplier',
- 'Maximum popularity importance multiplier for popularity-adjusted relevance searches (decimal value between 1.0 and 2.0)',
- 'cgf',
- 'label'
- ),
- '1.1',
- TRUE
-);
-
-CREATE TABLE rating.popularity_parameter (
- id INT PRIMARY KEY,
- name TEXT NOT NULL UNIQUE, -- i18n
- description TEXT,
- func TEXT,
- require_horizon BOOL NOT NULL DEFAULT FALSE,
- require_importance BOOL NOT NULL DEFAULT FALSE,
- require_percentile BOOL NOT NULL DEFAULT FALSE
-);
-
-INSERT INTO rating.popularity_parameter (id,name,func,require_horizon,require_importance,require_percentile) VALUES
- (1,'Holds Filled Over Time','rating.holds_filled_over_time',TRUE,FALSE,TRUE),
- (2,'Holds Requested Over Time','rating.holds_placed_over_time',TRUE,FALSE,TRUE),
- (3,'Current Hold Count','rating.current_hold_count',FALSE,FALSE,TRUE),
- (4,'Circulations Over Time','rating.circs_over_time',TRUE,FALSE,TRUE),
- (5,'Current Circulation Count','rating.current_circ_count',FALSE,FALSE,TRUE),
- (6,'Out/Total Ratio','rating.checked_out_total_ratio',FALSE,FALSE,TRUE),
- (7,'Holds/Total Ratio','rating.holds_total_ratio',FALSE,FALSE,TRUE),
- (8,'Holds/Holdable Ratio','rating.holds_holdable_ratio',FALSE,FALSE,TRUE),
- (9,'Percent of Time Circulating','rating.percent_time_circulating',FALSE,FALSE,TRUE),
- (10,'Bibliographic Record Age (days, newer is better)','rating.bib_record_age',FALSE,FALSE,TRUE),
- (11,'Publication Age (days, newer is better)','rating.bib_pub_age',FALSE,FALSE,TRUE),
- (12,'On-line Bib has attributes','rating.generic_fixed_rating_by_uri',FALSE,FALSE,FALSE),
- (13,'Bib has attributes and copies','rating.generic_fixed_rating_by_copy',FALSE,FALSE,FALSE),
- (14,'Bib has attributes and copies or URIs','rating.generic_fixed_rating_by_copy_or_uri',FALSE,FALSE,FALSE),
- (15,'Bib has attributes','rating.generic_fixed_rating_global',FALSE,FALSE,FALSE);
-
-CREATE TABLE rating.badge (
- id SERIAL PRIMARY KEY,
- name TEXT NOT NULL,
- description TEXT,
- scope INT NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
- weight INT NOT NULL DEFAULT 1,
- horizon_age INTERVAL,
- importance_age INTERVAL,
- importance_interval INTERVAL NOT NULL DEFAULT '1 day',
- importance_scale NUMERIC CHECK (importance_scale IS NULL OR importance_scale > 0.0),
- recalc_interval INTERVAL NOT NULL DEFAULT '1 month',
- attr_filter TEXT,
- src_filter INT REFERENCES config.bib_source (id) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
- circ_mod_filter TEXT REFERENCES config.circ_modifier (code) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
- loc_grp_filter INT REFERENCES asset.copy_location_group (id) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
- popularity_parameter INT NOT NULL REFERENCES rating.popularity_parameter (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
- fixed_rating INT CHECK (fixed_rating IS NULL OR fixed_rating BETWEEN -5 AND 5),
- percentile NUMERIC CHECK (percentile IS NULL OR (percentile >= 50.0 AND percentile < 100.0)),
- discard INT NOT NULL DEFAULT 0,
- last_calc TIMESTAMPTZ,
- CONSTRAINT unique_name_scope UNIQUE (name,scope)
-);
-
-CREATE TABLE rating.record_badge_score (
- id BIGSERIAL PRIMARY KEY,
- record BIGINT NOT NULL REFERENCES biblio.record_entry (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
- badge INT NOT NULL REFERENCES rating.badge (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
- score INT NOT NULL CHECK (score BETWEEN -5 AND 5),
- CONSTRAINT unique_record_badge UNIQUE (record,badge)
-);
-CREATE INDEX record_badge_score_badge_idx ON rating.record_badge_score (badge);
-CREATE INDEX record_badge_score_record_idx ON rating.record_badge_score (record);
-
-CREATE OR REPLACE VIEW rating.badge_with_orgs AS
- WITH org_scope AS (
- SELECT id,
- array_agg(tree) AS orgs
- FROM (SELECT id,
- (actor.org_unit_descendants(id)).id AS tree
- FROM actor.org_unit
- ) x
- GROUP BY 1
- )
- SELECT b.*,
- s.orgs
- FROM rating.badge b
- JOIN org_scope s ON (b.scope = s.id);
-
-CREATE OR REPLACE FUNCTION rating.precalc_src_filter(src INT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
-BEGIN
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_src_filter_bib_list;
- IF src IS NOT NULL THEN
- CREATE TEMP TABLE precalc_src_filter_bib_list ON COMMIT DROP AS
- SELECT id FROM biblio.record_entry
- WHERE source = src AND NOT deleted;
- ELSE
- CREATE TEMP TABLE precalc_src_filter_bib_list ON COMMIT DROP AS
- SELECT id FROM biblio.record_entry
- WHERE id > 0 AND NOT deleted;
- END IF;
-
- SELECT count(*) INTO cnt FROM precalc_src_filter_bib_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.precalc_circ_mod_filter(cm TEXT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
-BEGIN
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_circ_mod_filter_bib_list;
- IF cm IS NOT NULL THEN
- CREATE TEMP TABLE precalc_circ_mod_filter_bib_list ON COMMIT DROP AS
- SELECT cn.record AS id,
- cp.id AS copy
- FROM asset.call_number cn
- JOIN asset.copy cp ON (cn.id = cp.call_number)
- WHERE cp.circ_modifier = cm
- AND NOT cp.deleted;
- ELSE
- CREATE TEMP TABLE precalc_circ_mod_filter_bib_list ON COMMIT DROP AS
- SELECT cn.record AS id,
- cp.id AS copy
- FROM asset.call_number cn
- JOIN asset.copy cp ON (cn.id = cp.call_number)
- WHERE NOT cp.deleted;
- END IF;
-
- SELECT count(*) INTO cnt FROM precalc_circ_mod_filter_bib_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.precalc_location_filter(loc INT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
-BEGIN
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_location_filter_bib_list;
- IF loc IS NOT NULL THEN
- CREATE TEMP TABLE precalc_location_filter_bib_list ON COMMIT DROP AS
- SELECT cn.record AS id,
- cp.id AS copy
- FROM asset.call_number cn
- JOIN asset.copy cp ON (cn.id = cp.call_number)
- JOIN asset.copy_location_group_map lg ON (cp.location = lg.location)
- WHERE lg.lgroup = loc
- AND NOT cp.deleted;
- ELSE
- CREATE TEMP TABLE precalc_location_filter_bib_list ON COMMIT DROP AS
- SELECT cn.record AS id,
- cp.id AS copy
- FROM asset.call_number cn
- JOIN asset.copy cp ON (cn.id = cp.call_number)
- WHERE NOT cp.deleted;
- END IF;
-
- SELECT count(*) INTO cnt FROM precalc_location_filter_bib_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
--- all or limited...
-CREATE OR REPLACE FUNCTION rating.precalc_attr_filter(attr_filter TEXT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
- afilter TEXT;
-BEGIN
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_attr_filter_bib_list;
- IF attr_filter IS NOT NULL THEN
- afilter := metabib.compile_composite_attr(attr_filter);
- CREATE TEMP TABLE precalc_attr_filter_bib_list ON COMMIT DROP AS
- SELECT source AS id FROM metabib.record_attr_vector_list
- WHERE vlist @@ metabib.compile_composite_attr(attr_filter);
- ELSE
- CREATE TEMP TABLE precalc_attr_filter_bib_list ON COMMIT DROP AS
- SELECT source AS id FROM metabib.record_attr_vector_list;
- END IF;
-
- SELECT count(*) INTO cnt FROM precalc_attr_filter_bib_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_copy(badge_id INT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
- badge_row rating.badge_with_orgs%ROWTYPE;
- base TEXT;
- whr TEXT;
-BEGIN
-
- SELECT * INTO badge_row FROM rating.badge_with_orgs WHERE id = badge_id;
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bibs_by_copy_list;
- CREATE TEMP TABLE precalc_bibs_by_copy_list ON COMMIT DROP AS
- SELECT DISTINCT cn.record AS id
- FROM asset.call_number cn
- JOIN asset.copy cp ON (cp.call_number = cn.id AND NOT cp.deleted)
- JOIN precalc_copy_filter_bib_list f ON (cp.id = f.copy)
- WHERE cn.owning_lib = ANY (badge_row.orgs)
- AND NOT cn.deleted;
-
- SELECT count(*) INTO cnt FROM precalc_bibs_by_copy_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_uri(badge_id INT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
- badge_row rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge_row FROM rating.badge_with_orgs WHERE id = badge_id;
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bibs_by_uri_list;
- CREATE TEMP TABLE precalc_bibs_by_uri_list ON COMMIT DROP AS
- SELECT DISTINCT record AS id
- FROM asset.call_number cn
- JOIN asset.uri_call_number_map urim ON (urim.call_number = cn.id)
- JOIN asset.uri uri ON (urim.uri = uri.id AND uri.active)
- WHERE cn.owning_lib = ANY (badge_row.orgs)
- AND cn.label = '##URI##'
- AND NOT cn.deleted;
-
- SELECT count(*) INTO cnt FROM precalc_bibs_by_uri_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.precalc_bibs_by_copy_or_uri(badge_id INT)
- RETURNS INT AS $f$
-DECLARE
- cnt INT := 0;
-BEGIN
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
- PERFORM rating.precalc_bibs_by_uri(badge_id);
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bibs_by_copy_or_uri_list;
- CREATE TEMP TABLE precalc_bibs_by_copy_or_uri_list ON COMMIT DROP AS
- SELECT id FROM precalc_bibs_by_copy_list
- UNION
- SELECT id FROM precalc_bibs_by_uri_list;
-
- SELECT count(*) INTO cnt FROM precalc_bibs_by_copy_or_uri_list;
- RETURN cnt;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-
-CREATE OR REPLACE FUNCTION rating.recalculate_badge_score ( badge_id INT, setup_only BOOL DEFAULT FALSE ) RETURNS VOID AS $f$
-DECLARE
- badge_row rating.badge%ROWTYPE;
- param rating.popularity_parameter%ROWTYPE;
-BEGIN
- SET LOCAL client_min_messages = error;
-
- -- Find what we're doing
- SELECT * INTO badge_row FROM rating.badge WHERE id = badge_id;
- SELECT * INTO param FROM rating.popularity_parameter WHERE id = badge_row.popularity_parameter;
-
- -- Calculate the filtered bib set, or all bibs if none
- PERFORM rating.precalc_attr_filter(badge_row.attr_filter);
- PERFORM rating.precalc_src_filter(badge_row.src_filter);
- PERFORM rating.precalc_circ_mod_filter(badge_row.circ_mod_filter);
- PERFORM rating.precalc_location_filter(badge_row.loc_grp_filter);
-
- -- Bring the bib-level filter lists together
- DROP TABLE IF EXISTS precalc_bib_filter_bib_list;
- CREATE TEMP TABLE precalc_bib_filter_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_attr_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_src_filter_bib_list;
-
- -- Bring the copy-level filter lists together. We're keeping this for bib_by_copy filtering later.
- DROP TABLE IF EXISTS precalc_copy_filter_bib_list;
- CREATE TEMP TABLE precalc_copy_filter_bib_list ON COMMIT DROP AS
- SELECT id, copy FROM precalc_circ_mod_filter_bib_list
- INTERSECT
- SELECT id, copy FROM precalc_location_filter_bib_list;
-
- -- Bring the collapsed filter lists together
- DROP TABLE IF EXISTS precalc_filter_bib_list;
- CREATE TEMP TABLE precalc_filter_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_bib_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_copy_filter_bib_list;
-
- CREATE INDEX precalc_filter_bib_list_idx
- ON precalc_filter_bib_list (id);
-
- IF setup_only THEN
- RETURN;
- END IF;
-
- -- If it's a fixed-rating badge, just do it ...
- IF badge_row.fixed_rating IS NOT NULL THEN
- DELETE FROM rating.record_badge_score WHERE badge = badge_id;
- EXECUTE $e$
- INSERT INTO rating.record_badge_score (record, badge, score)
- SELECT record, $1, $2 FROM $e$ || param.func || $e$($1)$e$
- USING badge_id, badge_row.fixed_rating;
-
- UPDATE rating.badge SET last_calc = NOW() WHERE id = badge_id;
-
- RETURN;
- END IF;
- -- else, calculate!
-
- -- Make a session-local scratchpad for calculating scores
- CREATE TEMP TABLE record_score_scratchpad (
- bib BIGINT,
- value NUMERIC
- ) ON COMMIT DROP;
-
- -- Gather raw values
- EXECUTE $e$
- INSERT INTO record_score_scratchpad (bib, value)
- SELECT * FROM $e$ || param.func || $e$($1)$e$
- USING badge_id;
-
- IF badge_row.discard > 0 OR badge_row.percentile IS NOT NULL THEN
- -- To speed up discard-common
- CREATE INDEX record_score_scratchpad_score_idx ON record_score_scratchpad (value);
- ANALYZE record_score_scratchpad;
- END IF;
-
- IF badge_row.discard > 0 THEN -- Remove common low values (trim the long tail)
- DELETE FROM record_score_scratchpad WHERE value IN (
- SELECT DISTINCT value FROM record_score_scratchpad ORDER BY value LIMIT badge_row.discard
- );
- END IF;
-
- IF badge_row.percentile IS NOT NULL THEN -- Cut population down to exceptional records
- DELETE FROM record_score_scratchpad WHERE value <= (
- SELECT value FROM (
- SELECT value,
- CUME_DIST() OVER (ORDER BY value) AS p
- FROM record_score_scratchpad
- ) x WHERE p < badge_row.percentile / 100.0 ORDER BY p DESC LIMIT 1
- );
- END IF;
-
-
- -- And, finally, push new data in
- DELETE FROM rating.record_badge_score WHERE badge = badge_id;
- INSERT INTO rating.record_badge_score (badge, record, score)
- SELECT badge_id,
- bib,
- GREATEST(ROUND((CUME_DIST() OVER (ORDER BY value)) * 5), 1) AS value
- FROM record_score_scratchpad;
-
- DROP TABLE record_score_scratchpad;
-
- -- Now, finally-finally, mark the badge as recalculated
- UPDATE rating.badge SET last_calc = NOW() WHERE id = badge_id;
-
- RETURN;
-END;
-$f$ LANGUAGE PLPGSQL;
-
-CREATE OR REPLACE FUNCTION rating.holds_filled_over_time(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
- iage INT := 1;
- iint INT := NULL;
- iscale NUMERIC := NULL;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- IF badge.horizon_age IS NULL THEN
- RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
- badge.name,
- badge.id;
- END IF;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bib_list;
- CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list;
-
- iint := EXTRACT(EPOCH FROM badge.importance_interval);
- IF badge.importance_age IS NOT NULL THEN
- iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
- END IF;
-
- -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
- iscale := COALESCE(badge.importance_scale, 1.0);
-
- RETURN QUERY
- SELECT bib,
- SUM( holds * GREATEST( iscale * (iage - hage), 1.0 ))
- FROM (
- SELECT f.id AS bib,
- (1 + EXTRACT(EPOCH FROM AGE(h.fulfillment_time)) / iint)::INT AS hage,
- COUNT(h.id)::INT AS holds
- FROM action.hold_request h
- JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
- JOIN precalc_bib_list f ON (f.id = rhrr.bib_record)
- WHERE h.fulfillment_time >= NOW() - badge.horizon_age
- AND h.request_lib = ANY (badge.orgs)
- GROUP BY 1, 2
- ) x
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.holds_placed_over_time(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
- iage INT := 1;
- iint INT := NULL;
- iscale NUMERIC := NULL;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- IF badge.horizon_age IS NULL THEN
- RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
- badge.name,
- badge.id;
- END IF;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bib_list;
- CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list;
-
- iint := EXTRACT(EPOCH FROM badge.importance_interval);
- IF badge.importance_age IS NOT NULL THEN
- iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
- END IF;
-
- -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
- iscale := COALESCE(badge.importance_scale, 1.0);
-
- RETURN QUERY
- SELECT bib,
- SUM( holds * GREATEST( iscale * (iage - hage), 1.0 ))
- FROM (
- SELECT f.id AS bib,
- (1 + EXTRACT(EPOCH FROM AGE(h.request_time)) / iint)::INT AS hage,
- COUNT(h.id)::INT AS holds
- FROM action.hold_request h
- JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
- JOIN precalc_bib_list f ON (f.id = rhrr.bib_record)
- WHERE h.request_time >= NOW() - badge.horizon_age
- AND h.request_lib = ANY (badge.orgs)
- GROUP BY 1, 2
- ) x
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.current_hold_count(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT rhrr.bib_record AS bib,
- COUNT(DISTINCT h.id)::NUMERIC AS holds
- FROM action.hold_request h
- JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
- JOIN action.hold_copy_map m ON (m.hold = h.id)
- JOIN precalc_copy_filter_bib_list cf ON (rhrr.bib_record = cf.id AND m.target_copy = cf.copy)
- WHERE h.fulfillment_time IS NULL
- AND h.request_lib = ANY (badge.orgs)
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.circs_over_time(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
- iage INT := 1;
- iint INT := NULL;
- iscale NUMERIC := NULL;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- IF badge.horizon_age IS NULL THEN
- RAISE EXCEPTION 'Badge "%" with id % requires a horizon age but has none.',
- badge.name,
- badge.id;
- END IF;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- iint := EXTRACT(EPOCH FROM badge.importance_interval);
- IF badge.importance_age IS NOT NULL THEN
- iage := (EXTRACT(EPOCH FROM badge.importance_age) / iint)::INT;
- END IF;
-
- -- if iscale is smaller than 1, scaling slope will be shallow ... BEWARE!
- iscale := COALESCE(badge.importance_scale, 1.0);
-
- RETURN QUERY
- SELECT bib,
- SUM( circs * GREATEST( iscale * (iage - cage), 1.0 ))
- FROM (
- SELECT cn.record AS bib,
- (1 + EXTRACT(EPOCH FROM AGE(c.xact_start)) / iint)::INT AS cage,
- COUNT(c.id)::INT AS circs
- FROM action.circulation c
- JOIN precalc_copy_filter_bib_list cf ON (c.target_copy = cf.copy)
- JOIN asset.copy cp ON (cp.id = c.target_copy)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- WHERE c.xact_start >= NOW() - badge.horizon_age
- AND cn.owning_lib = ANY (badge.orgs)
- AND c.phone_renewal IS FALSE -- we don't count renewals
- AND c.desk_renewal IS FALSE
- AND c.opac_renewal IS FALSE
- GROUP BY 1, 2
- ) x
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.current_circ_count(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT cn.record AS bib,
- COUNT(c.id)::NUMERIC AS circs
- FROM action.circulation c
- JOIN precalc_copy_filter_bib_list cf ON (c.target_copy = cf.copy)
- JOIN asset.copy cp ON (cp.id = c.target_copy)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- WHERE c.checkin_time IS NULL
- AND cn.owning_lib = ANY (badge.orgs)
- GROUP BY 1;
-
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.checked_out_total_ratio(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT bib,
- SUM(checked_out)::NUMERIC / SUM(total)::NUMERIC
- FROM (SELECT cn.record AS bib,
- (cp.status = 1)::INT AS checked_out,
- 1 AS total
- FROM asset.copy cp
- JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- WHERE cn.owning_lib = ANY (badge.orgs)
- ) x
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.holds_total_ratio(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT cn.record AS bib,
- COUNT(DISTINCT m.hold)::NUMERIC / COUNT(DISTINCT cp.id)::NUMERIC
- FROM asset.copy cp
- JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
- WHERE cn.owning_lib = ANY (badge.orgs)
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.holds_holdable_ratio(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT cn.record AS bib,
- COUNT(DISTINCT m.hold)::NUMERIC / COUNT(DISTINCT cp.id)::NUMERIC
- FROM asset.copy cp
- JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
- JOIN asset.copy_location cl ON (cl.id = cp.location)
- JOIN config.copy_status cs ON (cs.id = cp.status)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
- WHERE cn.owning_lib = ANY (badge.orgs)
- AND cp.holdable IS TRUE
- AND cl.holdable IS TRUE
- AND cs.holdable IS TRUE
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.bib_record_age(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bib_list;
- CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_or_uri_list;
-
- RETURN QUERY
- SELECT b.id,
- 1.0 / EXTRACT(EPOCH FROM AGE(b.create_date))::NUMERIC + 1.0
- FROM precalc_bib_list pop
- JOIN biblio.record_entry b ON (b.id = pop.id);
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.bib_pub_age(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
-
- SET LOCAL client_min_messages = error;
- DROP TABLE IF EXISTS precalc_bib_list;
- CREATE TEMP TABLE precalc_bib_list ON COMMIT DROP AS
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_or_uri_list;
-
- RETURN QUERY
- SELECT pop.id AS bib,
- s.value::NUMERIC
- FROM precalc_bib_list pop
- JOIN metabib.record_sorter s ON (
- s.source = pop.id
- AND s.attr = 'pubdate'
- AND s.value ~ '^\d+$'
- )
- WHERE s.value::INT <= EXTRACT(YEAR FROM NOW())::INT;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.percent_time_circulating(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-DECLARE
- badge rating.badge_with_orgs%ROWTYPE;
-BEGIN
-
- SELECT * INTO badge FROM rating.badge_with_orgs WHERE id = badge_id;
-
- PERFORM rating.precalc_bibs_by_copy(badge_id);
-
- DELETE FROM precalc_copy_filter_bib_list WHERE id NOT IN (
- SELECT id FROM precalc_filter_bib_list
- INTERSECT
- SELECT id FROM precalc_bibs_by_copy_list
- );
-
- ANALYZE precalc_copy_filter_bib_list;
-
- RETURN QUERY
- SELECT bib,
- SUM(COALESCE(circ_time,0))::NUMERIC / SUM(age)::NUMERIC
- FROM (SELECT cn.record AS bib,
- cp.id,
- EXTRACT( EPOCH FROM AGE(cp.active_date) ) + 1 AS age,
- SUM( -- time copy spent circulating
- EXTRACT(
- EPOCH FROM
- AGE(
- COALESCE(circ.checkin_time, circ.stop_fines_time, NOW()),
- circ.xact_start
- )
- )
- )::NUMERIC AS circ_time
- FROM asset.copy cp
- JOIN precalc_copy_filter_bib_list c ON (cp.id = c.copy)
- JOIN asset.call_number cn ON (cn.id = cp.call_number)
- LEFT JOIN action.all_circulation circ ON (
- circ.target_copy = cp.id
- AND stop_fines NOT IN (
- 'LOST',
- 'LONGOVERDUE',
- 'CLAIMSRETURNED',
- 'LONGOVERDUE'
- )
- AND NOT (
- checkin_time IS NULL AND
- stop_fines = 'MAXFINES'
- )
- )
- WHERE cn.owning_lib = ANY (badge.orgs)
- AND cp.active_date IS NOT NULL
- -- Next line requires that copies with no circs (circ.id IS NULL) also not be deleted
- AND ((circ.id IS NULL AND NOT cp.deleted) OR circ.id IS NOT NULL)
- GROUP BY 1,2,3
- ) x
- GROUP BY 1;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_copy(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-BEGIN
- PERFORM rating.precalc_bibs_by_copy(badge_id);
- RETURN QUERY
- SELECT id, 1.0 FROM precalc_filter_bib_list
- INTERSECT
- SELECT id, 1.0 FROM precalc_bibs_by_copy_list;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_uri(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-BEGIN
- PERFORM rating.precalc_bibs_by_uri(badge_id);
- RETURN QUERY
- SELECT id, 1.0 FROM precalc_bib_filter_bib_list
- INTERSECT
- SELECT id, 1.0 FROM precalc_bibs_by_uri_list;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_by_copy_or_uri(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-BEGIN
- PERFORM rating.precalc_bibs_by_copy_or_uri(badge_id);
- RETURN QUERY
- (SELECT id, 1.0 FROM precalc_filter_bib_list
- INTERSECT
- SELECT id, 1.0 FROM precalc_bibs_by_copy_list)
- UNION
- (SELECT id, 1.0 FROM precalc_bib_filter_bib_list
- INTERSECT
- SELECT id, 1.0 FROM precalc_bibs_by_uri_list);
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE OR REPLACE FUNCTION rating.generic_fixed_rating_global(badge_id INT)
- RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
-BEGIN
- RETURN QUERY
- SELECT id, 1.0 FROM precalc_bib_filter_bib_list;
-END;
-$f$ LANGUAGE PLPGSQL STRICT;
-
-CREATE INDEX hold_fulfillment_time_idx ON action.hold_request (fulfillment_time) WHERE fulfillment_time IS NOT NULL;
-CREATE INDEX hold_request_time_idx ON action.hold_request (request_time);
-
-COMMIT;
-
+++ /dev/null
-/*
- * Copyright (C) 2016 Equinox Software, Inc.
- * Mike Rylander <miker@esilibrary.com>
- *
- * This program is free software; you can redistribute it and/or
- * modify it under the terms of the GNU General Public License
- * as published by the Free Software Foundation; either version 2
- * of the License, or (at your option) any later version.
- *
- * This program is distributed in the hope that it will be useful,
- * but WITHOUT ANY WARRANTY; without even the implied warranty of
- * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
- * GNU General Public License for more details.
- *
- */
-
-
-BEGIN;
-
-ALTER TYPE search.search_result ADD ATTRIBUTE badges TEXT, ADD ATTRIBUTE popularity NUMERIC;
-
-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,
- deleted_search BOOL,
- param_pref_ou INT DEFAULT NULL
-) RETURNS SETOF search.search_result AS $func$
-DECLARE
-
- current_res search.search_result%ROWTYPE;
- search_org_list INT[];
- luri_org_list INT[];
- tmp_int_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;
-
- luri_as_copy BOOL;
-BEGIN
-
- check_limit := COALESCE( param_check, 1000 );
- core_limit := COALESCE( param_limit, 25000 );
- core_offset := COALESCE( param_offset, 0 );
-
- SELECT COALESCE( enabled, FALSE ) INTO luri_as_copy FROM config.global_flag WHERE name = 'opac.located_uri.act_as_copy';
-
- -- 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;
-
- IF luri_as_copy THEN
- SELECT ARRAY_AGG(distinct id) INTO luri_org_list FROM actor.org_unit_full_path( param_search_ou );
- ELSE
- SELECT ARRAY_AGG(distinct id) INTO luri_org_list FROM actor.org_unit_ancestors( 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;
-
- FOR tmp_int IN SELECT * FROM UNNEST(search_org_list) LOOP
-
- IF luri_as_copy THEN
- SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_full_path( tmp_int );
- ELSE
- SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors( tmp_int );
- END IF;
-
- luri_org_list := luri_org_list || tmp_int_list;
- END LOOP;
-
- SELECT ARRAY_AGG(DISTINCT x.id) INTO luri_org_list FROM UNNEST(luri_org_list) x(id);
-
- ELSIF param_search_ou = 0 THEN
- -- reserved for user lassos (ou_buckets/type='lasso') with ID passed in depth ... hack? sure.
- END IF;
-
- IF param_pref_ou IS NOT NULL THEN
- IF luri_as_copy THEN
- SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_full_path( param_pref_ou );
- ELSE
- SELECT ARRAY_AGG(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors( param_pref_ou );
- END IF;
-
- luri_org_list := luri_org_list || tmp_int_list;
- 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;
-
- IF NOT deleted_search THEN
-
- 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;
- current_res.badges = core_result.badges;
- current_res.popularity = core_result.popularity;
-
- 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( luri_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;
- current_res.badges = core_result.badges;
- current_res.popularity = core_result.popularity;
-
- 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
- JOIN asset.copy cp ON (cp.call_number = cn.id)
- WHERE cn.record IN ( SELECT * FROM unnest( core_result.records ) )
- AND NOT cp.deleted
- LIMIT 1;
-
- IF NOT FOUND THEN
- -- Recheck Located URI visibility in the case of no "foreign" copies
- 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 cn.record IN ( SELECT * FROM unnest( core_result.records ) )
- AND cn.owning_lib NOT IN ( SELECT * FROM unnest( luri_org_list ) )
- LIMIT 1;
-
- IF FOUND THEN
- -- RAISE NOTICE ' % were excluded for foreign located URIs... ', core_result.records;
- excluded_count := excluded_count + 1;
- CONTINUE;
- END IF;
- ELSE
- -- 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;
-
- END IF;
-
- visible_count := visible_count + 1;
-
- current_res.id = core_result.id;
- current_res.rel = core_result.rel;
- current_res.badges = core_result.badges;
- current_res.popularity = core_result.popularity;
-
- 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.badges = NULL;
- current_res.popularity = 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 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, ' ||
- 'NULL AS badges, NULL::NUMERIC AS popularity, ' ||
- '1::NUMERIC 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, ' ||
- 'NULL AS badges, NULL::NUMERIC AS popularity, ' ||
- '1::NUMERIC 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;
-