[open-ils-commits] r16508 - branches/rel_1_6/Open-ILS/src/sql/Pg (miker)

svn at svn.open-ils.org svn at svn.open-ils.org
Wed May 26 14:10:34 EDT 2010


Author: miker
Date: 2010-05-26 14:10:30 -0400 (Wed, 26 May 2010)
New Revision: 16508

Added:
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.1-1.6.0.2-upgrade-db.sql
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.2-1.6.0.3-upgrade-db.sql
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.3-1.6.0.4-upgrade-db.sql
Modified:
   branches/rel_1_6/Open-ILS/src/sql/Pg/002.schema.config.sql
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.4.0.5-1.6.0.0-upgrade-db.sql
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.0-1.6.0.1-upgrade-db.sql
   branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.4-1.6.1.0-upgrade-db.sql
Log:
1.6.0.4-1.6.1.0 upgrade script, ready for testing!

Modified: branches/rel_1_6/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-05-26 18:07:46 UTC (rev 16507)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -51,7 +51,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0175'); -- miker
+INSERT INTO config.upgrade_log (version) VALUES ('1.6'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: branches/rel_1_6/Open-ILS/src/sql/Pg/1.4.0.5-1.6.0.0-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.4.0.5-1.6.0.0-upgrade-db.sql	2010-05-26 18:07:46 UTC (rev 16507)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.4.0.5-1.6.0.0-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -21,7 +21,7 @@
 
 BEGIN;
 
-INSERT INTO config.upgrade_log (version) VALUES ('1.6.0.0');
+INSERT INTO config.upgrade_log (version) VALUES ('1.6.0.0-GOLD');
  
 CREATE TABLE config.standing_penalty (
 	id		SERIAL	PRIMARY KEY,
@@ -1100,6 +1100,18 @@
 CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
 CREATE TRIGGER mat_summary_remove_tgr AFTER DELETE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_delete ();
 
+CREATE OR REPLACE FUNCTION action.push_circ_due_time () RETURNS TRIGGER AS $$
+BEGIN
+    IF (EXTRACT(EPOCH FROM NEW.duration)::INT % EXTRACT(EPOCH FROM '1 day'::INTERVAL)::INT) = 0 THEN
+        NEW.due_date = (NEW.due_date::DATE + '1 day'::INTERVAL - '1 second'::INTERVAL)::TIMESTAMPTZ;
+    END IF;
+
+    RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER push_due_date_tgr BEFORE INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE action.push_circ_due_time();
+
 CREATE OR REPLACE VIEW action.billable_circulations AS
  	SELECT	*
  	  FROM	action.circulation
@@ -1353,7 +1365,7 @@
           FROM  action.circulation circ
             JOIN asset.copy cp ON (cp.id = circ.target_copy)
           WHERE circ.usr = match_user
-               AND circ_lib IN ( SELECT * FROM explode_array(context_org_list) )
+               AND circ.circ_lib IN ( SELECT * FROM explode_array(context_org_list) )
             AND circ.checkin_time IS NULL
             AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL)
             AND cp.circ_modifier IN (SELECT circ_mod FROM config.circ_matrix_circ_mod_test_map WHERE circ_mod_test = out_by_circ_mod.id);
@@ -3251,6 +3263,7 @@
     cleanup_success TEXT        REFERENCES action_trigger.cleanup (module) DEFERRABLE INITIALLY DEFERRED,
     cleanup_failure TEXT        REFERENCES action_trigger.cleanup (module) DEFERRABLE INITIALLY DEFERRED,
     delay           INTERVAL    NOT NULL DEFAULT '5 minutes',
+    max_delay       INTERVAL,
     delay_field     TEXT,                 -- for instance, xact_start on a circ hook ... look for fields on hook.core_type where datatype=timestamp? If not set, delay from now()
     group_field     TEXT,                 -- field from this.hook.core_type to batch event targets together on, fed into reactor a group at a time.
     template        TEXT,                 -- the TT block.  will have an 'environment' hash (or array of hashes, grouped events) built up by validator and collector(s), which can be modified.
@@ -4056,16 +4069,19 @@
 INSERT INTO permission.perm_list (code) VALUES ('UPDATE_ORG_UNIT_SETTING.global.password_regex');
 INSERT INTO permission.perm_list (code) VALUES ('UPDATE_ORG_UNIT_SETTING.global.juvenile_age_threshold');
 INSERT INTO permission.perm_list (code) VALUES ('UPDATE_ORG_UNIT_SETTING.patron.password.use_phone');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_RECORD', 'Allow a user to update and undelete bibliographic records');
 
 INSERT INTO permission.grp_tree (name, parent, description, perm_interval, usergroup, application_perm) VALUES ('Acquisitions', 3, NULL, '3 years', TRUE, 'group_application.user.staff.acq');
 INSERT INTO permission.grp_tree (name, parent, description, perm_interval, usergroup, application_perm) VALUES ('Acquisitions Administrators', (SELECT id FROM permission.grp_tree WHERE name = 'Acquisitions'), NULL, '3 years', TRUE, 'group_application.user.staff.acq_admin');
 
 -- You can't log into the staff client without this
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (3, (SELECT id FROM permission.perm_list WHERE code = 'VIEW_BILLING_TYPE'), 0, false);
 INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (3, (SELECT id FROM permission.perm_list WHERE code = 'VIEW_ORG_SETTINGS'), 1, false);
 -- MFHD permissions are necessary for serials work; add to the default catalogers group
-INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (5, (SELECT id FROM permission.perm_list WHERE code = 'CREATE_MFHD_RECORD'), 1, false);
-INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (5, (SELECT id FROM permission.perm_list WHERE code = 'DELETE_MFHD_RECORD'), 1, false);
-INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (5, (SELECT id FROM permission.perm_list WHERE code = 'UPDATE_MFHD_RECORD'), 1, false);
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (4, (SELECT id FROM permission.perm_list WHERE code = 'CREATE_MFHD_RECORD'), 1, false);
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (4, (SELECT id FROM permission.perm_list WHERE code = 'DELETE_MFHD_RECORD'), 1, false);
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (4, (SELECT id FROM permission.perm_list WHERE code = 'UPDATE_MFHD_RECORD'), 1, false);
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES (4, (SELECT id FROM permission.perm_list WHERE code = 'UPDATE_RECORD'), 1, false);
 
 -- Add basic acquisitions permissions to the Acquisitions group
 INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable) VALUES ((SELECT id FROM permission.grp_tree WHERE name = 'Acquisitions'), (SELECT id FROM permission.perm_list WHERE code = 'GENERAL_ACQ'), 1, false);

Modified: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.0-1.6.0.1-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.0-1.6.0.1-upgrade-db.sql	2010-05-26 18:07:46 UTC (rev 16507)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.0-1.6.0.1-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -1,5 +1,5 @@
 /*
- * Copyright (C) 2009  Equinox Software, Inc.
+ * Copyright (C) 2010  Equinox Software, Inc.
  * Mike Rylander <miker at esilibrary.com>
  *
  * This program is free software; you can redistribute it and/or
@@ -15,6 +15,8 @@
  */
 
 
+BEGIN;
+
 INSERT INTO config.upgrade_log (version) VALUES ('1.6.0.1');
 
 CREATE OR REPLACE FUNCTION reporter.disable_materialized_simple_record_trigger () RETURNS VOID AS $$
@@ -28,3 +30,80 @@
     END;
 $$ LANGUAGE plpgsql;
 
+ALTER TABLE permission.grp_penalty_threshold DROP CONSTRAINT penalty_grp_once;
+ALTER TABLE permission.grp_penalty_threshold ADD CONSTRAINT penalty_grp_once UNIQUE (grp,penalty,org_unit); 
+
+CREATE OR REPLACE FUNCTION vandelay.ingest_bib_items ( ) RETURNS TRIGGER AS $func$
+DECLARE
+    attr_def    BIGINT;
+    item_data   vandelay.import_item%ROWTYPE;
+BEGIN
+
+    SELECT item_attr_def INTO attr_def FROM vandelay.bib_queue WHERE id = NEW.queue;
+
+    FOR item_data IN SELECT * FROM vandelay.ingest_items( NEW.id::BIGINT, attr_def ) LOOP
+        INSERT INTO vandelay.import_item (
+            record,
+            definition,
+            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,
+            opac_visible
+        ) VALUES (
+            NEW.id,
+            item_data.definition,
+            item_data.owning_lib,
+            item_data.circ_lib,
+            item_data.call_number,
+            item_data.copy_number,
+            item_data.status,
+            item_data.location,
+            item_data.circulate,
+            item_data.deposit,
+            item_data.deposit_amount,
+            item_data.ref,
+            item_data.holdable,
+            item_data.price,
+            item_data.barcode,
+            item_data.circ_modifier,
+            item_data.circ_as_type,
+            item_data.alert_message,
+            item_data.pub_note,
+            item_data.priv_note,
+            item_data.opac_visible
+        );
+    END LOOP;
+
+    RETURN NULL;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+UPDATE config.z3950_attr SET truncation = 1 WHERE source = 'biblios' AND name = 'title';
+
+COMMIT;
+
+INSERT INTO config.i18n_locale (code,marc_code,name,description)
+    VALUES ('cs-CZ', 'cze', oils_i18n_gettext('cs-CZ', 'Czech', 'i18n_l', 'name'), oils_i18n_gettext('cs-CZ', 'Czech', 'i18n_l', 'description'));
+INSERT INTO config.i18n_locale (code,marc_code,name,description)
+    VALUES ('ru-RU', 'rus', oils_i18n_gettext('ru-RU', 'Russian', 'i18n_l', 'name'), oils_i18n_gettext('ru-RU', 'Russian', 'i18n_l', 'description'));
+
+CREATE RULE protect_mfhd_delete AS ON DELETE TO serial.record_entry DO INSTEAD UPDATE serial.record_entry SET deleted = true WHERE old.id = serial.record_entry.id;
+
+INSERT INTO permission.perm_list (code) VALUES ('MERGE_USERS');
+
+

Added: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.1-1.6.0.2-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.1-1.6.0.2-upgrade-db.sql	                        (rev 0)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.1-1.6.0.2-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -0,0 +1,25 @@
+/*
+ * Copyright (C) 2010  Equinox Software, Inc.
+ * Mike Rylander <miker at esilibrary.com>
+ *
+ * This program is free software; you can redistribute it and/or
+ * modify it under the terms of the GNU General Public License
+ * as published by the Free Software Foundation; either version 2
+ * of the License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU General Public License for more details.
+ *
+ */
+
+
+
+INSERT INTO config.upgrade_log (version) VALUES ('1.6.0.1');
+
+INSERT INTO config.billing_type (id, name, owner) VALUES
+    ( 101, oils_i18n_gettext(101, 'Misc', 'cbt', 'name'), 1);
+ 
+SELECT SETVAL('config.billing_type_id_seq'::TEXT, (SELECT MAX(id) FROM config.billing_type));
+

Added: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.2-1.6.0.3-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.2-1.6.0.3-upgrade-db.sql	                        (rev 0)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.2-1.6.0.3-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -0,0 +1,20 @@
+/*
+ * Copyright (C) 2010  Equinox Software, Inc.
+ * Mike Rylander <miker at esilibrary.com>
+ *
+ * This program is free software; you can redistribute it and/or
+ * modify it under the terms of the GNU General Public License
+ * as published by the Free Software Foundation; either version 2
+ * of the License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU General Public License for more details.
+ *
+ */
+
+
+
+INSERT INTO config.upgrade_log (version) VALUES ('1.6.0.3');
+

Added: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.3-1.6.0.4-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.3-1.6.0.4-upgrade-db.sql	                        (rev 0)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.3-1.6.0.4-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -0,0 +1,733 @@
+/*
+ * Copyright (C) 2010 Laurentian University
+ * Dan Scott <dscott at laurentian.ca>
+ * Copyright (C) 2010  Equinox Software, Inc.
+ * Mike Rylander <miker at esilibrary.com>
+ *
+ * This program is free software; you can redistribute it and/or
+ * modify it under the terms of the GNU General Public License
+ * as published by the Free Software Foundation; either version 2
+ * of the License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU General Public License for more details.
+ *
+ */
+
+BEGIN;
+
+INSERT INTO config.upgrade_log(version) VALUES ('1.6.0.4');
+
+-- remove the metarecord link for "deleted" records
+CREATE OR REPLACE RULE protect_bib_rec_delete AS ON DELETE TO biblio.record_entry DO INSTEAD (UPDATE biblio.record_entry SET deleted = TRUE WHERE OLD.id = biblio.record_entry.id; DELETE FROM metabib.metarecord_source_map WHERE source = OLD.id);
+
+-- Match ingest fixes for leading / trailing whitespace on ISSNs and date ranges
+UPDATE metabib.real_full_rec
+    SET value = TRIM(value)
+    WHERE (tag = '022' AND subfield = 'a')
+        OR (tag = '100' AND subfield = 'd')
+;
+
+-- Correct reporter view definitions for ISSNs now that they contain spaces instead of hyphens
+CREATE OR REPLACE VIEW reporter.simple_record AS
+SELECT	r.id,
+	s.metarecord,
+	r.fingerprint,
+	r.quality,
+	r.tcn_source,
+	r.tcn_value,
+	title.value AS title,
+	uniform_title.value AS uniform_title,
+	author.value AS author,
+	publisher.value AS publisher,
+	SUBSTRING(pubdate.value FROM $$\d+$$) AS pubdate,
+	series_title.value AS series_title,
+	series_statement.value AS series_statement,
+	summary.value AS summary,
+	ARRAY_ACCUM( SUBSTRING(isbn.value FROM $$^\S+$$) ) AS isbn,
+	ARRAY_ACCUM( DISTINCT SUBSTRING(REGEXP_REPLACE(issn.value, E'^\\s*(\\d{4})[-\\s](\\d{3,4}x?)\\s*', E'\\1 \\2') FROM 1 FOR 9)) AS issn,
+	ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '650' AND subfield = 'a' AND record = r.id)) AS topic_subject,
+	ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '651' AND subfield = 'a' AND record = r.id)) AS geographic_subject,
+	ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '655' AND subfield = 'a' AND record = r.id)) AS genre,
+	ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '600' AND subfield = 'a' AND record = r.id)) AS name_subject,
+	ARRAY((SELECT DISTINCT value FROM metabib.full_rec WHERE tag = '610' AND subfield = 'a' AND record = r.id)) AS corporate_subject,
+	ARRAY((SELECT value FROM metabib.full_rec WHERE tag = '856' AND subfield IN ('3','y','u') AND record = r.id ORDER BY CASE WHEN subfield IN ('3','y') THEN 0 ELSE 1 END)) AS external_uri
+  FROM	biblio.record_entry r
+	JOIN metabib.metarecord_source_map s ON (s.source = r.id)
+	LEFT JOIN metabib.full_rec uniform_title ON (r.id = uniform_title.record AND uniform_title.tag = '240' AND uniform_title.subfield = 'a')
+	LEFT JOIN metabib.full_rec title ON (r.id = title.record AND title.tag = '245' AND title.subfield = 'a')
+	LEFT JOIN metabib.full_rec author ON (r.id = author.record AND author.tag = '100' AND author.subfield = 'a')
+	LEFT JOIN metabib.full_rec publisher ON (r.id = publisher.record AND publisher.tag = '260' AND publisher.subfield = 'b')
+	LEFT JOIN metabib.full_rec pubdate ON (r.id = pubdate.record AND pubdate.tag = '260' AND pubdate.subfield = 'c')
+	LEFT JOIN metabib.full_rec isbn ON (r.id = isbn.record AND isbn.tag IN ('024', '020') AND isbn.subfield IN ('a','z'))
+	LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a')
+	LEFT JOIN metabib.full_rec series_title ON (r.id = series_title.record AND series_title.tag IN ('830','440') AND series_title.subfield = 'a')
+	LEFT JOIN metabib.full_rec series_statement ON (r.id = series_statement.record AND series_statement.tag = '490' AND series_statement.subfield = 'a')
+	LEFT JOIN metabib.full_rec summary ON (r.id = summary.record AND summary.tag = '520' AND summary.subfield = 'a')
+  GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14;
+
+
+CREATE OR REPLACE VIEW reporter.old_super_simple_record AS
+SELECT	r.id,
+	r.fingerprint,
+	r.quality,
+	r.tcn_source,
+	r.tcn_value,
+	title.value AS title,
+	FIRST(author.value) AS author,
+	publisher.value AS publisher,
+	SUBSTRING(pubdate.value FROM $$\d+$$) AS pubdate,
+	ARRAY_ACCUM( DISTINCT SUBSTRING(isbn.value FROM $$^\S+$$) ) AS isbn,
+	ARRAY_ACCUM( DISTINCT SUBSTRING(REGEXP_REPLACE(issn.value, E'^\\s*(\\d{4})[-\\s](\\d{3,4}x?)\\s*', E'\\1 \\2') FROM 1 FOR 9) ) AS issn
+  FROM biblio.record_entry r
+	LEFT JOIN metabib.full_rec title ON (r.id = title.record AND title.tag = '245' AND title.subfield = 'a')
+	LEFT JOIN metabib.full_rec author ON (r.id = author.record AND author.tag IN ('100','110','111') AND author.subfield = 'a')
+	LEFT JOIN metabib.full_rec publisher ON (r.id = publisher.record AND publisher.tag = '260' AND publisher.subfield = 'b')
+	LEFT JOIN metabib.full_rec pubdate ON (r.id = pubdate.record AND pubdate.tag = '260' AND pubdate.subfield = 'c')
+	LEFT JOIN metabib.full_rec isbn ON (r.id = isbn.record AND isbn.tag IN ('024', '020') AND isbn.subfield IN ('a','z'))
+	LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a')
+  GROUP BY 1,2,3,4,5,6,8,9;
+
+-- Now rebuild the materialized simple record table that was built on reporter.old_super_simple_record
+-- If you're using Slony, delete instead of truncate!
+
+--DELETE FROM materialized.simple_record;
+TRUNCATE TABLE materialized.simple_record;
+
+INSERT INTO materialized.simple_record
+    SELECT * FROM reporter.old_super_simple_record;
+
+-- Replace the billable transaction summary view with one that is more cautious about NULL values
+CREATE OR REPLACE VIEW money.billable_xact_summary AS
+	SELECT	xact.id,
+		xact.usr,
+		xact.xact_start,
+		xact.xact_finish,
+		COALESCE(credit.amount, 0.0::numeric) AS total_paid,
+		credit.payment_ts AS last_payment_ts,
+		credit.note AS last_payment_note,
+		credit.payment_type AS last_payment_type,
+		COALESCE(debit.amount, 0.0::numeric) AS total_owed,
+		debit.billing_ts AS last_billing_ts,
+		debit.note AS last_billing_note,
+		debit.billing_type AS last_billing_type,
+		COALESCE(debit.amount, 0.0::numeric) - COALESCE(credit.amount, 0.0::numeric) AS balance_owed,
+		p.relname AS xact_type
+	  FROM	money.billable_xact xact
+		JOIN pg_class p ON xact.tableoid = p.oid
+		LEFT JOIN (
+			SELECT	billing.xact,
+				sum(billing.amount) AS amount,
+				max(billing.billing_ts) AS billing_ts,
+				last(billing.note) AS note,
+				last(billing.billing_type) AS billing_type
+			  FROM	money.billing
+			  WHERE	billing.voided IS FALSE
+			  GROUP BY billing.xact
+			) debit ON xact.id = debit.xact
+		LEFT JOIN (
+			SELECT	payment_view.xact,
+				sum(payment_view.amount) AS amount,
+				max(payment_view.payment_ts) AS payment_ts,
+				last(payment_view.note) AS note,
+				last(payment_view.payment_type) AS payment_type
+			  FROM	money.payment_view
+			  WHERE	payment_view.voided IS FALSE
+			  GROUP BY payment_view.xact
+			) credit ON xact.id = credit.xact
+	  ORDER BY debit.billing_ts, credit.payment_ts;
+
+/* BEFORE or AFTER trigger only! */
+CREATE OR REPLACE FUNCTION money.mat_summary_update () RETURNS TRIGGER AS $$
+BEGIN
+	UPDATE	money.materialized_billable_xact_summary
+	  SET	usr = NEW.usr,
+		xact_start = NEW.xact_start,
+		xact_finish = NEW.xact_finish
+	  WHERE	id = NEW.id;
+	RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- And rebuild the materialized view that was built on money.billable_xact_summary
+TRUNCATE TABLE money.materialized_billable_xact_summary;
+INSERT INTO TABLE money.materialized_billable_xact_summary
+	SELECT * FROM money.billable_xact_summary;
+
+-- Updated in-db circ and functions which return a matchpoint whenever possible, for override
+CREATE OR REPLACE FUNCTION action.item_user_circ_test( circ_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS SETOF action.matrix_test_result AS $func$
+DECLARE
+    user_object        actor.usr%ROWTYPE;
+    standing_penalty    config.standing_penalty%ROWTYPE;
+    item_object        asset.copy%ROWTYPE;
+    item_status_object    config.copy_status%ROWTYPE;
+    item_location_object    asset.copy_location%ROWTYPE;
+    result            action.matrix_test_result;
+    circ_test        config.circ_matrix_matchpoint%ROWTYPE;
+    out_by_circ_mod        config.circ_matrix_circ_mod_test%ROWTYPE;
+    circ_mod_map        config.circ_matrix_circ_mod_test_map%ROWTYPE;
+    penalty_type         TEXT;
+    tmp_grp         INT;
+    items_out        INT;
+    context_org_list        INT[];
+    done            BOOL := FALSE;
+BEGIN
+    result.success := TRUE;
+
+    -- Fail if the user is BARRED
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+    -- Fail if we couldn't find the user 
+    IF user_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+    -- Fail if we couldn't find the item 
+    IF item_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO circ_test * FROM action.find_circ_matrix_matchpoint(circ_ou, match_item, match_user, renewal);
+    result.matchpoint := circ_test.id;
+
+    -- Fail if we couldn't find a matchpoint
+    IF result.matchpoint IS NULL THEN
+        result.fail_part := 'no_matchpoint';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    IF user_object.barred IS TRUE THEN
+        result.fail_part := 'actor.usr.barred';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate
+    IF item_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item isn't in a circulateable status on a non-renewal
+    IF NOT renewal AND item_object.status NOT IN ( 0, 7, 8 ) THEN 
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    ELSIF renewal AND item_object.status <> 1 THEN
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate because of the shelving location
+    SELECT INTO item_location_object * FROM asset.copy_location WHERE id = item_object.location;
+    IF item_location_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy_location.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( circ_test.org_unit );
+
+    -- Fail if the test is set to hard non-circulating
+    IF circ_test.circulate IS FALSE THEN
+        result.fail_part := 'config.circ_matrix_test.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    IF renewal THEN
+        penalty_type = '%RENEW%';
+    ELSE
+        penalty_type = '%CIRC%';
+    END IF;
+
+    FOR standing_penalty IN
+        SELECT  DISTINCT csp.*
+          FROM  actor.usr_standing_penalty usp
+                JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+          WHERE usr = match_user
+                AND usp.org_unit IN ( SELECT * FROM explode_array(context_org_list) )
+                AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                AND csp.block_list LIKE penalty_type LOOP
+
+        result.fail_part := standing_penalty.name;
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END LOOP;
+
+    -- Fail if the user has too many items with specific circ_modifiers checked out
+    FOR out_by_circ_mod IN SELECT * FROM config.circ_matrix_circ_mod_test WHERE matchpoint = circ_test.id LOOP
+        SELECT  INTO items_out COUNT(*)
+          FROM  action.circulation circ
+            JOIN asset.copy cp ON (cp.id = circ.target_copy)
+          WHERE circ.usr = match_user
+               AND circ.circ_lib IN ( SELECT * FROM explode_array(context_org_list) )
+            AND circ.checkin_time IS NULL
+            AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL)
+            AND cp.circ_modifier IN (SELECT circ_mod FROM config.circ_matrix_circ_mod_test_map WHERE circ_mod_test = out_by_circ_mod.id);
+        IF items_out >= out_by_circ_mod.items_out THEN
+            result.fail_part := 'config.circ_matrix_circ_mod_test';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END LOOP;
+
+    -- If we passed everything, return the successful matchpoint id
+    IF NOT done THEN
+        RETURN NEXT result;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION action.hold_request_permit_test( pickup_ou INT, request_ou INT, match_item BIGINT, match_user INT, match_requestor INT ) RETURNS SETOF action.matrix_test_result AS $func$
+DECLARE
+    matchpoint_id        INT;
+    user_object        actor.usr%ROWTYPE;
+    age_protect_object    config.rule_age_hold_protect%ROWTYPE;
+    standing_penalty    config.standing_penalty%ROWTYPE;
+    transit_range_ou_type    actor.org_unit_type%ROWTYPE;
+    transit_source        actor.org_unit%ROWTYPE;
+    item_object        asset.copy%ROWTYPE;
+    result            action.matrix_test_result;
+    hold_test        config.hold_matrix_matchpoint%ROWTYPE;
+    hold_count        INT;
+    hold_transit_prox    INT;
+    frozen_hold_count    INT;
+    context_org_list    INT[];
+    done            BOOL := FALSE;
+BEGIN
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+    SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( pickup_ou );
+
+    result.success := TRUE;
+
+    -- Fail if we couldn't find a user
+    IF user_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+    -- Fail if we couldn't find a copy
+    IF item_object.id IS NULL THEN
+        result.fail_part := 'no_item';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO matchpoint_id action.find_hold_matrix_matchpoint(pickup_ou, request_ou, match_item, match_user, match_requestor);
+    result.matchpoint := matchpoint_id;
+
+    -- Fail if user is barred
+    IF user_object.barred IS TRUE THEN
+        result.fail_part := 'actor.usr.barred';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    -- Fail if we couldn't find any matchpoint (requires a default)
+    IF matchpoint_id IS NULL THEN
+        result.fail_part := 'no_matchpoint';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO hold_test * FROM config.hold_matrix_matchpoint WHERE id = matchpoint_id;
+
+    IF hold_test.holdable IS FALSE THEN
+        result.fail_part := 'config.hold_matrix_test.holdable';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    IF hold_test.transit_range IS NOT NULL THEN
+        SELECT INTO transit_range_ou_type * FROM actor.org_unit_type WHERE id = hold_test.transit_range;
+        IF hold_test.distance_is_from_owner THEN
+            SELECT INTO transit_source ou.* FROM actor.org_unit ou JOIN asset.call_number cn ON (cn.owning_lib = ou.id) WHERE cn.id = item_object.call_number;
+        ELSE
+            SELECT INTO transit_source * FROM actor.org_unit WHERE id = item_object.circ_lib;
+        END IF;
+
+        PERFORM * FROM actor.org_unit_descendants( transit_source.id, transit_range_ou_type.depth ) WHERE id = pickup_ou;
+
+        IF NOT FOUND THEN
+            result.fail_part := 'transit_range';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+ 
+    FOR standing_penalty IN
+        SELECT  DISTINCT csp.*
+          FROM  actor.usr_standing_penalty usp
+                JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+          WHERE usr = match_user
+                AND usp.org_unit IN ( SELECT * FROM explode_array(context_org_list) )
+                AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                AND csp.block_list LIKE '%HOLD%' LOOP
+
+        result.fail_part := standing_penalty.name;
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END LOOP;
+
+    IF hold_test.stop_blocked_user IS TRUE THEN
+        FOR standing_penalty IN
+            SELECT  DISTINCT csp.*
+              FROM  actor.usr_standing_penalty usp
+                    JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+              WHERE usr = match_user
+                    AND usp.org_unit IN ( SELECT * FROM explode_array(context_org_list) )
+                    AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                    AND csp.block_list LIKE '%CIRC%' LOOP
+    
+            result.fail_part := standing_penalty.name;
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END LOOP;
+    END IF;
+
+    IF hold_test.max_holds IS NOT NULL THEN
+        SELECT    INTO hold_count COUNT(*)
+          FROM    action.hold_request
+          WHERE    usr = match_user
+            AND fulfillment_time IS NULL
+            AND cancel_time IS NULL
+            AND CASE WHEN hold_test.include_frozen_holds THEN TRUE ELSE frozen IS FALSE END;
+
+        IF hold_count >= hold_test.max_holds THEN
+            result.fail_part := 'config.hold_matrix_test.max_holds';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    IF item_object.age_protect IS NOT NULL THEN
+        SELECT INTO age_protect_object * FROM config.rule_age_hold_protect WHERE id = item_object.age_protect;
+
+        IF item_object.create_date + age_protect_object.age > NOW() THEN
+            IF hold_test.distance_is_from_owner THEN
+                SELECT INTO hold_transit_prox prox FROM actor.org_unit_prox WHERE from_org = item_cn_object.owning_lib AND to_org = pickup_ou;
+            ELSE
+                SELECT INTO hold_transit_prox prox FROM actor.org_unit_prox WHERE from_org = item_object.circ_lib AND to_org = pickup_ou;
+            END IF;
+
+            IF hold_transit_prox > age_protect_object.prox THEN
+                result.fail_part := 'config.rule_age_hold_protect.prox';
+                result.success := FALSE;
+                done := TRUE;
+                RETURN NEXT result;
+            END IF;
+        END IF;
+    END IF;
+
+    IF NOT done THEN
+        RETURN NEXT result;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION permission.usr_has_perm_at_nd(
+	user_id    IN INTEGER,
+	perm_code  IN TEXT
+)
+RETURNS SETOF INTEGER AS $$
+--
+-- Return a set of all the org units for which a given user has a given
+-- permission, granted directly (not through inheritance from a parent
+-- org unit).
+--
+-- The permissions apply to a minimum depth of the org unit hierarchy,
+-- for the org unit(s) to which the user is assigned.  (They also apply
+-- to the subordinates of those org units, but we don't report the
+-- subordinates here.)
+--
+-- For purposes of this function, the permission.usr_work_ou_map table
+-- defines which users belong to which org units.  I.e. we ignore the
+-- home_ou column of actor.usr.
+--
+-- The result set may contain duplicates, which should be eliminated
+-- by a DISTINCT clause.
+--
+DECLARE
+	b_super       BOOLEAN;
+	n_perm        INTEGER;
+	n_min_depth   INTEGER; 
+	n_work_ou     INTEGER;
+	n_curr_ou     INTEGER;
+	n_depth       INTEGER;
+	n_curr_depth  INTEGER;
+BEGIN
+	--
+	-- Check for superuser
+	--
+	SELECT INTO b_super
+		super_user
+	FROM
+		actor.usr
+	WHERE
+		id = user_id;
+	--
+	IF NOT FOUND THEN
+		return;				-- No user?  No permissions.
+	ELSIF b_super THEN
+		--
+		-- Super user has all permissions everywhere
+		--
+		FOR n_work_ou IN
+			SELECT
+				id
+			FROM
+				actor.org_unit
+			WHERE
+				parent_ou IS NULL
+		LOOP
+			RETURN NEXT n_work_ou; 
+		END LOOP;
+		RETURN;
+	END IF;
+	--
+	-- Translate the permission name
+	-- to a numeric permission id
+	--
+	SELECT INTO n_perm
+		id
+	FROM
+		permission.perm_list
+	WHERE
+		code = perm_code;
+	--
+	IF NOT FOUND THEN
+		RETURN;               -- No such permission
+	END IF;
+	--
+	-- Find the highest-level org unit (i.e. the minimum depth)
+	-- to which the permission is applied for this user
+	--
+	-- This query is modified from the one in permission.usr_perms().
+	--
+	SELECT INTO n_min_depth
+		min( depth )
+	FROM	(
+		SELECT depth 
+		  FROM permission.usr_perm_map upm
+		 WHERE upm.usr = user_id 
+		   AND (upm.perm = n_perm OR upm.perm = -1)
+       				UNION
+		SELECT	gpm.depth
+		  FROM	permission.grp_perm_map gpm
+		  WHERE	(gpm.perm = n_perm OR gpm.perm = -1)
+	        AND gpm.grp IN (
+	 		   SELECT	(permission.grp_ancestors(
+					(SELECT profile FROM actor.usr WHERE id = user_id)
+				)).id
+			)
+       				UNION
+		SELECT	p.depth
+		  FROM	permission.grp_perm_map p 
+		  WHERE (p.perm = n_perm OR p.perm = -1)
+		    AND p.grp IN (
+		  		SELECT (permission.grp_ancestors(m.grp)).id 
+				FROM   permission.usr_grp_map m
+				WHERE  m.usr = user_id
+			)
+	) AS x;
+	--
+	IF NOT FOUND THEN
+		RETURN;                -- No such permission for this user
+	END IF;
+	--
+	-- Identify the org units to which the user is assigned.  Note that
+	-- we pay no attention to the home_ou column in actor.usr.
+	--
+	FOR n_work_ou IN
+		SELECT
+			work_ou
+		FROM
+			permission.usr_work_ou_map
+		WHERE
+			usr = user_id
+	LOOP            -- For each org unit to which the user is assigned
+		--
+		-- Determine the level of the org unit by a lookup in actor.org_unit_type.
+		-- We take it on faith that this depth agrees with the actual hierarchy
+		-- defined in actor.org_unit.
+		--
+		SELECT INTO n_depth
+		    type.depth
+		FROM
+		    actor.org_unit_type type
+		        INNER JOIN actor.org_unit ou
+		            ON ( ou.ou_type = type.id )
+		WHERE
+		    ou.id = n_work_ou;
+		--
+		IF NOT FOUND THEN
+			CONTINUE;        -- Maybe raise exception?
+		END IF;
+		--
+		-- Compare the depth of the work org unit to the
+		-- minimum depth, and branch accordingly
+		--
+		IF n_depth = n_min_depth THEN
+			--
+			-- The org unit is at the right depth, so return it.
+			--
+			RETURN NEXT n_work_ou;
+		ELSIF n_depth > n_min_depth THEN
+			--
+			-- Traverse the org unit tree toward the root,
+			-- until you reach the minimum depth determined above
+			--
+			n_curr_depth := n_depth;
+			n_curr_ou := n_work_ou;
+			WHILE n_curr_depth > n_min_depth LOOP
+				SELECT INTO n_curr_ou
+					parent_ou
+				FROM
+					actor.org_unit
+				WHERE
+					id = n_curr_ou;
+				--
+				IF FOUND THEN
+					n_curr_depth := n_curr_depth - 1;
+				ELSE
+					--
+					-- This can happen only if the hierarchy defined in
+					-- actor.org_unit is corrupted, or out of sync with
+					-- the depths defined in actor.org_unit_type.
+					-- Maybe we should raise an exception here, instead
+					-- of silently ignoring the problem.
+					--
+					n_curr_ou = NULL;
+					EXIT;
+				END IF;
+			END LOOP;
+			--
+			IF n_curr_ou IS NOT NULL THEN
+				RETURN NEXT n_curr_ou;
+			END IF;
+		ELSE
+			--
+			-- The permission applies only at a depth greater than the work org unit.
+			-- Use connectby() to find all dependent org units at the specified depth.
+			--
+			FOR n_curr_ou IN
+				SELECT ou::INTEGER
+				FROM connectby( 
+						'actor.org_unit',         -- table name
+						'id',                     -- key column
+						'parent_ou',              -- recursive foreign key
+						n_work_ou::TEXT,          -- id of starting point
+						(n_min_depth - n_depth)   -- max depth to search, relative
+					)                             --   to starting point
+					AS t(
+						ou text,            -- dependent org unit
+						parent_ou text,     -- (ignore)
+						level int           -- depth relative to starting point
+					)
+				WHERE
+					level = n_min_depth - n_depth
+			LOOP
+				RETURN NEXT n_curr_ou;
+			END LOOP;
+		END IF;
+		--
+	END LOOP;
+	--
+	RETURN;
+	--
+END;
+$$ LANGUAGE 'plpgsql';
+
+
+COMMIT;
+
+-- Ability to import a record with a different TCN
+INSERT INTO permission.perm_list (code, description) VALUES ('ALLOW_ALT_TCN', 'Allows staff to import a record using an alternate TCN to avoid conflicts');
+
+-- Ability to merge users
+INSERT INTO permission.perm_list (code, description) VALUES ('MERGE_USERS', 'Allows user records to be merged');
+
+-- More trigger event definition permissions
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_EVENT_DEF', 'Allow a user to administer trigger event definitions');
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_CLEANUP', 'Allow a user to create, delete, and update trigger cleanup entries');
+INSERT INTO permission.perm_list (code, description) VALUES ('CREATE_TRIGGER_CLEANUP', 'Allow a user to create trigger cleanup entries');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_CLEANUP', 'Allow a user to delete trigger cleanup entries');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_TRIGGER_CLEANUP', 'Allow a user to update trigger cleanup entries');
+INSERT INTO permission.perm_list (code, description) VALUES ('CREATE_TRIGGER_EVENT_DEF', 'Allow a user to create trigger event definitions');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_EVENT_DEF', 'Allow a user to delete trigger event definitions');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_TRIGGER_EVENT_DEF', 'Allow a user to update trigger event definitions');
+INSERT INTO permission.perm_list (code, description) VALUES ('VIEW_TRIGGER_EVENT_DEF', 'Allow a user to view trigger event definitions');
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_HOOK', 'Allow a user to create, update, and delete trigger hooks');
+INSERT INTO permission.perm_list (code, description) VALUES ('CREATE_TRIGGER_HOOK', 'Allow a user to create trigger hooks');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_HOOK', 'Allow a user to delete trigger hooks');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_TRIGGER_HOOK', 'Allow a user to update trigger hooks');
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_REACTOR', 'Allow a user to create, update, and delete trigger reactors');
+INSERT INTO permission.perm_list (code, description) VALUES ('CREATE_TRIGGER_REACTOR', 'Allow a user to create trigger reactors');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_REACTOR', 'Allow a user to delete trigger reactors');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_TRIGGER_REACTOR', 'Allow a user to update trigger reactors');
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_TEMPLATE_OUTPUT', 'Allow a user to delete trigger template output');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_TEMPLATE_OUTPUT', 'Allow a user to delete trigger template output');
+INSERT INTO permission.perm_list (code, description) VALUES ('ADMIN_TRIGGER_VALIDATOR', 'Allow a user to create, update, and delete trigger validators');
+INSERT INTO permission.perm_list (code, description) VALUES ('CREATE_TRIGGER_VALIDATOR', 'Allow a user to create trigger validators');
+INSERT INTO permission.perm_list (code, description) VALUES ('DELETE_TRIGGER_VALIDATOR', 'Allow a user to delete trigger validators');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_TRIGGER_VALIDATOR', 'Allow a user to update trigger validators');
+INSERT INTO permission.perm_list (code, description) VALUES ('UPDATE_ORG_UNIT_SETTING.circ.block_renews_for_holds','Allow a user to enable blocking of renews on items that could fulfill holds');
+
+
+-- Add trigger administration permissions to the Local System Administrator group
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable)
+    SELECT 10, id, 1, false FROM permission.perm_list
+        WHERE code LIKE 'ADMIN_TRIGGER%'
+            OR code LIKE 'CREATE_TRIGGER%'
+            OR code LIKE 'DELETE_TRIGGER%'
+            OR code LIKE 'UPDATE_TRIGGER%'
+;
+-- View trigger permissions are required at a consortial level for initial setup
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable)
+    SELECT 10, id, 0, false FROM permission.perm_list WHERE code LIKE 'VIEW_TRIGGER%';
+

Modified: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.4-1.6.1.0-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.4-1.6.1.0-upgrade-db.sql	2010-05-26 18:07:46 UTC (rev 16507)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.0.4-1.6.1.0-upgrade-db.sql	2010-05-26 18:10:30 UTC (rev 16508)
@@ -36,7 +36,7 @@
 
 INSERT INTO action_trigger.hook (key,core_type,description) VALUES ('password.reset_request','aupr','Patron has requested a self-serve password reset');
 INSERT INTO action_trigger.event_definition (id, active, owner, name, hook, validator, reactor, delay, template) 
-    VALUES (15, 'f', 1, 'Password reset request notification', 'password.reset_request', 'NOOP_True', 'SendEmail', '00:00:01',
+    VALUES (NEXTVAL('action_trigger.event_definition_id_seq'), 'f', 1, 'Password reset request notification', 'password.reset_request', 'NOOP_True', 'SendEmail', '00:00:01',
 $$
 [%- USE date -%]
 [%- user = target.usr -%]
@@ -62,8 +62,700 @@
 
 $$);
 INSERT INTO action_trigger.environment ( event_def, path) VALUES
-    ( 15, 'usr' );
+    ( CURRVAL('action_trigger.event_definition_id_seq'), 'usr' );
 INSERT INTO action_trigger.environment ( event_def, path) VALUES
-    ( 15, 'usr.home_ou' );
+    ( CURRVAL('action_trigger.event_definition_id_seq'), 'usr.home_ou' );
 
+-- Column telling us when the item hit the holds shelf
+ALTER TABLE action.hold_request ADD COLUMN shelf_time TIMESTAMP WITH TIME ZONE;
+
+-- Booking schema
+CREATE SCHEMA booking;
+
+CREATE TABLE booking.resource_type (
+	id             SERIAL          PRIMARY KEY,
+	name           TEXT            NOT NULL,
+	elbow_room     INTERVAL,
+	fine_interval  INTERVAL,
+	fine_amount    DECIMAL(8,2)    NOT NULL DEFAULT 0,
+	max_fine       DECIMAL(8,2),
+	owner          INT             NOT NULL
+	                               REFERENCES actor.org_unit( id )
+	                               DEFERRABLE INITIALLY DEFERRED,
+	catalog_item   BOOLEAN         NOT NULL DEFAULT FALSE,
+	transferable   BOOLEAN         NOT NULL DEFAULT FALSE,
+    record         INT             REFERENCES biblio.record_entry (id)
+                                   DEFERRABLE INITIALLY DEFERRED,
+	CONSTRAINT brt_name_once_per_owner UNIQUE(owner, name, record)
+);
+
+CREATE TABLE booking.resource (
+	id             SERIAL           PRIMARY KEY,
+	owner          INT              NOT NULL
+	                                REFERENCES actor.org_unit(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	type           INT              NOT NULL
+	                                REFERENCES booking.resource_type(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	overbook       BOOLEAN          NOT NULL DEFAULT FALSE,
+	barcode        TEXT             NOT NULL,
+	deposit        BOOLEAN          NOT NULL DEFAULT FALSE,
+	deposit_amount DECIMAL(8,2)     NOT NULL DEFAULT 0.00,
+	user_fee       DECIMAL(8,2)     NOT NULL DEFAULT 0.00,
+	CONSTRAINT br_unique UNIQUE(owner, barcode)
+);
+
+-- For non-catalog items: hijack barcode for name/description
+
+CREATE TABLE booking.resource_attr (
+	id              SERIAL          PRIMARY KEY,
+	owner           INT             NOT NULL
+	                                REFERENCES actor.org_unit(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	name            TEXT            NOT NULL,
+	resource_type   INT             NOT NULL
+	                                REFERENCES booking.resource_type(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	required        BOOLEAN         NOT NULL DEFAULT FALSE,
+	CONSTRAINT bra_name_once_per_type UNIQUE(resource_type, name)
+);
+
+CREATE TABLE booking.resource_attr_value (
+	id               SERIAL         PRIMARY KEY,
+	owner            INT            NOT NULL
+	                                REFERENCES actor.org_unit(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	attr             INT            NOT NULL
+	                                REFERENCES booking.resource_attr(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	valid_value      TEXT           NOT NULL,
+	CONSTRAINT brav_logical_key UNIQUE(owner, attr, valid_value)
+);
+
+-- Do we still need a name column?
+
+
+CREATE TABLE booking.resource_attr_map (
+	id               SERIAL         PRIMARY KEY,
+	resource         INT            NOT NULL
+	                                REFERENCES booking.resource(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	resource_attr    INT            NOT NULL
+	                                REFERENCES booking.resource_attr(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	value            INT            NOT NULL
+	                                REFERENCES booking.resource_attr_value(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	CONSTRAINT bram_one_value_per_attr UNIQUE(resource, resource_attr)
+);
+
+CREATE TABLE booking.reservation (
+	request_time     TIMESTAMPTZ   NOT NULL DEFAULT now(),
+	start_time       TIMESTAMPTZ,
+	end_time         TIMESTAMPTZ,
+	capture_time     TIMESTAMPTZ,
+	cancel_time      TIMESTAMPTZ,
+	pickup_time      TIMESTAMPTZ,
+	return_time      TIMESTAMPTZ,
+	booking_interval INTERVAL,
+	fine_interval    INTERVAL,
+	fine_amount      DECIMAL(8,2),
+	max_fine         DECIMAL(8,2),
+	target_resource_type  INT       NOT NULL
+	                                REFERENCES booking.resource_type(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	target_resource  INT            REFERENCES booking.resource(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	current_resource INT            REFERENCES booking.resource(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	request_lib      INT            NOT NULL
+	                                REFERENCES actor.org_unit(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	pickup_lib       INT            REFERENCES actor.org_unit(id)
+	                                DEFERRABLE INITIALLY DEFERRED,
+	capture_staff    INT            REFERENCES actor.usr(id)
+	                                DEFERRABLE INITIALLY DEFERRED
+) INHERITS (money.billable_xact);
+
+ALTER TABLE booking.reservation ADD PRIMARY KEY (id);
+
+ALTER TABLE booking.reservation
+	ADD CONSTRAINT booking_reservation_usr_fkey
+	FOREIGN KEY (usr) REFERENCES actor.usr (id)
+	DEFERRABLE INITIALLY DEFERRED;
+
+CREATE TRIGGER mat_summary_create_tgr AFTER INSERT ON booking.reservation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_create ('reservation');
+CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON booking.reservation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
+CREATE TRIGGER mat_summary_remove_tgr AFTER DELETE ON booking.reservation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_delete ();
+
+
+CREATE TABLE booking.reservation_attr_value_map (
+	id               SERIAL         PRIMARY KEY,
+	reservation      INT            NOT NULL
+	                                REFERENCES booking.reservation(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	attr_value       INT            NOT NULL
+	                                REFERENCES booking.resource_attr_value(id)
+	                                ON DELETE CASCADE
+	                                DEFERRABLE INITIALLY DEFERRED,
+	CONSTRAINT bravm_logical_key UNIQUE(reservation, attr_value)
+);
+
+CREATE TABLE action.reservation_transit_copy (
+    reservation    INT REFERENCES booking.reservation (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED
+) INHERITS (action.transit_copy);
+ALTER TABLE action.reservation_transit_copy ADD PRIMARY KEY (id);
+ALTER TABLE action.reservation_transit_copy ADD CONSTRAINT artc_tc_fkey FOREIGN KEY (target_copy) REFERENCES booking.resource (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
+CREATE INDEX active_reservation_transit_dest_idx ON "action".reservation_transit_copy (dest);
+CREATE INDEX active_reservation_transit_source_idx ON "action".reservation_transit_copy (source);
+CREATE INDEX active_reservation_transit_cp_idx ON "action".reservation_transit_copy (target_copy);
+
+
+
+-- Add booking to penalty calc
+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;
+    tmp_grp             INT;
+    items_overdue       INT;
+    items_out           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;
+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
+
+        FOR existing_sp_row IN
+                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
+                LOOP
+            RETURN NEXT existing_sp_row;
+        END LOOP;
+
+        SELECT  SUM(f.balance_owed) INTO current_fines
+          FROM  money.materialized_billable_xact_summary f
+                JOIN (
+                    SELECT  r.id
+                      FROM  booking.reservation r
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (r.pickup_lib = fp.id)
+                      WHERE usr = match_user
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  g.id
+                      FROM  money.grocery g
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (g.billing_location = fp.id)
+                      WHERE usr = match_user
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  circ.id
+                      FROM  action.circulation circ
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (circ.circ_lib = fp.id)
+                      WHERE usr = match_user
+                            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
+
+        FOR existing_sp_row IN
+                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
+                LOOP
+            RETURN NEXT existing_sp_row;
+        END LOOP;
+
+        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
+
+        FOR existing_sp_row IN
+                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
+                LOOP
+            RETURN NEXT existing_sp_row;
+        END LOOP;
+
+        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 ('MAXFINES','LONGOVERDUE') OR circ.stop_fines 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 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
+
+        FOR existing_sp_row IN
+                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
+                LOOP
+            RETURN NEXT existing_sp_row;
+        END LOOP;
+
+        SELECT  SUM(f.balance_owed) INTO current_fines
+          FROM  money.materialized_billable_xact_summary f
+                JOIN (
+                    SELECT  r.id
+                      FROM  booking.reservation r
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (r.pickup_lib = fp.id)
+                      WHERE usr = match_user
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  g.id
+                      FROM  money.grocery g
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (g.billing_location = fp.id)
+                      WHERE usr = match_user
+                            AND xact_finish IS NULL
+                                UNION ALL
+                    SELECT  circ.id
+                      FROM  action.circulation circ
+                            JOIN  actor.org_unit_full_path( max_fines.org_unit ) fp ON (circ.circ_lib = fp.id)
+                      WHERE usr = match_user
+                            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 := 4;
+            RETURN NEXT new_sp_row;
+        END IF;
+    END IF;
+
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+-- ACQ schema cleanup ... will probably end up being dropped entirely when 2.0 arrives, but...
+ALTER TABLE acq.provider DROP CONSTRAINT provider_code_key;
+ALTER TABLE acq.provider ALTER COLUMN code SET NOT NULL;
+ALTER TABLE acq.provider ADD CONSTRAINT code_once_per_owner UNIQUE (code, owner);
+
+ALTER TABLE acq.fund DROP CONSTRAINT fund_code_key;
+ALTER TABLE acq.fund ADD CONSTRAINT code_once_per_org_year UNIQUE (org, code, year);
+
+ALTER TABLE acq.purchase_order ADD COLUMN order_date TIMESTAMP WITH TIME ZONE;
+ALTER TABLE acq.purchase_order ADD COLUMN name TEXT NOT NULL;
+
+CREATE INDEX acq_po_org_name_order_date_idx ON acq.purchase_order( ordering_agency, name, order_date );
+
+-- The name should default to the id, as text.  We can't reference a column
+-- in a DEFAULT clause, so we use a trigger:
+
+CREATE OR REPLACE FUNCTION acq.purchase_order_name_default () RETURNS TRIGGER 
+AS $$
+BEGIN
+   IF NEW.name IS NULL THEN
+       NEW.name := NEW.id::TEXT;
+   END IF;
+
+   RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER po_name_default_trg
+  BEFORE INSERT OR UPDATE ON acq.purchase_order
+  FOR EACH ROW EXECUTE PROCEDURE acq.purchase_order_name_default ();
+
+-- The order name should be unique for a given ordering agency on a given order date
+-- (truncated to midnight), but only where the order_date is not NULL.  Conceptually
+-- this rule requires a check constraint with a subquery.  However you can't have a
+-- subquery in a CHECK constraint, so we fake it with a trigger.
+
+CREATE OR REPLACE FUNCTION acq.po_org_name_date_unique () RETURNS TRIGGER 
+AS $$
+DECLARE
+   collision INT;
+BEGIN
+   --
+   -- If order_date is not null, then make sure we don't have a collision
+   -- on order_date (truncated to day), org, and name
+   --
+   IF NEW.order_date IS NULL THEN
+       RETURN NEW;
+   END IF;
+   --
+   -- In the WHERE clause, we compare the order_dates without regard to time of day.
+   -- We use a pair of inequalities instead of comparing truncated dates so that the
+   -- query can do an indexed range scan.
+   --
+   SELECT 1 INTO collision
+   FROM acq.purchase_order
+   WHERE
+       ordering_agency = NEW.ordering_agency
+       AND name = NEW.name
+       AND order_date >= date_trunc( 'day', NEW.order_date )
+       AND order_date <  date_trunc( 'day', NEW.order_date ) + '1 day'::INTERVAL
+       AND id <> NEW.id;
+   --
+   IF collision IS NULL THEN
+       -- okay, no collision
+       RETURN NEW;
+   ELSE
+       -- collision; nip it in the bud
+       RAISE EXCEPTION 'Colliding purchase orders: ordering_agency %, date %, name ''%''',
+           NEW.ordering_agency, NEW.order_date, NEW.name;
+   END IF;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER po_org_name_date_unique_trg
+  BEFORE INSERT OR UPDATE ON acq.purchase_order
+  FOR EACH ROW EXECUTE PROCEDURE acq.po_org_name_date_unique ();
+
+CREATE TABLE acq.fiscal_calendar (
+   id              SERIAL         PRIMARY KEY,
+   name            TEXT           NOT NULL
+);
+
+CREATE TABLE acq.fiscal_year (
+   id              SERIAL         PRIMARY KEY,
+   calendar        INT            NOT NULL
+                                  REFERENCES acq.fiscal_calendar
+                                  ON DELETE CASCADE
+                                  DEFERRABLE INITIALLY DEFERRED,
+   year            INT            NOT NULL,
+   year_begin      TIMESTAMPTZ    NOT NULL,
+   year_end        TIMESTAMPTZ    NOT NULL,
+   CONSTRAINT acq_fy_logical_key  UNIQUE ( calendar, year ),
+    CONSTRAINT acq_fy_physical_key UNIQUE ( calendar, year_begin )
+);
+
+CREATE OR REPLACE FUNCTION acq.find_bad_fy()
+/*
+   Examine the acq.fiscal_year table, comparing successive years.
+   Report any inconsistencies, i.e. years that overlap, have gaps
+    between them, or are out of sequence.
+*/
+RETURNS SETOF RECORD AS $$
+DECLARE
+   first_row  BOOLEAN;
+   curr_year  RECORD;
+   prev_year  RECORD;
+   return_rec RECORD;
+BEGIN
+   first_row := true;
+   FOR curr_year in
+       SELECT
+           id,
+           calendar,
+           year,
+           year_begin,
+           year_end
+       FROM
+           acq.fiscal_year
+       ORDER BY
+           calendar,
+           year_begin
+   LOOP
+       --
+       IF first_row THEN
+           first_row := FALSE;
+       ELSIF curr_year.calendar    = prev_year.calendar THEN
+           IF curr_year.year_begin > prev_year.year_end THEN
+               -- This ugly kludge works around the fact that older
+               -- versions of PostgreSQL don't support RETURN QUERY SELECT
+               FOR return_rec IN SELECT
+                   prev_year.id,
+                   prev_year.year,
+                   'Gap between fiscal years'::TEXT
+               LOOP
+                   RETURN NEXT return_rec;
+               END LOOP;
+           ELSIF curr_year.year_begin < prev_year.year_end THEN
+               FOR return_rec IN SELECT
+                   prev_year.id,
+                   prev_year.year,
+                   'Overlapping fiscal years'::TEXT
+               LOOP
+                   RETURN NEXT return_rec;
+               END LOOP;
+           ELSIF curr_year.year < prev_year.year THEN
+               FOR return_rec IN SELECT
+                   prev_year.id,
+                   prev_year.year,
+                   'Fiscal years out of order'::TEXT
+               LOOP
+                   RETURN NEXT return_rec;
+               END LOOP;
+           END IF;
+       END IF;
+       --
+       prev_year := curr_year;
+   END LOOP;
+   --
+   RETURN;
+END;
+$$ LANGUAGE plpgsql;
+
+-- More booking related updates
+CREATE OR REPLACE VIEW money.open_billable_xact_summary AS
+    SELECT  xact.id AS id,
+        xact.usr AS usr,
+        COALESCE(circ.circ_lib,groc.billing_location,res.pickup_lib) AS billing_location,
+        xact.xact_start AS xact_start,
+        xact.xact_finish AS xact_finish,
+        SUM(credit.amount) AS total_paid,
+        MAX(credit.payment_ts) AS last_payment_ts,
+        LAST(credit.note) AS last_payment_note,
+        LAST(credit.payment_type) AS last_payment_type,
+        SUM(debit.amount) AS total_owed,
+        MAX(debit.billing_ts) AS last_billing_ts,
+        LAST(debit.note) AS last_billing_note,
+        LAST(debit.billing_type) AS last_billing_type,
+        COALESCE(SUM(debit.amount),0) - COALESCE(SUM(credit.amount),0) AS balance_owed,
+        p.relname AS xact_type
+      FROM  money.billable_xact xact
+        JOIN pg_class p ON (xact.tableoid = p.oid)
+        LEFT JOIN "action".circulation circ ON (circ.id = xact.id)
+        LEFT JOIN money.grocery groc ON (groc.id = xact.id)
+        LEFT JOIN booking.reservation res ON (groc.id = xact.id)
+        LEFT JOIN (
+            SELECT  billing.xact,
+                billing.voided,
+                sum(billing.amount) AS amount,
+                max(billing.billing_ts) AS billing_ts,
+                last(billing.note) AS note,
+                last(billing.billing_type) AS billing_type
+              FROM  money.billing
+              WHERE billing.voided IS FALSE
+              GROUP BY billing.xact, billing.voided
+        ) debit ON (xact.id = debit.xact AND debit.voided IS FALSE)
+        LEFT JOIN (
+            SELECT  payment_view.xact,
+                payment_view.voided,
+                sum(payment_view.amount) AS amount,
+                max(payment_view.payment_ts) AS payment_ts,
+                last(payment_view.note) AS note,
+                last(payment_view.payment_type) AS payment_type
+              FROM  money.payment_view
+              WHERE payment_view.voided IS FALSE
+              GROUP BY payment_view.xact, payment_view.voided
+        ) credit ON (xact.id = credit.xact AND credit.voided IS FALSE)
+      WHERE xact.xact_finish IS NULL
+      GROUP BY 1,2,3,4,5,15
+      ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts);
+
+INSERT INTO config.copy_status (id,name) VALUES (15,oils_i18n_gettext(15, 'On reservation shelf', 'ccs', 'name'));
+
+INSERT INTO permission.perm_list VALUES
+    (351, 'HOLD_LOCAL_AVAIL_OVERRIDE', oils_i18n_gettext(351, 'Allow a user to place a hold despite the availability of a local copy', 'ppl', 'description')),
+    (352, 'ADMIN_BOOKING_RESOURCE', oils_i18n_gettext(352, 'Enables the user to create/update/delete booking resources', 'ppl', 'description')),
+    (353, 'ADMIN_BOOKING_RESOURCE_TYPE', oils_i18n_gettext(353, 'Enables the user to create/update/delete booking resource types', 'ppl', 'description')),
+    (354, 'ADMIN_BOOKING_RESOURCE_ATTR', oils_i18n_gettext(354, 'Enables the user to create/update/delete booking resource attributes', 'ppl', 'description')),
+    (355, 'ADMIN_BOOKING_RESOURCE_ATTR_MAP', oils_i18n_gettext(355, 'Enables the user to create/update/delete booking resource attribute maps', 'ppl', 'description')),
+    (356, 'ADMIN_BOOKING_RESOURCE_ATTR_VALUE', oils_i18n_gettext(356, 'Enables the user to create/update/delete booking resource attribute values', 'ppl', 'description')),
+    (357, 'ADMIN_BOOKING_RESERVATION', oils_i18n_gettext(357, 'Enables the user to create/update/delete booking reservations', 'ppl', 'description')),
+    (358, 'ADMIN_BOOKING_RESERVATION_ATTR_VALUE_MAP', oils_i18n_gettext(358, 'Enables the user to create/update/delete booking reservation attribute value maps', 'ppl', 'description')),
+    (359, 'HOLD_ITEM_CHECKED_OUT.override', oils_i18n_gettext(359, 'Allows a user to place a hold on an item that they already have checked out', 'ppl', 'description')),
+    (360, 'RETRIEVE_RESERVATION_PULL_LIST', oils_i18n_gettext(360, 'Allows a user to retrieve a booking reservation pull list', 'ppl', 'description')),
+    (361, 'CAPTURE_RESERVATION', oils_i18n_gettext(361, 'Allows a user to capture booking reservations', 'ppl', 'description'));
+
+SELECT SETVAL('permission.perm_list_id_seq'::TEXT, 1000);
+
+-- Pinned via 1.6.0 insert
+UPDATE action_trigger.event_definition SET delay_field = 'shelf_time' WHERE id = 5;
+
+CREATE OR REPLACE VIEW reporter.old_super_simple_record AS
+SELECT  r.id,
+    r.fingerprint,
+    r.quality,
+    r.tcn_source,
+    r.tcn_value,
+    title.value AS title,
+    FIRST(author.value) AS author,
+    ARRAY_TO_STRING(ARRAY_ACCUM( DISTINCT publisher.value), ', ') AS publisher,
+    ARRAY_TO_STRING(ARRAY_ACCUM( DISTINCT SUBSTRING(pubdate.value FROM $$\d+$$) ), ', ') AS pubdate,
+    ARRAY_ACCUM( DISTINCT SUBSTRING(isbn.value FROM $$^\S+$$) ) AS isbn,
+    ARRAY_ACCUM( DISTINCT SUBSTRING(issn.value FROM $$^\S+$$) ) AS issn
+  FROM  biblio.record_entry r
+    LEFT JOIN metabib.full_rec title ON (r.id = title.record AND title.tag = '245' AND title.subfield = 'a')
+    LEFT JOIN metabib.full_rec author ON (r.id = author.record AND author.tag IN ('100','110','111') AND author.subfield = 'a')
+    LEFT JOIN metabib.full_rec publisher ON (r.id = publisher.record AND publisher.tag = '260' AND publisher.subfield = 'b')
+    LEFT JOIN metabib.full_rec pubdate ON (r.id = pubdate.record AND pubdate.tag = '260' AND pubdate.subfield = 'c')
+    LEFT JOIN metabib.full_rec isbn ON (r.id = isbn.record AND isbn.tag IN ('024', '020') AND isbn.subfield IN ('a','z'))
+    LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a')
+  GROUP BY 1,2,3,4,5,6;
+
 COMMIT;
+
+
+
+
+



More information about the open-ils-commits mailing list