$$ LANGUAGE SQL STABLE;
CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
- p_bibid bigint,
- p_ouid integer,
- p_depth integer DEFAULT NULL::integer,
- p_slimit public.hstore DEFAULT NULL::public.hstore,
- p_soffset public.hstore DEFAULT NULL::public.hstore,
- p_pref_lib integer DEFAULT NULL::integer,
- p_includes text[] DEFAULT NULL::text[]
-) RETURNS TABLE(
- id bigint,
- name text,
- label_sortkey text,
- rank bigint
-)
-LANGUAGE plpgsql
-STABLE
-AS $_$
-DECLARE
- v_depth int4;
-BEGIN
- v_depth := coalesce(
- p_depth,
- (
- SELECT depth
- FROM actor.org_unit_type aout
- INNER JOIN actor.org_unit ou ON ou_type = aout.id
- WHERE ou.id = p_ouid
- ),
- p_pref_lib
- );
-
- RETURN QUERY
- WITH RECURSIVE descendant_depth AS (
+ bibid BIGINT,
+ ouid INT,
+ depth INT DEFAULT NULL,
+ slimit HSTORE DEFAULT NULL,
+ soffset HSTORE DEFAULT NULL,
+ pref_lib INT DEFAULT NULL,
+ includes TEXT[] DEFAULT NULL::TEXT[]
+) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+ WITH RECURSIVE ou_depth AS (
+ SELECT COALESCE(
+ $3,
+ (
+ SELECT depth
+ FROM actor.org_unit_type aout
+ INNER JOIN actor.org_unit ou ON ou_type = aout.id
+ WHERE ou.id = $2
+ )
+ ) AS depth
+ ), descendant_depth AS (
SELECT ou.id,
ou.parent_ou,
out.depth
FROM actor.org_unit ou
JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
- JOIN anscestor_depth ad ON (ad.id = ou.id)
- WHERE ad.depth = v_depth
+ JOIN anscestor_depth ad ON (ad.id = ou.id),
+ ou_depth
+ WHERE ad.depth = ou_depth.depth
UNION ALL
SELECT ou.id,
ou.parent_ou,
out.depth
FROM actor.org_unit ou
JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
- WHERE ou.id = p_ouid
+ WHERE ou.id = $2
UNION ALL
SELECT ou.id,
ou.parent_ou,
FROM asset.call_number acn
JOIN asset.copy acp ON (acn.id = acp.call_number)
JOIN descendants AS aou ON (acp.circ_lib = aou.id)
- WHERE acn.record = p_bibid
+ WHERE acn.record = $1
AND acn.deleted IS FALSE
AND acp.deleted IS FALSE
- AND CASE WHEN ('exclude_invisible_acn' = ANY(p_includes)) THEN
+ AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN
EXISTS (
SELECT 1
FROM asset.opac_visible_copies
WINDOW w AS (
ORDER BY
COALESCE(
- CASE WHEN aou.id = p_ouid THEN -20000 END,
- CASE WHEN aou.id = p_pref_lib THEN -10000 END,
+ CASE WHEN aou.id = $2 THEN -20000 END,
+ CASE WHEN aou.id = $6 THEN -10000 END,
(SELECT distance - 5000
- FROM actor.org_unit_descendants_distance(p_pref_lib) as x
- WHERE x.id = aou.id AND p_pref_lib IN (
- SELECT q.id FROM actor.org_unit_descendants(p_ouid) as q)),
- (SELECT e.distance FROM actor.org_unit_descendants_distance(p_ouid) as e WHERE e.id = aou.id),
+ FROM actor.org_unit_descendants_distance($6) as x
+ WHERE x.id = aou.id AND $6 IN (
+ SELECT q.id FROM actor.org_unit_descendants($2) as q)),
+ (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id),
1000
),
evergreen.rank_cp_status(acp.status)
) AS ua
GROUP BY ua.id, ua.name, ua.label_sortkey
ORDER BY rank, ua.name, ua.label_sortkey
- LIMIT (p_slimit -> 'acn')::INT
- OFFSET (p_soffset -> 'acn')::INT;
-END;
-$_$;
+ LIMIT ($4 -> 'acn')::INT
+ OFFSET ($5 -> 'acn')::INT;
+$$ LANGUAGE SQL STABLE ROWS 10;
CREATE OR REPLACE FUNCTION evergreen.located_uris (
bibid BIGINT,
BEGIN;
-DROP FUNCTION evergreen.ranked_volumes(
- bibid BIGINT,
- ouid INT,
- depth INT,
- slimit HSTORE,
- soffset HSTORE,
- pref_lib INT,
- includes TEXT[]
-);
-
CREATE OR REPLACE FUNCTION evergreen.ranked_volumes(
- p_bibid bigint,
- p_ouid integer,
- p_depth integer DEFAULT NULL::integer,
- p_slimit public.hstore DEFAULT NULL::public.hstore,
- p_soffset public.hstore DEFAULT NULL::public.hstore,
- p_pref_lib integer DEFAULT NULL::integer,
- p_includes text[] DEFAULT NULL::text[]
-) RETURNS TABLE(
- id bigint,
- name text,
- label_sortkey text,
- rank bigint
-)
-LANGUAGE plpgsql
-STABLE
-AS $_$
-DECLARE
- v_depth int4;
-BEGIN
- v_depth := coalesce(
- p_depth,
- (
- SELECT depth
- FROM actor.org_unit_type aout
- INNER JOIN actor.org_unit ou ON ou_type = aout.id
- WHERE ou.id = p_ouid
- ),
- p_pref_lib
- );
-
- RETURN QUERY
- WITH RECURSIVE descendant_depth AS (
+ bibid BIGINT,
+ ouid INT,
+ depth INT DEFAULT NULL,
+ slimit HSTORE DEFAULT NULL,
+ soffset HSTORE DEFAULT NULL,
+ pref_lib INT DEFAULT NULL,
+ includes TEXT[] DEFAULT NULL::TEXT[]
+) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$
+ WITH RECURSIVE ou_depth AS (
+ SELECT COALESCE(
+ $3,
+ (
+ SELECT depth
+ FROM actor.org_unit_type aout
+ INNER JOIN actor.org_unit ou ON ou_type = aout.id
+ WHERE ou.id = $2
+ )
+ ) AS depth
+ ), descendant_depth AS (
SELECT ou.id,
ou.parent_ou,
out.depth
FROM actor.org_unit ou
JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
- JOIN anscestor_depth ad ON (ad.id = ou.id)
- WHERE ad.depth = v_depth
+ JOIN anscestor_depth ad ON (ad.id = ou.id),
+ ou_depth
+ WHERE ad.depth = ou_depth.depth
UNION ALL
SELECT ou.id,
ou.parent_ou,
out.depth
FROM actor.org_unit ou
JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
- WHERE ou.id = p_ouid
+ WHERE ou.id = $2
UNION ALL
SELECT ou.id,
ou.parent_ou,
FROM asset.call_number acn
JOIN asset.copy acp ON (acn.id = acp.call_number)
JOIN descendants AS aou ON (acp.circ_lib = aou.id)
- WHERE acn.record = p_bibid
+ WHERE acn.record = $1
AND acn.deleted IS FALSE
AND acp.deleted IS FALSE
- AND CASE WHEN ('exclude_invisible_acn' = ANY(p_includes)) THEN
+ AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN
EXISTS (
- SELECT 1
- FROM asset.opac_visible_copies
+ SELECT 1
+ FROM asset.opac_visible_copies
WHERE copy_id = acp.id AND record = acn.record
) ELSE TRUE END
GROUP BY acn.id, acp.status, aou.name, acn.label_sortkey, aou.id
WINDOW w AS (
- ORDER BY
+ ORDER BY
COALESCE(
- CASE WHEN aou.id = p_ouid THEN -20000 END,
- CASE WHEN aou.id = p_pref_lib THEN -10000 END,
+ CASE WHEN aou.id = $2 THEN -20000 END,
+ CASE WHEN aou.id = $6 THEN -10000 END,
(SELECT distance - 5000
- FROM actor.org_unit_descendants_distance(p_pref_lib) as x
- WHERE x.id = aou.id AND p_pref_lib IN (
- SELECT q.id FROM actor.org_unit_descendants(p_ouid) as q)),
- (SELECT e.distance FROM actor.org_unit_descendants_distance(p_ouid) as e WHERE e.id = aou.id),
+ FROM actor.org_unit_descendants_distance($6) as x
+ WHERE x.id = aou.id AND $6 IN (
+ SELECT q.id FROM actor.org_unit_descendants($2) as q)),
+ (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id),
1000
),
evergreen.rank_cp_status(acp.status)
) AS ua
GROUP BY ua.id, ua.name, ua.label_sortkey
ORDER BY rank, ua.name, ua.label_sortkey
- LIMIT (p_slimit -> 'acn')::INT
- OFFSET (p_soffset -> 'acn')::INT;
-END;
-$_$;
+ LIMIT ($4 -> 'acn')::INT
+ OFFSET ($5 -> 'acn')::INT;
+$$ LANGUAGE SQL STABLE ROWS 10;
COMMIT;