--- /dev/null
+BEGIN;
+
+\set ON_ERROR_STOP on
+SET statement_timeout = 0;
+
+/*
+KCLS upgrade tasks to run before 2.4.1-2.4.2-upgrade-db.sql
+*/
+
+/*
+In this section, change object schemas to match the community code.
+*/
+
+ALTER AGGREGATE public.array_accum(anyelement) set schema evergreen;
+ALTER FUNCTION public.extract_marc_field(text, bigint, text) set schema evergreen;
+ALTER FUNCTION public.extract_marc_field(text, bigint, text,text) set schema evergreen;
+ALTER FUNCTION public.is_json(text) set schema evergreen;
+
+DROP TRIGGER c_maintain_control_numbers on biblio.record_entry;
+DROP TRIGGER c_maintain_control_numbers on serial.record_entry;
+DROP TRIGGER c_maintain_control_numbers on authority.record_entry;
+DROP FUNCTION evergreen.maintain_control_numbers();
+ALTER FUNCTION public.maintain_control_numbers() set schema evergreen;
+CREATE TRIGGER c_maintain_control_numbers BEFORE INSERT OR UPDATE ON biblio.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_control_numbers();
+CREATE TRIGGER c_maintain_control_numbers BEFORE INSERT OR UPDATE ON serial.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_control_numbers();
+CREATE TRIGGER c_maintain_control_numbers BEFORE INSERT OR UPDATE ON authority.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_control_numbers();
+
+ALTER FUNCTION public.oils_i18n_code_tracking() set schema evergreen;
+ALTER FUNCTION public.oils_i18n_gettext(integer, text, text, text) set schema evergreen;
+ALTER FUNCTION public.oils_i18n_gettext(text, text, text, text) set schema evergreen;
+ALTER FUNCTION public.oils_i18n_id_tracking() set schema evergreen;
+ALTER FUNCTION public.oils_i18n_update_apply(old_ident text, new_ident text, hint text) set schema evergreen;
+ALTER FUNCTION public.oils_i18n_xlate(keytable text, keyclass text, keycol text, identcol text, keyvalue text, raw_locale text) set schema evergreen;
+ALTER FUNCTION public.oils_json_to_text(text) set schema evergreen;
+ALTER FUNCTION public.oils_text_as_bytea(text) set schema evergreen;
+ALTER FUNCTION public.oils_xpath(text, text, anyarray) set schema evergreen;
+ALTER FUNCTION public.oils_xpath(text, text) set schema evergreen;
+ALTER FUNCTION public.oils_xpath_string(text, text, text, anyarray) set schema evergreen;
+ALTER FUNCTION public.oils_xpath_string(text, text, text) set schema evergreen;
+ALTER FUNCTION public.oils_xpath_string(text, text, anyarray) set schema evergreen;
+ALTER FUNCTION public.oils_xpath_string(text, text) set schema evergreen;
+ALTER FUNCTION public.oils_xslt_process(text,text) set schema evergreen;
+ALTER FUNCTION public.tableoid2name(oid) set schema evergreen;
+
+/*
+A community version of the function with the same definition already exists in the evergreen schema.
+No references to this function name are schema-qualified, and therefore have been referencing the
+community version, not the public version. Therefore the public version has no use.
+*/
+DROP FUNCTION if exists public.oils_xpath_table(key text, document_field text, relation_name text, xpaths text, criteria text);
+
+--Upgrade Script for 2.4.1 to 2.4.2
+
+-- Evergreen DB patch 0819.schema.acn_dewey_normalizer.sql
+--
+-- Fixes Dewey call number sorting (per LP# 1150939)
+--
+
+CREATE OR REPLACE FUNCTION asset.label_normalizer_dewey(TEXT) RETURNS TEXT AS $func$
+ # Derived from the Koha C4::ClassSortRoutine::Dewey module
+ # Copyright (C) 2007 LibLime
+ # Licensed under the GPL v2 or later
+
+ use strict;
+ use warnings;
+
+ my $init = uc(shift);
+ $init =~ s/^\s+//;
+ $init =~ s/\s+$//;
+ $init =~ s!/!!g;
+ $init =~ s/^([\p{IsAlpha}]+)/$1 /;
+ my @tokens = split /\.|\s+/, $init;
+ my $digit_group_count = 0;
+ my $first_digit_group_idx;
+ for (my $i = 0; $i <= $#tokens; $i++) {
+ if ($tokens[$i] =~ /^\d+$/) {
+ $digit_group_count++;
+ if ($digit_group_count == 1) {
+ $first_digit_group_idx = $i;
+ }
+ if (2 == $digit_group_count) {
+ $tokens[$i] = sprintf("%-15.15s", $tokens[$i]);
+ $tokens[$i] =~ tr/ /0/;
+ }
+ }
+ }
+ my $key = join("_", @tokens);
+ $key =~ s/[^\p{IsAlnum}_]//g;
+
+ return $key;
+
+$func$ LANGUAGE PLPERLU;
+
+-- regenerate sort keys for any dewey call numbers
+
+-- Remove [ and ] characters from seriestitle.
+-- Those characters don't play well when searching.
+
+
+CREATE OR REPLACE FUNCTION reingest_metabib_field_entries(bib_id bigint, skip_facet boolean DEFAULT false, skip_browse boolean DEFAULT false, skip_search boolean DEFAULT false) RETURNS void
+ LANGUAGE plpgsql
+ AS $_X$
+DECLARE
+ fclass RECORD;
+ ind_data metabib.field_entry_template%ROWTYPE;
+ mbe_row metabib.browse_entry%ROWTYPE;
+ mbe_id BIGINT;
+ b_skip_facet BOOL;
+ b_skip_browse BOOL;
+ b_skip_search BOOL;
+ value_prepped TEXT;
+ field_class TEXT;
+BEGIN
+ --ver1.6 modified by kmain-1119
+ SELECT COALESCE(NULLIF(skip_facet, FALSE), EXISTS (SELECT enabled FROM config.internal_flag WHERE name = 'ingest.skip_facet_indexing' AND enabled)) INTO b_skip_facet;
+ SELECT COALESCE(NULLIF(skip_browse, FALSE), EXISTS (SELECT enabled FROM config.internal_flag WHERE name = 'ingest.skip_browse_indexing' AND enabled)) INTO b_skip_browse;
+ SELECT COALESCE(NULLIF(skip_search, FALSE), EXISTS (SELECT enabled FROM config.internal_flag WHERE name = 'ingest.skip_search_indexing' AND enabled)) INTO b_skip_search;
+
+ PERFORM * FROM config.internal_flag WHERE name = 'ingest.assume_inserts_only' AND enabled;
+ IF NOT FOUND THEN
+ IF NOT b_skip_search THEN
+ FOR fclass IN SELECT * FROM config.metabib_class LOOP
+ -- RAISE NOTICE 'Emptying out %', fclass.name;
+ EXECUTE $$DELETE FROM metabib.$$ || fclass.name || $$_field_entry WHERE source = $$ || bib_id;
+ END LOOP;
+ END IF;
+ IF NOT b_skip_facet THEN
+ DELETE FROM metabib.facet_entry WHERE source = bib_id;
+ END IF;
+ IF NOT b_skip_browse THEN
+ DELETE FROM metabib.browse_author_entry_def_map WHERE source = bib_id;
+ DELETE FROM metabib.browse_title_entry_def_map WHERE source = bib_id;
+ DELETE FROM metabib.browse_subject_entry_def_map WHERE source = bib_id;
+ DELETE FROM metabib.browse_series_entry_def_map WHERE source = bib_id;
+ DELETE FROM metabib.browse_call_number_entry_def_map WHERE source = bib_id;
+ END IF;
+ END IF;
+
+ FOR ind_data IN SELECT * FROM biblio.extract_metabib_field_entry( bib_id ) LOOP
+
+ --ind_data.field_class -- author, title, subject, etc
+
+ IF ind_data.field < 0 THEN
+ ind_data.field = -1 * ind_data.field;
+ END IF;
+
+ IF ind_data.facet_field AND NOT b_skip_facet THEN
+ INSERT INTO metabib.facet_entry (field, source, value)
+ VALUES (ind_data.field, ind_data.source, ind_data.value);
+ END IF;
+
+ IF ind_data.browse_field AND NOT b_skip_browse THEN
+ -- A caveat about this SELECT: this should take care of replacing
+ -- old mbe rows when data changes, but not if normalization (by
+ -- which I mean specifically the output of
+ -- evergreen.oils_tsearch2()) changes. It may or may not be
+ -- expensive to add a comparison of index_vector to index_vector
+ -- to the WHERE clause below.
+
+ value_prepped := metabib.browse_normalize(ind_data.value, ind_data.field);
+ IF char_length(value_prepped) > 0 THEN
+ CASE ind_data.field_class
+
+ WHEN 'author' THEN
+
+ SELECT INTO mbe_row * FROM metabib.browse_author_entry
+ WHERE sort_value = ind_data.sort_value
+ ORDER BY id;
+
+ IF FOUND THEN
+ mbe_id := mbe_row.id;
+ ELSE
+ INSERT INTO metabib.browse_author_entry
+ ( value, sort_value, truncated_sort_value ) VALUES
+ ( value_prepped, ind_data.sort_value, substr(ind_data.sort_value, 1, 2700) );
+
+ mbe_id := CURRVAL('metabib.browse_author_entry_id_seq'::REGCLASS);
+ END IF;
+
+ INSERT INTO metabib.browse_author_entry_def_map (entry, def, source, authority)
+ VALUES (mbe_id, ind_data.field, ind_data.source, ind_data.authority);
+
+ WHEN 'title' THEN
+
+ SELECT INTO mbe_row * FROM metabib.browse_title_entry
+ WHERE sort_value = ind_data.sort_value
+ ORDER BY id;
+
+ IF FOUND THEN
+ mbe_id := mbe_row.id;
+ ELSE
+ INSERT INTO metabib.browse_title_entry
+ ( value, sort_value, truncated_sort_value ) VALUES
+ ( value_prepped, ind_data.sort_value, substr(ind_data.sort_value, 1, 2700) );
+
+ mbe_id := CURRVAL('metabib.browse_title_entry_id_seq'::REGCLASS);
+ END IF;
+
+ INSERT INTO metabib.browse_title_entry_def_map (entry, def, source, authority)
+ VALUES (mbe_id, ind_data.field, ind_data.source, ind_data.authority);
+
+ WHEN 'subject' THEN
+
+ SELECT INTO mbe_row * FROM metabib.browse_subject_entry
+ WHERE sort_value = ind_data.sort_value
+ ORDER BY id;
+
+ IF FOUND THEN
+ mbe_id := mbe_row.id;
+ ELSE
+ INSERT INTO metabib.browse_subject_entry
+ ( value, sort_value, truncated_sort_value ) VALUES
+ ( value_prepped, ind_data.sort_value, substr(ind_data.sort_value, 1, 2700) );
+
+ mbe_id := CURRVAL('metabib.browse_subject_entry_id_seq'::REGCLASS);
+ END IF;
+
+ INSERT INTO metabib.browse_subject_entry_def_map (entry, def, source, authority)
+ VALUES (mbe_id, ind_data.field, ind_data.source, ind_data.authority);
+
+ WHEN 'series' THEN
+
+ SELECT INTO mbe_row * FROM metabib.browse_series_entry
+ WHERE sort_value = ind_data.sort_value
+ ORDER BY id;
+
+ IF FOUND THEN
+ mbe_id := mbe_row.id;
+ ELSE
+ INSERT INTO metabib.browse_series_entry
+ ( value, sort_value, truncated_sort_value ) VALUES
+ ( value_prepped, ind_data.sort_value, substr(ind_data.sort_value, 1, 2700) );
+
+ mbe_id := CURRVAL('metabib.browse_series_entry_id_seq'::REGCLASS);
+ END IF;
+
+ INSERT INTO metabib.browse_series_entry_def_map (entry, def, source, authority)
+ VALUES (mbe_id, ind_data.field, ind_data.source, ind_data.authority);
+
+ WHEN 'call_number' THEN
+
+ SELECT INTO mbe_row * FROM metabib.browse_call_number_entry
+ WHERE sort_value = ind_data.sort_value
+ ORDER BY id;
+
+ IF FOUND THEN
+ mbe_id := mbe_row.id;
+ ELSE
+ INSERT INTO metabib.browse_call_number_entry
+ ( value, sort_value, truncated_sort_value ) VALUES
+ ( value_prepped, ind_data.sort_value, substr(ind_data.sort_value, 1, 2700) );
+
+ mbe_id := CURRVAL('metabib.browse_call_number_entry_id_seq'::REGCLASS);
+ END IF;
+
+ INSERT INTO metabib.browse_call_number_entry_def_map (entry, def, source, authority)
+ VALUES (mbe_id, ind_data.field, ind_data.source, ind_data.authority);
+ ELSE
+ END CASE;
+ END IF;
+ END IF;
+
+ IF ind_data.search_field AND NOT b_skip_search THEN
+ -- Avoid inserting duplicate rows
+ EXECUTE 'SELECT 1 FROM metabib.' || ind_data.field_class ||
+ '_field_entry WHERE field = $1 AND source = $2 AND value = $3'
+ INTO mbe_id USING ind_data.field, ind_data.source, ind_data.value;
+ -- RAISE NOTICE 'Search for an already matching row returned %', mbe_id;
+ IF mbe_id IS NULL THEN
+ EXECUTE $$
+ INSERT INTO metabib.$$ || ind_data.field_class || $$_field_entry (field, source, value)
+ VALUES ($$ ||
+ quote_literal(ind_data.field) || $$, $$ ||
+ quote_literal(ind_data.source) || $$, $$ ||
+ quote_literal(ind_data.value) ||
+ $$);$$;
+ END IF;
+ END IF;
+
+ END LOOP;
+
+ IF NOT b_skip_search THEN
+ PERFORM metabib.update_combined_index_vectors(bib_id);
+ END IF;
+
+ RETURN;
+END;
+$_X$;
+
+
+--Upgrade Script for 2.4.2 to 2.4.3
+-- Evergreen DB patch 0825.data.bre_format.sql
+--
+-- Fix some templates that loop over bibs to not have duplicated/run-on titles
+--
+
+-- Function: actor.calculate_system_penalties(integer, integer)
+-- DROP FUNCTION actor.calculate_system_penalties(integer, integer);
+
+CREATE OR REPLACE FUNCTION actor.calculate_system_penalties(match_user integer, context_org integer)
+ RETURNS SETOF actor.usr_standing_penalty AS
+$BODY$
+DECLARE
+ user_object actor.usr%ROWTYPE;
+ new_sp_row actor.usr_standing_penalty%ROWTYPE;
+ existing_sp_row actor.usr_standing_penalty%ROWTYPE;
+ collections_fines permission.grp_penalty_threshold%ROWTYPE;
+ max_fines permission.grp_penalty_threshold%ROWTYPE;
+ max_overdue permission.grp_penalty_threshold%ROWTYPE;
+ max_items_out permission.grp_penalty_threshold%ROWTYPE;
+ max_lost permission.grp_penalty_threshold%ROWTYPE;
+ tmp_grp INT;
+ items_overdue INT;
+ items_out INT;
+ items_lost INT;
+ context_org_list INT[];
+ current_fines NUMERIC(8,2) := 0.0;
+ tmp_fines NUMERIC(8,2);
+ tmp_groc RECORD;
+ tmp_circ RECORD;
+ tmp_org actor.org_unit%ROWTYPE;
+ tmp_penalty config.standing_penalty%ROWTYPE;
+ tmp_depth INTEGER;
+BEGIN
+ SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+ -- Max fines
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has a high fine balance
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 1 AND org_unit = tmp_org.id;
+
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 1;
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL ) l USING (id);
+
+ IF current_fines >= max_fines.threshold THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_fines.org_unit;
+ new_sp_row.standing_penalty := 1;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max overdue
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many overdue items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+
+ SELECT * INTO max_overdue FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 2 AND org_unit = tmp_org.id;
+
+ IF max_overdue.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_overdue.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_overdue.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_overdue.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 2;
+
+ SELECT INTO items_overdue COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_overdue.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND circ.due_date < NOW()
+ AND (circ.stop_fines = 'MAXFINES' OR circ.stop_fines IS NULL);
+
+ IF items_overdue >= max_overdue.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_overdue.org_unit;
+ new_sp_row.standing_penalty := 2;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max out
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many checked out items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_items_out FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 3 AND org_unit = tmp_org.id;
+
+ IF max_items_out.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_items_out.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ -- Fail if the user has too many items checked out
+ IF max_items_out.threshold IS NOT NULL THEN
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_items_out.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 3;
+ SELECT INTO items_out COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_items_out.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND (circ.stop_fines IN (
+ SELECT 'MAXFINES'::TEXT
+ UNION ALL
+ SELECT 'LONGOVERDUE'::TEXT
+ UNION ALL
+ SELECT 'LOST'::TEXT
+ WHERE 'true' ILIKE
+ (
+ SELECT CASE
+ WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.tally_lost', circ.circ_lib)) ILIKE 'true' THEN 'true'
+ ELSE 'false'
+ END
+ )
+ UNION ALL
+ SELECT 'CLAIMSRETURNED'::TEXT
+ WHERE 'false' ILIKE
+ (
+ SELECT CASE
+ WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.do_not_tally_claims_returned', circ.circ_lib)) ILIKE 'true' THEN 'true'
+ ELSE 'false'
+ END
+ )
+ ) OR circ.stop_fines IS NULL)
+ AND xact_finish IS NULL;
+
+ IF items_out >= max_items_out.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_items_out.org_unit;
+ new_sp_row.standing_penalty := 3;
+ RETURN NEXT new_sp_row;
+ END IF;
+END IF;
+
+ -- Start over for max lost
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many lost items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_lost FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 5 AND org_unit = tmp_org.id;
+ IF max_lost.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_lost.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_lost.threshold IS NOT NULL THEN
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_lost.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 5;
+
+ SELECT INTO items_lost COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_lost.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND (circ.stop_fines = 'LOST')
+ AND xact_finish IS NULL;
+
+ IF items_lost >= max_lost.threshold::INT AND 0 < max_lost.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_lost.org_unit;
+ new_sp_row.standing_penalty := 5;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for collections warning
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has a collections-level fine balance
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 4 AND org_unit = tmp_org.id;
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 4;
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND r.xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND g.xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND circ.xact_finish IS NULL ) l USING (id);
+
+ IF current_fines >= max_fines.threshold THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_fines.org_unit;
+ new_sp_row.standing_penalty := 4;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for in collections
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Remove the in-collections penalty if the user has paid down enough
+ -- This penalty is different, because this code is not responsible for creating
+ -- new in-collections penalties, only for removing them
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 30 AND org_unit = tmp_org.id;
+
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ -- first, see if the user had paid down to the threshold
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND r.xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND g.xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND circ.xact_finish IS NULL ) l USING (id);
+
+ IF current_fines IS NULL OR current_fines <= max_fines.threshold THEN
+ -- patron has paid down enough
+
+ SELECT INTO tmp_penalty * FROM config.standing_penalty WHERE id = 30;
+
+ IF tmp_penalty.org_depth IS NOT NULL THEN
+
+ -- since this code is not responsible for applying the penalty, it can't
+ -- guarantee the current context org will match the org at which the penalty
+ --- was applied. search up the org tree until we hit the configured penalty depth
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+ SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+
+ WHILE tmp_depth >= tmp_penalty.org_depth LOOP
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = tmp_org.id
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 30;
+
+ IF tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+ SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+ END LOOP;
+
+ ELSE
+
+ -- no penalty depth is defined, look for exact matches
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 30;
+ END IF;
+
+ END IF;
+
+ END IF;
+
+ RETURN;
+END;
+$BODY$
+ LANGUAGE plpgsql VOLATILE
+ COST 100
+ ROWS 1000;
+
+
+
+CREATE OR REPLACE FUNCTION
+ evergreen.z3950_attr_name_is_valid(TEXT) RETURNS BOOLEAN AS $func$
+ SELECT EXISTS (SELECT 1 FROM config.z3950_attr WHERE name = $1);
+$func$ LANGUAGE SQL STRICT STABLE;
+
+COMMENT ON FUNCTION evergreen.z3950_attr_name_is_valid(TEXT) IS $$
+Results in TRUE if there exists at least one config.z3950_attr
+with the provided name. Used by config.z3950_index_field_map
+to verify z3950_attr_type maps.
+$$;
+
+CREATE TABLE config.z3950_index_field_map (
+ id SERIAL PRIMARY KEY,
+ label TEXT NOT NULL, -- i18n
+ metabib_field INTEGER REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ record_attr TEXT REFERENCES config.record_attr_definition(name),
+ z3950_attr INTEGER REFERENCES config.z3950_attr(id),
+ z3950_attr_type TEXT,-- REFERENCES config.z3950_attr(name)
+ CONSTRAINT metabib_field_or_record_attr CHECK (
+ metabib_field IS NOT NULL OR
+ record_attr IS NOT NULL
+ ),
+ CONSTRAINT attr_or_attr_type CHECK (
+ z3950_attr IS NOT NULL OR
+ z3950_attr_type IS NOT NULL
+ ),
+ -- ensure the selected z3950_attr_type refers to a valid attr name
+ CONSTRAINT valid_z3950_attr_type CHECK (
+ z3950_attr_type IS NULL OR
+ evergreen.z3950_attr_name_is_valid(z3950_attr_type)
+ )
+);
+
+-- check whether patch can be applied
+
+ALTER TABLE config.metabib_field_ts_map DROP CONSTRAINT metabib_field_ts_map_metabib_field_fkey;
+ALTER TABLE config.metabib_search_alias DROP CONSTRAINT metabib_search_alias_field_fkey;
+ALTER TABLE metabib.browse_entry_def_map DROP CONSTRAINT browse_entry_def_map_def_fkey;
+ALTER TABLE metabib.browse_author_entry_def_map DROP CONSTRAINT browse_author_entry_def_map_def_fkey;
+ALTER TABLE metabib.browse_series_entry_def_map DROP CONSTRAINT browse_series_entry_def_map_def_fkey;
+ALTER TABLE metabib.browse_subject_entry_def_map DROP CONSTRAINT browse_subject_entry_def_map_def_fkey;
+ALTER TABLE metabib.browse_title_entry_def_map DROP CONSTRAINT browse_title_entry_def_map_def_fkey;
+ALTER TABLE metabib.browse_call_number_entry_def_map DROP CONSTRAINT browse_call_number_entry_def_map_def_fkey;
+ALTER TABLE config.z3950_index_field_map DROP CONSTRAINT z3950_index_field_map_metabib_field_fkey;
+ALTER TABLE authority.control_set_bib_field_metabib_field_map DROP CONSTRAINT control_set_bib_field_metabib_field_map_metabib_field_fkey;
+
+ALTER TABLE config.metabib_field_ts_map ADD CONSTRAINT metabib_field_ts_map_metabib_field_fkey
+ FOREIGN KEY (metabib_field) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE config.metabib_search_alias ADD CONSTRAINT metabib_search_alias_field_fkey
+ FOREIGN KEY (field) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_entry_def_map ADD CONSTRAINT browse_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_author_entry_def_map ADD CONSTRAINT browse_author_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_series_entry_def_map ADD CONSTRAINT browse_series_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_subject_entry_def_map ADD CONSTRAINT browse_subject_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_title_entry_def_map ADD CONSTRAINT browse_title_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE metabib.browse_call_number_entry_def_map ADD CONSTRAINT browse_call_number_entry_def_map_def_fkey
+ FOREIGN KEY (def) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE config.z3950_index_field_map ADD CONSTRAINT z3950_index_field_map_metabib_field_fkey
+ FOREIGN KEY (metabib_field) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+ALTER TABLE authority.control_set_bib_field_metabib_field_map ADD CONSTRAINT control_set_bib_field_metabib_field_map_metabib_field_fkey
+ FOREIGN KEY (metabib_field) REFERENCES config.metabib_field(id) ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED;
+
+-- seed data
+
+
+ALTER TABLE vandelay.bib_queue ADD COLUMN match_bucket
+ INTEGER REFERENCES container.biblio_record_entry_bucket(id)
+ ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED;
+
+CREATE OR REPLACE FUNCTION vandelay.match_bib_record() RETURNS TRIGGER AS $func$
+DECLARE
+ incoming_existing_id TEXT;
+ test_result vandelay.match_set_test_result%ROWTYPE;
+ tmp_rec BIGINT;
+ match_set INT;
+ match_bucket INT;
+BEGIN
+ IF TG_OP IN ('INSERT','UPDATE') AND NEW.imported_as IS NOT NULL THEN
+ RETURN NEW;
+ END IF;
+
+ DELETE FROM vandelay.bib_match WHERE queued_record = NEW.id;
+
+ SELECT q.match_set INTO match_set FROM vandelay.bib_queue q WHERE q.id = NEW.queue;
+
+ IF match_set IS NOT NULL THEN
+ NEW.quality := vandelay.measure_record_quality( NEW.marc, match_set );
+ END IF;
+
+ -- Perfect matches on 901$c exit early with a match with high quality.
+ incoming_existing_id :=
+ oils_xpath_string('//*[@tag="901"]/*[@code="c"][1]', NEW.marc);
+
+ IF incoming_existing_id IS NOT NULL AND incoming_existing_id != '' THEN
+ SELECT id INTO tmp_rec FROM biblio.record_entry WHERE id = incoming_existing_id::bigint;
+ IF tmp_rec IS NOT NULL THEN
+ INSERT INTO vandelay.bib_match (queued_record, eg_record, match_score, quality)
+ SELECT
+ NEW.id,
+ b.id,
+ 9999,
+ -- note: no match_set means quality==0
+ vandelay.measure_record_quality( b.marc, match_set )
+ FROM biblio.record_entry b
+ WHERE id = incoming_existing_id::bigint;
+ END IF;
+ END IF;
+
+ IF match_set IS NULL THEN
+ RETURN NEW;
+ END IF;
+
+ SELECT q.match_bucket INTO match_bucket FROM vandelay.bib_queue q WHERE q.id = NEW.queue;
+
+ FOR test_result IN SELECT * FROM
+ vandelay.match_set_test_marcxml(match_set, NEW.marc, match_bucket) LOOP
+
+ INSERT INTO vandelay.bib_match ( queued_record, eg_record, match_score, quality )
+ SELECT
+ NEW.id,
+ test_result.record,
+ test_result.quality,
+ vandelay.measure_record_quality( b.marc, match_set )
+ FROM biblio.record_entry b
+ WHERE id = test_result.record;
+
+ END LOOP;
+
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+
+DROP FUNCTION IF EXISTS vandelay.match_set_test_marcxml(INTEGER, TEXT);
+
+CREATE OR REPLACE FUNCTION vandelay.match_set_test_marcxml(
+ match_set_id INTEGER, record_xml TEXT, bucket_id INTEGER
+) RETURNS SETOF vandelay.match_set_test_result AS $$
+DECLARE
+ tags_rstore HSTORE;
+ svf_rstore HSTORE;
+ coal TEXT;
+ joins TEXT;
+ query_ TEXT;
+ wq TEXT;
+ qvalue INTEGER;
+ rec RECORD;
+BEGIN
+ tags_rstore := vandelay.flatten_marc_hstore(record_xml);
+ svf_rstore := vandelay.extract_rec_attrs(record_xml);
+
+ CREATE TEMPORARY TABLE _vandelay_tmp_qrows (q INTEGER);
+ CREATE TEMPORARY TABLE _vandelay_tmp_jrows (j TEXT);
+
+ -- generate the where clause and return that directly (into wq), and as
+ -- a side-effect, populate the _vandelay_tmp_[qj]rows tables.
+ wq := vandelay.get_expr_from_match_set(match_set_id, tags_rstore);
+
+ query_ := 'SELECT DISTINCT(record), ';
+
+ -- qrows table is for the quality bits we add to the SELECT clause
+ SELECT ARRAY_TO_STRING(
+ ARRAY_ACCUM('COALESCE(n' || q::TEXT || '.quality, 0)'), ' + '
+ ) INTO coal FROM _vandelay_tmp_qrows;
+
+ -- our query string so far is the SELECT clause and the inital FROM.
+ -- no JOINs yet nor the WHERE clause
+ query_ := query_ || coal || ' AS quality ' || E'\n';
+
+ -- jrows table is for the joins we must make (and the real text conditions)
+ SELECT ARRAY_TO_STRING(ARRAY_ACCUM(j), E'\n') INTO joins
+ FROM _vandelay_tmp_jrows;
+
+ -- add those joins and the where clause to our query.
+ query_ := query_ || joins || E'\n';
+
+ -- join the record bucket
+ IF bucket_id IS NOT NULL THEN
+ query_ := query_ || 'JOIN container.biblio_record_entry_bucket_item ' ||
+ 'brebi ON (brebi.target_biblio_record_entry = record ' ||
+ 'AND brebi.bucket = ' || bucket_id || E')\n';
+ END IF;
+
+ query_ := query_ || 'JOIN biblio.record_entry bre ON (bre.id = record) ' || 'WHERE ' || wq || ' AND not bre.deleted';
+
+ -- this will return rows of record,quality
+ FOR rec IN EXECUTE query_ USING tags_rstore, svf_rstore LOOP
+ RETURN NEXT rec;
+ END LOOP;
+
+ DROP TABLE _vandelay_tmp_qrows;
+ DROP TABLE _vandelay_tmp_jrows;
+ RETURN;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+
+CREATE OR REPLACE FUNCTION action.purge_holds() RETURNS INT AS $func$
+DECLARE
+ current_hold RECORD;
+ purged_holds INT;
+ cgf_d INTERVAL;
+ cgf_f INTERVAL;
+ cgf_c INTERVAL;
+ prev_usr INT;
+ user_start TIMESTAMPTZ;
+ user_age INTERVAL;
+ user_count INT;
+BEGIN
+ purged_holds := 0;
+ SELECT INTO cgf_d value::INTERVAL FROM config.global_flag WHERE name = 'history.hold.retention_age' AND enabled;
+ SELECT INTO cgf_f value::INTERVAL FROM config.global_flag WHERE name = 'history.hold.retention_age_fulfilled' AND enabled;
+ SELECT INTO cgf_c value::INTERVAL FROM config.global_flag WHERE name = 'history.hold.retention_age_canceled' AND enabled;
+ FOR current_hold IN
+ SELECT
+ rank() OVER (PARTITION BY usr ORDER BY COALESCE(fulfillment_time, cancel_time) DESC),
+ cgf_cs.value::INTERVAL as cgf_cs,
+ ahr.*
+ FROM
+ action.hold_request ahr
+ LEFT JOIN config.global_flag cgf_cs ON (ahr.cancel_cause IS NOT NULL AND cgf_cs.name = 'history.hold.retention_age_canceled_' || ahr.cancel_cause AND cgf_cs.enabled)
+ WHERE
+ (fulfillment_time IS NOT NULL OR cancel_time IS NOT NULL)
+ LOOP
+ IF prev_usr IS NULL OR prev_usr != current_hold.usr THEN
+ prev_usr := current_hold.usr;
+ SELECT INTO user_start oils_json_to_text(value)::TIMESTAMPTZ FROM actor.usr_setting WHERE usr = prev_usr AND name = 'history.hold.retention_start';
+ SELECT INTO user_age oils_json_to_text(value)::INTERVAL FROM actor.usr_setting WHERE usr = prev_usr AND name = 'history.hold.retention_age';
+ SELECT INTO user_count oils_json_to_text(value)::INT FROM actor.usr_setting WHERE usr = prev_usr AND name = 'history.hold.retention_count';
+ IF user_start IS NOT NULL THEN
+ user_age := LEAST(user_age, AGE(NOW(), user_start));
+ END IF;
+ IF user_count IS NULL THEN
+ user_count := 1000; -- Assumption based on the user visible holds routine
+ END IF;
+ END IF;
+ -- Library keep age trumps user keep anything, for purposes of being able to hold on to things when staff canceled and such.
+ IF current_hold.fulfillment_time IS NOT NULL AND current_hold.fulfillment_time > NOW() - COALESCE(cgf_f, cgf_d) THEN
+ CONTINUE;
+ END IF;
+ IF current_hold.cancel_time IS NOT NULL AND current_hold.cancel_time > NOW() - COALESCE(current_hold.cgf_cs, cgf_c, cgf_d) THEN
+ CONTINUE;
+ END IF;
+
+ -- User keep age needs combining with count. If too old AND within the count, keep!
+ IF user_start IS NOT NULL AND COALESCE(current_hold.fulfillment_time, current_hold.cancel_time) > NOW() - user_age AND current_hold.rank <= user_count THEN
+ CONTINUE;
+ END IF;
+
+ -- All checks should have passed, delete!
+ DELETE FROM action.hold_request WHERE id = current_hold.id;
+ purged_holds := purged_holds + 1;
+ END LOOP;
+ RETURN purged_holds;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION action.usr_visible_holds (usr_id INT) RETURNS SETOF action.hold_request AS $func$
+DECLARE
+ h action.hold_request%ROWTYPE;
+ view_age INTERVAL;
+ view_count INT;
+ usr_view_count actor.usr_setting%ROWTYPE;
+ usr_view_age actor.usr_setting%ROWTYPE;
+ usr_view_start actor.usr_setting%ROWTYPE;
+BEGIN
+ SELECT * INTO usr_view_count FROM actor.usr_setting WHERE usr = usr_id AND name = 'history.hold.retention_count';
+ SELECT * INTO usr_view_age FROM actor.usr_setting WHERE usr = usr_id AND name = 'history.hold.retention_age';
+ SELECT * INTO usr_view_start FROM actor.usr_setting WHERE usr = usr_id AND name = 'history.hold.retention_start';
+
+ FOR h IN
+ SELECT *
+ FROM action.hold_request
+ WHERE usr = usr_id
+ AND fulfillment_time IS NULL
+ AND cancel_time IS NULL
+ ORDER BY request_time DESC
+ LOOP
+ RETURN NEXT h;
+ END LOOP;
+
+ IF usr_view_start.value IS NULL THEN
+ RETURN;
+ END IF;
+
+ IF usr_view_age.value IS NOT NULL THEN
+ -- User opted in and supplied a retention age
+ IF oils_json_to_text(usr_view_age.value)::INTERVAL > AGE(NOW(), oils_json_to_text(usr_view_start.value)::TIMESTAMPTZ) THEN
+ view_age := AGE(NOW(), oils_json_to_text(usr_view_start.value)::TIMESTAMPTZ);
+ ELSE
+ view_age := oils_json_to_text(usr_view_age.value)::INTERVAL;
+ END IF;
+ ELSE
+ -- User opted in
+ view_age := AGE(NOW(), oils_json_to_text(usr_view_start.value)::TIMESTAMPTZ);
+ END IF;
+
+ IF usr_view_count.value IS NOT NULL THEN
+ view_count := oils_json_to_text(usr_view_count.value)::INT;
+ ELSE
+ view_count := 1000;
+ END IF;
+
+ -- show some fulfilled/canceled holds
+ FOR h IN
+ SELECT *
+ FROM action.hold_request
+ WHERE usr = usr_id
+ AND ( fulfillment_time IS NOT NULL OR cancel_time IS NOT NULL )
+ AND COALESCE(fulfillment_time, cancel_time) > NOW() - view_age
+ ORDER BY COALESCE(fulfillment_time, cancel_time) DESC
+ LIMIT view_count
+ LOOP
+ RETURN NEXT h;
+ END LOOP;
+
+ RETURN;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE TABLE action.aged_hold_request (
+ usr_post_code TEXT,
+ usr_home_ou INT NOT NULL,
+ usr_profile INT NOT NULL,
+ usr_birth_year INT,
+ staff_placed BOOLEAN NOT NULL,
+ LIKE action.hold_request
+);
+ALTER TABLE action.aged_hold_request
+ ADD PRIMARY KEY (id),
+ DROP COLUMN usr,
+ DROP COLUMN requestor,
+ DROP COLUMN sms_carrier,
+ ALTER COLUMN phone_notify TYPE BOOLEAN
+ USING CASE WHEN phone_notify IS NULL OR phone_notify = '' THEN FALSE ELSE TRUE END,
+ ALTER COLUMN sms_notify TYPE BOOLEAN
+ USING CASE WHEN sms_notify IS NULL OR sms_notify = '' THEN FALSE ELSE TRUE END,
+ ALTER COLUMN phone_notify SET NOT NULL,
+ ALTER COLUMN sms_notify SET NOT NULL;
+CREATE INDEX aged_hold_request_target_idx ON action.aged_hold_request (target);
+CREATE INDEX aged_hold_request_pickup_lib_idx ON action.aged_hold_request (pickup_lib);
+CREATE INDEX aged_hold_request_current_copy_idx ON action.aged_hold_request (current_copy);
+CREATE INDEX aged_hold_request_fulfillment_staff_idx ON action.aged_hold_request ( fulfillment_staff );
+
+CREATE OR REPLACE VIEW action.all_hold_request AS
+ SELECT DISTINCT
+ COALESCE(a.post_code, b.post_code) AS usr_post_code,
+ p.home_ou AS usr_home_ou,
+ p.profile AS usr_profile,
+ EXTRACT(YEAR FROM p.dob)::INT AS usr_birth_year,
+ CAST(ahr.requestor <> ahr.usr AS BOOLEAN) AS staff_placed,
+ ahr.id,
+ ahr.request_time,
+ ahr.capture_time,
+ ahr.fulfillment_time,
+ ahr.checkin_time,
+ ahr.return_time,
+ ahr.prev_check_time,
+ ahr.expire_time,
+ ahr.cancel_time,
+ ahr.cancel_cause,
+ ahr.cancel_note,
+ ahr.target,
+ ahr.current_copy,
+ ahr.fulfillment_staff,
+ ahr.fulfillment_lib,
+ ahr.request_lib,
+ ahr.selection_ou,
+ ahr.selection_depth,
+ ahr.pickup_lib,
+ ahr.hold_type,
+ ahr.holdable_formats,
+ CASE
+ WHEN ahr.phone_notify IS NULL THEN FALSE
+ WHEN ahr.phone_notify = '' THEN FALSE
+ ELSE TRUE
+ END AS phone_notify,
+ ahr.email_notify,
+ CASE
+ WHEN ahr.sms_notify IS NULL THEN FALSE
+ WHEN ahr.sms_notify = '' THEN FALSE
+ ELSE TRUE
+ END AS sms_notify,
+ ahr.frozen,
+ ahr.thaw_date,
+ ahr.shelf_time,
+ ahr.cut_in_line,
+ ahr.mint_condition,
+ ahr.shelf_expire_time,
+ ahr.current_shelf_lib
+ FROM action.hold_request ahr
+ JOIN actor.usr p ON (ahr.usr = p.id)
+ LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
+ LEFT JOIN actor.usr_address b ON (p.billing_address = b.id)
+ UNION ALL
+ SELECT
+ usr_post_code,
+ usr_home_ou,
+ usr_profile,
+ usr_birth_year,
+ staff_placed,
+ id,
+ request_time,
+ capture_time,
+ fulfillment_time,
+ checkin_time,
+ return_time,
+ prev_check_time,
+ expire_time,
+ cancel_time,
+ cancel_cause,
+ cancel_note,
+ target,
+ current_copy,
+ fulfillment_staff,
+ fulfillment_lib,
+ request_lib,
+ selection_ou,
+ selection_depth,
+ pickup_lib,
+ hold_type,
+ holdable_formats,
+ phone_notify,
+ email_notify,
+ sms_notify,
+ frozen,
+ thaw_date,
+ shelf_time,
+ cut_in_line,
+ mint_condition,
+ shelf_expire_time,
+ current_shelf_lib
+ FROM action.aged_hold_request;
+
+CREATE OR REPLACE FUNCTION action.age_hold_on_delete () RETURNS TRIGGER AS $$
+DECLARE
+BEGIN
+ -- Archive a copy of the old row to action.aged_hold_request
+
+ INSERT INTO action.aged_hold_request
+ (usr_post_code,
+ usr_home_ou,
+ usr_profile,
+ usr_birth_year,
+ staff_placed,
+ id,
+ request_time,
+ capture_time,
+ fulfillment_time,
+ checkin_time,
+ return_time,
+ prev_check_time,
+ expire_time,
+ cancel_time,
+ cancel_cause,
+ cancel_note,
+ target,
+ current_copy,
+ fulfillment_staff,
+ fulfillment_lib,
+ request_lib,
+ selection_ou,
+ selection_depth,
+ pickup_lib,
+ hold_type,
+ holdable_formats,
+ phone_notify,
+ email_notify,
+ sms_notify,
+ frozen,
+ thaw_date,
+ shelf_time,
+ cut_in_line,
+ mint_condition,
+ shelf_expire_time,
+ current_shelf_lib)
+ SELECT
+ usr_post_code,
+ usr_home_ou,
+ usr_profile,
+ usr_birth_year,
+ staff_placed,
+ id,
+ request_time,
+ capture_time,
+ fulfillment_time,
+ checkin_time,
+ return_time,
+ prev_check_time,
+ expire_time,
+ cancel_time,
+ cancel_cause,
+ cancel_note,
+ target,
+ current_copy,
+ fulfillment_staff,
+ fulfillment_lib,
+ request_lib,
+ selection_ou,
+ selection_depth,
+ pickup_lib,
+ hold_type,
+ holdable_formats,
+ phone_notify,
+ email_notify,
+ sms_notify,
+ frozen,
+ thaw_date,
+ shelf_time,
+ cut_in_line,
+ mint_condition,
+ shelf_expire_time,
+ current_shelf_lib
+ FROM action.all_hold_request WHERE id = OLD.id;
+
+ RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE TRIGGER action_hold_request_aging_tgr
+ BEFORE DELETE ON action.hold_request
+ FOR EACH ROW
+ EXECUTE PROCEDURE action.age_hold_on_delete ();
+
+
+
+-- allow state to be null
+ALTER TABLE actor.usr_address ALTER COLUMN state DROP NOT NULL;
+
+-- check whether patch can be applied
+
+-- check whether patch can be applied
+
+ALTER TABLE config.usr_setting_type
+ ADD COLUMN reg_default TEXT;
+
+
+ALTER TABLE actor.org_address ALTER COLUMN state DROP NOT NULL;
+
+
+-- Evergreen DB patch 0812.data.add_library_info_url_OUS.sql
+--
+-- Adds YAOUS for enabling information links from the TPAC to a library URL
+--
+
+-- check whether patch can be applied
+
+-- FIXME: add/check SQL statements to perform the upgrade
+
+-- Don't require state in the auditor tracking for user addresses
+
+ALTER TABLE auditor.actor_usr_address_history ALTER COLUMN state DROP NOT NULL;
+
+-- Change constraint on actor.org_unit_setting_log to be deferrable initially
+
+ALTER TABLE config.org_unit_setting_type_log
+ DROP CONSTRAINT org_unit_setting_type_log_field_name_fkey,
+ ADD CONSTRAINT org_unit_setting_type_log_field_name_fkey FOREIGN KEY (field_name)
+ REFERENCES config.org_unit_setting_type (name) MATCH SIMPLE
+ ON UPDATE NO ACTION ON DELETE NO ACTION DEFERRABLE INITIALLY DEFERRED;
+
+-- Fix names in the org unit setting configuration
+
+-- Fix names if they have already been set in the editor
+
+-- and the logs too
+
+-- check whether patch can be applied
+
+-- Given an authority record's ID, control set ID (if known), and marc::XML,
+-- return all links to other authority records in the form of rows that
+-- can be inserted into authority.authority_linking.
+CREATE OR REPLACE FUNCTION authority.calculate_authority_linking(
+ rec_id BIGINT, rec_control_set INT, rec_marc_xml XML
+) RETURNS SETOF authority.authority_linking AS $func$
+DECLARE
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ link TEXT;
+ aal authority.authority_linking%ROWTYPE;
+BEGIN
+ IF rec_control_set IS NULL THEN
+ -- No control_set on record? Guess at one
+ SELECT control_set INTO rec_control_set
+ FROM authority.control_set_authority_field
+ WHERE tag IN (
+ SELECT UNNEST(
+ XPATH('//*[starts-with(@tag,"1")]/@tag',rec_marc_xml::XML)::TEXT[]
+ )
+ ) LIMIT 1;
+
+ IF NOT FOUND THEN
+ RAISE WARNING 'Could not even guess at control set for authority record %', rec_id;
+ RETURN;
+ END IF;
+ END IF;
+
+ aal.source := rec_id;
+
+ FOR acsaf IN
+ SELECT * FROM authority.control_set_authority_field
+ WHERE control_set = rec_control_set
+ AND linking_subfield IS NOT NULL
+ AND main_entry IS NOT NULL
+ LOOP
+ link := SUBSTRING(
+ (XPATH('//*[@tag="' || acsaf.tag || '"]/*[@code="' ||
+ acsaf.linking_subfield || '"]/text()', rec_marc_xml))[1]::TEXT,
+ '\d+$'
+ );
+
+ -- Ignore links that are null, malformed, circular, or point to
+ -- non-existent authority records.
+ IF link IS NOT NULL AND link::BIGINT <> rec_id THEN
+ PERFORM * FROM authority.record_entry WHERE id = link::BIGINT;
+ IF FOUND THEN
+ aal.target := link::BIGINT;
+ aal.field := acsaf.id;
+ RETURN NEXT aal;
+ END IF;
+ END IF;
+ END LOOP;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+
+-- check whether patch can be applied
+
+-- NOTE: very IDs are still correct for perms and event_def data at merge.
+
+
+-- copy status
+
+
+-- checkin override perm
+
+
+-- billing types
+
+-- mark long-overdue reactor
+
+ALTER TABLE action.hold_request
+ ADD COLUMN behind_desk BOOLEAN NOT NULL DEFAULT FALSE;
+
+-- Track the requesting user
+ALTER TABLE staging.user_stage
+ ADD COLUMN requesting_usr INTEGER
+ REFERENCES actor.usr(id) ON DELETE SET NULL;
+
+-- add county column to staged address tables and
+-- drop state requirement to match actor.usr_address
+ALTER TABLE staging.mailing_address_stage
+ ADD COLUMN county TEXT,
+ ALTER COLUMN state DROP DEFAULT,
+ ALTER COLUMN state DROP NOT NULL;
+
+ALTER TABLE staging.billing_address_stage
+ ADD COLUMN county TEXT,
+ ALTER COLUMN state DROP DEFAULT,
+ ALTER COLUMN state DROP NOT NULL;
+
+-- stored procedure for deleting expired pending patrons
+CREATE OR REPLACE FUNCTION staging.purge_pending_users() RETURNS VOID AS $$
+DECLARE
+ org_id INT;
+ intvl TEXT;
+BEGIN
+ FOR org_id IN SELECT DISTINCT(home_ou) FROM staging.user_stage LOOP
+
+ SELECT INTO intvl value FROM
+ actor.org_unit_ancestor_setting(
+ 'opac.pending_user_expire_interval', org_id);
+
+ CONTINUE WHEN intvl IS NULL OR intvl ILIKE 'null';
+
+ -- de-JSON-ify the string
+ SELECT INTO intvl TRIM(BOTH '"' FROM intvl);
+
+ DELETE FROM staging.user_stage
+ WHERE home_ou = org_id AND row_date + intvl::INTERVAL < NOW();
+
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+
+CREATE OR REPLACE FUNCTION vandelay.ingest_items ( import_id BIGINT, attr_def_id BIGINT ) RETURNS SETOF vandelay.import_item AS $$
+DECLARE
+
+ owning_lib TEXT;
+ circ_lib TEXT;
+ call_number TEXT;
+ copy_number TEXT;
+ status TEXT;
+ location TEXT;
+ circulate TEXT;
+ deposit TEXT;
+ deposit_amount TEXT;
+ ref TEXT;
+ holdable TEXT;
+ price TEXT;
+ barcode TEXT;
+ circ_modifier TEXT;
+ circ_as_type TEXT;
+ alert_message TEXT;
+ opac_visible TEXT;
+ pub_note TEXT;
+ priv_note TEXT;
+ internal_id TEXT;
+
+ attr_def RECORD;
+ tmp_attr_set RECORD;
+ attr_set vandelay.import_item%ROWTYPE;
+
+ xpath TEXT;
+ tmp_str TEXT;
+
+BEGIN
+
+ SELECT * INTO attr_def FROM vandelay.import_item_attr_definition WHERE id = attr_def_id;
+
+ IF FOUND THEN
+
+ attr_set.definition := attr_def.id;
+
+ -- Build the combined XPath
+
+ owning_lib :=
+ CASE
+ WHEN attr_def.owning_lib IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.owning_lib ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.owning_lib || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.owning_lib
+ END;
+
+ circ_lib :=
+ CASE
+ WHEN attr_def.circ_lib IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.circ_lib ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.circ_lib || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.circ_lib
+ END;
+
+ call_number :=
+ CASE
+ WHEN attr_def.call_number IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.call_number ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.call_number || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.call_number
+ END;
+
+ copy_number :=
+ CASE
+ WHEN attr_def.copy_number IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.copy_number ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.copy_number || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.copy_number
+ END;
+
+ status :=
+ CASE
+ WHEN attr_def.status IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.status ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.status || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.status
+ END;
+
+ location :=
+ CASE
+ WHEN attr_def.location IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.location ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.location || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.location
+ END;
+
+ circulate :=
+ CASE
+ WHEN attr_def.circulate IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.circulate ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.circulate || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.circulate
+ END;
+
+ deposit :=
+ CASE
+ WHEN attr_def.deposit IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.deposit ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.deposit || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.deposit
+ END;
+
+ deposit_amount :=
+ CASE
+ WHEN attr_def.deposit_amount IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.deposit_amount ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.deposit_amount || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.deposit_amount
+ END;
+
+ ref :=
+ CASE
+ WHEN attr_def.ref IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.ref ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.ref || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.ref
+ END;
+
+ holdable :=
+ CASE
+ WHEN attr_def.holdable IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.holdable ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.holdable || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.holdable
+ END;
+
+ price :=
+ CASE
+ WHEN attr_def.price IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.price ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.price || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.price
+ END;
+
+ barcode :=
+ CASE
+ WHEN attr_def.barcode IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.barcode ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.barcode || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.barcode
+ END;
+
+ circ_modifier :=
+ CASE
+ WHEN attr_def.circ_modifier IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.circ_modifier ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.circ_modifier || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.circ_modifier
+ END;
+
+ circ_as_type :=
+ CASE
+ WHEN attr_def.circ_as_type IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.circ_as_type ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.circ_as_type || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.circ_as_type
+ END;
+
+ alert_message :=
+ CASE
+ WHEN attr_def.alert_message IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.alert_message ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.alert_message || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.alert_message
+ END;
+
+ opac_visible :=
+ CASE
+ WHEN attr_def.opac_visible IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.opac_visible ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.opac_visible || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.opac_visible
+ END;
+
+ pub_note :=
+ CASE
+ WHEN attr_def.pub_note IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.pub_note ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.pub_note || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.pub_note
+ END;
+ priv_note :=
+ CASE
+ WHEN attr_def.priv_note IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.priv_note ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.priv_note || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.priv_note
+ END;
+
+ internal_id :=
+ CASE
+ WHEN attr_def.internal_id IS NULL THEN 'null()'
+ WHEN LENGTH( attr_def.internal_id ) = 1 THEN '//*[@tag="' || attr_def.tag || '"]/*[@code="' || attr_def.internal_id || '"]'
+ ELSE '//*[@tag="' || attr_def.tag || '"]/*' || attr_def.internal_id
+ END;
+
+
+
+ xpath :=
+ owning_lib || '|' ||
+ circ_lib || '|' ||
+ call_number || '|' ||
+ copy_number || '|' ||
+ status || '|' ||
+ location || '|' ||
+ circulate || '|' ||
+ deposit || '|' ||
+ deposit_amount || '|' ||
+ ref || '|' ||
+ holdable || '|' ||
+ price || '|' ||
+ barcode || '|' ||
+ circ_modifier || '|' ||
+ circ_as_type || '|' ||
+ alert_message || '|' ||
+ pub_note || '|' ||
+ priv_note || '|' ||
+ internal_id || '|' ||
+ opac_visible;
+
+ FOR tmp_attr_set IN
+ SELECT *
+ FROM oils_xpath_table( 'id', 'marc', 'vandelay.queued_bib_record', xpath, 'id = ' || import_id )
+ AS t( id INT, ol TEXT, clib TEXT, cn TEXT, cnum TEXT, cs TEXT, cl TEXT, circ TEXT,
+ dep TEXT, dep_amount TEXT, r TEXT, hold TEXT, pr TEXT, bc TEXT, circ_mod TEXT,
+ circ_as TEXT, amessage TEXT, note TEXT, pnote TEXT, internal_id TEXT, opac_vis TEXT )
+ LOOP
+
+ attr_set.import_error := NULL;
+ attr_set.error_detail := NULL;
+ attr_set.deposit_amount := NULL;
+ attr_set.copy_number := NULL;
+ attr_set.price := NULL;
+ attr_set.circ_modifier := NULL;
+ attr_set.location := NULL;
+ attr_set.barcode := NULL;
+ attr_set.call_number := NULL;
+
+ IF tmp_attr_set.pr != '' THEN
+ tmp_str = REGEXP_REPLACE(tmp_attr_set.pr, E'[^0-9\\.]', '', 'g');
+ IF tmp_str = '' THEN
+ attr_set.import_error := 'import.item.invalid.price';
+ attr_set.error_detail := tmp_attr_set.pr; -- original value
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ attr_set.price := tmp_str::NUMERIC(8,2);
+ END IF;
+
+ IF tmp_attr_set.dep_amount != '' THEN
+ tmp_str = REGEXP_REPLACE(tmp_attr_set.dep_amount, E'[^0-9\\.]', '', 'g');
+ IF tmp_str = '' THEN
+ attr_set.import_error := 'import.item.invalid.deposit_amount';
+ attr_set.error_detail := tmp_attr_set.dep_amount;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ attr_set.deposit_amount := tmp_str::NUMERIC(8,2);
+ END IF;
+
+ IF tmp_attr_set.cnum != '' THEN
+ tmp_str = REGEXP_REPLACE(tmp_attr_set.cnum, E'[^0-9]', '', 'g');
+ IF tmp_str = '' THEN
+ attr_set.import_error := 'import.item.invalid.copy_number';
+ attr_set.error_detail := tmp_attr_set.cnum;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ attr_set.copy_number := tmp_str::INT;
+ END IF;
+
+ IF tmp_attr_set.ol != '' THEN
+ SELECT id INTO attr_set.owning_lib FROM actor.org_unit WHERE shortname = UPPER(tmp_attr_set.ol); -- INT
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.owning_lib';
+ attr_set.error_detail := tmp_attr_set.ol;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ IF tmp_attr_set.clib != '' THEN
+ SELECT id INTO attr_set.circ_lib FROM actor.org_unit WHERE shortname = UPPER(tmp_attr_set.clib); -- INT
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.circ_lib';
+ attr_set.error_detail := tmp_attr_set.clib;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ IF tmp_attr_set.cs != '' THEN
+ SELECT id INTO attr_set.status FROM config.copy_status WHERE LOWER(name) = LOWER(tmp_attr_set.cs); -- INT
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.status';
+ attr_set.error_detail := tmp_attr_set.cs;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ IF COALESCE(tmp_attr_set.circ_mod, '') = '' THEN
+
+ -- no circ mod defined, see if we should apply a default
+ SELECT INTO attr_set.circ_modifier TRIM(BOTH '"' FROM value)
+ FROM actor.org_unit_ancestor_setting(
+ 'vandelay.item.circ_modifier.default',
+ attr_set.owning_lib
+ );
+
+ -- make sure the value from the org setting is still valid
+ PERFORM 1 FROM config.circ_modifier WHERE code = attr_set.circ_modifier;
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.circ_modifier';
+ attr_set.error_detail := tmp_attr_set.circ_mod;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+
+ ELSE
+
+ SELECT code INTO attr_set.circ_modifier FROM config.circ_modifier WHERE code = tmp_attr_set.circ_mod;
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.circ_modifier';
+ attr_set.error_detail := tmp_attr_set.circ_mod;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ IF tmp_attr_set.circ_as != '' THEN
+ SELECT code INTO attr_set.circ_as_type FROM config.coded_value_map WHERE ctype = 'item_type' AND code = tmp_attr_set.circ_as;
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.circ_as_type';
+ attr_set.error_detail := tmp_attr_set.circ_as;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ IF COALESCE(tmp_attr_set.cl, '') = '' THEN
+ -- no location specified, see if we should apply a default
+
+ SELECT INTO attr_set.location TRIM(BOTH '"' FROM value)
+ FROM actor.org_unit_ancestor_setting(
+ 'vandelay.item.copy_location.default',
+ attr_set.owning_lib
+ );
+
+ -- make sure the value from the org setting is still valid
+ PERFORM 1 FROM asset.copy_location WHERE id = attr_set.location;
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.location';
+ attr_set.error_detail := tmp_attr_set.cs;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ ELSE
+
+ -- search up the org unit tree for a matching copy location
+ WITH RECURSIVE anscestor_depth AS (
+ SELECT ou.id,
+ out.depth AS depth,
+ ou.parent_ou
+ FROM actor.org_unit ou
+ JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+ WHERE ou.id = COALESCE(attr_set.owning_lib, attr_set.circ_lib)
+ UNION ALL
+ SELECT ou.id,
+ out.depth,
+ ou.parent_ou
+ FROM actor.org_unit ou
+ JOIN actor.org_unit_type out ON (out.id = ou.ou_type)
+ JOIN anscestor_depth ot ON (ot.parent_ou = ou.id)
+ ) SELECT cpl.id INTO attr_set.location
+ FROM anscestor_depth a
+ JOIN asset.copy_location cpl ON (cpl.owning_lib = a.id)
+ WHERE LOWER(cpl.name) = LOWER(tmp_attr_set.cl)
+ ORDER BY a.depth DESC
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ attr_set.import_error := 'import.item.invalid.location';
+ attr_set.error_detail := tmp_attr_set.cs;
+ RETURN NEXT attr_set; CONTINUE;
+ END IF;
+ END IF;
+
+ attr_set.circulate :=
+ LOWER( SUBSTRING( tmp_attr_set.circ, 1, 1)) IN ('t','y','1')
+ OR LOWER(tmp_attr_set.circ) = 'circulating'; -- BOOL
+
+ attr_set.deposit :=
+ LOWER( SUBSTRING( tmp_attr_set.dep, 1, 1 ) ) IN ('t','y','1')
+ OR LOWER(tmp_attr_set.dep) = 'deposit'; -- BOOL
+
+ attr_set.holdable :=
+ LOWER( SUBSTRING( tmp_attr_set.hold, 1, 1 ) ) IN ('t','y','1')
+ OR LOWER(tmp_attr_set.hold) = 'holdable'; -- BOOL
+
+ attr_set.opac_visible :=
+ LOWER( SUBSTRING( tmp_attr_set.opac_vis, 1, 1 ) ) IN ('t','y','1')
+ OR LOWER(tmp_attr_set.opac_vis) = 'visible'; -- BOOL
+
+ attr_set.ref :=
+ LOWER( SUBSTRING( tmp_attr_set.r, 1, 1 ) ) IN ('t','y','1')
+ OR LOWER(tmp_attr_set.r) = 'reference'; -- BOOL
+
+ attr_set.call_number := tmp_attr_set.cn; -- TEXT
+ attr_set.barcode := tmp_attr_set.bc; -- TEXT,
+ attr_set.alert_message := tmp_attr_set.amessage; -- TEXT,
+ attr_set.pub_note := tmp_attr_set.note; -- TEXT,
+ attr_set.priv_note := tmp_attr_set.pnote; -- TEXT,
+ attr_set.alert_message := tmp_attr_set.amessage; -- TEXT,
+ attr_set.internal_id := tmp_attr_set.internal_id::BIGINT;
+
+ RETURN NEXT attr_set;
+
+ END LOOP;
+
+ END IF;
+
+ RETURN;
+
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+--
+-- Adds a setting for selecting the number of items per page of a my list.
+--
+
+-- check whether patch can be applied
+
+-- Adds a setting for selecting the number of lists per page for my list.
+--
+
+-- check whether patch can be applied
+
+
+CREATE OR REPLACE FUNCTION actor.calculate_system_penalties( match_user INT, context_org INT ) RETURNS SETOF actor.usr_standing_penalty AS $func$
+DECLARE
+ user_object actor.usr%ROWTYPE;
+ new_sp_row actor.usr_standing_penalty%ROWTYPE;
+ existing_sp_row actor.usr_standing_penalty%ROWTYPE;
+ collections_fines permission.grp_penalty_threshold%ROWTYPE;
+ max_fines permission.grp_penalty_threshold%ROWTYPE;
+ max_overdue permission.grp_penalty_threshold%ROWTYPE;
+ max_items_out permission.grp_penalty_threshold%ROWTYPE;
+ max_lost permission.grp_penalty_threshold%ROWTYPE;
+ max_longoverdue permission.grp_penalty_threshold%ROWTYPE;
+ tmp_grp INT;
+ items_overdue INT;
+ items_out INT;
+ items_lost INT;
+ items_longoverdue INT;
+ context_org_list INT[];
+ current_fines NUMERIC(8,2) := 0.0;
+ tmp_fines NUMERIC(8,2);
+ tmp_groc RECORD;
+ tmp_circ RECORD;
+ tmp_org actor.org_unit%ROWTYPE;
+ tmp_penalty config.standing_penalty%ROWTYPE;
+ tmp_depth INTEGER;
+BEGIN
+ SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+ -- Max fines
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has a high fine balance
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 1 AND org_unit = tmp_org.id;
+
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 1;
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND xact_finish IS NULL ) l USING (id);
+
+ IF current_fines >= max_fines.threshold THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_fines.org_unit;
+ new_sp_row.standing_penalty := 1;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max overdue
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many overdue items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+
+ SELECT * INTO max_overdue FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 2 AND org_unit = tmp_org.id;
+
+ IF max_overdue.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_overdue.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_overdue.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_overdue.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 2;
+
+ SELECT INTO items_overdue COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_overdue.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND circ.due_date < NOW()
+ AND (circ.stop_fines = 'MAXFINES' OR circ.stop_fines IS NULL);
+
+ IF items_overdue >= max_overdue.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_overdue.org_unit;
+ new_sp_row.standing_penalty := 2;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max out
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many checked out items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_items_out FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 3 AND org_unit = tmp_org.id;
+
+ IF max_items_out.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_items_out.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+
+ -- Fail if the user has too many items checked out
+ IF max_items_out.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_items_out.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 3;
+
+ SELECT INTO items_out COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_items_out.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND (circ.stop_fines IN (
+ SELECT 'MAXFINES'::TEXT
+ UNION ALL
+ SELECT 'LONGOVERDUE'::TEXT
+ UNION ALL
+ SELECT 'LOST'::TEXT
+ WHERE 'true' ILIKE
+ (
+ SELECT CASE
+ WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.tally_lost', circ.circ_lib)) ILIKE 'true' THEN 'true'
+ ELSE 'false'
+ END
+ )
+ UNION ALL
+ SELECT 'CLAIMSRETURNED'::TEXT
+ WHERE 'false' ILIKE
+ (
+ SELECT CASE
+ WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.do_not_tally_claims_returned', circ.circ_lib)) ILIKE 'true' THEN 'true'
+ ELSE 'false'
+ END
+ )
+ ) OR circ.stop_fines IS NULL)
+ AND xact_finish IS NULL;
+
+ IF items_out >= max_items_out.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_items_out.org_unit;
+ new_sp_row.standing_penalty := 3;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max lost
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many lost items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+
+ SELECT * INTO max_lost FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 5 AND org_unit = tmp_org.id;
+
+ IF max_lost.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_lost.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_lost.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_lost.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 5;
+
+ SELECT INTO items_lost COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_lost.org_unit ) fp ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND (circ.stop_fines = 'LOST')
+ AND xact_finish IS NULL;
+
+ IF items_lost >= max_lost.threshold::INT AND 0 < max_lost.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_lost.org_unit;
+ new_sp_row.standing_penalty := 5;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for max longoverdue
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has too many longoverdue items
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+
+ SELECT * INTO max_longoverdue
+ FROM permission.grp_penalty_threshold
+ WHERE grp = tmp_grp AND
+ penalty = 35 AND
+ org_unit = tmp_org.id;
+
+ IF max_longoverdue.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp
+ FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_longoverdue.threshold IS NOT NULL
+ OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_longoverdue.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_longoverdue.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 35;
+
+ SELECT INTO items_longoverdue COUNT(*)
+ FROM action.circulation circ
+ JOIN actor.org_unit_full_path( max_longoverdue.org_unit ) fp
+ ON (circ.circ_lib = fp.id)
+ WHERE circ.usr = match_user
+ AND circ.checkin_time IS NULL
+ AND (circ.stop_fines = 'LONGOVERDUE')
+ AND xact_finish IS NULL;
+
+ IF items_longoverdue >= max_longoverdue.threshold::INT
+ AND 0 < max_longoverdue.threshold::INT THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_longoverdue.org_unit;
+ new_sp_row.standing_penalty := 35;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+
+ -- Start over for collections warning
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Fail if the user has a collections-level fine balance
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 4 AND org_unit = tmp_org.id;
+
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 4;
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND r.xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND g.xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND circ.xact_finish IS NULL ) l USING (id);
+
+ IF current_fines >= max_fines.threshold THEN
+ new_sp_row.usr := match_user;
+ new_sp_row.org_unit := max_fines.org_unit;
+ new_sp_row.standing_penalty := 4;
+ RETURN NEXT new_sp_row;
+ END IF;
+ END IF;
+
+ -- Start over for in collections
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+
+ -- Remove the in-collections penalty if the user has paid down enough
+ -- This penalty is different, because this code is not responsible for creating
+ -- new in-collections penalties, only for removing them
+ LOOP
+ tmp_grp := user_object.profile;
+ LOOP
+ SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 30 AND org_unit = tmp_org.id;
+
+ IF max_fines.threshold IS NULL THEN
+ SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp;
+ ELSE
+ EXIT;
+ END IF;
+
+ IF tmp_grp IS NULL THEN
+ EXIT;
+ END IF;
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+
+ END LOOP;
+
+ IF max_fines.threshold IS NOT NULL THEN
+
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( max_fines.org_unit );
+
+ -- first, see if the user had paid down to the threshold
+ SELECT SUM(f.balance_owed) INTO current_fines
+ FROM money.materialized_billable_xact_summary f
+ JOIN (
+ SELECT r.id
+ FROM booking.reservation r
+ WHERE r.usr = match_user
+ AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list))
+ AND r.xact_finish IS NULL
+ UNION ALL
+ SELECT g.id
+ FROM money.grocery g
+ WHERE g.usr = match_user
+ AND g.billing_location IN (SELECT * FROM unnest(context_org_list))
+ AND g.xact_finish IS NULL
+ UNION ALL
+ SELECT circ.id
+ FROM action.circulation circ
+ WHERE circ.usr = match_user
+ AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list))
+ AND circ.xact_finish IS NULL ) l USING (id);
+
+ IF current_fines IS NULL OR current_fines <= max_fines.threshold THEN
+ -- patron has paid down enough
+
+ SELECT INTO tmp_penalty * FROM config.standing_penalty WHERE id = 30;
+
+ IF tmp_penalty.org_depth IS NOT NULL THEN
+
+ -- since this code is not responsible for applying the penalty, it can't
+ -- guarantee the current context org will match the org at which the penalty
+ --- was applied. search up the org tree until we hit the configured penalty depth
+ SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org;
+ SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+
+ WHILE tmp_depth >= tmp_penalty.org_depth LOOP
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = tmp_org.id
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 30;
+
+ IF tmp_org.parent_ou IS NULL THEN
+ EXIT;
+ END IF;
+
+ SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou;
+ SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type;
+ END LOOP;
+
+ ELSE
+
+ -- no penalty depth is defined, look for exact matches
+
+ RETURN QUERY
+ SELECT *
+ FROM actor.usr_standing_penalty
+ WHERE usr = match_user
+ AND org_unit = max_fines.org_unit
+ AND (stop_date IS NULL or stop_date > NOW())
+ AND standing_penalty = 30;
+ END IF;
+
+ END IF;
+
+ END IF;
+
+ RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+
+
+
+ALTER TABLE serial.subscription_note
+ ADD COLUMN alert BOOL NOT NULL DEFAULT FALSE;
+
+ALTER TABLE serial.distribution_note
+ ADD COLUMN alert BOOL NOT NULL DEFAULT FALSE;
+
+ALTER TABLE serial.item_note
+ ADD COLUMN alert BOOL NOT NULL DEFAULT FALSE;
+
+
+
+
+CREATE TABLE config.floating_group (
+ id SERIAL PRIMARY KEY,
+ name TEXT UNIQUE NOT NULL,
+ manual BOOL NOT NULL DEFAULT FALSE
+ );
+
+CREATE TABLE config.floating_group_member (
+ id SERIAL PRIMARY KEY,
+ floating_group INT NOT NULL REFERENCES config.floating_group (id),
+ org_unit INT NOT NULL REFERENCES actor.org_unit (id),
+ stop_depth INT NOT NULL DEFAULT 0,
+ max_depth INT,
+ exclude BOOL NOT NULL DEFAULT FALSE
+ );
+
+CREATE OR REPLACE FUNCTION evergreen.can_float( copy_floating_group integer, from_ou integer, to_ou integer ) RETURNS BOOL AS $f$
+DECLARE
+ float_member config.floating_group_member%ROWTYPE;
+ shared_ou_depth INT;
+ to_ou_depth INT;
+BEGIN
+ -- Grab the shared OU depth. If this is less than the stop depth later we ignore the entry.
+ SELECT INTO shared_ou_depth max(depth) FROM actor.org_unit_common_ancestors( from_ou, to_ou ) aou JOIN actor.org_unit_type aout ON aou.ou_type = aout.id;
+ -- Grab the to ou depth. If this is greater than max depth we ignore the entry.
+ SELECT INTO to_ou_depth depth FROM actor.org_unit aou JOIN actor.org_unit_type aout ON aou.ou_type = aout.id WHERE aou.id = to_ou;
+ -- Grab float members that apply. We don't care what we get beyond wanting excluded ones first.
+ SELECT INTO float_member *
+ FROM
+ config.floating_group_member cfgm
+ JOIN actor.org_unit aou ON cfgm.org_unit = aou.id
+ JOIN actor.org_unit_type aout ON aou.ou_type = aout.id
+ WHERE
+ cfgm.floating_group = copy_floating_group
+ AND to_ou IN (SELECT id FROM actor.org_unit_descendants(aou.id))
+ AND cfgm.stop_depth <= shared_ou_depth
+ AND (cfgm.max_depth IS NULL OR to_ou_depth <= max_depth)
+ ORDER BY
+ exclude DESC;
+ -- If we found something then we want to return the opposite of the exclude flag
+ IF FOUND THEN
+ RETURN NOT float_member.exclude;
+ END IF;
+ -- Otherwise no floating.
+ RETURN false;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+-- We need to drop these before we can update asset.copy
+DROP VIEW auditor.asset_copy_lifecycle;
+DROP VIEW auditor.serial_unit_lifecycle;
+
+-- Update the appropriate auditor tables
+ALTER TABLE auditor.asset_copy_history
+ ALTER COLUMN floating DROP DEFAULT,
+ ALTER COLUMN floating DROP NOT NULL,
+ ALTER COLUMN floating TYPE int USING CASE WHEN floating THEN 1 ELSE NULL END;
+ALTER TABLE auditor.serial_unit_history
+ ALTER COLUMN floating DROP DEFAULT,
+ ALTER COLUMN floating DROP NOT NULL,
+ ALTER COLUMN floating TYPE int USING CASE WHEN floating THEN 1 ELSE NULL END;
+
+-- KCLS: to update asset.copy, we have to drop/recreate local view
+DROP VIEW stats.fleshed_circulation;
+DROP VIEW stats.fleshed_copy;
+
+-- Update asset.copy itself (does not appear to trigger update triggers!)
+ALTER TABLE asset.copy
+ ALTER COLUMN floating DROP DEFAULT,
+ ALTER COLUMN floating DROP NOT NULL,
+ ALTER COLUMN floating TYPE int USING CASE WHEN floating THEN 1 ELSE NULL END;
+
+ALTER TABLE asset.copy ADD CONSTRAINT asset_copy_floating_fkey FOREIGN KEY (floating) REFERENCES config.floating_group (id) DEFERRABLE INITIALLY DEFERRED;
+
+-- KCLS: rebuild the view from above
+CREATE VIEW stats.fleshed_copy AS
+ SELECT cp.id, cp.circ_lib, cp.creator, cp.call_number, cp.editor, cp.create_date, cp.edit_date, cp.copy_number, cp.status, cp.location, cp.loan_duration, cp.fine_level, cp.age_protect, cp.circulate, cp.deposit, cp.ref, cp.holdable, cp.deposit_amount, cp.price, cp.barcode, cp.circ_modifier, cp.circ_as_type, cp.dummy_title, cp.dummy_author, cp.alert_message, cp.opac_visible, cp.deleted, cp.floating, cp.dummy_isbn, cp.status_changed_time, cp.mint_condition, cp.cost, (cp.create_date)::date AS create_date_day, (cp.edit_date)::date AS edit_date_day, date_trunc('hour'::text, cp.create_date) AS create_date_hour, date_trunc('hour'::text, cp.edit_date) AS edit_date_hour, cn.label AS call_number_label, cn.owning_lib, rd.item_lang, rd.item_type, rd.item_form FROM ((asset.copy cp JOIN asset.call_number cn ON ((cp.call_number = cn.id))) JOIN metabib.rec_descriptor rd ON ((rd.record = cn.record)));
+
+CREATE VIEW stats.fleshed_circulation AS
+ SELECT c.id, c.usr, c.xact_start, c.xact_finish, c.unrecovered, c.target_copy, c.circ_lib, c.circ_staff, c.checkin_staff, c.checkin_lib, c.renewal_remaining, c.due_date, c.stop_fines_time, c.checkin_time, c.create_time, c.duration, c.fine_interval, c.recurring_fine, c.max_fine, c.phone_renewal, c.desk_renewal, c.opac_renewal, c.duration_rule, c.recurring_fine_rule, c.max_fine_rule, c.stop_fines, c.workstation, c.checkin_workstation, c.checkin_scan_time, c.parent_circ, c.grace_period, (c.xact_start)::date AS start_date_day, (c.xact_finish)::date AS finish_date_day, date_trunc('hour'::text, c.xact_start) AS start_date_hour, date_trunc('hour'::text, c.xact_finish) AS finish_date_hour, cp.call_number_label, cp.owning_lib, cp.item_lang, cp.item_type, cp.item_form FROM (action.circulation c JOIN stats.fleshed_copy cp ON ((cp.id = c.target_copy)));
+
+-- Update asset.copy_template too
+ALTER TABLE asset.copy_template
+ ALTER COLUMN floating TYPE int USING CASE WHEN floating THEN 1 ELSE NULL END;
+ALTER TABLE asset.copy_template ADD CONSTRAINT asset_copy_template_floating_fkey FOREIGN KEY (floating) REFERENCES config.floating_group (id) DEFERRABLE INITIALLY DEFERRED;
+
+-- And lets just update all auditors to re-create those lifecycle views
+SELECT auditor.update_auditors();
+
+-- Evergreen DB patch 0837.schema.browse-auth-linking.plus-joiner.sql
+--
+-- In this upgrade script we complete inter-subfield joiner support, so that
+-- subject components can be separated by " -- ", for instance. That's the
+-- easy part.
+--
+-- We also add the ability to browse by in-use authority main entries and find
+-- bibs that use unauthorized versions of the authority's value, by string matching.
+--
+
+
+-- check whether patch can be applied
+
+CREATE OR REPLACE FUNCTION authority.normalize_heading( marcxml TEXT, no_thesaurus BOOL ) RETURNS TEXT AS $func$
+DECLARE
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ tag_used TEXT;
+ nfi_used TEXT;
+ sf TEXT;
+ sf_node TEXT;
+ tag_node TEXT;
+ thes_code TEXT;
+ cset INT;
+ heading_text TEXT;
+ tmp_text TEXT;
+ first_sf BOOL;
+ auth_id INT DEFAULT oils_xpath_string('//*[@tag="901"]/*[local-name()="subfield" and @code="c"]', marcxml)::INT;
+BEGIN
+ SELECT control_set INTO cset FROM authority.record_entry WHERE id = auth_id;
+
+ IF cset IS NULL THEN
+ SELECT control_set INTO cset
+ FROM authority.control_set_authority_field
+ WHERE tag IN ( SELECT UNNEST(XPATH('//*[starts-with(@tag,"1")]/@tag',marcxml::XML)::TEXT[]))
+ LIMIT 1;
+ END IF;
+
+ thes_code := vandelay.marc21_extract_fixed_field(marcxml,'Subj');
+ IF thes_code IS NULL THEN
+ thes_code := '|';
+ ELSIF thes_code = 'z' THEN
+ thes_code := COALESCE( oils_xpath_string('//*[@tag="040"]/*[@code="f"][1]', marcxml), '' );
+ END IF;
+
+ heading_text := '';
+ FOR acsaf IN SELECT * FROM authority.control_set_authority_field WHERE control_set = cset AND main_entry IS NULL LOOP
+ tag_used := acsaf.tag;
+ nfi_used := acsaf.nfi;
+ first_sf := TRUE;
+
+ FOR tag_node IN SELECT unnest(oils_xpath('//*[@tag="'||tag_used||'"]',marcxml)) LOOP
+ FOR sf_node IN SELECT unnest(oils_xpath('./*[contains("'||acsaf.sf_list||'",@code)]',tag_node)) LOOP
+
+ tmp_text := oils_xpath_string('.', sf_node);
+ sf := oils_xpath_string('./@code', sf_node);
+
+ IF first_sf AND tmp_text IS NOT NULL AND nfi_used IS NOT NULL THEN
+
+ tmp_text := SUBSTRING(
+ tmp_text FROM
+ COALESCE(
+ NULLIF(
+ REGEXP_REPLACE(
+ oils_xpath_string('./@ind'||nfi_used, tag_node),
+ $$\D+$$,
+ '',
+ 'g'
+ ),
+ ''
+ )::INT,
+ 0
+ ) + 1
+ );
+
+ END IF;
+
+ first_sf := FALSE;
+
+ IF tmp_text IS NOT NULL AND tmp_text <> '' THEN
+ heading_text := heading_text || E'\u2021' || sf || ' ' || tmp_text;
+ END IF;
+ END LOOP;
+
+ EXIT WHEN heading_text <> '';
+ END LOOP;
+
+ EXIT WHEN heading_text <> '';
+ END LOOP;
+
+ IF heading_text <> '' THEN
+ IF no_thesaurus IS TRUE THEN
+ heading_text := tag_used || ' ' || public.naco_normalize(heading_text);
+ ELSE
+ heading_text := tag_used || '_' || COALESCE(nfi_used,'-') || '_' || thes_code || ' ' || public.naco_normalize(heading_text);
+ END IF;
+ ELSE
+ heading_text := 'NOHEADING_' || thes_code || ' ' || MD5(marcxml);
+ END IF;
+
+ RETURN heading_text;
+END;
+$func$ LANGUAGE PLPGSQL IMMUTABLE;
+
+COMMENT ON FUNCTION authority.normalize_heading(marcxml text) IS '
+Extract the authority heading, thesaurus, and NACO-normalized values
+from an authority record. The primary purpose is to build a unique
+index to defend against duplicated authority records from the same
+thesaurus.
+';
+
+CREATE OR REPLACE FUNCTION authority.simple_heading_set( marcxml TEXT ) RETURNS SETOF authority.simple_heading AS $func$
+DECLARE
+ res authority.simple_heading%ROWTYPE;
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ tag_used TEXT;
+ nfi_used TEXT;
+ sf TEXT;
+ cset INT;
+ heading_text TEXT;
+ joiner_text TEXT;
+ sort_text TEXT;
+ tmp_text TEXT;
+ tmp_xml TEXT;
+ first_sf BOOL;
+ auth_id INT DEFAULT COALESCE(NULLIF(oils_xpath_string('//*[@tag="901"]/*[local-name()="subfield" and @code="c"]', marcxml), ''), '0')::INT;
+BEGIN
+
+ SELECT control_set INTO cset FROM authority.record_entry WHERE id = auth_id;
+
+ IF cset IS NULL THEN
+ SELECT control_set INTO cset
+ FROM authority.control_set_authority_field
+ WHERE tag IN ( SELECT UNNEST(XPATH('//*[starts-with(@tag,"1")]/@tag',marcxml::XML)::TEXT[]))
+ LIMIT 1;
+ END IF;
+
+ res.record := auth_id;
+
+ FOR acsaf IN SELECT * FROM authority.control_set_authority_field WHERE control_set = cset LOOP
+
+ res.atag := acsaf.id;
+ tag_used := acsaf.tag;
+ nfi_used := acsaf.nfi;
+ joiner_text := COALESCE(acsaf.joiner, ' ');
+
+ FOR tmp_xml IN SELECT UNNEST(XPATH('//*[@tag="'||tag_used||'"]', marcxml::XML)) LOOP
+
+ heading_text := COALESCE(
+ oils_xpath_string('./*[contains("'||acsaf.sf_list||'",@code)]', tmp_xml::TEXT, joiner_text),
+ ''
+ );
+
+ IF nfi_used IS NOT NULL THEN
+
+ sort_text := SUBSTRING(
+ heading_text FROM
+ COALESCE(
+ NULLIF(
+ REGEXP_REPLACE(
+ oils_xpath_string('./@ind'||nfi_used, tmp_xml::TEXT),
+ $$\D+$$,
+ '',
+ 'g'
+ ),
+ ''
+ )::INT,
+ 0
+ ) + 1
+ );
+
+ ELSE
+ sort_text := heading_text;
+ END IF;
+
+ IF heading_text IS NOT NULL AND heading_text <> '' THEN
+ res.value := heading_text;
+ res.sort_value := public.naco_normalize(sort_text);
+ res.index_vector = to_tsvector('keyword'::regconfig, res.sort_value);
+ RETURN NEXT res;
+ END IF;
+
+ END LOOP;
+
+ END LOOP;
+
+ RETURN;
+END;
+$func$ LANGUAGE PLPGSQL IMMUTABLE;
+
+CREATE TABLE metabib.browse_entry_simple_heading_map (
+ id BIGSERIAL PRIMARY KEY,
+ entry BIGINT REFERENCES metabib.browse_entry (id),
+ simple_heading BIGINT REFERENCES authority.simple_heading (id) ON DELETE CASCADE
+);
+CREATE INDEX browse_entry_sh_map_entry_idx ON metabib.browse_entry_simple_heading_map (entry);
+CREATE INDEX browse_entry_sh_map_sh_idx ON metabib.browse_entry_simple_heading_map (simple_heading);
+
+CREATE OR REPLACE
+ FUNCTION metabib.autosuggest_prepare_tsquery(orig TEXT) RETURNS TEXT[] AS
+$$
+DECLARE
+ orig_ended_in_space BOOLEAN;
+ result RECORD;
+ plain TEXT;
+ normalized TEXT;
+BEGIN
+ orig_ended_in_space := orig ~ E'\\s$';
+
+ orig := ARRAY_TO_STRING(
+ evergreen.regexp_split_to_array(orig, E'\\W+'), ' '
+ );
+
+ normalized := public.naco_normalize(orig); -- also trim()s
+ plain := trim(orig);
+
+ IF NOT orig_ended_in_space THEN
+ plain := plain || ':*';
+ normalized := normalized || ':*';
+ END IF;
+
+ plain := ARRAY_TO_STRING(
+ evergreen.regexp_split_to_array(plain, E'\\s+'), ' & '
+ );
+ normalized := ARRAY_TO_STRING(
+ evergreen.regexp_split_to_array(normalized, E'\\s+'), ' & '
+ );
+
+ RETURN ARRAY[normalized, plain];
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION metabib.browse_bib_pivot(
+ INT[],
+ TEXT
+) RETURNS BIGINT AS $p$
+ SELECT mbe.id
+ FROM metabib.browse_entry mbe
+ JOIN metabib.browse_entry_def_map mbedm ON (
+ mbedm.entry = mbe.id
+ AND mbedm.def = ANY($1)
+ )
+ WHERE mbe.sort_value >= public.naco_normalize($2)
+ ORDER BY mbe.sort_value, mbe.value LIMIT 1;
+$p$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION metabib.browse_authority_refs_pivot(
+ INT[],
+ TEXT
+) RETURNS BIGINT AS $p$
+ SELECT mbe.id
+ FROM metabib.browse_entry mbe
+ JOIN metabib.browse_entry_simple_heading_map mbeshm ON ( mbeshm.entry = mbe.id )
+ JOIN authority.simple_heading ash ON ( mbeshm.simple_heading = ash.id )
+ JOIN authority.control_set_auth_field_metabib_field_map_refs_only map ON (
+ ash.atag = map.authority_field
+ AND map.metabib_field = ANY($1)
+ )
+ WHERE mbe.sort_value >= public.naco_normalize($2)
+ ORDER BY mbe.sort_value, mbe.value LIMIT 1;
+$p$ LANGUAGE SQL;
+
+CREATE FUNCTION metabib.browse_pivot(
+ INT[],
+ TEXT
+) RETURNS BIGINT AS $p$
+ SELECT id FROM metabib.browse_entry
+ WHERE id IN (
+ metabib.browse_bib_pivot($1, $2),
+ metabib.browse_authority_refs_pivot($1,$2) -- only look in 4xx, 5xx, 7xx of authority
+ )
+ ORDER BY sort_value, value LIMIT 1;
+$p$ LANGUAGE SQL;
+
+--Keeping this for reference against the community version. KCLS version has a different function signature. Eric Worden
+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
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT aal.source), $$,$$), -- 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),
+ ARRAY_TO_STRING(ARRAY_AGG(DISTINCT authority), $$,$$),
+ ARRAY_AGG(DISTINCT def)
+ FROM metabib.browse_entry_def_map
+ WHERE entry = rec.id
+ AND def = ANY(fields);
+
+ SELECT INTO result_row.fields ARRAY_TO_STRING(ARRAY_AGG(DISTINCT x), $$,$$) FROM UNNEST(afields || bfields) x;
+
+ result_row.sources := 0;
+ result_row.asources := 0;
+
+ -- Bib-linked vis checking
+ IF ARRAY_UPPER(all_brecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_brecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.sources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_brecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, until we've
+ -- either exhausted that set of records or found at least 1
+ -- visible record.
+
+ SELECT INTO result_row.sources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+ -- Accurate? Well, probably.
+ result_row.accurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ -- Authority-linked vis checking
+ IF ARRAY_UPPER(all_arecords,1) IS NOT NULL THEN
+
+ full_end := ARRAY_LENGTH(all_arecords, 1);
+ superpage_size := COALESCE(browse_superpage_size, full_end);
+ slice_start := 1;
+ slice_end := superpage_size;
+
+ WHILE result_row.asources = 0 AND slice_start <= full_end LOOP
+ superpage_of_records := all_arecords[slice_start:slice_end];
+ qpfts_query :=
+ 'SELECT NULL::BIGINT AS id, ARRAY[r] AS records, ' ||
+ '1::INT AS rel FROM (SELECT UNNEST(' ||
+ quote_literal(superpage_of_records) || '::BIGINT[]) AS r) rr';
+
+ -- We use search.query_parser_fts() for visibility testing.
+ -- We're calling it once per browse-superpage worth of records
+ -- out of the set of records related to a given mbe, via
+ -- authority until we've either exhausted that set of records
+ -- or found at least 1 visible record.
+
+ SELECT INTO result_row.asources visible
+ FROM search.query_parser_fts(
+ context_org, NULL, qpfts_query, NULL,
+ context_locations, 0, NULL, NULL, FALSE, staff, FALSE
+ ) qpfts
+ WHERE qpfts.rel IS NULL;
+
+ slice_start := slice_start + superpage_size;
+ slice_end := slice_end + superpage_size;
+ END LOOP;
+
+
+ -- Accurate? Well, probably.
+ result_row.aaccurate := browse_superpage_size IS NULL OR
+ browse_superpage_size >= full_end;
+
+ END IF;
+
+ IF result_row.sources > 0 OR result_row.asources > 0 THEN
+
+ -- The function that calls this function needs row_number in order
+ -- to correctly order results from two different runs of this
+ -- functions.
+ result_row.row_number := row_number;
+
+ -- Now, if row_counter is still less than limit, return a row. If
+ -- not, but it is less than next_pivot_pos, continue on without
+ -- returning actual result rows until we find
+ -- that next pivot, and return it.
+
+ IF row_counter < result_limit THEN
+ result_row.browse_entry := rec.id;
+ result_row.value := rec.value;
+
+ RETURN NEXT result_row;
+ ELSE
+ result_row.browse_entry := NULL;
+ result_row.authorities := NULL;
+ result_row.fields := NULL;
+ result_row.value := NULL;
+ result_row.sources := NULL;
+ result_row.sees := NULL;
+ result_row.accurate := NULL;
+ result_row.aaccurate := NULL;
+ result_row.pivot_point := rec.id;
+
+ IF row_counter >= next_pivot_pos THEN
+ RETURN NEXT result_row;
+ RETURN;
+ END IF;
+ END IF;
+
+ IF count_up_from_zero THEN
+ row_number := row_number + 1;
+ ELSE
+ row_number := row_number - 1;
+ END IF;
+
+ -- row_counter is different from row_number.
+ -- It simply counts up from zero so that we know when
+ -- we've reached our limit.
+ row_counter := row_counter + 1;
+ END IF;
+ END LOOP;
+END;
+$p$ LANGUAGE PLPGSQL;
+
+
+-- check whether patch can be applied
+
+ALTER FUNCTION metabib.browse_pivot (integer[], text) STABLE;
+ALTER FUNCTION metabib.browse_bib_pivot (integer[], text) STABLE;
+ALTER FUNCTION metabib.browse_authority_pivot (integer[], text) STABLE;
+ALTER FUNCTION metabib.browse_authority_refs_pivot (integer[], text) STABLE;
+
+
+
+CREATE OR REPLACE FUNCTION vandelay.add_field ( target_xml TEXT, source_xml TEXT, field TEXT, force_add INT ) RETURNS TEXT AS $_$
+
+ use MARC::Record;
+ use MARC::File::XML (BinaryEncoding => 'UTF-8');
+ use MARC::Charset;
+ use strict;
+
+ MARC::Charset->assume_unicode(1);
+
+ my $target_xml = shift;
+ my $source_xml = shift;
+ my $field_spec = shift;
+ my $force_add = shift || 0;
+
+ my $target_r = MARC::Record->new_from_xml( $target_xml );
+ my $source_r = MARC::Record->new_from_xml( $source_xml );
+
+ return $target_xml unless ($target_r && $source_r);
+
+ my @field_list = split(',', $field_spec);
+
+ my %fields;
+ for my $f (@field_list) {
+ $f =~ s/^\s*//; $f =~ s/\s*$//;
+ if ($f =~ /^(.{3})(\w*)(?:\[([^]]*)\])?$/) {
+ my $field = $1;
+ $field =~ s/\s+//;
+ my $sf = $2;
+ $sf =~ s/\s+//;
+ my $match = $3;
+ $match =~ s/^\s*//; $match =~ s/\s*$//;
+ $fields{$field} = { sf => [ split('', $sf) ] };
+ if ($match) {
+ my ($msf,$mre) = split('~', $match);
+ if (length($msf) > 0 and length($mre) > 0) {
+ $msf =~ s/^\s*//; $msf =~ s/\s*$//;
+ $mre =~ s/^\s*//; $mre =~ s/\s*$//;
+ $fields{$field}{match} = { sf => $msf, re => qr/$mre/ };
+ }
+ }
+ }
+ }
+
+ for my $f ( keys %fields) {
+ if ( @{$fields{$f}{sf}} ) {
+ for my $from_field ($source_r->field( $f )) {
+ my @tos = $target_r->field( $f );
+ if (!@tos) {
+ next if (exists($fields{$f}{match}) and !$force_add);
+ my @new_fields = map { $_->clone } $source_r->field( $f );
+ $target_r->insert_fields_ordered( @new_fields );
+ } else {
+ for my $to_field (@tos) {
+ if (exists($fields{$f}{match})) {
+ next unless (grep { $_ =~ $fields{$f}{match}{re} } $to_field->subfield($fields{$f}{match}{sf}));
+ }
+ for my $old_sf ($from_field->subfields) {
+ $to_field->add_subfields( @$old_sf ) if grep(/$$old_sf[0]/,@{$fields{$f}{sf}});
+ }
+ }
+ }
+ }
+ } else {
+ my @new_fields = map { $_->clone } $source_r->field( $f );
+ $target_r->insert_fields_ordered( @new_fields );
+ }
+ }
+
+ $target_xml = $target_r->as_xml_record;
+ $target_xml =~ s/^<\?.+?\?>$//mo;
+ $target_xml =~ s/\n//sgo;
+ $target_xml =~ s/>\s+</></sgo;
+
+ return $target_xml;
+
+$_$ LANGUAGE PLPERLU;
+
+
+
+
+SET CONSTRAINTS ALL IMMEDIATE;
+-- otherwise, the ALTER TABLE statement below
+-- will fail with pending trigger events.
+ALTER TABLE action_trigger.event_definition ADD COLUMN repeat_delay INTERVAL;
+
+
+--Upgrade Script for 2.5.0 to 2.5.1
+
+
+CREATE OR REPLACE FUNCTION authority.normalize_heading( marcxml TEXT, no_thesaurus BOOL ) RETURNS TEXT AS $func$
+DECLARE
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ tag_used TEXT;
+ nfi_used TEXT;
+ sf TEXT;
+ sf_node TEXT;
+ tag_node TEXT;
+ thes_code TEXT;
+ cset INT;
+ heading_text TEXT;
+ tmp_text TEXT;
+ first_sf BOOL;
+ auth_id INT DEFAULT COALESCE(NULLIF(oils_xpath_string('//*[@tag="901"]/*[local-name()="subfield" and @code="c"]', marcxml), ''), '0')::INT;
+BEGIN
+ SELECT control_set INTO cset FROM authority.record_entry WHERE id = auth_id;
+
+ IF cset IS NULL THEN
+ SELECT control_set INTO cset
+ FROM authority.control_set_authority_field
+ WHERE tag IN ( SELECT UNNEST(XPATH('//*[starts-with(@tag,"1")]/@tag',marcxml::XML)::TEXT[]))
+ LIMIT 1;
+ END IF;
+
+ thes_code := vandelay.marc21_extract_fixed_field(marcxml,'Subj');
+ IF thes_code IS NULL THEN
+ thes_code := '|';
+ ELSIF thes_code = 'z' THEN
+ thes_code := COALESCE( oils_xpath_string('//*[@tag="040"]/*[@code="f"][1]', marcxml), '' );
+ END IF;
+
+ heading_text := '';
+ FOR acsaf IN SELECT * FROM authority.control_set_authority_field WHERE control_set = cset AND main_entry IS NULL LOOP
+ tag_used := acsaf.tag;
+ nfi_used := acsaf.nfi;
+ first_sf := TRUE;
+
+ FOR tag_node IN SELECT unnest(oils_xpath('//*[@tag="'||tag_used||'"]',marcxml)) LOOP
+ FOR sf_node IN SELECT unnest(oils_xpath('//*[contains("'||acsaf.sf_list||'",@code)]',tag_node)) LOOP
+
+ tmp_text := oils_xpath_string('.', sf_node);
+ sf := oils_xpath_string('./@code', sf_node);
+
+ IF first_sf AND tmp_text IS NOT NULL AND nfi_used IS NOT NULL THEN
+
+ tmp_text := SUBSTRING(
+ tmp_text FROM
+ COALESCE(
+ NULLIF(
+ REGEXP_REPLACE(
+ oils_xpath_string('./@ind'||nfi_used, tag_node),
+ $$\D+$$,
+ '',
+ 'g'
+ ),
+ ''
+ )::INT,
+ 0
+ ) + 1
+ );
+
+ END IF;
+
+ first_sf := FALSE;
+
+ IF tmp_text IS NOT NULL AND tmp_text <> '' THEN
+ heading_text := heading_text || E'\u2021' || sf || ' ' || tmp_text;
+ END IF;
+ END LOOP;
+
+ EXIT WHEN heading_text <> '';
+ END LOOP;
+
+ EXIT WHEN heading_text <> '';
+ END LOOP;
+
+ IF heading_text <> '' THEN
+ IF no_thesaurus IS TRUE THEN
+ heading_text := tag_used || ' ' || public.naco_normalize(heading_text);
+ ELSE
+ heading_text := tag_used || '_' || COALESCE(nfi_used,'-') || '_' || thes_code || ' ' || public.naco_normalize(heading_text);
+ END IF;
+ ELSE
+ heading_text := 'NOHEADING_' || thes_code || ' ' || MD5(marcxml);
+ END IF;
+
+ RETURN heading_text;
+END;
+$func$ LANGUAGE PLPGSQL IMMUTABLE;
+
+CREATE OR REPLACE FUNCTION authority.simple_heading_set( marcxml TEXT ) RETURNS SETOF authority.simple_heading AS $func$
+DECLARE
+ res authority.simple_heading%ROWTYPE;
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ tag_used TEXT;
+ nfi_used TEXT;
+ sf TEXT;
+ cset INT;
+ heading_text TEXT;
+ sort_text TEXT;
+ tmp_text TEXT;
+ tmp_xml TEXT;
+ first_sf BOOL;
+ auth_id INT DEFAULT oils_xpath_string('//*[@tag="901"]/*[local-name()="subfield" and @code="c"]', marcxml)::INT;
+BEGIN
+
+ res.record := auth_id;
+
+ SELECT control_set INTO cset
+ FROM authority.control_set_authority_field
+ WHERE tag IN ( SELECT UNNEST(XPATH('//*[starts-with(@tag,"1")]/@tag',marcxml::XML)::TEXT[]) )
+ LIMIT 1;
+
+ FOR acsaf IN SELECT * FROM authority.control_set_authority_field WHERE control_set = cset LOOP
+
+ res.atag := acsaf.id;
+ tag_used := acsaf.tag;
+ nfi_used := acsaf.nfi;
+
+ FOR tmp_xml IN SELECT UNNEST(XPATH('//*[@tag="'||tag_used||'"]', marcxml::XML)) LOOP
+
+ heading_text := public.naco_normalize(
+ COALESCE(
+ oils_xpath_string('//*[contains("'||acsaf.sf_list||'",@code)]',tmp_xml::TEXT, ' '),
+ ''
+ )
+ );
+
+ IF nfi_used IS NOT NULL THEN
+
+ sort_text := SUBSTRING(
+ heading_text FROM
+ COALESCE(
+ NULLIF(
+ REGEXP_REPLACE(
+ oils_xpath_string('./@ind'||nfi_used, tmp_xml::TEXT),
+ $$\D+$$,
+ '',
+ 'g'
+ ),
+ ''
+ )::INT,
+ 0
+ ) + 1
+ );
+
+ ELSE
+ sort_text := heading_text;
+ END IF;
+
+ IF heading_text IS NOT NULL AND heading_text <> '' THEN
+ res.value := heading_text;
+ res.sort_value := sort_text;
+ RETURN NEXT res;
+ END IF;
+
+ END LOOP;
+
+ END LOOP;
+
+ RETURN;
+END;
+$func$ LANGUAGE PLPGSQL IMMUTABLE;
+
+
+--Upgrade Script for 2.5.1 to 2.5.2
+
+--ALTER EXTENSION evergreen.hstore SET SCHEMA public;
+
+
+CREATE OR REPLACE FUNCTION unapi.mra ( obj_id BIGINT, format TEXT, ename TEXT, includes TEXT[], org TEXT, depth INT DEFAULT NULL, slimit HSTORE DEFAULT NULL, soffset HSTORE DEFAULT NULL, include_xmlns BOOL DEFAULT TRUE ) RETURNS XML AS $F$
+ SELECT XMLELEMENT(
+ name attributes,
+ XMLATTRIBUTES(
+ CASE WHEN $9 THEN 'http://open-ils.org/spec/indexing/v1' ELSE NULL END AS xmlns,
+ 'tag:open-ils.org:U2@mra/' || mra.id AS id,
+ 'tag:open-ils.org:U2@bre/' || mra.id AS record
+ ),
+ (SELECT XMLAGG(foo.y)
+ FROM (SELECT XMLELEMENT(
+ name field,
+ XMLATTRIBUTES(
+ key AS name,
+ cvm.value AS "coded-value",
+ cvm.id AS "cvmid",
+ rad.filter,
+ rad.sorter
+ ),
+ x.value
+ )
+ FROM EACH(mra.attrs) AS x
+ JOIN config.record_attr_definition rad ON (x.key = rad.name)
+ LEFT JOIN config.coded_value_map cvm ON (cvm.ctype = x.key AND code = x.value)
+ )foo(y)
+ )
+ )
+ FROM metabib.record_attr mra
+ WHERE mra.id = $1;
+$F$ LANGUAGE SQL STABLE;
+
+
+
+CREATE OR REPLACE FUNCTION action.hold_copy_calculated_proximity(
+ ahr_id INT,
+ acp_id BIGINT,
+ copy_context_ou INT DEFAULT NULL
+ -- TODO maybe? hold_context_ou INT DEFAULT NULL. This would optionally
+ -- support an "ahprox" measurement: adjust prox between copy circ lib and
+ -- hold request lib, but I'm unsure whether to use this theoretical
+ -- argument only in the baseline calculation or later in the other
+ -- queries in this function.
+) RETURNS NUMERIC AS $f$
+DECLARE
+ aoupa actor.org_unit_proximity_adjustment%ROWTYPE;
+ ahr action.hold_request%ROWTYPE;
+ acp asset.copy%ROWTYPE;
+ acn asset.call_number%ROWTYPE;
+ acl asset.copy_location%ROWTYPE;
+ baseline_prox NUMERIC;
+
+ icl_list INT[];
+ iol_list INT[];
+ isl_list INT[];
+ hpl_list INT[];
+ hrl_list INT[];
+
+BEGIN
+
+ SELECT * INTO ahr FROM action.hold_request WHERE id = ahr_id;
+ SELECT * INTO acp FROM asset.copy WHERE id = acp_id;
+ SELECT * INTO acn FROM asset.call_number WHERE id = acp.call_number;
+ SELECT * INTO acl FROM asset.copy_location WHERE id = acp.location;
+
+ IF copy_context_ou IS NULL THEN
+ copy_context_ou := acp.circ_lib;
+ END IF;
+
+ -- First, gather the baseline proximity of "here" to pickup lib
+ SELECT prox INTO baseline_prox FROM actor.org_unit_proximity WHERE from_org = copy_context_ou AND to_org = ahr.pickup_lib;
+
+ -- Find any absolute adjustments, and set the baseline prox to that
+ SELECT adj.* INTO aoupa
+ FROM actor.org_unit_proximity_adjustment adj
+ LEFT JOIN actor.org_unit_ancestors_distance(copy_context_ou) acp_cl ON (acp_cl.id = adj.item_circ_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acn.owning_lib) acn_ol ON (acn_ol.id = adj.item_owning_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acl.owning_lib) acl_ol ON (acl_ol.id = adj.copy_location)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.pickup_lib) ahr_pl ON (ahr_pl.id = adj.hold_pickup_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.request_lib) ahr_rl ON (ahr_rl.id = adj.hold_request_lib)
+ WHERE (adj.circ_mod IS NULL OR adj.circ_mod = acp.circ_modifier) AND
+ (adj.item_circ_lib IS NULL OR adj.item_circ_lib = acp_cl.id) AND
+ (adj.item_owning_lib IS NULL OR adj.item_owning_lib = acn_ol.id) AND
+ (adj.copy_location IS NULL OR adj.copy_location = acl_ol.id) AND
+ (adj.hold_pickup_lib IS NULL OR adj.hold_pickup_lib = ahr_pl.id) AND
+ (adj.hold_request_lib IS NULL OR adj.hold_request_lib = ahr_rl.id) AND
+ absolute_adjustment AND
+ COALESCE(acp_cl.id, acn_ol.id, acl_ol.id, ahr_pl.id, ahr_rl.id) IS NOT NULL
+ ORDER BY
+ COALESCE(acp_cl.distance,999)
+ + COALESCE(acn_ol.distance,999)
+ + COALESCE(acl_ol.distance,999)
+ + COALESCE(ahr_pl.distance,999)
+ + COALESCE(ahr_rl.distance,999),
+ adj.pos
+ LIMIT 1;
+
+ IF FOUND THEN
+ baseline_prox := aoupa.prox_adjustment;
+ END IF;
+
+ -- Now find any relative adjustments, and change the baseline prox based on them
+ FOR aoupa IN
+ SELECT adj.*
+ FROM actor.org_unit_proximity_adjustment adj
+ LEFT JOIN actor.org_unit_ancestors_distance(copy_context_ou) acp_cl ON (acp_cl.id = adj.item_circ_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acn.owning_lib) acn_ol ON (acn_ol.id = adj.item_owning_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acl.owning_lib) acl_ol ON (acn_ol.id = adj.copy_location)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.pickup_lib) ahr_pl ON (ahr_pl.id = adj.hold_pickup_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.request_lib) ahr_rl ON (ahr_rl.id = adj.hold_request_lib)
+ WHERE (adj.circ_mod IS NULL OR adj.circ_mod = acp.circ_modifier) AND
+ (adj.item_circ_lib IS NULL OR adj.item_circ_lib = acp_cl.id) AND
+ (adj.item_owning_lib IS NULL OR adj.item_owning_lib = acn_ol.id) AND
+ (adj.copy_location IS NULL OR adj.copy_location = acl_ol.id) AND
+ (adj.hold_pickup_lib IS NULL OR adj.hold_pickup_lib = ahr_pl.id) AND
+ (adj.hold_request_lib IS NULL OR adj.hold_request_lib = ahr_rl.id) AND
+ NOT absolute_adjustment AND
+ COALESCE(acp_cl.id, acn_ol.id, acl_ol.id, ahr_pl.id, ahr_rl.id) IS NOT NULL
+ LOOP
+ baseline_prox := baseline_prox + aoupa.prox_adjustment;
+ END LOOP;
+
+ RETURN baseline_prox;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION action.hold_copy_calculated_proximity(
+ ahr_id INT,
+ acp_id BIGINT,
+ copy_context_ou INT DEFAULT NULL
+ -- TODO maybe? hold_context_ou INT DEFAULT NULL. This would optionally
+ -- support an "ahprox" measurement: adjust prox between copy circ lib and
+ -- hold request lib, but I'm unsure whether to use this theoretical
+ -- argument only in the baseline calculation or later in the other
+ -- queries in this function.
+) RETURNS NUMERIC AS $f$
+DECLARE
+ aoupa actor.org_unit_proximity_adjustment%ROWTYPE;
+ ahr action.hold_request%ROWTYPE;
+ acp asset.copy%ROWTYPE;
+ acn asset.call_number%ROWTYPE;
+ acl asset.copy_location%ROWTYPE;
+ baseline_prox NUMERIC;
+
+ icl_list INT[];
+ iol_list INT[];
+ isl_list INT[];
+ hpl_list INT[];
+ hrl_list INT[];
+
+BEGIN
+
+ SELECT * INTO ahr FROM action.hold_request WHERE id = ahr_id;
+ SELECT * INTO acp FROM asset.copy WHERE id = acp_id;
+ SELECT * INTO acn FROM asset.call_number WHERE id = acp.call_number;
+ SELECT * INTO acl FROM asset.copy_location WHERE id = acp.location;
+
+ IF copy_context_ou IS NULL THEN
+ copy_context_ou := acp.circ_lib;
+ END IF;
+
+ -- First, gather the baseline proximity of "here" to pickup lib
+ SELECT prox INTO baseline_prox FROM actor.org_unit_proximity WHERE from_org = copy_context_ou AND to_org = ahr.pickup_lib;
+
+ -- Find any absolute adjustments, and set the baseline prox to that
+ SELECT adj.* INTO aoupa
+ FROM actor.org_unit_proximity_adjustment adj
+ LEFT JOIN actor.org_unit_ancestors_distance(copy_context_ou) acp_cl ON (acp_cl.id = adj.item_circ_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acn.owning_lib) acn_ol ON (acn_ol.id = adj.item_owning_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acl.owning_lib) acl_ol ON (acl_ol.id = adj.copy_location)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.pickup_lib) ahr_pl ON (ahr_pl.id = adj.hold_pickup_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.request_lib) ahr_rl ON (ahr_rl.id = adj.hold_request_lib)
+ WHERE (adj.circ_mod IS NULL OR adj.circ_mod = acp.circ_modifier) AND
+ (adj.item_circ_lib IS NULL OR adj.item_circ_lib = acp_cl.id) AND
+ (adj.item_owning_lib IS NULL OR adj.item_owning_lib = acn_ol.id) AND
+ (adj.copy_location IS NULL OR adj.copy_location = acl_ol.id) AND
+ (adj.hold_pickup_lib IS NULL OR adj.hold_pickup_lib = ahr_pl.id) AND
+ (adj.hold_request_lib IS NULL OR adj.hold_request_lib = ahr_rl.id) AND
+ absolute_adjustment AND
+ COALESCE(acp_cl.id, acn_ol.id, acl_ol.id, ahr_pl.id, ahr_rl.id) IS NOT NULL
+ ORDER BY
+ COALESCE(acp_cl.distance,999)
+ + COALESCE(acn_ol.distance,999)
+ + COALESCE(acl_ol.distance,999)
+ + COALESCE(ahr_pl.distance,999)
+ + COALESCE(ahr_rl.distance,999),
+ adj.pos
+ LIMIT 1;
+
+ IF FOUND THEN
+ baseline_prox := aoupa.prox_adjustment;
+ END IF;
+
+ -- Now find any relative adjustments, and change the baseline prox based on them
+ FOR aoupa IN
+ SELECT adj.*
+ FROM actor.org_unit_proximity_adjustment adj
+ LEFT JOIN actor.org_unit_ancestors_distance(copy_context_ou) acp_cl ON (acp_cl.id = adj.item_circ_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acn.owning_lib) acn_ol ON (acn_ol.id = adj.item_owning_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(acl.owning_lib) acl_ol ON (acn_ol.id = adj.copy_location)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.pickup_lib) ahr_pl ON (ahr_pl.id = adj.hold_pickup_lib)
+ LEFT JOIN actor.org_unit_ancestors_distance(ahr.request_lib) ahr_rl ON (ahr_rl.id = adj.hold_request_lib)
+ WHERE (adj.circ_mod IS NULL OR adj.circ_mod = acp.circ_modifier) AND
+ (adj.item_circ_lib IS NULL OR adj.item_circ_lib = acp_cl.id) AND
+ (adj.item_owning_lib IS NULL OR adj.item_owning_lib = acn_ol.id) AND
+ (adj.copy_location IS NULL OR adj.copy_location = acl_ol.id) AND
+ (adj.hold_pickup_lib IS NULL OR adj.hold_pickup_lib = ahr_pl.id) AND
+ (adj.hold_request_lib IS NULL OR adj.hold_request_lib = ahr_rl.id) AND
+ NOT absolute_adjustment AND
+ COALESCE(acp_cl.id, acn_ol.id, acl_ol.id, ahr_pl.id, ahr_rl.id) IS NOT NULL
+ LOOP
+ baseline_prox := baseline_prox + aoupa.prox_adjustment;
+ END LOOP;
+
+ RETURN baseline_prox;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+--Upgrade Script for 2.5.3 to 2.5.4
+
+/* KCLS: already back-ported
+
+
+CREATE OR REPLACE FUNCTION action.hold_copy_calculated_proximity_update () RETURNS TRIGGER AS $f$
+BEGIN
+ NEW.proximity := action.hold_copy_calculated_proximity(NEW.hold,NEW.target_copy);
+ RETURN NEW;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER hold_copy_proximity_update_tgr BEFORE INSERT OR UPDATE ON action.hold_copy_map FOR EACH ROW EXECUTE PROCEDURE action.hold_copy_calculated_proximity_update ();
+
+-- Now, cause the update we need in a HOT-friendly manner (http://pgsql.tapoueh.org/site/html/misc/hot.html)
+UPDATE action.hold_copy_map SET proximity = proximity WHERE proximity IS NULL;
+*/
+
+
+
+/* KCLS don't modify existing indexes
+
+-- Don't use Series search field as the browse field
+UPDATE config.metabib_field SET
+ browse_field = FALSE,
+ browse_xpath = NULL,
+ browse_sort_xpath = NULL,
+ xpath = $$//mods32:mods/mods32:relatedItem[@type="series"]/mods32:titleInfo[not(@type="nfi")]$$
+WHERE id = 1;
+
+-- Create a new series browse config
+INSERT INTO config.metabib_field ( id, field_class, name, label, format, xpath, search_field, authority_xpath, browse_field, browse_sort_xpath ) VALUES
+ (32, 'series', 'browse', oils_i18n_gettext(32, 'Series Title (Browse)', 'cmf', 'label'), 'mods32', $$//mods32:mods/mods32:relatedItem[@type="series"]/mods32:titleInfo[@type="nfi"]$$, FALSE, '//@xlink:href', TRUE, $$*[local-name() != "nonSort"]$$ );
+
+
+-- "Quick Fix" indexing of series for search
+INSERT INTO metabib.series_field_entry (field,source,value)
+ SELECT 1,record,value FROM metabib.full_rec WHERE tag = '490' AND subfield = 'a';
+
+INSERT INTO metabib.series_field_entry (field,source,value)
+ SELECT 1,record,value FROM metabib.full_rec WHERE tag IN ('800','810','811') AND subfield = 't';
+
+INSERT INTO metabib.series_field_entry (field,source,value)
+ SELECT 1,record,value FROM metabib.full_rec WHERE tag = '830' AND subfield IN ('a','t');
+
+DELETE FROM metabib.combined_series_field_entry;
+INSERT INTO metabib.combined_series_field_entry(record, metabib_field, index_vector)
+ SELECT source, field, strip(COALESCE(string_agg(index_vector::TEXT,' '),'')::tsvector)
+ FROM metabib.series_field_entry GROUP BY source, field;
+INSERT INTO metabib.combined_series_field_entry(record, index_vector)
+ SELECT source, strip(COALESCE(string_agg(index_vector::TEXT,' '),'')::tsvector)
+ FROM metabib.series_field_entry GROUP BY source;
+
+*/
+
+--Upgrade Script for 2.5.4 to 2.5.5
+
+CREATE OR REPLACE FUNCTION authority.calculate_authority_linking(
+ rec_id BIGINT, rec_control_set INT, rec_marc_xml XML
+) RETURNS SETOF authority.authority_linking AS $func$
+DECLARE
+ acsaf authority.control_set_authority_field%ROWTYPE;
+ link TEXT;
+ aal authority.authority_linking%ROWTYPE;
+BEGIN
+ IF rec_control_set IS NULL THEN
+ -- No control_set on record? Guess at one
+ SELECT control_set INTO rec_control_set
+ FROM authority.control_set_authority_field
+ WHERE tag IN (
+ SELECT UNNEST(
+ XPATH('//*[starts-with(@tag,"1")]/@tag',rec_marc_xml)::TEXT[]
+ )
+ ) LIMIT 1;
+
+ IF NOT FOUND THEN
+ RAISE WARNING 'Could not even guess at control set for authority record %', rec_id;
+ RETURN;
+ END IF;
+ END IF;
+
+ aal.source := rec_id;
+
+ FOR acsaf IN
+ SELECT * FROM authority.control_set_authority_field
+ WHERE control_set = rec_control_set
+ AND linking_subfield IS NOT NULL
+ AND main_entry IS NOT NULL
+ LOOP
+ -- Loop over the trailing-number contents of all linking subfields
+ FOR link IN
+ SELECT SUBSTRING( x::TEXT, '\d+$' )
+ FROM UNNEST(
+ XPATH(
+ '//*[@tag="'
+ || acsaf.tag
+ || '"]/*[@code="'
+ || acsaf.linking_subfield
+ || '"]/text()',
+ rec_marc_xml
+ )
+ ) x
+ LOOP
+
+ -- Ignore links that are null, malformed, circular, or point to
+ -- non-existent authority records.
+ IF link IS NOT NULL AND link::BIGINT <> rec_id THEN
+ PERFORM * FROM authority.record_entry WHERE id = link::BIGINT;
+ IF FOUND THEN
+ aal.target := link::BIGINT;
+ aal.field := acsaf.id;
+ RETURN NEXT aal;
+ END IF;
+ END IF;
+ END LOOP;
+ END LOOP;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+
+--Upgrade Script for 2.5.5 to 2.5.6
+
+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;
+
+BEGIN
+
+ check_limit := COALESCE( param_check, 1000 );
+ core_limit := COALESCE( param_limit, 25000 );
+ core_offset := COALESCE( param_offset, 0 );
+
+ -- core_skip_chk := COALESCE( param_skip_chk, 1 );
+
+ IF param_search_ou > 0 THEN
+ IF param_depth IS NOT NULL THEN
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou, param_depth );
+ ELSE
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou );
+ END IF;
+
+ SELECT array_accum(distinct id) INTO luri_org_list FROM actor.org_unit_ancestors( param_search_ou );
+
+ ELSIF param_search_ou < 0 THEN
+ SELECT array_accum(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
+ SELECT array_accum(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors( tmp_int );
+ luri_org_list := luri_org_list || tmp_int_list;
+ END LOOP;
+
+ SELECT array_accum(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
+ SELECT array_accum(distinct id) INTO tmp_int_list FROM actor.org_unit_ancestors(param_pref_ou);
+ 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;
+
+ 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;
+
+ 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;
+
+ 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.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;
+
+--Upgrade Script for 2.5.6 to 2.5.7
+
+CREATE OR REPLACE FUNCTION acq.transfer_fund(
+ old_fund IN INT,
+ old_amount IN NUMERIC, -- in currency of old fund
+ new_fund IN INT,
+ new_amount IN NUMERIC, -- in currency of new fund
+ user_id IN INT,
+ xfer_note IN TEXT -- to be recorded in acq.fund_transfer
+ -- ,funding_source_in IN INT -- if user wants to specify a funding source (see notes)
+) RETURNS VOID AS $$
+/* -------------------------------------------------------------------------------
+
+Function to transfer money from one fund to another.
+
+A transfer is represented as a pair of entries in acq.fund_allocation, with a
+negative amount for the old (losing) fund and a positive amount for the new
+(gaining) fund. In some cases there may be more than one such pair of entries
+in order to pull the money from different funding sources, or more specifically
+from different funding source credits. For each such pair there is also an
+entry in acq.fund_transfer.
+
+Since funding_source is a non-nullable column in acq.fund_allocation, we must
+choose a funding source for the transferred money to come from. This choice
+must meet two constraints, so far as possible:
+
+1. The amount transferred from a given funding source must not exceed the
+amount allocated to the old fund by the funding source. To that end we
+compare the amount being transferred to the amount allocated.
+
+2. We shouldn't transfer money that has already been spent or encumbered, as
+defined by the funding attribution process. We attribute expenses to the
+oldest funding source credits first. In order to avoid transferring that
+attributed money, we reverse the priority, transferring from the newest funding
+source credits first. There can be no guarantee that this approach will
+avoid overcommitting a fund, but no other approach can do any better.
+
+In this context the age of a funding source credit is defined by the
+deadline_date for credits with deadline_dates, and by the effective_date for
+credits without deadline_dates, with the proviso that credits with deadline_dates
+are all considered "older" than those without.
+
+----------
+
+In the signature for this function, there is one last parameter commented out,
+named "funding_source_in". Correspondingly, the WHERE clause for the query
+driving the main loop has an OR clause commented out, which references the
+funding_source_in parameter.
+
+If these lines are uncommented, this function will allow the user optionally to
+restrict a fund transfer to a specified funding source. If the source
+parameter is left NULL, then there will be no such restriction.
+
+------------------------------------------------------------------------------- */
+DECLARE
+ same_currency BOOLEAN;
+ currency_ratio NUMERIC;
+ old_fund_currency TEXT;
+ old_remaining NUMERIC; -- in currency of old fund
+ new_fund_currency TEXT;
+ new_fund_active BOOLEAN;
+ new_remaining NUMERIC; -- in currency of new fund
+ curr_old_amt NUMERIC; -- in currency of old fund
+ curr_new_amt NUMERIC; -- in currency of new fund
+ source_addition NUMERIC; -- in currency of funding source
+ source_deduction NUMERIC; -- in currency of funding source
+ orig_allocated_amt NUMERIC; -- in currency of funding source
+ allocated_amt NUMERIC; -- in currency of fund
+ source RECORD;
+BEGIN
+ --
+ -- Sanity checks
+ --
+ IF old_fund IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: old fund id is NULL';
+ END IF;
+ --
+ IF old_amount IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
+ END IF;
+ --
+ -- The new fund and its amount must be both NULL or both not NULL.
+ --
+ IF new_fund IS NOT NULL AND new_amount IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: amount to transfer to receiving fund is NULL';
+ END IF;
+ --
+ IF new_fund IS NULL AND new_amount IS NOT NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: receiving fund is NULL, its amount is not NULL';
+ END IF;
+ --
+ IF user_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
+ END IF;
+ --
+ -- Initialize the amounts to be transferred, each denominated
+ -- in the currency of its respective fund. They will be
+ -- reduced on each iteration of the loop.
+ --
+ old_remaining := old_amount;
+ new_remaining := new_amount;
+ --
+ -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
+ -- old_amount, old_fund, new_amount, new_fund;
+ --
+ -- Get the currency types of the old and new funds.
+ --
+ SELECT
+ currency_type
+ INTO
+ old_fund_currency
+ FROM
+ acq.fund
+ WHERE
+ id = old_fund;
+ --
+ IF old_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: old fund id % is not defined', old_fund;
+ END IF;
+ --
+ IF new_fund IS NOT NULL THEN
+ SELECT
+ currency_type,
+ active
+ INTO
+ new_fund_currency,
+ new_fund_active
+ FROM
+ acq.fund
+ WHERE
+ id = new_fund;
+ --
+ IF new_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: new fund id % is not defined', new_fund;
+ ELSIF NOT new_fund_active THEN
+ --
+ -- No point in putting money into a fund from whence you can't spend it
+ --
+ RAISE EXCEPTION 'acq.transfer_fund: new fund id % is inactive', new_fund;
+ END IF;
+ --
+ IF new_amount = old_amount THEN
+ same_currency := true;
+ currency_ratio := 1;
+ ELSE
+ --
+ -- We'll have to translate currency between funds. We presume that
+ -- the calling code has already applied an appropriate exchange rate,
+ -- so we'll apply the same conversion to each sub-transfer.
+ --
+ same_currency := false;
+ currency_ratio := new_amount / old_amount;
+ END IF;
+ END IF;
+ --
+ -- Identify the funding source(s) from which we want to transfer the money.
+ -- The principle is that we want to transfer the newest money first, because
+ -- we spend the oldest money first. The priority for spending is defined
+ -- by a sort of the view acq.ordered_funding_source_credit.
+ --
+ FOR source in
+ SELECT
+ ofsc.id,
+ ofsc.funding_source,
+ ofsc.amount,
+ ofsc.amount * acq.exchange_ratio( fs.currency_type, old_fund_currency )
+ AS converted_amt,
+ fs.currency_type
+ FROM
+ acq.ordered_funding_source_credit AS ofsc,
+ acq.funding_source fs
+ WHERE
+ ofsc.funding_source = fs.id
+ and ofsc.funding_source IN
+ (
+ SELECT funding_source
+ FROM acq.fund_allocation
+ WHERE fund = old_fund
+ )
+ -- and
+ -- (
+ -- ofsc.funding_source = funding_source_in
+ -- OR funding_source_in IS NULL
+ -- )
+ ORDER BY
+ ofsc.sort_priority desc,
+ ofsc.sort_date desc,
+ ofsc.id desc
+ LOOP
+ --
+ -- Determine how much money the old fund got from this funding source,
+ -- denominated in the currency types of the source and of the fund.
+ -- This result may reflect transfers from previous iterations.
+ --
+ SELECT
+ COALESCE( sum( amount ), 0 ),
+ COALESCE( sum( amount )
+ * acq.exchange_ratio( source.currency_type, old_fund_currency ), 0 )
+ INTO
+ orig_allocated_amt, -- in currency of the source
+ allocated_amt -- in currency of the old fund
+ FROM
+ acq.fund_allocation
+ WHERE
+ fund = old_fund
+ and funding_source = source.funding_source;
+ --
+ -- Determine how much to transfer from this credit, in the currency
+ -- of the fund. Begin with the amount remaining to be attributed:
+ --
+ curr_old_amt := old_remaining;
+ --
+ -- Can't attribute more than was allocated from the fund:
+ --
+ IF curr_old_amt > allocated_amt THEN
+ curr_old_amt := allocated_amt;
+ END IF;
+ --
+ -- Can't attribute more than the amount of the current credit:
+ --
+ IF curr_old_amt > source.converted_amt THEN
+ curr_old_amt := source.converted_amt;
+ END IF;
+ --
+ curr_old_amt := trunc( curr_old_amt, 2 );
+ --
+ old_remaining := old_remaining - curr_old_amt;
+ --
+ -- Determine the amount to be deducted, if any,
+ -- from the old allocation.
+ --
+ IF old_remaining > 0 THEN
+ --
+ -- In this case we're using the whole allocation, so use that
+ -- amount directly instead of applying a currency translation
+ -- and thereby inviting round-off errors.
+ --
+ source_deduction := - curr_old_amt;
+ ELSE
+ source_deduction := trunc(
+ ( - curr_old_amt ) *
+ acq.exchange_ratio( old_fund_currency, source.currency_type ),
+ 2 );
+ END IF;
+ --
+ IF source_deduction <> 0 THEN
+ --
+ -- Insert negative allocation for old fund in fund_allocation,
+ -- converted into the currency of the funding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note
+ ) VALUES (
+ source.funding_source,
+ old_fund,
+ source_deduction,
+ user_id,
+ 'Transfer to fund ' || new_fund
+ );
+ END IF;
+ --
+ IF new_fund IS NOT NULL THEN
+ --
+ -- Determine how much to add to the new fund, in
+ -- its currency, and how much remains to be added:
+ --
+ IF same_currency THEN
+ curr_new_amt := curr_old_amt;
+ ELSE
+ IF old_remaining = 0 THEN
+ --
+ -- This is the last iteration, so nothing should be left
+ --
+ curr_new_amt := new_remaining;
+ new_remaining := 0;
+ ELSE
+ curr_new_amt := trunc( curr_old_amt * currency_ratio, 2 );
+ new_remaining := new_remaining - curr_new_amt;
+ END IF;
+ END IF;
+ --
+ -- Determine how much to add, if any,
+ -- to the new fund's allocation.
+ --
+ IF old_remaining > 0 THEN
+ --
+ -- In this case we're using the whole allocation, so use that amount
+ -- amount directly instead of applying a currency translation and
+ -- thereby inviting round-off errors.
+ --
+ source_addition := curr_new_amt;
+ ELSIF source.currency_type = old_fund_currency THEN
+ --
+ -- In this case we don't need a round trip currency translation,
+ -- thereby inviting round-off errors:
+ --
+ source_addition := curr_old_amt;
+ ELSE
+ source_addition := trunc(
+ curr_new_amt *
+ acq.exchange_ratio( new_fund_currency, source.currency_type ),
+ 2 );
+ END IF;
+ --
+ IF source_addition <> 0 THEN
+ --
+ -- Insert positive allocation for new fund in fund_allocation,
+ -- converted to the currency of the founding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note
+ ) VALUES (
+ source.funding_source,
+ new_fund,
+ source_addition,
+ user_id,
+ 'Transfer from fund ' || old_fund
+ );
+ END IF;
+ END IF;
+ --
+ IF trunc( curr_old_amt, 2 ) <> 0
+ OR trunc( curr_new_amt, 2 ) <> 0 THEN
+ --
+ -- Insert row in fund_transfer, using amounts in the currency of the funds
+ --
+ INSERT INTO acq.fund_transfer (
+ src_fund,
+ src_amount,
+ dest_fund,
+ dest_amount,
+ transfer_user,
+ note,
+ funding_source_credit
+ ) VALUES (
+ old_fund,
+ trunc( curr_old_amt, 2 ),
+ new_fund,
+ trunc( curr_new_amt, 2 ),
+ user_id,
+ xfer_note,
+ source.id
+ );
+ END IF;
+ --
+ if old_remaining <= 0 THEN
+ EXIT; -- Nothing more to be transferred
+ END IF;
+ END LOOP;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMIT;
\ No newline at end of file