[open-ils-commits] [GIT] Evergreen ILS branch master updated. 8153d519d933571b4a0ec81d898d105ac05378f4

Evergreen Git git at git.evergreen-ils.org
Tue Mar 20 13:44:50 EDT 2012


This is an automated email from the git hooks/post-receive script. It was
generated because a ref change was pushed to the repository containing
the project "Evergreen ILS".

The branch, master has been updated
       via  8153d519d933571b4a0ec81d898d105ac05378f4 (commit)
       via  db327a6c66de2efaf1aaebbe2f0220fa65cf317f (commit)
       via  7ca2c02e3e7e08c8b067be0707670616c1bf183f (commit)
       via  60ae1d172c4abaee2744a36596dcb6ccf31a777e (commit)
      from  6b59eda856fe61c2fb85007dfb792512e8c31fd7 (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.

- Log -----------------------------------------------------------------
commit 8153d519d933571b4a0ec81d898d105ac05378f4
Author: Mike Rylander <mrylander at gmail.com>
Date:   Tue Mar 20 13:50:31 2012 -0400

    Stamping upgrade script (and updating 2.1-2.2 version upgrade script)
    
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql
index 67308e6..79916bb 100644
--- a/Open-ILS/src/sql/Pg/002.schema.config.sql
+++ b/Open-ILS/src/sql/Pg/002.schema.config.sql
@@ -86,7 +86,7 @@ CREATE TRIGGER no_overlapping_deps
     BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
     FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
 
-INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0685', :eg_version); -- tsbere/miker
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0686', :eg_version); -- tsbere/miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql b/Open-ILS/src/sql/Pg/upgrade/0686.schema.auditor_boost.sql
similarity index 98%
rename from Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql
rename to Open-ILS/src/sql/Pg/upgrade/0686.schema.auditor_boost.sql
index edaf795..9ec8145 100644
--- a/Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql
+++ b/Open-ILS/src/sql/Pg/upgrade/0686.schema.auditor_boost.sql
@@ -1,3 +1,14 @@
+-- Evergreen DB patch 0686.schema.auditor_boost.sql
+--
+-- FIXME: insert description of change, if needed
+--
+BEGIN;
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0686', :eg_version);
+
+-- FIXME: add/check SQL statements to perform the upgrade
 -- These three functions are for capturing, getting, and clearing user and workstation information
 
 -- Set the User AND workstation in one call. Tis faster. And less calls.
@@ -274,3 +285,6 @@ $BODY$ LANGUAGE plpgsql;
 
 -- Go ahead and update them all now
 SELECT auditor.update_auditors();
+
+
+COMMIT;
diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.1-2.2-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.1-2.2-upgrade-db.sql
index 6e05201..3a9074e 100644
--- a/Open-ILS/src/sql/Pg/version-upgrade/2.1-2.2-upgrade-db.sql
+++ b/Open-ILS/src/sql/Pg/version-upgrade/2.1-2.2-upgrade-db.sql
@@ -13312,4 +13312,425 @@ CREATE TABLE asset.copy_location_group_map (
     CONSTRAINT  lgroup_once_per_group UNIQUE (lgroup,location)
 );
 
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0683', :eg_version);
+
+INSERT INTO action_trigger.event_params (event_def, param, value)
+    VALUES (5, 'check_email_notify', 1);
+INSERT INTO action_trigger.event_params (event_def, param, value)
+    VALUES (7, 'check_email_notify', 1);
+INSERT INTO action_trigger.event_params (event_def, param, value)
+    VALUES (9, 'check_email_notify', 1);
+INSERT INTO action_trigger.validator (module,description) VALUES
+    ('HoldNotifyCheck',
+    oils_i18n_gettext(
+        'HoldNotifyCheck',
+        'Check Hold notification flag(s)',
+        'atval',
+        'description'
+    ));
+UPDATE action_trigger.event_definition SET validator = 'HoldNotifyCheck' WHERE id = 9;
+
+-- NOT COVERED: Adding check_sms_notify to the proper trigger. It doesn't have a static id.
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0684', :eg_version);
+
+-- schema --
+
+-- Replace the constraints with more flexible ENUM's
+ALTER TABLE vandelay.queue DROP CONSTRAINT queue_queue_type_check;
+ALTER TABLE vandelay.bib_queue DROP CONSTRAINT bib_queue_queue_type_check;
+ALTER TABLE vandelay.authority_queue DROP CONSTRAINT authority_queue_queue_type_check;
+
+CREATE TYPE vandelay.bib_queue_queue_type AS ENUM ('bib', 'acq');
+CREATE TYPE vandelay.authority_queue_queue_type AS ENUM ('authority');
+
+-- dropped column is also implemented by the child tables
+ALTER TABLE vandelay.queue DROP COLUMN queue_type; 
+
+-- to recover after using the undo sql from below
+-- alter table vandelay.bib_queue  add column queue_type text default 'bib' not null;
+-- alter table vandelay.authority_queue  add column queue_type text default 'authority' not null;
+
+-- modify the child tables to use the ENUMs
+ALTER TABLE vandelay.bib_queue 
+    ALTER COLUMN queue_type DROP DEFAULT,
+    ALTER COLUMN queue_type TYPE vandelay.bib_queue_queue_type 
+        USING (queue_type::vandelay.bib_queue_queue_type),
+    ALTER COLUMN queue_type SET DEFAULT 'bib';
+
+ALTER TABLE vandelay.authority_queue 
+    ALTER COLUMN queue_type DROP DEFAULT,
+    ALTER COLUMN queue_type TYPE vandelay.authority_queue_queue_type 
+        USING (queue_type::vandelay.authority_queue_queue_type),
+    ALTER COLUMN queue_type SET DEFAULT 'authority';
+
+-- give lineitems a pointer to their vandelay queued_record
+
+ALTER TABLE acq.lineitem ADD COLUMN queued_record BIGINT
+    REFERENCES vandelay.queued_bib_record (id) 
+    ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED;
+
+ALTER TABLE acq.acq_lineitem_history ADD COLUMN queued_record BIGINT
+    REFERENCES vandelay.queued_bib_record (id) 
+    ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED;
+
+-- seed data --
+
+INSERT INTO permission.perm_list ( id, code, description ) 
+    VALUES ( 
+        521, 
+        'IMPORT_ACQ_LINEITEM_BIB_RECORD_UPLOAD', 
+        oils_i18n_gettext( 
+            521,
+            'Allows a user to create new bibs directly from an ACQ MARC file upload', 
+            'ppl', 
+            'description' 
+        )
+    );
+
+
+INSERT INTO vandelay.import_error ( code, description ) 
+    VALUES ( 
+        'import.record.perm_failure', 
+        oils_i18n_gettext(
+            'import.record.perm_failure', 
+            'Perm failure creating a record', 'vie', 'description') 
+    );
+
+
+
+
+-- Evergreen DB patch 0685.data.bluray_vr_format.sql
+--
+-- FIXME: insert description of change, if needed
+--
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0685', :eg_version);
+
+-- FIXME: add/check SQL statements to perform the upgrade
+DO $FUNC$
+DECLARE
+    same_marc BOOL;
+BEGIN
+    -- Check if it is already there
+    PERFORM * FROM config.marc21_physical_characteristic_value_map v
+        JOIN config.marc21_physical_characteristic_subfield_map s ON v.ptype_subfield = s.id
+        WHERE s.ptype_key = 'v' AND s.subfield = 'e' AND s.start_pos = '4' AND s.length = '1'
+            AND v.value = 's';
+
+    -- If it is, bail.
+    IF FOUND THEN
+        RETURN;
+    END IF;
+
+    -- Otherwise, insert it
+    INSERT INTO config.marc21_physical_characteristic_value_map (value,ptype_subfield,label)
+    SELECT 's',id,'Blu-ray'
+        FROM config.marc21_physical_characteristic_subfield_map
+        WHERE ptype_key = 'v' AND subfield = 'e' AND start_pos = '4' AND length = '1';
+
+    -- And reingest the blue-ray items so that things see the new value
+    SELECT INTO same_marc enabled FROM config.internal_flag WHERE name = 'ingest.reingest.force_on_same_marc';
+    UPDATE config.internal_flag SET enabled = true WHERE name = 'ingest.reingest.force_on_same_marc';
+    UPDATE biblio.record_entry SET marc=marc WHERE id IN (SELECT record
+        FROM
+            metabib.full_rec a JOIN metabib.full_rec b USING (record)
+        WHERE
+            a.tag = 'LDR' AND a.value LIKE '______g%'
+        AND b.tag = '007' AND b.value LIKE 'v___s%');
+    UPDATE config.internal_flag SET enabled = same_marc WHERE name = 'ingest.reingest.force_on_same_marc';
+END;
+$FUNC$;
+
+
+-- Evergreen DB patch 0686.schema.auditor_boost.sql
+--
+-- FIXME: insert description of change, if needed
+--
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0686', :eg_version);
+
+-- FIXME: add/check SQL statements to perform the upgrade
+-- These three functions are for capturing, getting, and clearing user and workstation information
+
+-- Set the User AND workstation in one call. Tis faster. And less calls.
+-- First argument is user, second is workstation
+CREATE OR REPLACE FUNCTION auditor.set_audit_info(INT, INT) RETURNS VOID AS $$
+    $_SHARED{"eg_audit_user"} = $_[0];
+    $_SHARED{"eg_audit_ws"} = $_[1];
+$$ LANGUAGE plperl;
+
+-- Get the User AND workstation in one call. Less calls, useful for joins ;)
+CREATE OR REPLACE FUNCTION auditor.get_audit_info() RETURNS TABLE (eg_user INT, eg_ws INT) AS $$
+    return [{eg_user => $_SHARED{"eg_audit_user"}, eg_ws => $_SHARED{"eg_audit_ws"}}];
+$$ LANGUAGE plperl;
+
+-- Clear the audit info, for whatever reason
+CREATE OR REPLACE FUNCTION auditor.clear_audit_info() RETURNS VOID AS $$
+    delete($_SHARED{"eg_audit_user"});
+    delete($_SHARED{"eg_audit_ws"});
+$$ LANGUAGE plperl;
+
+CREATE FUNCTION auditor.create_auditor_history ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+BEGIN
+    EXECUTE $$
+        CREATE TABLE auditor.$$ || sch || $$_$$ || tbl || $$_history (
+            audit_id	BIGINT				PRIMARY KEY,
+            audit_time	TIMESTAMP WITH TIME ZONE	NOT NULL,
+            audit_action	TEXT				NOT NULL,
+            audit_user  INT,
+            audit_ws    INT,
+            LIKE $$ || sch || $$.$$ || tbl || $$
+        );
+    $$;
+	RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION auditor.create_auditor_func    ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
+BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
+    EXECUTE $$
+        CREATE OR REPLACE FUNCTION auditor.audit_$$ || sch || $$_$$ || tbl || $$_func ()
+        RETURNS TRIGGER AS $func$
+        BEGIN
+            INSERT INTO auditor.$$ || sch || $$_$$ || tbl || $$_history ( audit_id, audit_time, audit_action, audit_user, audit_ws, $$
+            || array_to_string(column_list, ', ') || $$ )
+                SELECT  nextval('auditor.$$ || sch || $$_$$ || tbl || $$_pkey_seq'),
+                    now(),
+                    SUBSTR(TG_OP,1,1),
+                    eg_user,
+                    eg_ws,
+                    OLD.$$ || array_to_string(column_list, ', OLD.') || $$
+                FROM auditor.get_audit_info();
+            RETURN NULL;
+        END;
+        $func$ LANGUAGE 'plpgsql';
+    $$;
+    RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION auditor.create_auditor_lifecycle     ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
+BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
+    EXECUTE $$
+        CREATE VIEW auditor.$$ || sch || $$_$$ || tbl || $$_lifecycle AS
+            SELECT -1 AS audit_id,
+                   now() AS audit_time,
+                   '-' AS audit_action,
+                   -1 AS audit_user,
+                   -1 AS audit_ws,
+                   $$ || array_to_string(column_list, ', ') || $$
+              FROM $$ || sch || $$.$$ || tbl || $$
+                UNION ALL
+            SELECT audit_id, audit_time, audit_action, audit_user, audit_ws,
+            $$ || array_to_string(column_list, ', ') || $$
+              FROM auditor.$$ || sch || $$_$$ || tbl || $$_history;
+    $$;
+    RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+-- Corrects all column discrepencies between audit table and core table:
+-- Adds missing columns
+-- Removes leftover columns
+-- Updates types
+-- Also, ensures all core auditor columns exist.
+CREATE OR REPLACE FUNCTION auditor.fix_columns() RETURNS VOID AS $BODY$
+DECLARE
+    current_table TEXT = ''; -- Storage for post-loop main table name
+    current_audit_table TEXT = ''; -- Storage for post-loop audit table name
+    query TEXT = ''; -- Storage for built query
+    cr RECORD; -- column record object
+    alter_t BOOL = false; -- Has the alter table command been appended yet
+    auditor_cores TEXT[] = ARRAY[]::TEXT[]; -- Core auditor function list (filled inside of loop)
+    core_column TEXT; -- The current core column we are adding
+BEGIN
+    FOR cr IN
+        WITH audit_tables AS ( -- Basic grab of auditor tables. Anything in the auditor namespace, basically. With oids.
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS ( -- Union of auditor tables with their "main" tables. With oids.
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        ),
+        column_lists AS ( -- All columns associated with the auditor or main table, grouped by the main table's oid.
+            SELECT DISTINCT ON (main_oid, attname) t.main_oid, a.attname
+            FROM table_set t
+            JOIN pg_catalog.pg_attribute a ON a.attrelid IN (t.main_oid, t.audit_oid)
+            WHERE attnum > 0 AND NOT attisdropped
+        ),
+        column_defs AS ( -- The motherload, every audit table and main table plus column names and defs.
+            SELECT audit_table,
+                   main_namespace,
+                   main_table,
+                   a.attname AS main_column, -- These two will be null for columns that have since been deleted, or for auditor core columns
+                   pg_catalog.format_type(a.atttypid, a.atttypmod) AS main_column_def,
+                   b.attname AS audit_column, -- These two will be null for columns that have since been added
+                   pg_catalog.format_type(b.atttypid, b.atttypmod) AS audit_column_def
+            FROM table_set t
+            JOIN column_lists c USING (main_oid)
+            LEFT JOIN pg_catalog.pg_attribute a ON a.attname = c.attname AND a.attrelid = t.main_oid AND a.attnum > 0 AND NOT a.attisdropped
+            LEFT JOIN pg_catalog.pg_attribute b ON b.attname = c.attname AND b.attrelid = t.audit_oid AND b.attnum > 0 AND NOT b.attisdropped
+        )
+        -- Nice sorted output from the above
+        SELECT * FROM column_defs WHERE main_column_def IS DISTINCT FROM audit_column_def ORDER BY main_namespace, main_table, main_column, audit_column
+    LOOP
+        IF current_table <> (cr.main_namespace || '.' || cr.main_table) THEN -- New table?
+            FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Update missing core auditor columns
+                IF NOT alter_t THEN -- Add ALTER TABLE if we haven't already
+                    query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                    alter_t:=TRUE;
+                ELSE
+                    query:=query || $$,$$;
+                END IF;
+                -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+                query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+            END LOOP;
+            IF alter_t THEN -- Open alter table = needs a semicolon
+                query:=query || $$; $$;
+                alter_t:=FALSE;
+                IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+                    -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+                    -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+                    EXECUTE query;
+                    EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                        $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+                    EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                        $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+                    query:='';
+                END IF;
+            END IF;
+            -- New table means we reset the list of needed auditor core columns
+            auditor_cores = ARRAY['audit_id bigint', 'audit_time timestamp with time zone', 'audit_action text', 'audit_user integer', 'audit_ws integer'];
+            -- And store some values for use later, because we can't rely on cr in all places.
+            current_table:=cr.main_namespace || '.' || cr.main_table;
+            current_audit_table:=cr.audit_table;
+        END IF;
+        IF cr.main_column IS NULL AND cr.audit_column LIKE 'audit_%' THEN -- Core auditor column?
+            -- Remove core from list of cores
+            SELECT INTO auditor_cores array_agg(core) FROM unnest(auditor_cores) AS core WHERE core != (cr.audit_column || ' ' || cr.audit_column_def);
+        ELSIF cr.main_column IS NULL THEN -- Main column doesn't exist, and it isn't an auditor column. Needs dropping from the auditor.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ DROP COLUMN $$ || cr.audit_column;
+        ELSIF cr.audit_column IS NULL AND cr.main_column IS NOT NULL THEN -- New column auditor doesn't have. Add it.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ADD COLUMN $$ || cr.main_column || $$ $$ || cr.main_column_def;
+        ELSIF cr.main_column IS NOT NULL AND cr.audit_column IS NOT NULL THEN -- Both sides have this column, but types differ. Fix that.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ALTER COLUMN $$ || cr.audit_column || $$ TYPE $$ || cr.main_column_def;
+        END IF;
+    END LOOP;
+    FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Repeat this outside of the loop to catch the last table
+        IF NOT alter_t THEN
+            query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+            alter_t:=TRUE;
+        ELSE
+            query:=query || $$,$$;
+        END IF;
+        -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+        query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+    END LOOP;
+    IF alter_t THEN -- Open alter table = needs a semicolon
+        query:=query || $$;$$;
+        IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+            -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+            -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+            EXECUTE query;
+            EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+            EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+            query:='';
+        END IF;
+    END IF;
+    EXECUTE query;
+END;
+$BODY$ LANGUAGE plpgsql;
+
+-- Update it all routine
+CREATE OR REPLACE FUNCTION auditor.update_auditors() RETURNS boolean AS $BODY$
+DECLARE
+    auditor_name TEXT;
+    table_schema TEXT;
+    table_name TEXT;
+BEGIN
+    -- Drop Lifecycle view(s) before potential column changes
+    FOR auditor_name IN
+        SELECT c.relname
+            FROM pg_catalog.pg_class c
+                JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind = 'v' AND n.nspname = 'auditor' LOOP
+        EXECUTE $$ DROP VIEW auditor.$$ || auditor_name || $$;$$;
+    END LOOP;
+    -- Fix all column discrepencies
+    PERFORM auditor.fix_columns();
+    -- Re-create trigger functions and lifecycle views
+    FOR table_schema, table_name IN
+        WITH audit_tables AS (
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS (
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        )
+        SELECT main_namespace, main_table FROM table_set LOOP
+        
+        PERFORM auditor.create_auditor_func(table_schema, table_name);
+        PERFORM auditor.create_auditor_lifecycle(table_schema, table_name);
+    END LOOP;
+    RETURN TRUE;
+END;
+$BODY$ LANGUAGE plpgsql;
+
+-- Go ahead and update them all now
+SELECT auditor.update_auditors();
+
+
 COMMIT;

commit db327a6c66de2efaf1aaebbe2f0220fa65cf317f
Author: Thomas Berezansky <tsbere at mvlc.org>
Date:   Mon Nov 21 16:51:50 2011 -0500

    Call set_audit_info and clear_audit_info DB funcs
    
    Set whenever we can (including automatically via pcrud)
    Clear whenever we disconnect (hopefully) from a location we set from.
    
    Signed-off-by: Thomas Berezansky <tsbere at mvlc.org>
    Signed-off-by: Jason Stephenson <jstephenson at mvlc.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/include/openils/oils_sql.h b/Open-ILS/include/openils/oils_sql.h
index 6674d21..d581c4b 100644
--- a/Open-ILS/include/openils/oils_sql.h
+++ b/Open-ILS/include/openils/oils_sql.h
@@ -56,6 +56,8 @@ int doIdList( osrfMethodContext* ctx );
 int is_identifier( const char* s);
 int is_good_operator( const char* op );
 
+int setAuditInfo( osrfMethodContext* ctx );
+
 #ifdef __cplusplus
 }
 #endif
diff --git a/Open-ILS/src/c-apps/oils_cstore.c b/Open-ILS/src/c-apps/oils_cstore.c
index a2aa3fa..5014605 100644
--- a/Open-ILS/src/c-apps/oils_cstore.c
+++ b/Open-ILS/src/c-apps/oils_cstore.c
@@ -69,6 +69,7 @@ void osrfAppChildExit( void ) {
 	- savepoint.set
 	- savepoint.release
 	- savepoint.rollback
+	- set_audit_info
 
 	For each non-virtual class, create up to eight class-specific methods:
 
@@ -165,6 +166,12 @@ int osrfAppInitialize( void ) {
 	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
 			"rollbackSavepoint", "", 1, 0 );
 
+	buffer_reset(method_name);
+	OSRF_BUFFER_ADD(method_name, modulename );
+	OSRF_BUFFER_ADD(method_name, ".set_audit_info");
+	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
+			"setAuditInfo", "", 3, 0 );
+
 	static const char* global_method[] = {
 		"create",
 		"retrieve",
diff --git a/Open-ILS/src/c-apps/oils_pcrud.c b/Open-ILS/src/c-apps/oils_pcrud.c
index b95bdae..18fadfc 100644
--- a/Open-ILS/src/c-apps/oils_pcrud.c
+++ b/Open-ILS/src/c-apps/oils_pcrud.c
@@ -72,6 +72,7 @@ void osrfAppChildExit( void ) {
 	- savepoint.set
 	- savepoint.release
 	- savepoint.rollback
+	- set_audit_info
 
 	For each non-virtual class, create up to eight class-specific methods:
 
@@ -160,6 +161,12 @@ int osrfAppInitialize( void ) {
 	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
 			"rollbackSavepoint", "", 1, 0 );
 
+	buffer_reset(method_name);
+	OSRF_BUFFER_ADD(method_name, modulename );
+	OSRF_BUFFER_ADD(method_name, ".set_audit_info");
+	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
+			"setAuditInfo", "", 3, 0 );
+
 	static const char* global_method[] = {
 		"create",
 		"retrieve",
diff --git a/Open-ILS/src/c-apps/oils_rstore.c b/Open-ILS/src/c-apps/oils_rstore.c
index ae76a76..d503ce1 100644
--- a/Open-ILS/src/c-apps/oils_rstore.c
+++ b/Open-ILS/src/c-apps/oils_rstore.c
@@ -69,6 +69,7 @@ void osrfAppChildExit( void ) {
 	- savepoint.set
 	- savepoint.release
 	- savepoint.rollback
+	- set_audit_info
 
 	For each non-virtual class, create up to eight class-specific methods:
 
@@ -164,6 +165,12 @@ int osrfAppInitialize( void ) {
 	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
 			"rollbackSavepoint", "", 1, 0 );
 
+	buffer_reset(method_name);
+	OSRF_BUFFER_ADD(method_name, modulename );
+	OSRF_BUFFER_ADD(method_name, ".set_audit_info");
+	osrfAppRegisterMethod( modulename, OSRF_BUFFER_C_STR(method_name),
+			"setAuditInfo", "", 3, 0 );
+
 	static const char* global_method[] = {
 		"create",
 		"retrieve",
diff --git a/Open-ILS/src/c-apps/oils_sql.c b/Open-ILS/src/c-apps/oils_sql.c
index 29d80d5..887a2df 100644
--- a/Open-ILS/src/c-apps/oils_sql.c
+++ b/Open-ILS/src/c-apps/oils_sql.c
@@ -143,6 +143,8 @@ static int perm_at_threshold = 5;
 static int enforce_pcrud = 0;     // Boolean
 static char* modulename = NULL;
 
+int writeAuditInfo( osrfMethodContext* ctx, const char* user_id, const char* ws_id);
+
 /**
 	@brief Connect to the database.
 	@return A database connection if successful, or NULL if not.
@@ -473,6 +475,14 @@ void userDataFree( void* blob ) {
 				errnum, msg ? msg : "(No description available)" );
 		};
 	}
+	if( writehandle ) {
+		if( !dbi_conn_query( writehandle, "SELECT auditor.clear_audit_info();" ) ) {
+			const char* msg;
+			int errnum = dbi_conn_error( writehandle, &msg );
+			osrfLogWarning( OSRF_LOG_MARK, "Unable to perform audit info clearing: %d %s",
+				errnum, msg ? msg : "(No description available)" );
+		}
+	}
 
 	osrfHashFree( hash );
 }
@@ -1408,6 +1418,10 @@ static const jsonObject* verifyUserPCRUD( osrfMethodContext* ctx ) {
 		free( m );
 		jsonObjectFree( user );
 		user = NULL;
+	} else if( writeAuditInfo( ctx, oilsFMGetStringConst( user, "id" ), oilsFMGetStringConst( user, "wsid" ) ) ) {
+		// Failed to set audit information - But note that write_audit_info already set error information.
+		jsonObjectFree( user );
+		user = NULL;
 	}
 
 	setUserLogin( ctx, user );
@@ -7140,4 +7154,87 @@ static void clear_query_stack( void ) {
 		pop_query_frame();
 }
 
+/**
+	@brief Implement the set_audit_info method.
+	@param ctx Pointer to the method context.
+	@return Zero if successful, or -1 if not.
+
+	Issue a SAVEPOINT to the database server.
+
+	Method parameters:
+	- authkey
+	- user id (int)
+	- workstation id (int)
+
+	If user id is not provided the authkey will be used.
+	For PCRUD the authkey is always used, even if a user is provided.
+*/
+int setAuditInfo( osrfMethodContext* ctx ) {
+	if(osrfMethodVerifyContext( ctx )) {
+		osrfLogError( OSRF_LOG_MARK,  "Invalid method context" );
+		return -1;
+	}
+
+	// Get the user id from the parameters
+	const char* user_id = jsonObjectGetString( jsonObjectGetIndex(ctx->params, 1) );
+
+	if( enforce_pcrud || !user_id ) {
+		timeout_needs_resetting = 1;
+		const jsonObject* user = verifyUserPCRUD( ctx );
+		if( !user )
+			return -1;
+		osrfAppRespondComplete( ctx, NULL );
+		return 0;
+	}
+
+	// Not PCRUD and have a user_id?
+	int result = writeAuditInfo( ctx, user_id, jsonObjectGetString( jsonObjectGetIndex(ctx->params, 2) ) );
+	osrfAppRespondComplete( ctx, NULL );
+	return result;
+}
+
+/**
+	@brief Save a audit info
+	@param ctx Pointer to the method context.
+	@param user_id User ID to write as a string
+	@param ws_id Workstation ID to write as a string
+*/
+int writeAuditInfo( osrfMethodContext* ctx, const char* user_id, const char* ws_id) {
+	if( ctx && ctx->session ) {
+		osrfAppSession* session = ctx->session;
+
+		osrfHash* cache = session->userData;
+
+		// If the session doesn't already have a hash, create one.  Make sure
+		// that the application session frees the hash when it terminates.
+		if( NULL == cache ) {
+			session->userData = cache = osrfNewHash();
+			osrfHashSetCallback( cache, &sessionDataFree );
+			ctx->session->userDataFree = &userDataFree;
+		}
+
+		dbi_result result = dbi_conn_queryf( writehandle, "SELECT auditor.set_audit_info( %s, %s );", user_id, ws_id ? ws_id : "NULL" );
+		if( !result ) {
+			osrfLogWarning( OSRF_LOG_MARK, "BAD RESULT" );
+			const char* msg;
+			int errnum = dbi_conn_error( writehandle, &msg );
+			osrfLogError(
+				OSRF_LOG_MARK,
+				"%s: Error setting auditor information: %d %s",
+				modulename,
+				errnum,
+				msg ? msg : "(No description available)"
+			);
+			osrfAppSessionStatus( ctx->session, OSRF_STATUS_INTERNALSERVERERROR,
+				"osrfMethodException", ctx->request, "Error setting auditor info" );
+			if( !oilsIsDBConnected( writehandle ))
+				osrfAppSessionPanic( ctx->session );
+			return -1;
+		} else {
+			dbi_result_free( result );
+			return 0;
+		}
+	}
+}
+
 /*@}*/
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Actor.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Actor.pm
index 1599d30..4ba9ad5 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Actor.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Actor.pm
@@ -351,6 +351,7 @@ sub update_patron {
 	$evt = check_group_perm($session, $user_obj, $patron);
 	return $evt if $evt;
 
+	$apputils->set_audit_info($session, $user_session, $user_obj->id, $user_obj->wsid);
 
 	# $new_patron is the patron in progress.  $patron is the original patron
 	# passed in with the method.  new_patron will change as the components
@@ -1037,6 +1038,7 @@ sub set_user_work_ous {
 	return $evt if $evt;
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($session, $ses, $requestor->id, $requestor->wsid);
 
 	for my $map (@$maps) {
 
@@ -1077,6 +1079,7 @@ sub set_user_perms {
 
 	my( $user_obj, $evt ) = $U->checkses($ses);
 	return $evt if $evt;
+	$apputils->set_audit_info($session, $ses, $user_obj->id, $user_obj->wsid);
 
 	my $perms = $session->request('open-ils.storage.permission.user_perms.atomic', $user_obj->id)->gather(1);
 
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/AppUtils.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/AppUtils.pm
index e8369ea..07bd151 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/AppUtils.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/AppUtils.pm
@@ -45,6 +45,18 @@ sub start_db_session {
 	return $session;
 }
 
+sub set_audit_info {
+	my $self = shift;
+	my $session = shift;
+	my $authtoken = shift;
+	my $user_id = shift;
+	my $ws_id = shift;
+	
+	my $audit_req = $session->request( "open-ils.storage.set_audit_info", $authtoken, $user_id, $ws_id );
+	my $audit_resp = $audit_req->recv();
+	$audit_req->finish();
+}
+
 my $PERM_QUERY = {
     select => {
         au => [ {
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Money.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Money.pm
index 1058e8c..d400853 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Money.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Money.pm
@@ -586,6 +586,7 @@ sub create_grocery_bill {
 
     $transaction->clear_id;
     my $session = $apputils->start_db_session;
+    $apputils->set_audit_info($login, $staff->id, $staff->wsid);
     my $transid = $session->request(
         'open-ils.storage.direct.money.grocery.create', $transaction)->gather(1);
 
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/StatCat.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/StatCat.pm
index 8ca8325..aadb8c7 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/StatCat.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/StatCat.pm
@@ -177,6 +177,7 @@ sub stat_cat_create {
 
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $newid = _create_stat_cat($session, $stat_cat, $method);
 
 	if( ref($stat_cat->entries) ) {
@@ -296,6 +297,7 @@ sub update_stat_entry {
 	return $evt if $evt;
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $req = $session->request($method, $entry); 
 	my $status = $req->gather(1);
 	$apputils->commit_db_session($session);
@@ -328,6 +330,7 @@ sub update_stat {
 	return $evt if $evt;
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $req = $session->request($method, $cat); 
 	my $status = $req->gather(1);
 	$apputils->commit_db_session($session);
@@ -361,6 +364,7 @@ sub create_stat_entry {
 
 	$entry->clear_id();
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $req = $session->request($method, $entry); 
 	my $status = $req->gather(1);
 	$apputils->commit_db_session($session);
@@ -416,6 +420,7 @@ sub create_stat_map {
 	$map->clear_id();
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $req = $session->request($method, $map); 
 	my $newid = $req->gather(1);
 	warn "Created new stat cat map with id $newid\n";
@@ -466,6 +471,7 @@ sub update_stat_map {
 
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $req = $session->request($method, $map); 
 	my $newid = $req->gather(1);
 	warn "Updated new stat cat map with id $newid\n";
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Survey.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Survey.pm
index 9f75be3..98f046f 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Survey.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Survey.pm
@@ -38,6 +38,7 @@ sub add_survey {
     return $evt if $evt;
 
 	my $session = $apputils->start_db_session();
+	$apputils->set_audit_info($user_session, $user_obj->id, $user_obj->wsid);
 	my $err = undef; my $id;
 
 
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Transit.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Transit.pm
index ff4796e..e0900dc 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Transit.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Transit.pm
@@ -44,6 +44,7 @@ sub copy_transit_receive {
 	($copy, $evt) = $U->fetch_copy_by_barcode($params{barcode}) unless $copy;
 	return $evt if $evt;
 	my $session = $U->start_db_session();
+	$U->set_audit_info($authtoken, $requestor->id, $requestor->wsid);
 	$evt = transit_receive( $self, $copy, $requestor, $session );
 	$U->commit_db_session($session) if $U->event_equals($evt,'SUCCESS');
 	return $evt;
@@ -133,6 +134,7 @@ sub copy_transit_create {
 	my $source		= $requestor->home_ou;
 	my $dest			= $params{destination} || $copy->circ_lib;
 	my $transit		= Fieldmapper::action::transit_copy->new;
+	$U->set_audit_info($authtoken, $requestor->id, $requestor->wsid);
 
 	$logger->activity("User ". $requestor->id ." creating a ".
 		" new copy transit for copy ".$copy->id." to org $dest");
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg.pm
index 8fd8515..95d9db4 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg.pm
@@ -145,6 +145,7 @@
 #	}
 
 	my $_xact_session;
+	my $_audit_session;
 
 	sub current_xact_session {
 		my $self = shift;
@@ -154,6 +155,14 @@
 		return undef;
 	}
 
+	sub current_audit_session {
+		my $self = shift;
+		if (defined($_audit_session)) {
+			return $_audit_session;
+		}
+		return undef;
+	}
+
 	sub current_xact_is_auto {
 		my $self = shift;
 		my $auto = shift;
@@ -183,6 +192,16 @@
 		return $_xact_session;
 	}
 
+	sub set_audit_session {
+		my $self = shift;
+		my $ses = shift;
+		if (!defined($ses)) {
+			return undef;
+		}
+		$_audit_session = $ses;
+		return $_audit_session;
+	}
+
 	sub unset_xact_session {
 		my $self = shift;
 		my $ses = $_xact_session;
@@ -190,6 +209,13 @@
 		return $ses;
 	}
 
+	sub unset_audit_session {
+		my $self = shift;
+		my $ses = $_audit_session;
+		undef $_audit_session;
+		return $ses;
+	}
+
 }
 
 1;
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg/storage.pm b/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg/storage.pm
index d7623d0..989d84c 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg/storage.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Application/Storage/Driver/Pg/storage.pm
@@ -222,6 +222,84 @@
 	        argc            => 1,
 	);
 
+	sub pg_set_audit_info {
+		my $self = shift;
+		my $client = shift;
+		my $authtoken = shift;
+		my $user_id = shift;
+		my $ws_id = shift;
+
+		local $OpenILS::Application::Storage::WRITE = 1;
+
+		$log->debug("Setting auditor information", INFO);
+
+		if($pg->current_audit_session) {
+			$log->debug("Already sent audit data.", INFO);
+			return 1;
+		}
+
+		my $dbh = OpenILS::Application::Storage::CDBI->db_Main;
+		
+		try {
+			if(!$user_id) {
+				my $ses = OpenSRF::AppSession->create('open-ils.auth');
+				my $content = $ses->request('open-ils.auth.session.retrieve', $authtoken, 1)->gather(1);
+				if(!$content or !$content->{userObj}) {
+					return 0;
+				}
+				$user_id = $content->{userObj}->id;
+				$ws_id = $content->{userObj}->wsid;
+			}
+			$ws_id = 'NULL' unless $ws_id;
+			$dbh->do("SELECT auditor.set_audit_info($user_id, $ws_id);");
+		} catch Error with {
+			my $e = shift;
+			$log->debug("Failed to set auditor information: ".$e, INFO);
+			throw $e;
+		};
+
+		$pg->set_audit_session( $client->session );
+
+		my $death_cb = $client->session->register_callback(
+			death => sub {
+				__PACKAGE__->pg_clear_audit_info;
+			}
+		);
+
+		$log->debug("Registered 'death' callback [$death_cb] for clearing audit information", DEBUG);
+
+		$client->session->session_data( death_cb_ai => $death_cb );
+
+		return 1;
+
+	}
+	__PACKAGE__->register_method(
+		method		=> 'pg_set_audit_info',
+		api_name	=> 'open-ils.storage.set_audit_info',
+		api_level	=> 1,
+		argc		=> 3,
+	);
+
+	sub pg_clear_audit_info {
+		my $self = shift;
+
+		try {
+			my $dbh = OpenILS::Application::Storage::CDBI->db_Main;
+			$log->debug("Clearing Audit Information", INFO);
+			$dbh->do("SELECT auditor.clear_audit_info();");
+		} catch Error with {
+			my $e = shift;
+			$log->debug("Failed to clear audit information: ".$e, INFO);
+		};
+
+		$pg->current_audit_session->unregister_callback( death => 
+			$pg->current_audit_session->session_data( 'death_cb_ai' )
+		) if ($pg->current_audit_session);
+
+		$pg->unset_audit_session;
+	}
+
+
 
 	sub copy_create_start {
 		my $self = shift;
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Utils/CStoreEditor.pm b/Open-ILS/src/perlmods/lib/OpenILS/Utils/CStoreEditor.pm
index 18e1775..d41e435 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Utils/CStoreEditor.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Utils/CStoreEditor.pm
@@ -237,6 +237,18 @@ sub xact_begin {
 	    my $stat = $self->request($self->app . '.transaction.begin');
 	    $self->log(E, "error starting database transaction") unless $stat;
         $self->{xact_id} = $stat;
+        if($self->authtoken) {
+            if(!$self->requestor) {
+                $self->checkauth;
+            }
+            my $user_id = undef;
+            my $ws_id = undef;
+            if($self->requestor) {
+                $user_id = $self->requestor->id;
+                $ws_id = $self->requestor->wsid;
+            }
+            $self->request($self->app . '.set_audit_info', $self->authtoken, $user_id, $ws_id);
+        }
     }
     $self->{xact} = 1;
     return $self->{xact_id};
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/Utils/Editor.pm b/Open-ILS/src/perlmods/lib/OpenILS/Utils/Editor.pm
index 801faff..e31e29d 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/Utils/Editor.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/Utils/Editor.pm
@@ -135,6 +135,18 @@ sub xact_start {
 	$self->log(D, "starting new db session");
 	my $stat = $self->request('open-ils.storage.transaction.begin');
 	$self->log(E, "error starting database transaction") unless $stat;
+    if($self->authtoken) {
+        if(!$self->requestor) {
+            $self->checkauth;
+        }
+        my $user_id = undef;
+        my $ws_id = undef;
+        if($self->requestor) {
+            $user_id = $self->requestor->id;
+            $ws_id = $self->requestor->wsid;
+        }
+        $self->request('open-ils.storage.set_audit_info', $self->authtoken, $user_id, $ws_id);
+    }
 	return $stat;
 }
 
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/WWW/BadDebt.pm b/Open-ILS/src/perlmods/lib/OpenILS/WWW/BadDebt.pm
index 72cce27..007623d 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/WWW/BadDebt.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/WWW/BadDebt.pm
@@ -89,6 +89,7 @@ sub handler {
 
     $cstore->connect();
     $cstore->request('open-ils.cstore.transaction.begin')->gather(1);
+    $cstore->request('open-ils.cstore.set_audit_info', $auth_ses, $user->id, $user->wsid)->gather(1);
 
     for my $xact ( @xacts ) {
         try {
diff --git a/Open-ILS/src/perlmods/lib/OpenILS/WWW/TemplateBatchBibUpdate.pm b/Open-ILS/src/perlmods/lib/OpenILS/WWW/TemplateBatchBibUpdate.pm
index 56af440..f72ac17 100644
--- a/Open-ILS/src/perlmods/lib/OpenILS/WWW/TemplateBatchBibUpdate.pm
+++ b/Open-ILS/src/perlmods/lib/OpenILS/WWW/TemplateBatchBibUpdate.pm
@@ -89,6 +89,7 @@ sub handler {
 
     my $e = OpenSRF::AppSession->connect('open-ils.cstore');
     $e->request('open-ils.cstore.transaction.begin')->gather(1);
+    $e->request('open-ils.cstore.set_audit_info', $authid, $usr->id, $usr->wsid)->gather(1);
 
     # still no records ...
     my $container = $cgi->param('containerid');

commit 7ca2c02e3e7e08c8b067be0707670616c1bf183f
Author: Thomas Berezansky <tsbere at mvlc.org>
Date:   Mon Nov 21 11:18:49 2011 -0500

    Auditor Function Overhaul
    
    Alter create_auditor_history to include two new columns:
        audit_user - To refer to the user who made this change
        audit_ws - To refer to the workstation they were logged into
    
    Alter create_auditor_func to include the new columns, as well as make it
    stop assuming that the auditor table and the table it is based on use the
    same column ordering. In additon, make it use OR REPLACE so it can be run
    again later.
    
    Alter create_auditor_lifecycle similarly to create_auditor_func, sans the
    OR REPLACE functionality.
    
    Add five new functions:
    
    set_audit_info - To set the user and workstation IDs
    get_audit_info - Used by the auditor functions to retrieve said IDs
    clear_audit_info - To remove the stored IDs for whatever reason
    fix_columns - To add/remove/update columns that have changed since any
        auditors were initially created
    update_auditors - To run a full pass of dropping all lifecycle views,
        update for all column changes, re-create the auditor functions, and
        re-create the auditor lifecycle views.
    
    Signed-off-by: Thomas Berezansky <tsbere at mvlc.org>
    Signed-off-by: Jason Stephenson <jstephenson at mvlc.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/src/sql/Pg/900.audit-functions.sql b/Open-ILS/src/sql/Pg/900.audit-functions.sql
index a8ee115..6c0dc3f 100644
--- a/Open-ILS/src/sql/Pg/900.audit-functions.sql
+++ b/Open-ILS/src/sql/Pg/900.audit-functions.sql
@@ -21,6 +21,26 @@ BEGIN;
 
 CREATE SCHEMA auditor;
 
+-- These three functions are for capturing, getting, and clearing user and workstation information
+
+-- Set the User AND workstation in one call. Tis faster. And less calls.
+-- First argument is user, second is workstation
+CREATE OR REPLACE FUNCTION auditor.set_audit_info(INT, INT) RETURNS VOID AS $$
+    $_SHARED{"eg_audit_user"} = $_[0];
+    $_SHARED{"eg_audit_ws"} = $_[1];
+$$ LANGUAGE plperl;
+
+-- Get the User AND workstation in one call. Less calls, useful for joins ;)
+CREATE OR REPLACE FUNCTION auditor.get_audit_info() RETURNS TABLE (eg_user INT, eg_ws INT) AS $$
+    return [{eg_user => $_SHARED{"eg_audit_user"}, eg_ws => $_SHARED{"eg_audit_ws"}}];
+$$ LANGUAGE plperl;
+
+-- Clear the audit info, for whatever reason
+CREATE OR REPLACE FUNCTION auditor.clear_audit_info() RETURNS VOID AS $$
+    delete($_SHARED{"eg_audit_user"});
+    delete($_SHARED{"eg_audit_ws"});
+$$ LANGUAGE plperl;
+
 CREATE FUNCTION auditor.create_auditor_seq     ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
 BEGIN
     EXECUTE $$
@@ -37,6 +57,8 @@ BEGIN
             audit_id	BIGINT				PRIMARY KEY,
             audit_time	TIMESTAMP WITH TIME ZONE	NOT NULL,
             audit_action	TEXT				NOT NULL,
+            audit_user  INT,
+            audit_ws    INT,
             LIKE $$ || sch || $$.$$ || tbl || $$
         );
     $$;
@@ -44,22 +66,34 @@ BEGIN
 END;
 $creator$ LANGUAGE 'plpgsql';
 
-CREATE FUNCTION auditor.create_auditor_func    ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+CREATE OR REPLACE FUNCTION auditor.create_auditor_func    ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
 BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
     EXECUTE $$
-        CREATE FUNCTION auditor.audit_$$ || sch || $$_$$ || tbl || $$_func ()
+        CREATE OR REPLACE FUNCTION auditor.audit_$$ || sch || $$_$$ || tbl || $$_func ()
         RETURNS TRIGGER AS $func$
         BEGIN
-            INSERT INTO auditor.$$ || sch || $$_$$ || tbl || $$_history
-                SELECT	nextval('auditor.$$ || sch || $$_$$ || tbl || $$_pkey_seq'),
+            INSERT INTO auditor.$$ || sch || $$_$$ || tbl || $$_history ( audit_id, audit_time, audit_action, audit_user, audit_ws, $$
+            || array_to_string(column_list, ', ') || $$ )
+                SELECT  nextval('auditor.$$ || sch || $$_$$ || tbl || $$_pkey_seq'),
                     now(),
                     SUBSTR(TG_OP,1,1),
-                    OLD.*;
+                    eg_user,
+                    eg_ws,
+                    OLD.$$ || array_to_string(column_list, ', OLD.') || $$
+                FROM auditor.get_audit_info();
             RETURN NULL;
         END;
         $func$ LANGUAGE 'plpgsql';
     $$;
-	RETURN TRUE;
+    RETURN TRUE;
 END;
 $creator$ LANGUAGE 'plpgsql';
 
@@ -74,17 +108,31 @@ BEGIN
 END;
 $creator$ LANGUAGE 'plpgsql';
 
-CREATE FUNCTION auditor.create_auditor_lifecycle     ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+CREATE OR REPLACE FUNCTION auditor.create_auditor_lifecycle     ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
 BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
     EXECUTE $$
         CREATE VIEW auditor.$$ || sch || $$_$$ || tbl || $$_lifecycle AS
-            SELECT	-1, now() as audit_time, '-' as audit_action, *
-              FROM	$$ || sch || $$.$$ || tbl || $$
+            SELECT -1 AS audit_id,
+                   now() AS audit_time,
+                   '-' AS audit_action,
+                   -1 AS audit_user,
+                   -1 AS audit_ws,
+                   $$ || array_to_string(column_list, ', ') || $$
+              FROM $$ || sch || $$.$$ || tbl || $$
                 UNION ALL
-            SELECT	*
-              FROM	auditor.$$ || sch || $$_$$ || tbl || $$_history;
+            SELECT audit_id, audit_time, audit_action, audit_user, audit_ws,
+            $$ || array_to_string(column_list, ', ') || $$
+              FROM auditor.$$ || sch || $$_$$ || tbl || $$_history;
     $$;
-	RETURN TRUE;
+    RETURN TRUE;
 END;
 $creator$ LANGUAGE 'plpgsql';
 
@@ -102,5 +150,184 @@ BEGIN
 END;
 $creator$ LANGUAGE 'plpgsql';
 
+-- Corrects all column discrepencies between audit table and core table:
+-- Adds missing columns
+-- Removes leftover columns
+-- Updates types
+-- Also, ensures all core auditor columns exist.
+CREATE OR REPLACE FUNCTION auditor.fix_columns() RETURNS VOID AS $BODY$
+DECLARE
+    current_table TEXT = ''; -- Storage for post-loop main table name
+    current_audit_table TEXT = ''; -- Storage for post-loop audit table name
+    query TEXT = ''; -- Storage for built query
+    cr RECORD; -- column record object
+    alter_t BOOL = false; -- Has the alter table command been appended yet
+    auditor_cores TEXT[] = ARRAY[]::TEXT[]; -- Core auditor function list (filled inside of loop)
+    core_column TEXT; -- The current core column we are adding
+BEGIN
+    FOR cr IN
+        WITH audit_tables AS ( -- Basic grab of auditor tables. Anything in the auditor namespace, basically. With oids.
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS ( -- Union of auditor tables with their "main" tables. With oids.
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        ),
+        column_lists AS ( -- All columns associated with the auditor or main table, grouped by the main table's oid.
+            SELECT DISTINCT ON (main_oid, attname) t.main_oid, a.attname
+            FROM table_set t
+            JOIN pg_catalog.pg_attribute a ON a.attrelid IN (t.main_oid, t.audit_oid)
+            WHERE attnum > 0 AND NOT attisdropped
+        ),
+        column_defs AS ( -- The motherload, every audit table and main table plus column names and defs.
+            SELECT audit_table,
+                   main_namespace,
+                   main_table,
+                   a.attname AS main_column, -- These two will be null for columns that have since been deleted, or for auditor core columns
+                   pg_catalog.format_type(a.atttypid, a.atttypmod) AS main_column_def,
+                   b.attname AS audit_column, -- These two will be null for columns that have since been added
+                   pg_catalog.format_type(b.atttypid, b.atttypmod) AS audit_column_def
+            FROM table_set t
+            JOIN column_lists c USING (main_oid)
+            LEFT JOIN pg_catalog.pg_attribute a ON a.attname = c.attname AND a.attrelid = t.main_oid AND a.attnum > 0 AND NOT a.attisdropped
+            LEFT JOIN pg_catalog.pg_attribute b ON b.attname = c.attname AND b.attrelid = t.audit_oid AND b.attnum > 0 AND NOT b.attisdropped
+        )
+        -- Nice sorted output from the above
+        SELECT * FROM column_defs WHERE main_column_def IS DISTINCT FROM audit_column_def ORDER BY main_namespace, main_table, main_column, audit_column
+    LOOP
+        IF current_table <> (cr.main_namespace || '.' || cr.main_table) THEN -- New table?
+            FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Update missing core auditor columns
+                IF NOT alter_t THEN -- Add ALTER TABLE if we haven't already
+                    query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                    alter_t:=TRUE;
+                ELSE
+                    query:=query || $$,$$;
+                END IF;
+                -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+                query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+            END LOOP;
+            IF alter_t THEN -- Open alter table = needs a semicolon
+                query:=query || $$; $$;
+                alter_t:=FALSE;
+                IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+                    -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+                    -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+                    EXECUTE query;
+                    EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                        $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+                    EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                        $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+                    query:='';
+                END IF;
+            END IF;
+            -- New table means we reset the list of needed auditor core columns
+            auditor_cores = ARRAY['audit_id bigint', 'audit_time timestamp with time zone', 'audit_action text', 'audit_user integer', 'audit_ws integer'];
+            -- And store some values for use later, because we can't rely on cr in all places.
+            current_table:=cr.main_namespace || '.' || cr.main_table;
+            current_audit_table:=cr.audit_table;
+        END IF;
+        IF cr.main_column IS NULL AND cr.audit_column LIKE 'audit_%' THEN -- Core auditor column?
+            -- Remove core from list of cores
+            SELECT INTO auditor_cores array_agg(core) FROM unnest(auditor_cores) AS core WHERE core != (cr.audit_column || ' ' || cr.audit_column_def);
+        ELSIF cr.main_column IS NULL THEN -- Main column doesn't exist, and it isn't an auditor column. Needs dropping from the auditor.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ DROP COLUMN $$ || cr.audit_column;
+        ELSIF cr.audit_column IS NULL AND cr.main_column IS NOT NULL THEN -- New column auditor doesn't have. Add it.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ADD COLUMN $$ || cr.main_column || $$ $$ || cr.main_column_def;
+        ELSIF cr.main_column IS NOT NULL AND cr.audit_column IS NOT NULL THEN -- Both sides have this column, but types differ. Fix that.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ALTER COLUMN $$ || cr.audit_column || $$ TYPE $$ || cr.main_column_def;
+        END IF;
+    END LOOP;
+    FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Repeat this outside of the loop to catch the last table
+        IF NOT alter_t THEN
+            query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+            alter_t:=TRUE;
+        ELSE
+            query:=query || $$,$$;
+        END IF;
+        -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+        query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+    END LOOP;
+    IF alter_t THEN -- Open alter table = needs a semicolon
+        query:=query || $$;$$;
+        IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+            -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+            -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+            EXECUTE query;
+            EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+            EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+            query:='';
+        END IF;
+    END IF;
+    EXECUTE query;
+END;
+$BODY$ LANGUAGE plpgsql;
+
+-- Update it all routine
+CREATE OR REPLACE FUNCTION auditor.update_auditors() RETURNS boolean AS $BODY$
+DECLARE
+    auditor_name TEXT;
+    table_schema TEXT;
+    table_name TEXT;
+BEGIN
+    -- Drop Lifecycle view(s) before potential column changes
+    FOR auditor_name IN
+        SELECT c.relname
+            FROM pg_catalog.pg_class c
+                JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind = 'v' AND n.nspname = 'auditor' LOOP
+        EXECUTE $$ DROP VIEW auditor.$$ || auditor_name || $$;$$;
+    END LOOP;
+    -- Fix all column discrepencies
+    PERFORM auditor.fix_columns();
+    -- Re-create trigger functions and lifecycle views
+    FOR table_schema, table_name IN
+        WITH audit_tables AS (
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS (
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        )
+        SELECT main_namespace, main_table FROM table_set LOOP
+        
+        PERFORM auditor.create_auditor_func(table_schema, table_name);
+        PERFORM auditor.create_auditor_lifecycle(table_schema, table_name);
+    END LOOP;
+    RETURN TRUE;
+END;
+$BODY$ LANGUAGE plpgsql;
+
 COMMIT;
 

commit 60ae1d172c4abaee2744a36596dcb6ccf31a777e
Author: Thomas Berezansky <tsbere at mvlc.org>
Date:   Mon Nov 21 11:18:58 2011 -0500

    Unwrapped auditor upgrade script
    
    Signed-off-by: Thomas Berezansky <tsbere at mvlc.org>
    Signed-off-by: Jason Stephenson <jstephenson at mvlc.org>
    Signed-off-by: Mike Rylander <mrylander at gmail.com>

diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql
new file mode 100644
index 0000000..edaf795
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/XXXX.auditor_boost.sql
@@ -0,0 +1,276 @@
+-- These three functions are for capturing, getting, and clearing user and workstation information
+
+-- Set the User AND workstation in one call. Tis faster. And less calls.
+-- First argument is user, second is workstation
+CREATE OR REPLACE FUNCTION auditor.set_audit_info(INT, INT) RETURNS VOID AS $$
+    $_SHARED{"eg_audit_user"} = $_[0];
+    $_SHARED{"eg_audit_ws"} = $_[1];
+$$ LANGUAGE plperl;
+
+-- Get the User AND workstation in one call. Less calls, useful for joins ;)
+CREATE OR REPLACE FUNCTION auditor.get_audit_info() RETURNS TABLE (eg_user INT, eg_ws INT) AS $$
+    return [{eg_user => $_SHARED{"eg_audit_user"}, eg_ws => $_SHARED{"eg_audit_ws"}}];
+$$ LANGUAGE plperl;
+
+-- Clear the audit info, for whatever reason
+CREATE OR REPLACE FUNCTION auditor.clear_audit_info() RETURNS VOID AS $$
+    delete($_SHARED{"eg_audit_user"});
+    delete($_SHARED{"eg_audit_ws"});
+$$ LANGUAGE plperl;
+
+CREATE FUNCTION auditor.create_auditor_history ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+BEGIN
+    EXECUTE $$
+        CREATE TABLE auditor.$$ || sch || $$_$$ || tbl || $$_history (
+            audit_id	BIGINT				PRIMARY KEY,
+            audit_time	TIMESTAMP WITH TIME ZONE	NOT NULL,
+            audit_action	TEXT				NOT NULL,
+            audit_user  INT,
+            audit_ws    INT,
+            LIKE $$ || sch || $$.$$ || tbl || $$
+        );
+    $$;
+	RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION auditor.create_auditor_func    ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
+BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
+    EXECUTE $$
+        CREATE OR REPLACE FUNCTION auditor.audit_$$ || sch || $$_$$ || tbl || $$_func ()
+        RETURNS TRIGGER AS $func$
+        BEGIN
+            INSERT INTO auditor.$$ || sch || $$_$$ || tbl || $$_history ( audit_id, audit_time, audit_action, audit_user, audit_ws, $$
+            || array_to_string(column_list, ', ') || $$ )
+                SELECT  nextval('auditor.$$ || sch || $$_$$ || tbl || $$_pkey_seq'),
+                    now(),
+                    SUBSTR(TG_OP,1,1),
+                    eg_user,
+                    eg_ws,
+                    OLD.$$ || array_to_string(column_list, ', OLD.') || $$
+                FROM auditor.get_audit_info();
+            RETURN NULL;
+        END;
+        $func$ LANGUAGE 'plpgsql';
+    $$;
+    RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION auditor.create_auditor_lifecycle     ( sch TEXT, tbl TEXT ) RETURNS BOOL AS $creator$
+DECLARE
+    column_list TEXT[];
+BEGIN
+    SELECT INTO column_list array_agg(a.attname)
+        FROM pg_catalog.pg_attribute a
+            JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+        WHERE relkind = 'r' AND n.nspname = sch AND c.relname = tbl AND a.attnum > 0 AND NOT a.attisdropped;
+
+    EXECUTE $$
+        CREATE VIEW auditor.$$ || sch || $$_$$ || tbl || $$_lifecycle AS
+            SELECT -1 AS audit_id,
+                   now() AS audit_time,
+                   '-' AS audit_action,
+                   -1 AS audit_user,
+                   -1 AS audit_ws,
+                   $$ || array_to_string(column_list, ', ') || $$
+              FROM $$ || sch || $$.$$ || tbl || $$
+                UNION ALL
+            SELECT audit_id, audit_time, audit_action, audit_user, audit_ws,
+            $$ || array_to_string(column_list, ', ') || $$
+              FROM auditor.$$ || sch || $$_$$ || tbl || $$_history;
+    $$;
+    RETURN TRUE;
+END;
+$creator$ LANGUAGE 'plpgsql';
+
+-- Corrects all column discrepencies between audit table and core table:
+-- Adds missing columns
+-- Removes leftover columns
+-- Updates types
+-- Also, ensures all core auditor columns exist.
+CREATE OR REPLACE FUNCTION auditor.fix_columns() RETURNS VOID AS $BODY$
+DECLARE
+    current_table TEXT = ''; -- Storage for post-loop main table name
+    current_audit_table TEXT = ''; -- Storage for post-loop audit table name
+    query TEXT = ''; -- Storage for built query
+    cr RECORD; -- column record object
+    alter_t BOOL = false; -- Has the alter table command been appended yet
+    auditor_cores TEXT[] = ARRAY[]::TEXT[]; -- Core auditor function list (filled inside of loop)
+    core_column TEXT; -- The current core column we are adding
+BEGIN
+    FOR cr IN
+        WITH audit_tables AS ( -- Basic grab of auditor tables. Anything in the auditor namespace, basically. With oids.
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS ( -- Union of auditor tables with their "main" tables. With oids.
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        ),
+        column_lists AS ( -- All columns associated with the auditor or main table, grouped by the main table's oid.
+            SELECT DISTINCT ON (main_oid, attname) t.main_oid, a.attname
+            FROM table_set t
+            JOIN pg_catalog.pg_attribute a ON a.attrelid IN (t.main_oid, t.audit_oid)
+            WHERE attnum > 0 AND NOT attisdropped
+        ),
+        column_defs AS ( -- The motherload, every audit table and main table plus column names and defs.
+            SELECT audit_table,
+                   main_namespace,
+                   main_table,
+                   a.attname AS main_column, -- These two will be null for columns that have since been deleted, or for auditor core columns
+                   pg_catalog.format_type(a.atttypid, a.atttypmod) AS main_column_def,
+                   b.attname AS audit_column, -- These two will be null for columns that have since been added
+                   pg_catalog.format_type(b.atttypid, b.atttypmod) AS audit_column_def
+            FROM table_set t
+            JOIN column_lists c USING (main_oid)
+            LEFT JOIN pg_catalog.pg_attribute a ON a.attname = c.attname AND a.attrelid = t.main_oid AND a.attnum > 0 AND NOT a.attisdropped
+            LEFT JOIN pg_catalog.pg_attribute b ON b.attname = c.attname AND b.attrelid = t.audit_oid AND b.attnum > 0 AND NOT b.attisdropped
+        )
+        -- Nice sorted output from the above
+        SELECT * FROM column_defs WHERE main_column_def IS DISTINCT FROM audit_column_def ORDER BY main_namespace, main_table, main_column, audit_column
+    LOOP
+        IF current_table <> (cr.main_namespace || '.' || cr.main_table) THEN -- New table?
+            FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Update missing core auditor columns
+                IF NOT alter_t THEN -- Add ALTER TABLE if we haven't already
+                    query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                    alter_t:=TRUE;
+                ELSE
+                    query:=query || $$,$$;
+                END IF;
+                -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+                query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+            END LOOP;
+            IF alter_t THEN -- Open alter table = needs a semicolon
+                query:=query || $$; $$;
+                alter_t:=FALSE;
+                IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+                    -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+                    -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+                    EXECUTE query;
+                    EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                        $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+                    EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                        $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+                    query:='';
+                END IF;
+            END IF;
+            -- New table means we reset the list of needed auditor core columns
+            auditor_cores = ARRAY['audit_id bigint', 'audit_time timestamp with time zone', 'audit_action text', 'audit_user integer', 'audit_ws integer'];
+            -- And store some values for use later, because we can't rely on cr in all places.
+            current_table:=cr.main_namespace || '.' || cr.main_table;
+            current_audit_table:=cr.audit_table;
+        END IF;
+        IF cr.main_column IS NULL AND cr.audit_column LIKE 'audit_%' THEN -- Core auditor column?
+            -- Remove core from list of cores
+            SELECT INTO auditor_cores array_agg(core) FROM unnest(auditor_cores) AS core WHERE core != (cr.audit_column || ' ' || cr.audit_column_def);
+        ELSIF cr.main_column IS NULL THEN -- Main column doesn't exist, and it isn't an auditor column. Needs dropping from the auditor.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ DROP COLUMN $$ || cr.audit_column;
+        ELSIF cr.audit_column IS NULL AND cr.main_column IS NOT NULL THEN -- New column auditor doesn't have. Add it.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ADD COLUMN $$ || cr.main_column || $$ $$ || cr.main_column_def;
+        ELSIF cr.main_column IS NOT NULL AND cr.audit_column IS NOT NULL THEN -- Both sides have this column, but types differ. Fix that.
+            IF NOT alter_t THEN
+                query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+                alter_t:=TRUE;
+            ELSE
+                query:=query || $$,$$;
+            END IF;
+            query:=query || $$ ALTER COLUMN $$ || cr.audit_column || $$ TYPE $$ || cr.main_column_def;
+        END IF;
+    END LOOP;
+    FOR core_column IN SELECT DISTINCT unnest(auditor_cores) LOOP -- Repeat this outside of the loop to catch the last table
+        IF NOT alter_t THEN
+            query:=query || $$ALTER TABLE auditor.$$ || current_audit_table;
+            alter_t:=TRUE;
+        ELSE
+            query:=query || $$,$$;
+        END IF;
+        -- Bit of a sneaky bit here. Create audit_id as a bigserial so it gets automatic values and doesn't complain about nulls when becoming a PRIMARY KEY.
+        query:=query || $$ ADD COLUMN $$ || CASE WHEN core_column = 'audit_id bigint' THEN $$audit_id bigserial PRIMARY KEY$$ ELSE core_column END;
+    END LOOP;
+    IF alter_t THEN -- Open alter table = needs a semicolon
+        query:=query || $$;$$;
+        IF 'audit_id bigint' = ANY(auditor_cores) THEN -- We added a primary key...
+            -- Fun! Drop the default on audit_id, drop the auto-created sequence, create a new one, and set the current value
+            -- For added fun, we have to execute in chunks due to the parser checking setval/currval arguments at parse time.
+            EXECUTE query;
+            EXECUTE $$ALTER TABLE auditor.$$ || current_audit_table || $$ ALTER COLUMN audit_id DROP DEFAULT; $$ ||
+                $$CREATE SEQUENCE auditor.$$ || current_audit_table || $$_pkey_seq;$$;
+            EXECUTE $$SELECT setval('auditor.$$ || current_audit_table || $$_pkey_seq', currval('auditor.$$ || current_audit_table || $$_audit_id_seq')); $$ ||
+                $$DROP SEQUENCE auditor.$$ || current_audit_table || $$_audit_id_seq;$$;
+            query:='';
+        END IF;
+    END IF;
+    EXECUTE query;
+END;
+$BODY$ LANGUAGE plpgsql;
+
+-- Update it all routine
+CREATE OR REPLACE FUNCTION auditor.update_auditors() RETURNS boolean AS $BODY$
+DECLARE
+    auditor_name TEXT;
+    table_schema TEXT;
+    table_name TEXT;
+BEGIN
+    -- Drop Lifecycle view(s) before potential column changes
+    FOR auditor_name IN
+        SELECT c.relname
+            FROM pg_catalog.pg_class c
+                JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind = 'v' AND n.nspname = 'auditor' LOOP
+        EXECUTE $$ DROP VIEW auditor.$$ || auditor_name || $$;$$;
+    END LOOP;
+    -- Fix all column discrepencies
+    PERFORM auditor.fix_columns();
+    -- Re-create trigger functions and lifecycle views
+    FOR table_schema, table_name IN
+        WITH audit_tables AS (
+            SELECT c.oid AS audit_oid, c.relname AS audit_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            WHERE relkind='r' AND nspname = 'auditor'
+        ),
+        table_set AS (
+            SELECT a.audit_oid, a.audit_table, c.oid AS main_oid, n.nspname as main_namespace, c.relname as main_table
+            FROM pg_catalog.pg_class c
+            JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
+            JOIN audit_tables a ON a.audit_table = n.nspname || '_' || c.relname || '_history'
+            WHERE relkind = 'r'
+        )
+        SELECT main_namespace, main_table FROM table_set LOOP
+        
+        PERFORM auditor.create_auditor_func(table_schema, table_name);
+        PERFORM auditor.create_auditor_lifecycle(table_schema, table_name);
+    END LOOP;
+    RETURN TRUE;
+END;
+$BODY$ LANGUAGE plpgsql;
+
+-- Go ahead and update them all now
+SELECT auditor.update_auditors();

-----------------------------------------------------------------------

Summary of changes:
 Open-ILS/include/openils/oils_sql.h                |    2 +
 Open-ILS/src/c-apps/oils_cstore.c                  |    7 +
 Open-ILS/src/c-apps/oils_pcrud.c                   |    7 +
 Open-ILS/src/c-apps/oils_rstore.c                  |    7 +
 Open-ILS/src/c-apps/oils_sql.c                     |   97 +++++
 .../src/perlmods/lib/OpenILS/Application/Actor.pm  |    3 +
 .../perlmods/lib/OpenILS/Application/AppUtils.pm   |   12 +
 .../perlmods/lib/OpenILS/Application/Circ/Money.pm |    1 +
 .../lib/OpenILS/Application/Circ/StatCat.pm        |    6 +
 .../lib/OpenILS/Application/Circ/Survey.pm         |    1 +
 .../lib/OpenILS/Application/Circ/Transit.pm        |    2 +
 .../lib/OpenILS/Application/Storage/Driver/Pg.pm   |   26 ++
 .../Application/Storage/Driver/Pg/storage.pm       |   78 ++++
 .../src/perlmods/lib/OpenILS/Utils/CStoreEditor.pm |   12 +
 Open-ILS/src/perlmods/lib/OpenILS/Utils/Editor.pm  |   12 +
 Open-ILS/src/perlmods/lib/OpenILS/WWW/BadDebt.pm   |    1 +
 .../lib/OpenILS/WWW/TemplateBatchBibUpdate.pm      |    1 +
 Open-ILS/src/sql/Pg/002.schema.config.sql          |    2 +-
 Open-ILS/src/sql/Pg/900.audit-functions.sql        |  251 +++++++++++-
 .../sql/Pg/upgrade/0686.schema.auditor_boost.sql   |  290 ++++++++++++++
 .../sql/Pg/version-upgrade/2.1-2.2-upgrade-db.sql  |  421 ++++++++++++++++++++
 21 files changed, 1226 insertions(+), 13 deletions(-)
 create mode 100644 Open-ILS/src/sql/Pg/upgrade/0686.schema.auditor_boost.sql


hooks/post-receive
-- 
Evergreen ILS


More information about the open-ils-commits mailing list