FROM actor.org_unit
) x
GROUP BY 1
- ),
- badge_data AS (
- SELECT *,
- metabib.compile_composite_attr(COALESCE(attr_filter,'{}')) AS afilter
- FROM rating.badge
)
SELECT DISTINCT ON (b.id)
b.id AS bib,
s.orgs
FROM biblio.record_entry b
JOIN metabib.record_attr_vector_list r ON (b.id = r.source)
- JOIN badge_data ON (
+ JOIN rating.badge badge_data ON (
badge_data.circ_mod_filter IS NULL
AND (badge_data.src_filter IS NULL OR b.source = badge_data.src_filter)
- AND (badge_data.attr_filter IS NULL OR r.vlist @@ badge_data.afilter)
)
JOIN org_scope s ON (badge_data.scope = s.id);
FROM actor.org_unit
) x
GROUP BY 1
- ),
- badge_data AS (
- SELECT *,
- metabib.compile_composite_attr(COALESCE(attr_filter,'{}')) AS afilter
- FROM rating.badge
)
SELECT DISTINCT ON (b.id)
b.id AS bib,
JOIN asset.call_number cn ON (cn.record = b.id AND NOT cn.deleted)
JOIN asset.copy cp ON (cp.call_number = cn.id AND NOT cp.deleted)
JOIN org_scope s ON (cn.owning_lib = ANY (s.orgs))
- JOIN badge_data ON (
+ JOIN rating.badge badge_data ON (
badge_data.scope = s.id
AND (badge_data.src_filter IS NULL OR b.source = badge_data.src_filter)
AND (badge_data.circ_mod_filter IS NULL OR cp.circ_modifier = badge_data.circ_mod_filter)
- AND (badge_data.attr_filter IS NULL OR r.vlist @@ badge_data.afilter)
)
LEFT JOIN asset.copy_location_group_map lg ON (cp.location = lg.location)
WHERE (badge_data.loc_grp_filter IS NULL OR lg.lgroup = badge_data.loc_grp_filter);
FROM actor.org_unit
) x
GROUP BY 1
- ),
- badge_data AS (
- SELECT *,
- metabib.compile_composite_attr(COALESCE(attr_filter,'{}')) AS afilter
- FROM rating.badge
)
SELECT DISTINCT ON (b.id)
b.id AS bib,
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)
JOIN org_scope s ON (cn.owning_lib = ANY (s.orgs))
- JOIN badge_data ON (
+ JOIN rating.badge badge_data ON (
badge_data.scope = s.id
AND badge_data.circ_mod_filter IS NULL
AND (badge_data.src_filter IS NULL OR b.source = badge_data.src_filter)
- AND (badge_data.attr_filter IS NULL OR r.vlist @@ badge_data.afilter)
);
CREATE VIEW rating.generic_bib_population_by_copy_or_uri AS
FROM actor.org_unit
) x
GROUP BY 1
- ),
- badge_data AS (
- SELECT *,
- metabib.compile_composite_attr(COALESCE(attr_filter,'{}')) AS afilter
- FROM rating.badge
)
SELECT DISTINCT ON (b.id)
b.id AS bib,
JOIN metabib.record_attr_vector_list r ON (b.id = r.source)
JOIN asset.call_number cn ON (cn.record = b.id AND NOT cn.deleted)
JOIN org_scope s ON (cn.owning_lib = ANY (s.orgs))
- JOIN badge_data ON (
+ JOIN rating.badge badge_data ON (
badge_data.scope = s.id
AND (badge_data.src_filter IS NULL OR b.source = badge_data.src_filter)
- AND (badge_data.attr_filter IS NULL OR r.vlist @@ badge_data.afilter)
)
LEFT JOIN asset.copy cp ON (cp.call_number = cn.id AND NOT cp.deleted)
LEFT JOIN asset.uri_call_number_map urim ON (urim.call_number = cn.id)
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 attribute filter set, or all bibs if none
+ PERFORM rating.precalc_attr_filter(badge_row.attr_filter);
+
-- 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;
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 := 0;
+BEGIN
+
+ 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
+
+ CREATE INDEX precalc_attr_filter_bib_list_idx
+ ON precalc_attr_filter_bib_list (id);
+
+ SELECT count(*) INTO cnt FROM precalc_attr_filter_bib_list;
+ RETURN cnt;
+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
COUNT(h.id)::INT AS holds
FROM action.hold_request h
JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = rhrr.bib_record)
JOIN rating.generic_bib_population_by_copy pop ON (rhrr.bib_record = pop.bib AND pop.badge = badge.id)
WHERE h.fulfillment_time >= NOW() - badge.horizon_age
AND h.request_lib = ANY (pop.orgs)
COUNT(h.id)::INT AS holds
FROM action.hold_request h
JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = rhrr.bib_record)
JOIN rating.generic_bib_population_by_copy pop ON (rhrr.bib_record = pop.bib AND pop.badge = badge.id)
WHERE h.request_time >= NOW() - badge.horizon_age
AND h.request_lib = ANY (pop.orgs)
COUNT(h.id)::NUMERIC AS holds
FROM action.hold_request h
JOIN reporter.hold_request_record rhrr ON (rhrr.id = h.id)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = rhrr.bib_record)
JOIN rating.generic_bib_population_by_copy pop ON (rhrr.bib_record = pop.bib AND pop.badge = $1)
WHERE h.fulfillment_time IS NULL
AND h.request_lib = ANY (pop.orgs)
FROM action.circulation c
JOIN asset.copy cp ON (cp.id = c.target_copy)
JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = badge.id)
WHERE c.xact_start >= NOW() - badge.horizon_age
AND cn.owning_lib = ANY (pop.orgs)
FROM action.circulation c
JOIN asset.copy cp ON (cp.id = c.target_copy)
JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = $1)
WHERE c.checkin_time IS NULL
AND cn.owning_lib = ANY (pop.orgs)
1 AS total
FROM asset.copy cp
JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = $1)
WHERE cn.owning_lib = ANY (pop.orgs)
) x
COUNT(DISTINCT m.hold)::NUMERIC / COUNT(DISTINCT cp.id)::NUMERIC
FROM asset.copy cp
JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = $1)
LEFT JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
WHERE cn.owning_lib = ANY (pop.orgs)
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 precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = $1)
LEFT JOIN action.hold_copy_map m ON (m.target_copy = cp.id)
WHERE cn.owning_lib = ANY (pop.orgs)
1.0 / EXTRACT(EPOCH FROM AGE(b.create_date))::NUMERIC + 1.0
FROM rating.generic_bib_population_by_copy_or_uri pop
JOIN biblio.record_entry b ON (b.id = pop.bib)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = b.id)
WHERE pop.badge = $1
$f$ LANGUAGE SQL STABLE STRICT;
SELECT pop.bib AS bib,
s.value::NUMERIC
FROM rating.generic_bib_population_by_copy_or_uri pop
+ JOIN precalc_attr_filter_bib_list f ON (f.id = pop.bib)
JOIN metabib.record_sorter s ON (
s.source = pop.bib
AND s.attr = 'pubdate'
)::NUMERIC AS circ_time
FROM asset.copy cp
JOIN asset.call_number cn ON (cn.id = cp.call_number)
+ JOIN precalc_attr_filter_bib_list f ON (f.id = cn.record)
JOIN rating.generic_bib_population_by_copy pop ON (cn.record = pop.bib AND pop.badge = $1)
LEFT JOIN action.all_circulation circ ON (circ.target_copy = cp.id)
WHERE cn.owning_lib = ANY (pop.orgs)
RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
SELECT bib, 1.0
FROM rating.generic_bib_population_by_copy pop
+ JOIN precalc_attr_filter_bib_list f ON (f.id = pop.bib)
WHERE pop.badge = $1;
$f$ LANGUAGE SQL STABLE STRICT;
RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
SELECT bib, 1.0
FROM rating.generic_bib_population_by_uri pop
+ JOIN precalc_attr_filter_bib_list f ON (f.id = pop.bib)
WHERE pop.badge = $1;
$f$ LANGUAGE SQL STABLE STRICT;
RETURNS TABLE (record BIGINT, value NUMERIC) AS $f$
SELECT bib, 1.0
FROM rating.generic_bib_population_global pop
+ JOIN precalc_attr_filter_bib_list f ON (f.id = pop.bib)
WHERE pop.badge = $1;
$f$ LANGUAGE SQL STABLE STRICT;