LP#1635354 Invoice close date/by fields
authorBill Erickson <berickxx@gmail.com>
Tue, 13 Mar 2018 20:02:41 +0000 (16:02 -0400)
committerKathy Lussier <klussier@masslnc.org>
Wed, 5 Sep 2018 03:49:14 +0000 (23:49 -0400)
Acquisitions invoices have 2 new fields:

* Close Date -- This is set to the time when the ACQ user clicks the
  "Close" button in the invoice interface.

This field replaces the existing "Complete" field.  An invoice is now
considered complete if a close date value is set.

* Closed By -- This is set to the logged in staff user who performs the
  "Close" action.

As with the now-defunct 'complete' field, but new fields are cleared in the
event an invoice is reopened.

These new fields are visible in the invoice interface under the 'Show
Details' action for closed invoices.

Signed-off-by: Bill Erickson <berickxx@gmail.com>
Signed-off-by: Kathy Lussier <klussier@masslnc.org>
Open-ILS/examples/fm_IDL.xml
Open-ILS/src/perlmods/lib/OpenILS/Application/Acq/Invoice.pm
Open-ILS/src/sql/Pg/200.schema.acq.sql
Open-ILS/src/sql/Pg/999.functions.global.sql
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.invoice-close-date.sql [new file with mode: 0644]
Open-ILS/web/js/ui/default/acq/invoice/view.js

index 4a10387..790a337 100644 (file)
@@ -8634,7 +8634,8 @@ SELECT  usr,
                        <field reporter:label="Payment Auth" name="payment_auth" reporter:datatype="text" />
                        <field reporter:label="Payment Method" name="payment_method" reporter:datatype="link" />
                        <field reporter:label="Note" name="note" reporter:datatype="text" />
-                       <field reporter:label="Complete" name="complete" reporter:datatype="bool" />
+                       <field reporter:label="Close Date" name="close_date" reporter:datatype="timestamp" />
+                       <field reporter:label="Closed By" name="closed_by" reporter:datatype="link" />
                        <field reporter:label="Invoice Entries" name="entries" reporter:datatype="link" oils_persist:virtual="true"/>
                        <field reporter:label="Invoice Items" name="items" reporter:datatype="link" oils_persist:virtual="true"/>
                </fields>
@@ -8646,6 +8647,7 @@ SELECT  usr,
                        <link field="payment_method" reltype="has_a" key="code" map="" class="acqipm"/>
                        <link field="entries" reltype="has_many" key="invoice" map="" class="acqie"/>
                        <link field="items" reltype="has_many" key="invoice" map="" class="acqii"/>
+                       <link field="closed_by" reltype="has_a" key="id" map="" class="au"/>
                </links>
         <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
             <actions>
index 80d8e3c..78765c6 100644 (file)
@@ -56,7 +56,10 @@ sub build_invoice_impl {
     if ($invoice->isnew) {
         $invoice->recv_method('PPR') unless $invoice->recv_method;
         $invoice->recv_date('now') unless $invoice->recv_date;
-        $inv_closing = $U->is_true($invoice->complete);
+        if ($invoice->close_date) {
+            $inv_closing = 1;
+            $invoice->closed_by($e->requestor->id);
+        }
         $e->create_acq_invoice($invoice) or return $e->die_event;
     } elsif ($invoice->isdeleted) {
         $e->delete_acq_invoice($invoice) or return $e->die_event;
@@ -64,13 +67,14 @@ sub build_invoice_impl {
         my $orig_inv = $e->retrieve_acq_invoice($invoice->id)
             or return $e->die_event;
 
-        $inv_closing = (
-            !$U->is_true($orig_inv->complete) && 
-            $U->is_true($invoice->complete));
+        if (!$orig_inv->close_date && $invoice->close_date) {
+            $inv_closing = 1;
+            $invoice->closed_by($e->requestor->id);
 
-        $inv_reopening = (
-            $U->is_true($orig_inv->complete) && 
-            !$U->is_true($invoice->complete));
+        } elsif ($orig_inv->close_date && !$invoice->close_date) {
+            $inv_reopening = 1;
+            $invoice->clear_closed_by;
+        }
 
         $e->update_acq_invoice($invoice) or return $e->die_event;
     }
@@ -140,8 +144,7 @@ sub build_invoice_impl {
                 #       being.
 
                 if (not $U->is_true($item_type->prorate) and
-                    ($item->po_item or $item->fund or
-                        $U->is_true($invoice->complete))) {
+                    ($item->po_item or $item->fund or $invoice->close_date)) {
 
                     my $debit;
                     if ($item->po_item) {
@@ -381,8 +384,8 @@ sub rollback_entry_debits {
 }
 
 # invoiced -- debits already linked to this invoice
-# inv_closing -- invoice is going from complete=f to t.
-# inv_reopening -- invoice is going from complete=t to f.
+# inv_closing -- invoice is going from close_date=null to now
+# inv_reopening -- invoice is going from close_date=date to null
 sub update_entry_debits {
     my($e, $entry, $link_state, $inv_closing, $inv_reopening) = @_;
 
@@ -709,7 +712,7 @@ sub fetch_invoice_impl {
         {
             "flesh" => 6,
             "flesh_fields" => {
-                "acqinv" => ["entries", "items"],
+                "acqinv" => ["entries", "items", "closed_by"],
                 "acqii" => ["fund_debit", "purchase_order", "po_item"]
             }
         }
index 68efce9..717f620 100644 (file)
@@ -854,7 +854,10 @@ CREATE TABLE acq.invoice (
        payment_method TEXT     REFERENCES acq.invoice_payment_method (code)
                                DEFERRABLE INITIALLY DEFERRED,
        note        TEXT,
-    complete    BOOL        NOT NULL DEFAULT FALSE,
+    close_date  TIMESTAMPTZ,
+    closed_by   INTEGER     REFERENCES actor.usr (id) 
+                            DEFERRABLE INITIALLY DEFERRED,
+
     CONSTRAINT  inv_ident_once_per_provider UNIQUE(provider, inv_ident)
 );
 
index 65dcdae..5b2bc74 100644 (file)
@@ -224,6 +224,7 @@ BEGIN
     -- acq.*
     UPDATE acq.fund_allocation SET allocator = dest_usr WHERE allocator = src_usr;
        UPDATE acq.fund_transfer SET transfer_user = dest_usr WHERE transfer_user = src_usr;
+    UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr;
 
        -- transfer picklists the same way we transfer buckets (see above)
        FOR picklist_row in
@@ -422,6 +423,7 @@ BEGIN
        UPDATE acq.lineitem SET selector = dest_usr WHERE selector = src_usr;
        UPDATE acq.lineitem_note SET creator = dest_usr WHERE creator = src_usr;
        UPDATE acq.lineitem_note SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr;
        DELETE FROM acq.lineitem_usr_attr_definition WHERE usr = src_usr;
 
        -- Update with a rename to avoid collisions
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.invoice-close-date.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.invoice-close-date.sql
new file mode 100644 (file)
index 0000000..2681be0
--- /dev/null
@@ -0,0 +1,696 @@
+BEGIN;
+
+-- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+DROP VIEW auditor.acq_invoice_lifecycle;
+
+ALTER TABLE acq.invoice
+    ADD COLUMN close_date TIMESTAMPTZ,
+    ADD COLUMN closed_by  INTEGER 
+        REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED;
+
+-- duplicate steps for auditor table
+ALTER TABLE auditor.acq_invoice_history
+    ADD COLUMN close_date TIMESTAMPTZ,
+    ADD COLUMN closed_by  INTEGER;
+
+UPDATE acq.invoice SET close_date = NOW() WHERE complete;
+UPDATE auditor.acq_invoice_history SET close_date = NOW() WHERE complete;
+
+ALTER TABLE acq.invoice DROP COLUMN complete;
+ALTER TABLE auditor.acq_invoice_history DROP COLUMN complete;
+
+-- this recreates auditor.acq_invoice_lifecycle;
+SELECT auditor.update_auditors();
+
+CREATE OR REPLACE FUNCTION actor.usr_merge( src_usr INT, dest_usr INT, del_addrs BOOLEAN, del_cards BOOLEAN, deactivate_cards BOOLEAN ) RETURNS VOID AS $$
+DECLARE
+       suffix TEXT;
+       bucket_row RECORD;
+       picklist_row RECORD;
+       queue_row RECORD;
+       folder_row RECORD;
+BEGIN
+
+    -- do some initial cleanup 
+    UPDATE actor.usr SET card = NULL WHERE id = src_usr;
+    UPDATE actor.usr SET mailing_address = NULL WHERE id = src_usr;
+    UPDATE actor.usr SET billing_address = NULL WHERE id = src_usr;
+
+    -- actor.*
+    IF del_cards THEN
+        DELETE FROM actor.card where usr = src_usr;
+    ELSE
+        IF deactivate_cards THEN
+            UPDATE actor.card SET active = 'f' WHERE usr = src_usr;
+        END IF;
+        UPDATE actor.card SET usr = dest_usr WHERE usr = src_usr;
+    END IF;
+
+
+    IF del_addrs THEN
+        DELETE FROM actor.usr_address WHERE usr = src_usr;
+    ELSE
+        UPDATE actor.usr_address SET usr = dest_usr WHERE usr = src_usr;
+    END IF;
+
+    UPDATE actor.usr_note SET usr = dest_usr WHERE usr = src_usr;
+    -- dupes are technically OK in actor.usr_standing_penalty, should manually delete them...
+    UPDATE actor.usr_standing_penalty SET usr = dest_usr WHERE usr = src_usr;
+    PERFORM actor.usr_merge_rows('actor.usr_org_unit_opt_in', 'usr', src_usr, dest_usr);
+    PERFORM actor.usr_merge_rows('actor.usr_setting', 'usr', src_usr, dest_usr);
+
+    -- permission.*
+    PERFORM actor.usr_merge_rows('permission.usr_perm_map', 'usr', src_usr, dest_usr);
+    PERFORM actor.usr_merge_rows('permission.usr_object_perm_map', 'usr', src_usr, dest_usr);
+    PERFORM actor.usr_merge_rows('permission.usr_grp_map', 'usr', src_usr, dest_usr);
+    PERFORM actor.usr_merge_rows('permission.usr_work_ou_map', 'usr', src_usr, dest_usr);
+
+
+    -- container.*
+       
+       -- For each *_bucket table: transfer every bucket belonging to src_usr
+       -- into the custody of dest_usr.
+       --
+       -- In order to avoid colliding with an existing bucket owned by
+       -- the destination user, append the source user's id (in parenthesese)
+       -- to the name.  If you still get a collision, add successive
+       -- spaces to the name and keep trying until you succeed.
+       --
+       FOR bucket_row in
+               SELECT id, name
+               FROM   container.biblio_record_entry_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.biblio_record_entry_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = bucket_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR bucket_row in
+               SELECT id, name
+               FROM   container.call_number_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.call_number_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = bucket_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR bucket_row in
+               SELECT id, name
+               FROM   container.copy_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.copy_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = bucket_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR bucket_row in
+               SELECT id, name
+               FROM   container.user_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.user_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = bucket_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       UPDATE container.user_bucket_item SET target_user = dest_usr WHERE target_user = src_usr;
+
+    -- vandelay.*
+       -- transfer queues the same way we transfer buckets (see above)
+       FOR queue_row in
+               SELECT id, name
+               FROM   vandelay.queue
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  vandelay.queue
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = queue_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+    -- money.*
+    PERFORM actor.usr_merge_rows('money.collections_tracker', 'usr', src_usr, dest_usr);
+    PERFORM actor.usr_merge_rows('money.collections_tracker', 'collector', src_usr, dest_usr);
+    UPDATE money.billable_xact SET usr = dest_usr WHERE usr = src_usr;
+    UPDATE money.billing SET voider = dest_usr WHERE voider = src_usr;
+    UPDATE money.bnm_payment SET accepting_usr = dest_usr WHERE accepting_usr = src_usr;
+
+    -- action.*
+    UPDATE action.circulation SET usr = dest_usr WHERE usr = src_usr;
+    UPDATE action.circulation SET circ_staff = dest_usr WHERE circ_staff = src_usr;
+    UPDATE action.circulation SET checkin_staff = dest_usr WHERE checkin_staff = src_usr;
+    UPDATE action.usr_circ_history SET usr = dest_usr WHERE usr = src_usr;
+
+    UPDATE action.hold_request SET usr = dest_usr WHERE usr = src_usr;
+    UPDATE action.hold_request SET fulfillment_staff = dest_usr WHERE fulfillment_staff = src_usr;
+    UPDATE action.hold_request SET requestor = dest_usr WHERE requestor = src_usr;
+    UPDATE action.hold_notification SET notify_staff = dest_usr WHERE notify_staff = src_usr;
+
+    UPDATE action.in_house_use SET staff = dest_usr WHERE staff = src_usr;
+    UPDATE action.non_cataloged_circulation SET staff = dest_usr WHERE staff = src_usr;
+    UPDATE action.non_cataloged_circulation SET patron = dest_usr WHERE patron = src_usr;
+    UPDATE action.non_cat_in_house_use SET staff = dest_usr WHERE staff = src_usr;
+    UPDATE action.survey_response SET usr = dest_usr WHERE usr = src_usr;
+
+    -- acq.*
+    UPDATE acq.fund_allocation SET allocator = dest_usr WHERE allocator = src_usr;
+       UPDATE acq.fund_transfer SET transfer_user = dest_usr WHERE transfer_user = src_usr;
+    UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr;
+
+       -- transfer picklists the same way we transfer buckets (see above)
+       FOR picklist_row in
+               SELECT id, name
+               FROM   acq.picklist
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  acq.picklist
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = picklist_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+    UPDATE acq.purchase_order SET owner = dest_usr WHERE owner = src_usr;
+    UPDATE acq.po_note SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE acq.po_note SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE acq.provider_note SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE acq.provider_note SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE acq.lineitem_note SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE acq.lineitem_note SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE acq.lineitem_usr_attr_definition SET usr = dest_usr WHERE usr = src_usr;
+
+    -- asset.*
+    UPDATE asset.copy SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE asset.copy SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE asset.copy_note SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE asset.call_number SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE asset.call_number SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE asset.call_number_note SET creator = dest_usr WHERE creator = src_usr;
+
+    -- serial.*
+    UPDATE serial.record_entry SET creator = dest_usr WHERE creator = src_usr;
+    UPDATE serial.record_entry SET editor = dest_usr WHERE editor = src_usr;
+
+    -- reporter.*
+    -- It's not uncommon to define the reporter schema in a replica 
+    -- DB only, so don't assume these tables exist in the write DB.
+    BEGIN
+       UPDATE reporter.template SET owner = dest_usr WHERE owner = src_usr;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+    BEGIN
+       UPDATE reporter.report SET owner = dest_usr WHERE owner = src_usr;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+    BEGIN
+       UPDATE reporter.schedule SET runner = dest_usr WHERE runner = src_usr;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+    BEGIN
+               -- transfer folders the same way we transfer buckets (see above)
+               FOR folder_row in
+                       SELECT id, name
+                       FROM   reporter.template_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.template_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = folder_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+    BEGIN
+               -- transfer folders the same way we transfer buckets (see above)
+               FOR folder_row in
+                       SELECT id, name
+                       FROM   reporter.report_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.report_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = folder_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+    BEGIN
+               -- transfer folders the same way we transfer buckets (see above)
+               FOR folder_row in
+                       SELECT id, name
+                       FROM   reporter.output_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.output_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = folder_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+    EXCEPTION WHEN undefined_table THEN
+        -- do nothing
+    END;
+
+    -- Finally, delete the source user
+    DELETE FROM actor.usr WHERE id = src_usr;
+
+END;
+$$ LANGUAGE plpgsql;
+
+
+CREATE OR REPLACE FUNCTION actor.usr_purge_data(
+       src_usr  IN INTEGER,
+       specified_dest_usr IN INTEGER
+) RETURNS VOID AS $$
+DECLARE
+       suffix TEXT;
+       renamable_row RECORD;
+       dest_usr INTEGER;
+BEGIN
+
+       IF specified_dest_usr IS NULL THEN
+               dest_usr := 1; -- Admin user on stock installs
+       ELSE
+               dest_usr := specified_dest_usr;
+       END IF;
+
+       -- acq.*
+       UPDATE acq.fund_allocation SET allocator = dest_usr WHERE allocator = src_usr;
+       UPDATE acq.lineitem SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE acq.lineitem SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE acq.lineitem SET selector = dest_usr WHERE selector = src_usr;
+       UPDATE acq.lineitem_note SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE acq.lineitem_note SET editor = dest_usr WHERE editor = src_usr;
+    UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr;
+       DELETE FROM acq.lineitem_usr_attr_definition WHERE usr = src_usr;
+
+       -- Update with a rename to avoid collisions
+       FOR renamable_row in
+               SELECT id, name
+               FROM   acq.picklist
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  acq.picklist
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       UPDATE acq.picklist SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE acq.picklist SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE acq.po_note SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE acq.po_note SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE acq.purchase_order SET owner = dest_usr WHERE owner = src_usr;
+       UPDATE acq.purchase_order SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE acq.purchase_order SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE acq.claim_event SET creator = dest_usr WHERE creator = src_usr;
+
+       -- action.*
+       DELETE FROM action.circulation WHERE usr = src_usr;
+       UPDATE action.circulation SET circ_staff = dest_usr WHERE circ_staff = src_usr;
+       UPDATE action.circulation SET checkin_staff = dest_usr WHERE checkin_staff = src_usr;
+       UPDATE action.hold_notification SET notify_staff = dest_usr WHERE notify_staff = src_usr;
+       UPDATE action.hold_request SET fulfillment_staff = dest_usr WHERE fulfillment_staff = src_usr;
+       UPDATE action.hold_request SET requestor = dest_usr WHERE requestor = src_usr;
+       DELETE FROM action.hold_request WHERE usr = src_usr;
+       UPDATE action.in_house_use SET staff = dest_usr WHERE staff = src_usr;
+       UPDATE action.non_cat_in_house_use SET staff = dest_usr WHERE staff = src_usr;
+       DELETE FROM action.non_cataloged_circulation WHERE patron = src_usr;
+       UPDATE action.non_cataloged_circulation SET staff = dest_usr WHERE staff = src_usr;
+       DELETE FROM action.survey_response WHERE usr = src_usr;
+       UPDATE action.fieldset SET owner = dest_usr WHERE owner = src_usr;
+       DELETE FROM action.usr_circ_history WHERE usr = src_usr;
+
+       -- actor.*
+       DELETE FROM actor.card WHERE usr = src_usr;
+       DELETE FROM actor.stat_cat_entry_usr_map WHERE target_usr = src_usr;
+
+       -- The following update is intended to avoid transient violations of a foreign
+       -- key constraint, whereby actor.usr_address references itself.  It may not be
+       -- necessary, but it does no harm.
+       UPDATE actor.usr_address SET replaces = NULL
+               WHERE usr = src_usr AND replaces IS NOT NULL;
+       DELETE FROM actor.usr_address WHERE usr = src_usr;
+       DELETE FROM actor.usr_note WHERE usr = src_usr;
+       UPDATE actor.usr_note SET creator = dest_usr WHERE creator = src_usr;
+       DELETE FROM actor.usr_org_unit_opt_in WHERE usr = src_usr;
+       UPDATE actor.usr_org_unit_opt_in SET staff = dest_usr WHERE staff = src_usr;
+       DELETE FROM actor.usr_setting WHERE usr = src_usr;
+       DELETE FROM actor.usr_standing_penalty WHERE usr = src_usr;
+       UPDATE actor.usr_standing_penalty SET staff = dest_usr WHERE staff = src_usr;
+
+       -- asset.*
+       UPDATE asset.call_number SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE asset.call_number SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE asset.call_number_note SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE asset.copy SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE asset.copy SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE asset.copy_note SET creator = dest_usr WHERE creator = src_usr;
+
+       -- auditor.*
+       DELETE FROM auditor.actor_usr_address_history WHERE id = src_usr;
+       DELETE FROM auditor.actor_usr_history WHERE id = src_usr;
+       UPDATE auditor.asset_call_number_history SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE auditor.asset_call_number_history SET editor  = dest_usr WHERE editor  = src_usr;
+       UPDATE auditor.asset_copy_history SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE auditor.asset_copy_history SET editor  = dest_usr WHERE editor  = src_usr;
+       UPDATE auditor.biblio_record_entry_history SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE auditor.biblio_record_entry_history SET editor  = dest_usr WHERE editor  = src_usr;
+
+       -- biblio.*
+       UPDATE biblio.record_entry SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE biblio.record_entry SET editor = dest_usr WHERE editor = src_usr;
+       UPDATE biblio.record_note SET creator = dest_usr WHERE creator = src_usr;
+       UPDATE biblio.record_note SET editor = dest_usr WHERE editor = src_usr;
+
+       -- container.*
+       -- Update buckets with a rename to avoid collisions
+       FOR renamable_row in
+               SELECT id, name
+               FROM   container.biblio_record_entry_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.biblio_record_entry_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR renamable_row in
+               SELECT id, name
+               FROM   container.call_number_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.call_number_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR renamable_row in
+               SELECT id, name
+               FROM   container.copy_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.copy_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       FOR renamable_row in
+               SELECT id, name
+               FROM   container.user_bucket
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  container.user_bucket
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+       DELETE FROM container.user_bucket_item WHERE target_user = src_usr;
+
+       -- money.*
+       DELETE FROM money.billable_xact WHERE usr = src_usr;
+       DELETE FROM money.collections_tracker WHERE usr = src_usr;
+       UPDATE money.collections_tracker SET collector = dest_usr WHERE collector = src_usr;
+
+       -- permission.*
+       DELETE FROM permission.usr_grp_map WHERE usr = src_usr;
+       DELETE FROM permission.usr_object_perm_map WHERE usr = src_usr;
+       DELETE FROM permission.usr_perm_map WHERE usr = src_usr;
+       DELETE FROM permission.usr_work_ou_map WHERE usr = src_usr;
+
+       -- reporter.*
+       -- Update with a rename to avoid collisions
+       BEGIN
+               FOR renamable_row in
+                       SELECT id, name
+                       FROM   reporter.output_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.output_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = renamable_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+       EXCEPTION WHEN undefined_table THEN
+               -- do nothing
+       END;
+
+       BEGIN
+               UPDATE reporter.report SET owner = dest_usr WHERE owner = src_usr;
+       EXCEPTION WHEN undefined_table THEN
+               -- do nothing
+       END;
+
+       -- Update with a rename to avoid collisions
+       BEGIN
+               FOR renamable_row in
+                       SELECT id, name
+                       FROM   reporter.report_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.report_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = renamable_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+       EXCEPTION WHEN undefined_table THEN
+               -- do nothing
+       END;
+
+       BEGIN
+               UPDATE reporter.schedule SET runner = dest_usr WHERE runner = src_usr;
+       EXCEPTION WHEN undefined_table THEN
+               -- do nothing
+       END;
+
+       BEGIN
+               UPDATE reporter.template SET owner = dest_usr WHERE owner = src_usr;
+       EXCEPTION WHEN undefined_table THEN
+               -- do nothing
+       END;
+
+       -- Update with a rename to avoid collisions
+       BEGIN
+               FOR renamable_row in
+                       SELECT id, name
+                       FROM   reporter.template_folder
+                       WHERE  owner = src_usr
+               LOOP
+                       suffix := ' (' || src_usr || ')';
+                       LOOP
+                               BEGIN
+                                       UPDATE  reporter.template_folder
+                                       SET     owner = dest_usr, name = name || suffix
+                                       WHERE   id = renamable_row.id;
+                               EXCEPTION WHEN unique_violation THEN
+                                       suffix := suffix || ' ';
+                                       CONTINUE;
+                               END;
+                               EXIT;
+                       END LOOP;
+               END LOOP;
+       EXCEPTION WHEN undefined_table THEN
+       -- do nothing
+       END;
+
+       -- vandelay.*
+       -- Update with a rename to avoid collisions
+       FOR renamable_row in
+               SELECT id, name
+               FROM   vandelay.queue
+               WHERE  owner = src_usr
+       LOOP
+               suffix := ' (' || src_usr || ')';
+               LOOP
+                       BEGIN
+                               UPDATE  vandelay.queue
+                               SET     owner = dest_usr, name = name || suffix
+                               WHERE   id = renamable_row.id;
+                       EXCEPTION WHEN unique_violation THEN
+                               suffix := suffix || ' ';
+                               CONTINUE;
+                       END;
+                       EXIT;
+               END LOOP;
+       END LOOP;
+
+    -- NULL-ify addresses last so other cleanup (e.g. circ anonymization)
+    -- can access the information before deletion.
+       UPDATE actor.usr SET
+               active = FALSE,
+               card = NULL,
+               mailing_address = NULL,
+               billing_address = NULL
+       WHERE id = src_usr;
+
+END;
+$$ LANGUAGE plpgsql;
+
+
+
+COMMIT;
+
+
+-- UNDO (minus user purge/merge changes)
+/*
+
+BEGIN;
+DROP VIEW auditor.acq_invoice_lifecycle;
+ALTER TABLE acq.invoice ADD COLUMN complete BOOLEAN NOT NULL DEFAULT FALSE;
+ALTER TABLE auditor.acq_invoice_history 
+    ADD COLUMN complete BOOLEAN NOT NULL DEFAULT FALSE;
+UPDATE acq.invoice SET complete = TRUE where close_date IS NOT NULL;
+UPDATE auditor.acq_invoice_history 
+    SET complete = TRUE where close_date IS NOT NULL;
+SET CONSTRAINTS ALL IMMEDIATE; -- or get pending triggers error.
+ALTER TABLE acq.invoice DROP COLUMN close_date, DROP COLUMN closed_by;
+ALTER TABLE auditor.acq_invoice_history
+    DROP COLUMN close_date, DROP COLUMN closed_by;
+SELECT auditor.update_auditors();
+COMMIT;
+
+*/
+
index 9ac5e25..4888d5e 100644 (file)
@@ -138,7 +138,7 @@ function renderInvoice() {
 
     updateTotalCost();
 
-    if(invoice && openils.Util.isTrue(invoice.complete())) {
+    if(invoice && invoice.close_date()) {
 
         dojo.forEach( // hide widgets that should not be visible for a completed invoice
             dojo.query('.hide-complete'), 
@@ -632,7 +632,7 @@ function addInvoiceItem(item) {
                     fmClass : 'acqii',
                     fmObject : item,
                     fmField : field,
-                    readOnly : invoice && openils.Util.isTrue(invoice.complete()),
+                    readOnly : invoice && invoice.close_date(),
                     dijitArgs : args,
                     parentNode : nodeByName(field, row)
                 }),
@@ -660,7 +660,7 @@ function addInvoiceItem(item) {
         labelFormat : fundLabelFormat,
         searchFormat : fundSearchFormat,
         searchFilter : fundSearchFilter,
-        readOnly : invoice && openils.Util.isTrue(invoice.complete()),
+        readOnly : invoice && invoice.close_date(),
         dijitArgs : {required : true},
         parentNode : nodeByName('fund', row)
     }
@@ -736,7 +736,7 @@ function addInvoiceItem(item) {
                 fmObject : item,
                 fmField : 'inv_item_type',
                 parentNode : nodeByName('inv_item_type', row),
-                readOnly : invoice && openils.Util.isTrue(invoice.complete()),
+                readOnly : invoice && invoice.close_date(),
                 dijitArgs : {required : true}
             }),
             function(w, ww) {
@@ -932,7 +932,7 @@ function addInvoiceEntry(entry) {
                             fmClass : 'acqie',
                             fmField : field,
                             dijitArgs : dijitArgs,
-                            readOnly : invoice && openils.Util.isTrue(invoice.complete()),
+                            readOnly : invoice && invoice.close_date(),
                             parentNode : nodeByName(field, row)
                         }),
                         function(w) {    
@@ -1056,7 +1056,7 @@ function saveChangesPartTwo(args) {
     args = args || {};
 
     if(args.reopen) {
-        invoice.complete('f');
+        invoice.close_date(null);
 
     } else {
 
@@ -1075,7 +1075,7 @@ function saveChangesPartTwo(args) {
         }
 
         if(args.close)
-            invoice.complete('t');
+            invoice.close_date('now');
 
 
         // Prepare any charge items
@@ -1245,6 +1245,11 @@ function drawInvoicePane(parentNode, inv, args) {
             },
             recv_method : {widgetValue : 'PPR'}
         };
+    } else {
+        if (inv.closed_by()) {
+            dojo.mixin(override, 
+                {closed_by: {widgetValue : inv.closed_by().usrname()}});
+        }
     }
 
     dojo.mixin(override, {
@@ -1286,6 +1291,10 @@ function drawInvoicePane(parentNode, inv, args) {
     );
 
 
+    // Display the close date/by data for closed invoices.
+    var readOnly = inv && inv.close_date();
+    var suppress = readOnly ? ['id'] : ['id', 'close_date', 'closed_by'];
+
     pane = new openils.widget.EditPane({
         fmObject : inv,
         paneStackCount : 2,
@@ -1293,7 +1302,7 @@ function drawInvoicePane(parentNode, inv, args) {
         mode : (inv) ? 'edit' : 'create',
         hideActionButtons : true,
         overrideWidgetArgs : override,
-        readOnly : (inv) && openils.Util.isTrue(inv.complete()),
+        readOnly : readOnly,
         requiredFields : [
             'inv_ident', 
             'recv_date', 
@@ -1308,7 +1317,7 @@ function drawInvoicePane(parentNode, inv, args) {
             'provider', 
             'shipper'
         ],
-        suppressFields : ['id', 'complete']
+        suppressFields : suppress
     });
 
     pane.startup();