]> git.evergreen-ils.org Git - Evergreen.git/blob - Open-ILS/src/sql/Pg/200.schema.acq.sql
Acq: Improved invoice-linking and -viewing features in LI, PO interfaces
[Evergreen.git] / Open-ILS / src / sql / Pg / 200.schema.acq.sql
1 DROP SCHEMA acq CASCADE;
2
3 BEGIN;
4
5 CREATE SCHEMA acq;
6
7
8 -- Tables
9
10
11 CREATE TABLE acq.currency_type (
12         code    TEXT PRIMARY KEY,
13         label   TEXT
14 );
15
16 -- Use the ISO 4217 abbreviations for currency codes
17 INSERT INTO acq.currency_type (code, label) VALUES ('USD','US Dollars');
18 INSERT INTO acq.currency_type (code, label) VALUES ('CAN','Canadian Dollars');
19 INSERT INTO acq.currency_type (code, label) VALUES ('EUR','Euros');
20
21 CREATE TABLE acq.exchange_rate (
22     id              SERIAL  PRIMARY KEY,
23     from_currency   TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
24     to_currency     TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
25     ratio           NUMERIC NOT NULL,
26     CONSTRAINT exchange_rate_from_to_once UNIQUE (from_currency,to_currency)
27 );
28
29 INSERT INTO acq.exchange_rate (from_currency,to_currency,ratio) VALUES ('USD','CAN',1.2);
30 INSERT INTO acq.exchange_rate (from_currency,to_currency,ratio) VALUES ('USD','EUR',0.5);
31
32 CREATE TABLE acq.claim_policy (
33         id              SERIAL       PRIMARY KEY,
34         org_unit        INT          NOT NULL REFERENCES actor.org_unit
35                                      DEFERRABLE INITIALLY DEFERRED,
36         name            TEXT         NOT NULL,
37         description     TEXT         NOT NULL,
38         CONSTRAINT name_once_per_org UNIQUE (org_unit, name)
39 );
40
41 CREATE TABLE acq.claim_event_type (
42         id             SERIAL           PRIMARY KEY,
43         org_unit       INT              NOT NULL REFERENCES actor.org_unit(id)
44                                                  DEFERRABLE INITIALLY DEFERRED,
45         code           TEXT             NOT NULL,
46         description    TEXT             NOT NULL,
47         library_initiated BOOL          NOT NULL DEFAULT FALSE,
48         CONSTRAINT event_type_once_per_org UNIQUE ( org_unit, code )
49 );
50
51 CREATE TABLE acq.claim_policy_action (
52         id              SERIAL       PRIMARY KEY,
53         claim_policy    INT          NOT NULL REFERENCES acq.claim_policy
54                                  ON DELETE CASCADE
55                                      DEFERRABLE INITIALLY DEFERRED,
56         action_interval INTERVAL     NOT NULL,
57         action          INT          NOT NULL REFERENCES acq.claim_event_type
58                                      DEFERRABLE INITIALLY DEFERRED,
59         CONSTRAINT action_sequence UNIQUE (claim_policy, action_interval)
60 );
61
62 CREATE TABLE acq.provider (
63     id                  SERIAL  PRIMARY KEY,
64     name                TEXT    NOT NULL,
65     owner               INT     NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
66     currency_type       TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
67     code                TEXT    NOT NULL,
68     holding_tag         TEXT,
69     san                 TEXT,
70     edi_default         INT,          -- REFERENCES acq.edi_account (id) DEFERRABLE INITIALLY DEFERRED
71         active              BOOL    NOT NULL DEFAULT TRUE,
72         prepayment_required BOOL    NOT NULL DEFAULT FALSE,
73     url                 TEXT,
74     email               TEXT,
75     phone               TEXT,
76     fax_phone           TEXT,
77         default_claim_policy INT    REFERENCES acq.claim_policy
78                                     DEFERRABLE INITIALLY DEFERRED,
79     CONSTRAINT provider_name_once_per_owner UNIQUE (name,owner),
80         CONSTRAINT code_once_per_owner UNIQUE (code, owner)
81 );
82
83 CREATE TABLE acq.provider_holding_subfield_map (
84     id          SERIAL  PRIMARY KEY,
85     provider    INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
86     name        TEXT    NOT NULL, -- barcode, price, etc
87     subfield    TEXT    NOT NULL,
88     CONSTRAINT name_once_per_provider UNIQUE (provider,name)
89 );
90
91 CREATE TABLE acq.provider_address (
92         id              SERIAL  PRIMARY KEY,
93         valid           BOOL    NOT NULL DEFAULT TRUE,
94         address_type    TEXT,
95     provider    INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
96         street1         TEXT    NOT NULL,
97         street2         TEXT,
98         city            TEXT    NOT NULL,
99         county          TEXT,
100         state           TEXT    NOT NULL,
101         country         TEXT    NOT NULL,
102         post_code       TEXT    NOT NULL,
103         fax_phone       TEXT    NOT NULL
104 );
105
106 CREATE TABLE acq.provider_contact (
107         id              SERIAL  PRIMARY KEY,
108     provider    INT NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
109     name    TEXT NULL NULL,
110     role    TEXT, -- free-form.. e.g. "our sales guy"
111     email   TEXT,
112     phone   TEXT
113 );
114
115 CREATE TABLE acq.provider_contact_address (
116         id                      SERIAL  PRIMARY KEY,
117         valid                   BOOL    NOT NULL DEFAULT TRUE,
118         address_type    TEXT,
119         contact                 INT         NOT NULL REFERENCES acq.provider_contact (id) DEFERRABLE INITIALLY DEFERRED,
120         street1                 TEXT    NOT NULL,
121         street2                 TEXT,
122         city                    TEXT    NOT NULL,
123         county                  TEXT,
124         state                   TEXT    NOT NULL,
125         country                 TEXT    NOT NULL,
126         post_code               TEXT    NOT NULL,
127         fax_phone               TEXT
128 );
129
130 CREATE TABLE acq.provider_note (
131         id              SERIAL                          PRIMARY KEY,
132         provider    INT                         NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
133         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
134         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
135         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
136         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
137         value           TEXT                    NOT NULL
138 );
139 CREATE INDEX acq_pro_note_pro_idx      ON acq.provider_note ( provider );
140 CREATE INDEX acq_pro_note_creator_idx  ON acq.provider_note ( creator );
141 CREATE INDEX acq_pro_note_editor_idx   ON acq.provider_note ( editor );
142
143
144 CREATE TABLE acq.funding_source (
145         id              SERIAL  PRIMARY KEY,
146         name            TEXT    NOT NULL,
147         owner           INT     NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
148         currency_type   TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
149         code            TEXT    UNIQUE,
150         CONSTRAINT funding_source_name_once_per_owner UNIQUE (name,owner)
151 );
152
153 CREATE TABLE acq.funding_source_credit (
154         id      SERIAL     PRIMARY KEY,
155         funding_source INT      NOT NULL REFERENCES acq.funding_source (id) DEFERRABLE INITIALLY DEFERRED,
156         amount         NUMERIC  NOT NULL,
157         note           TEXT,
158         deadline_date  TIMESTAMPTZ,
159         effective_date TIMESTAMPTZ NOT NULL default now()
160 );
161
162 CREATE VIEW acq.ordered_funding_source_credit AS
163     SELECT
164         CASE WHEN deadline_date IS NULL THEN
165             2
166         ELSE
167             1
168         END AS sort_priority,
169         CASE WHEN deadline_date IS NULL THEN
170             effective_date
171         ELSE
172             deadline_date
173         END AS sort_date,
174         id,
175         funding_source,
176         amount,
177         note
178     FROM
179         acq.funding_source_credit;
180
181 COMMENT ON VIEW acq.ordered_funding_source_credit IS $$
182 /*
183  * Copyright (C) 2009  Georgia Public Library Service
184  * Scott McKellar <scott@gmail.com>
185  *
186  * The acq.ordered_funding_source_credit view is a prioritized
187  * ordering of funding source credits.  When ordered by the first
188  * three columns, this view defines the order in which the various
189  * credits are to be tapped for spending, subject to the allocations
190  * in the acq.fund_allocation table.
191  *
192  * The first column reflects the principle that we should spend
193  * money with deadlines before spending money without deadlines.
194  *
195  * The second column reflects the principle that we should spend the
196  * oldest money first.  For money with deadlines, that means that we
197  * spend first from the credit with the earliest deadline.  For
198  * money without deadlines, we spend first from the credit with the
199  * earliest effective date.
200  *
201  * The third column is a tie breaker to ensure a consistent
202  * ordering.
203  *
204  * ****
205  *
206  * This program is free software; you can redistribute it and/or
207  * modify it under the terms of the GNU General Public License
208  * as published by the Free Software Foundation; either version 2
209  * of the License, or (at your option) any later version.
210  *
211  * This program is distributed in the hope that it will be useful,
212  * but WITHOUT ANY WARRANTY; without even the implied warranty of
213  * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
214  * GNU General Public License for more details.
215  */
216 $$;
217
218 CREATE TABLE acq.fund (
219     id              SERIAL  PRIMARY KEY,
220     org             INT     NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
221     name            TEXT    NOT NULL,
222     year            INT     NOT NULL DEFAULT EXTRACT( YEAR FROM NOW() ),
223     currency_type   TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
224     code            TEXT,
225         rollover        BOOL    NOT NULL DEFAULT FALSE,
226         propagate       BOOL    NOT NULL DEFAULT TRUE,
227         active          BOOL    NOT NULL DEFAULT TRUE,
228         balance_warning_percent INT CONSTRAINT balance_warning_percent_limit
229                                     CHECK( balance_warning_percent <= 100 ),
230         balance_stop_percent    INT CONSTRAINT balance_stop_percent_limit
231                                     CHECK( balance_stop_percent <= 100 ),
232     CONSTRAINT name_once_per_org_year UNIQUE (org,name,year),
233     CONSTRAINT code_once_per_org_year UNIQUE (org, code, year),
234         CONSTRAINT acq_fund_rollover_implies_propagate CHECK ( propagate OR NOT rollover )
235 );
236
237 CREATE TABLE acq.fund_debit (
238         id                      SERIAL  PRIMARY KEY,
239         fund                    INT     NOT NULL REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
240         origin_amount           NUMERIC NOT NULL,  -- pre-exchange-rate amount
241         origin_currency_type    TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
242         amount                  NUMERIC NOT NULL,
243         encumbrance             BOOL    NOT NULL DEFAULT TRUE,
244         debit_type              TEXT    NOT NULL,
245         xfer_destination        INT     REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
246         create_time     TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
247 );
248
249 CREATE TABLE acq.fund_allocation (
250     id          SERIAL  PRIMARY KEY,
251     funding_source        INT     NOT NULL REFERENCES acq.funding_source (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
252     fund        INT     NOT NULL REFERENCES acq.fund (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
253     amount      NUMERIC NOT NULL,
254     allocator   INT NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
255     note        TEXT,
256         create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
257 );
258 CREATE INDEX fund_alloc_allocator_idx ON acq.fund_allocation ( allocator );
259
260 CREATE TABLE acq.fund_allocation_percent
261 (
262     id                   SERIAL            PRIMARY KEY,
263     funding_source       INT               NOT NULL REFERENCES acq.funding_source
264                                                DEFERRABLE INITIALLY DEFERRED,
265     org                  INT               NOT NULL REFERENCES actor.org_unit
266                                                DEFERRABLE INITIALLY DEFERRED,
267     fund_code            TEXT,
268     percent              NUMERIC           NOT NULL,
269     allocator            INTEGER           NOT NULL REFERENCES actor.usr
270                                                DEFERRABLE INITIALLY DEFERRED,
271     note                 TEXT,
272     create_time          TIMESTAMPTZ       NOT NULL DEFAULT now(),
273     CONSTRAINT logical_key UNIQUE( funding_source, org, fund_code ),
274     CONSTRAINT percentage_range CHECK( percent >= 0 AND percent <= 100 )
275 );
276
277 -- Trigger function to validate combination of org_unit and fund_code
278
279 CREATE OR REPLACE FUNCTION acq.fund_alloc_percent_val()
280 RETURNS TRIGGER AS $$
281 --
282 DECLARE
283 --
284 dummy int := 0;
285 --
286 BEGIN
287     SELECT
288         1
289     INTO
290         dummy
291     FROM
292         acq.fund
293     WHERE
294         org = NEW.org
295         AND code = NEW.fund_code
296         LIMIT 1;
297     --
298     IF dummy = 1 then
299         RETURN NEW;
300     ELSE
301         RAISE EXCEPTION 'No fund exists for org % and code %', NEW.org, NEW.fund_code;
302     END IF;
303 END;
304 $$ LANGUAGE plpgsql;
305
306 CREATE TRIGGER acq_fund_alloc_percent_val_trig
307     BEFORE INSERT OR UPDATE ON acq.fund_allocation_percent
308     FOR EACH ROW EXECUTE PROCEDURE acq.fund_alloc_percent_val();
309
310 -- To do: trigger to verify that percentages don't add up to more than 100
311
312 CREATE OR REPLACE FUNCTION acq.fap_limit_100()
313 RETURNS TRIGGER AS $$
314 DECLARE
315 --
316 total_percent numeric;
317 --
318 BEGIN
319     SELECT
320         sum( percent )
321     INTO
322         total_percent
323     FROM
324         acq.fund_allocation_percent AS fap
325     WHERE
326         fap.funding_source = NEW.funding_source;
327     --
328     IF total_percent > 100 THEN
329         RAISE EXCEPTION 'Total percentages exceed 100 for funding_source %',
330             NEW.funding_source;
331     ELSE
332         RETURN NEW;
333     END IF;
334 END;
335 $$ LANGUAGE plpgsql;
336
337 CREATE TRIGGER acqfap_limit_100_trig
338     AFTER INSERT OR UPDATE ON acq.fund_allocation_percent
339     FOR EACH ROW EXECUTE PROCEDURE acq.fap_limit_100();
340
341 CREATE TABLE acq.picklist (
342         id              SERIAL                          PRIMARY KEY,
343         owner           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
344         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
345         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
346         org_unit        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
347         name            TEXT                            NOT NULL,
348         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
349         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
350         CONSTRAINT name_once_per_owner UNIQUE (name,owner)
351 );
352 CREATE INDEX acq_picklist_owner_idx   ON acq.picklist ( owner );
353 CREATE INDEX acq_picklist_creator_idx ON acq.picklist ( creator );
354 CREATE INDEX acq_picklist_editor_idx  ON acq.picklist ( editor );
355
356 CREATE TABLE acq.cancel_reason (
357         id            SERIAL            PRIMARY KEY,
358         org_unit      INTEGER           NOT NULL REFERENCES actor.org_unit( id )
359                                         DEFERRABLE INITIALLY DEFERRED,
360         label         TEXT              NOT NULL,
361         description   TEXT              NOT NULL,
362         CONSTRAINT acq_cancel_reason_one_per_org_unit UNIQUE( org_unit, label )
363 );
364
365 -- Reserve ids 1-999 for stock reasons
366 -- Reserve ids 1000-1999 for EDI reasons
367 -- 2000+ are available for staff to create
368
369 SELECT SETVAL('acq.cancel_reason_id_seq'::TEXT, 2000);
370
371 CREATE TABLE acq.purchase_order (
372         id              SERIAL                          PRIMARY KEY,
373         owner           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
374         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
375         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
376         ordering_agency INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
377         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
378         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
379         provider        INT                             NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
380         state                   TEXT                                    NOT NULL DEFAULT 'new',
381         order_date              TIMESTAMP WITH TIME ZONE,
382         name                    TEXT                                    NOT NULL,
383         cancel_reason   INT                     REFERENCES acq.cancel_reason( id )
384                                             DEFERRABLE INITIALLY DEFERRED,
385         prepayment_required BOOLEAN NOT NULL DEFAULT FALSE
386 );
387 CREATE INDEX po_owner_idx ON acq.purchase_order (owner);
388 CREATE INDEX po_provider_idx ON acq.purchase_order (provider);
389 CREATE INDEX po_state_idx ON acq.purchase_order (state);
390 CREATE INDEX po_creator_idx  ON acq.purchase_order ( creator );
391 CREATE INDEX po_editor_idx   ON acq.purchase_order ( editor );
392 CREATE INDEX acq_po_org_name_order_date_idx ON acq.purchase_order( ordering_agency, name, order_date );
393
394 -- The name should default to the id, as text.  We can't reference a column
395 -- in a DEFAULT clause, so we use a trigger:
396
397 CREATE OR REPLACE FUNCTION acq.purchase_order_name_default () RETURNS TRIGGER 
398 AS $$
399 BEGIN
400         IF NEW.name IS NULL THEN
401                 NEW.name := NEW.id::TEXT;
402         END IF;
403
404         RETURN NEW;
405 END;
406 $$ LANGUAGE PLPGSQL;
407
408 CREATE TRIGGER po_name_default_trg
409   BEFORE INSERT OR UPDATE ON acq.purchase_order
410   FOR EACH ROW EXECUTE PROCEDURE acq.purchase_order_name_default ();
411
412 -- The order name should be unique for a given ordering agency on a given order date
413 -- (truncated to midnight), but only where the order_date is not NULL.  Conceptually
414 -- this rule requires a check constraint with a subquery.  However you can't have a
415 -- subquery in a CHECK constraint, so we fake it with a trigger.
416
417 CREATE OR REPLACE FUNCTION acq.po_org_name_date_unique () RETURNS TRIGGER 
418 AS $$
419 DECLARE
420         collision INT;
421 BEGIN
422         --
423         -- If order_date is not null, then make sure we don't have a collision
424         -- on order_date (truncated to day), org, and name
425         --
426         IF NEW.order_date IS NULL THEN
427                 RETURN NEW;
428         END IF;
429         --
430         -- In the WHERE clause, we compare the order_dates without regard to time of day.
431         -- We use a pair of inequalities instead of comparing truncated dates so that the
432         -- query can do an indexed range scan.
433         --
434         SELECT 1 INTO collision
435         FROM acq.purchase_order
436         WHERE
437                 ordering_agency = NEW.ordering_agency
438                 AND name = NEW.name
439                 AND order_date >= date_trunc( 'day', NEW.order_date )
440                 AND order_date <  date_trunc( 'day', NEW.order_date ) + '1 day'::INTERVAL
441                 AND id <> NEW.id;
442         --
443         IF collision IS NULL THEN
444                 -- okay, no collision
445                 RETURN NEW;
446         ELSE
447                 -- collision; nip it in the bud
448                 RAISE EXCEPTION 'Colliding purchase orders: ordering_agency %, date %, name ''%''',
449                         NEW.ordering_agency, NEW.order_date, NEW.name;
450         END IF;
451 END;
452 $$ LANGUAGE PLPGSQL;
453
454 CREATE TRIGGER po_org_name_date_unique_trg
455   BEFORE INSERT OR UPDATE ON acq.purchase_order
456   FOR EACH ROW EXECUTE PROCEDURE acq.po_org_name_date_unique ();
457
458 CREATE TABLE acq.po_note (
459         id              SERIAL                          PRIMARY KEY,
460         purchase_order  INT                             NOT NULL REFERENCES acq.purchase_order (id) DEFERRABLE INITIALLY DEFERRED,
461         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
462         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
463         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
464         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
465         value           TEXT                    NOT NULL,
466         vendor_public BOOLEAN       NOT NULL DEFAULT FALSE
467 );
468 CREATE INDEX po_note_po_idx ON acq.po_note (purchase_order);
469 CREATE INDEX acq_po_note_creator_idx  ON acq.po_note ( creator );
470 CREATE INDEX acq_po_note_editor_idx   ON acq.po_note ( editor );
471
472 CREATE TABLE acq.lineitem (
473         id                  BIGSERIAL                   PRIMARY KEY,
474         creator             INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
475         editor              INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
476         selector            INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
477         provider            INT                         REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
478         purchase_order      INT                         REFERENCES acq.purchase_order (id) DEFERRABLE INITIALLY DEFERRED,
479         picklist            INT                         REFERENCES acq.picklist (id) DEFERRABLE INITIALLY DEFERRED,
480         expected_recv_time  TIMESTAMP WITH TIME ZONE,
481         create_time         TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
482         edit_time           TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
483         marc                TEXT                        NOT NULL,
484         eg_bib_id           INT                         REFERENCES biblio.record_entry (id) DEFERRABLE INITIALLY DEFERRED,
485         source_label        TEXT,
486         state               TEXT                        NOT NULL DEFAULT 'new',
487         cancel_reason       INT                         REFERENCES acq.cancel_reason( id )
488                                                     DEFERRABLE INITIALLY DEFERRED,
489         estimated_unit_price NUMERIC,
490         claim_policy        INT                         REFERENCES acq.claim_policy
491                                                                 DEFERRABLE INITIALLY DEFERRED,
492     CONSTRAINT picklist_or_po CHECK (picklist IS NOT NULL OR purchase_order IS NOT NULL)
493 );
494 CREATE INDEX li_po_idx ON acq.lineitem (purchase_order);
495 CREATE INDEX li_pl_idx ON acq.lineitem (picklist);
496 CREATE INDEX li_creator_idx   ON acq.lineitem ( creator );
497 CREATE INDEX li_editor_idx    ON acq.lineitem ( editor );
498 CREATE INDEX li_selector_idx  ON acq.lineitem ( selector );
499
500 CREATE TABLE acq.lineitem_alert_text (
501     id               SERIAL         PRIMARY KEY,
502     code             TEXT           NOT NULL,
503     description      TEXT,
504         owning_lib       INT            NOT NULL
505                                         REFERENCES actor.org_unit(id)
506                                         DEFERRABLE INITIALLY DEFERRED,
507         CONSTRAINT alert_one_code_per_org UNIQUE (code, owning_lib)
508 );
509
510 CREATE TABLE acq.lineitem_note (
511         id              SERIAL                          PRIMARY KEY,
512         lineitem        INT                             NOT NULL REFERENCES acq.lineitem (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
513         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
514         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
515         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
516         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
517         value           TEXT                    NOT NULL,
518         alert_text      INT                                              REFERENCES acq.lineitem_alert_text(id)
519                                                                                  DEFERRABLE INITIALLY DEFERRED,
520         vendor_public BOOLEAN       NOT NULL DEFAULT FALSE
521 );
522 CREATE INDEX li_note_li_idx ON acq.lineitem_note (lineitem);
523 CREATE INDEX li_note_creator_idx  ON acq.lineitem_note ( creator );
524 CREATE INDEX li_note_editor_idx   ON acq.lineitem_note ( editor );
525
526 CREATE TABLE acq.lineitem_detail (
527     id          BIGSERIAL       PRIMARY KEY,
528     lineitem    INT         NOT NULL REFERENCES acq.lineitem (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
529     fund        INT         REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
530     fund_debit  INT         REFERENCES acq.fund_debit (id) DEFERRABLE INITIALLY DEFERRED,
531     eg_copy_id  BIGINT      REFERENCES asset.copy (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
532     barcode     TEXT,
533     cn_label    TEXT,
534     note        TEXT,
535     collection_code TEXT,
536     circ_modifier   TEXT    REFERENCES config.circ_modifier (code) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
537     owning_lib  INT         REFERENCES actor.org_unit (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
538     location    INT         REFERENCES asset.copy_location (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
539     recv_time   TIMESTAMP WITH TIME ZONE,
540         cancel_reason   INT     REFERENCES acq.cancel_reason( id ) DEFERRABLE INITIALLY DEFERRED
541 );
542
543 CREATE INDEX li_detail_li_idx ON acq.lineitem_detail (lineitem);
544
545 CREATE TABLE acq.lineitem_attr_definition (
546         id              BIGSERIAL       PRIMARY KEY,
547         code            TEXT            NOT NULL,
548         description     TEXT            NOT NULL,
549         remove          TEXT            NOT NULL DEFAULT '',
550         ident           BOOL            NOT NULL DEFAULT FALSE
551 );
552
553 CREATE TABLE acq.lineitem_marc_attr_definition (
554         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
555         xpath           TEXT            NOT NULL
556 ) INHERITS (acq.lineitem_attr_definition);
557
558 CREATE TABLE acq.lineitem_provider_attr_definition (
559         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
560         xpath           TEXT            NOT NULL,
561         provider        INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED
562 ) INHERITS (acq.lineitem_attr_definition);
563
564 CREATE TABLE acq.lineitem_generated_attr_definition (
565         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
566         xpath           TEXT            NOT NULL
567 ) INHERITS (acq.lineitem_attr_definition);
568
569 CREATE TABLE acq.lineitem_usr_attr_definition (
570         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
571         usr             INT     NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED
572 ) INHERITS (acq.lineitem_attr_definition);
573 CREATE INDEX li_usr_attr_def_usr_idx  ON acq.lineitem_usr_attr_definition ( usr );
574
575 CREATE TABLE acq.lineitem_local_attr_definition (
576         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq')
577 ) INHERITS (acq.lineitem_attr_definition);
578
579 CREATE TABLE acq.lineitem_attr (
580         id              BIGSERIAL       PRIMARY KEY,
581         definition      BIGINT          NOT NULL,
582         lineitem        BIGINT          NOT NULL REFERENCES acq.lineitem (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
583         attr_type       TEXT            NOT NULL,
584         attr_name       TEXT            NOT NULL,
585         attr_value      TEXT            NOT NULL
586 );
587
588 CREATE INDEX li_attr_li_idx ON acq.lineitem_attr (lineitem);
589 CREATE INDEX li_attr_value_idx ON acq.lineitem_attr (attr_value);
590 CREATE INDEX li_attr_definition_idx ON acq.lineitem_attr (definition);
591
592
593 -- Seed data
594
595
596 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('title','Title of work','//*[@tag="245"]/*[contains("abcmnopr",@code)]');
597 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('author','Author of work','//*[@tag="100" or @tag="110" or @tag="113"]/*[contains("ad",@code)]');
598 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('language','Language of work','//*[@tag="240"]/*[@code="l"][1]');
599 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('pagination','Pagination','//*[@tag="300"]/*[@code="a"][1]');
600 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath, remove ) VALUES ('isbn','ISBN','//*[@tag="020"]/*[@code="a"]', $r$(?:-|\s.+$)$r$);
601 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath, remove ) VALUES ('issn','ISSN','//*[@tag="022"]/*[@code="a"]', $r$(?:-|\s.+$)$r$);
602 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('price','Price','//*[@tag="020" or @tag="022"]/*[@code="c"][1]');
603 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('identifier','Identifier','//*[@tag="001"]');
604 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('publisher','Publisher','//*[@tag="260"]/*[@code="b"][1]');
605 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('pubdate','Publication Date','//*[@tag="260"]/*[@code="c"][1]');
606 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('edition','Edition','//*[@tag="250"]/*[@code="a"][1]');
607
608 INSERT INTO acq.lineitem_local_attr_definition ( code, description ) VALUES ('estimated_price', 'Estimated Price');
609
610
611 CREATE TABLE acq.distribution_formula (
612         id              SERIAL PRIMARY KEY,
613         owner   INT NOT NULL
614                         REFERENCES actor.org_unit(id) DEFERRABLE INITIALLY DEFERRED,
615         name    TEXT NOT NULL,
616         skip_count      INT NOT NULL DEFAULT 0,
617         CONSTRAINT acqdf_name_once_per_owner UNIQUE (name, owner)
618 );
619
620 CREATE TABLE acq.distribution_formula_entry (
621         id                      SERIAL PRIMARY KEY,
622         formula         INTEGER NOT NULL REFERENCES acq.distribution_formula(id)
623                                 ON DELETE CASCADE
624                                 DEFERRABLE INITIALLY DEFERRED,
625         position        INTEGER NOT NULL,
626         item_count      INTEGER NOT NULL,
627         owning_lib      INTEGER REFERENCES actor.org_unit(id)
628                                 DEFERRABLE INITIALLY DEFERRED,
629         location        INTEGER REFERENCES asset.copy_location(id),
630         CONSTRAINT acqdfe_lib_once_per_formula UNIQUE( formula, position ),
631         CONSTRAINT acqdfe_must_be_somewhere
632                                 CHECK( owning_lib IS NOT NULL OR location IS NOT NULL ) 
633 );
634
635 CREATE TABLE acq.distribution_formula_application (
636     id BIGSERIAL PRIMARY KEY,
637     creator INT NOT NULL REFERENCES actor.usr(id) DEFERRABLE INITIALLY DEFERRED,
638     create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
639     formula INT NOT NULL
640         REFERENCES acq.distribution_formula(id) DEFERRABLE INITIALLY DEFERRED,
641     lineitem INT NOT NULL
642         REFERENCES acq.lineitem(id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
643 );
644
645 CREATE INDEX acqdfa_df_idx
646     ON acq.distribution_formula_application(formula);
647 CREATE INDEX acqdfa_li_idx
648     ON acq.distribution_formula_application(lineitem);
649 CREATE INDEX acqdfa_creator_idx
650     ON acq.distribution_formula_application(creator);
651
652 CREATE TABLE acq.fund_tag (
653         id              SERIAL PRIMARY KEY,
654         owner   INT NOT NULL
655                         REFERENCES actor.org_unit(id) DEFERRABLE INITIALLY DEFERRED,
656         name    TEXT NOT NULL,
657         CONSTRAINT acqft_tag_once_per_owner UNIQUE (name, owner)
658 );
659
660 CREATE TABLE acq.fund_tag_map (
661         id                      SERIAL PRIMARY KEY,
662         fund            INTEGER NOT NULL REFERENCES acq.fund(id)
663                                 DEFERRABLE INITIALLY DEFERRED,
664         tag         INTEGER REFERENCES acq.fund_tag(id)
665                                 ON DELETE CASCADE
666                                 DEFERRABLE INITIALLY DEFERRED,
667         CONSTRAINT acqftm_fund_once_per_tag UNIQUE( fund, tag )
668 );
669
670 CREATE TABLE acq.fund_transfer (
671     id               SERIAL         PRIMARY KEY,
672     src_fund         INT            NOT NULL REFERENCES acq.fund( id )
673                                     DEFERRABLE INITIALLY DEFERRED,
674     src_amount       NUMERIC        NOT NULL,
675     dest_fund        INT            NOT NULL REFERENCES acq.fund( id )
676                                     DEFERRABLE INITIALLY DEFERRED,
677     dest_amount      NUMERIC        NOT NULL,
678     transfer_time    TIMESTAMPTZ    NOT NULL DEFAULT now(),
679     transfer_user    INT            NOT NULL REFERENCES actor.usr( id )
680                                     DEFERRABLE INITIALLY DEFERRED,
681     note             TEXT,
682         funding_source_credit INT       NOT NULL REFERENCES acq.funding_source_credit( id )
683                                     DEFERRABLE INITIALLY DEFERRED
684 );
685
686 CREATE INDEX acqftr_usr_idx
687 ON acq.fund_transfer( transfer_user );
688
689 COMMENT ON TABLE acq.fund_transfer IS $$
690 /*
691  * Copyright (C) 2009  Georgia Public Library Service
692  * Scott McKellar <scott@esilibrary.com>
693  *
694  * Fund Transfer
695  *
696  * Each row represents the transfer of money from a source fund
697  * to a destination fund.  There should be corresponding entries
698  * in acq.fund_allocation.  The purpose of acq.fund_transfer is
699  * to record how much money moved from which fund to which other
700  * fund.
701  *
702  * The presence of two amount fields, rather than one, reflects
703  * the possibility that the two funds are denominated in different
704  * currencies.  If they use the same currency type, the two
705  * amounts should be the same.
706  *
707  * ****
708  *
709  * This program is free software; you can redistribute it and/or
710  * modify it under the terms of the GNU General Public License
711  * as published by the Free Software Foundation; either version 2
712  * of the License, or (at your option) any later version.
713  *
714  * This program is distributed in the hope that it will be useful,
715  * but WITHOUT ANY WARRANTY; without even the implied warranty of
716  * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
717  * GNU General Public License for more details.
718  */
719 $$;
720
721 CREATE TABLE acq.fiscal_calendar (
722         id              SERIAL         PRIMARY KEY,
723         name            TEXT           NOT NULL
724 );
725
726 -- Create a default calendar (though we don't specify its contents). 
727 -- Create a foreign key in actor.org_unit, initially pointing to
728 -- the default calendar.
729
730 INSERT INTO acq.fiscal_calendar (
731     name
732 ) VALUES (
733
734     'Default'
735 );
736
737 ALTER TABLE actor.org_unit ADD FOREIGN KEY
738         (fiscal_calendar) REFERENCES acq.fiscal_calendar( id )
739         DEFERRABLE INITIALLY DEFERRED;
740
741 CREATE TABLE acq.fiscal_year (
742         id              SERIAL         PRIMARY KEY,
743         calendar        INT            NOT NULL
744                                        REFERENCES acq.fiscal_calendar
745                                        ON DELETE CASCADE
746                                        DEFERRABLE INITIALLY DEFERRED,
747         year            INT            NOT NULL,
748         year_begin      TIMESTAMPTZ    NOT NULL,
749         year_end        TIMESTAMPTZ    NOT NULL,
750         CONSTRAINT acq_fy_logical_key  UNIQUE ( calendar, year ),
751     CONSTRAINT acq_fy_physical_key UNIQUE ( calendar, year_begin )
752 );
753
754 CREATE TABLE acq.edi_account (      -- similar tables can extend remote_account for other parts of EG
755     provider    INT     NOT NULL REFERENCES acq.provider          (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
756     in_dir      TEXT    -- incoming messages dir (probably different than config.remote_account.path, the outgoing dir)
757 ) INHERITS (config.remote_account);
758
759 -- We need a UNIQUE constraint here also, to support the FK from acq.provider.edi_default
760 ALTER TABLE acq.edi_account ADD CONSTRAINT acq_edi_account_id_unique UNIQUE (id);
761
762 -- Note below that the primary key is NOT a SERIAL type.  We will periodically truncate and rebuild
763 -- the table, assigning ids programmatically instead of using a sequence.
764 CREATE TABLE acq.debit_attribution (
765     id                     INT         NOT NULL PRIMARY KEY,
766     fund_debit             INT         NOT NULL
767                                        REFERENCES acq.fund_debit
768                                        DEFERRABLE INITIALLY DEFERRED,
769     debit_amount           NUMERIC     NOT NULL,
770     funding_source_credit  INT         REFERENCES acq.funding_source_credit
771                                        DEFERRABLE INITIALLY DEFERRED,
772     credit_amount          NUMERIC
773 );
774
775 CREATE INDEX acq_attribution_debit_idx
776     ON acq.debit_attribution( fund_debit );
777
778 CREATE INDEX acq_attribution_credit_idx
779     ON acq.debit_attribution( funding_source_credit );
780
781 -- Invoicing
782
783 CREATE TABLE acq.invoice_method (
784     code    TEXT    PRIMARY KEY,
785     name    TEXT    NOT NULL -- i18n-ize
786 );
787
788 CREATE TABLE acq.invoice_payment_method (
789     code    TEXT    PRIMARY KEY,
790     name    TEXT    NOT NULL -- i18n-ize
791 );
792
793 CREATE TABLE acq.invoice (
794     id          SERIAL      PRIMARY KEY,
795     receiver    INT         NOT NULL REFERENCES actor.org_unit (id),
796     provider    INT         NOT NULL REFERENCES acq.provider (id),
797     shipper     INT         NOT NULL REFERENCES acq.provider (id),
798     recv_date   TIMESTAMPTZ NOT NULL DEFAULT NOW(),
799     recv_method TEXT        NOT NULL REFERENCES acq.invoice_method (code) DEFAULT 'EDI',
800     inv_type    TEXT,       -- A "type" field is desired, but no idea what goes here
801     inv_ident   TEXT        NOT NULL, -- vendor-supplied invoice id/number
802         payment_auth TEXT,
803         payment_method TEXT     REFERENCES acq.invoice_payment_method (code)
804                                 DEFERRABLE INITIALLY DEFERRED,
805         note        TEXT,
806     CONSTRAINT  inv_ident_once_per_provider UNIQUE(provider, inv_ident)
807 );
808
809 CREATE TABLE acq.invoice_entry (
810     id              SERIAL      PRIMARY KEY,
811     invoice         INT         NOT NULL REFERENCES acq.invoice (id) ON DELETE CASCADE,
812     purchase_order  INT         REFERENCES acq.purchase_order (id) ON UPDATE CASCADE ON DELETE SET NULL,
813     lineitem        INT         REFERENCES acq.lineitem (id) ON UPDATE CASCADE ON DELETE SET NULL,
814     inv_item_count  INT         NOT NULL, -- How many acqlids did they say they sent
815     phys_item_count INT, -- and how many did staff count
816     note            TEXT,
817     billed_per_item BOOL,
818     cost_billed     NUMERIC(8,2),
819     actual_cost     NUMERIC(8,2),
820         amount_paid     NUMERIC (8,2)
821 );
822
823 CREATE TABLE acq.invoice_item_type (
824     code    TEXT    PRIMARY KEY,
825     name    TEXT    NOT NULL,  -- i18n-ize
826         prorate BOOL    NOT NULL DEFAULT FALSE
827 );
828
829 CREATE TABLE acq.invoice_item ( -- for invoice-only debits: taxes/fees/non-bib items/etc
830     id              SERIAL      PRIMARY KEY,
831     invoice         INT         NOT NULL REFERENCES acq.invoice (id) ON UPDATE CASCADE ON DELETE CASCADE,
832     purchase_order  INT         REFERENCES acq.purchase_order (id) ON UPDATE CASCADE ON DELETE SET NULL,
833     fund_debit      INT         REFERENCES acq.fund_debit (id),
834     inv_item_type   TEXT        NOT NULL REFERENCES acq.invoice_item_type (code),
835     title           TEXT,
836     author          TEXT,
837     note            TEXT,
838     cost_billed     NUMERIC(8,2),
839     actual_cost     NUMERIC(8,2),
840         fund            INT         REFERENCES acq.fund (id)
841                                     DEFERRABLE INITIALLY DEFERRED,
842         amount_paid     NUMERIC (8,2)
843 );
844
845 -- Patron requests
846 CREATE TABLE acq.user_request_type (
847     id      SERIAL  PRIMARY KEY,
848     label   TEXT    NOT NULL UNIQUE -- i18n-ize
849 );
850
851 INSERT INTO acq.user_request_type (id,label) VALUES (1, oils_i18n_gettext('1', 'Books', 'aurt', 'label'));
852 INSERT INTO acq.user_request_type (id,label) VALUES (2, oils_i18n_gettext('2', 'Journal/Magazine & Newspaper Articles', 'aurt', 'label'));
853 INSERT INTO acq.user_request_type (id,label) VALUES (3, oils_i18n_gettext('3', 'Audiobooks', 'aurt', 'label'));
854 INSERT INTO acq.user_request_type (id,label) VALUES (4, oils_i18n_gettext('4', 'Music', 'aurt', 'label'));
855 INSERT INTO acq.user_request_type (id,label) VALUES (5, oils_i18n_gettext('5', 'DVDs', 'aurt', 'label'));
856
857 SELECT SETVAL('acq.user_request_type_id_seq'::TEXT, 6);
858
859 CREATE TABLE acq.user_request (
860     id                  SERIAL  PRIMARY KEY,
861     usr                 INT     NOT NULL REFERENCES actor.usr (id), -- requesting user
862     hold                BOOL    NOT NULL DEFAULT TRUE,
863
864     pickup_lib          INT     NOT NULL REFERENCES actor.org_unit (id), -- pickup lib
865     holdable_formats    TEXT,           -- nullable, for use in hold creation
866     phone_notify        TEXT,
867     email_notify        BOOL    NOT NULL DEFAULT TRUE,
868     lineitem            INT     REFERENCES acq.lineitem (id) ON DELETE CASCADE,
869     eg_bib              BIGINT  REFERENCES biblio.record_entry (id) ON DELETE CASCADE,
870     request_date        TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- when they requested it
871     need_before         TIMESTAMPTZ,    -- don't create holds after this
872     max_fee             TEXT,
873   
874     request_type        INT     NOT NULL REFERENCES acq.user_request_type (id),
875     isxn                TEXT,
876     title               TEXT,
877     volume              TEXT,
878     author              TEXT,
879     article_title       TEXT,
880     article_pages       TEXT,
881     publisher           TEXT,
882     location            TEXT,
883     pubdate             TEXT,
884     mentioned           TEXT,
885     other_info          TEXT,
886         cancel_reason       INT    REFERENCES acq.cancel_reason( id )
887                                    DEFERRABLE INITIALLY DEFERRED
888 );
889
890
891 -- Functions
892
893 CREATE TYPE acq.flat_lineitem_holding_subfield AS (lineitem int, holding int, subfield text, data text);
894 CREATE OR REPLACE FUNCTION acq.extract_holding_attr_table (lineitem int, tag text) RETURNS SETOF acq.flat_lineitem_holding_subfield AS $$
895 DECLARE
896     counter INT;
897     lida    acq.flat_lineitem_holding_subfield%ROWTYPE;
898 BEGIN
899
900     SELECT  COUNT(*) INTO counter
901       FROM  oils_xpath_table(
902                 'id',
903                 'marc',
904                 'acq.lineitem',
905                 '//*[@tag="' || tag || '"]',
906                 'id=' || lineitem
907             ) as t(i int,c text);
908
909     FOR i IN 1 .. counter LOOP
910         FOR lida IN
911             SELECT  * 
912               FROM  (   SELECT  id,i,t,v
913                           FROM  oils_xpath_table(
914                                     'id',
915                                     'marc',
916                                     'acq.lineitem',
917                                     '//*[@tag="' || tag || '"][position()=' || i || ']/*/@code|' ||
918                                         '//*[@tag="' || tag || '"][position()=' || i || ']/*[@code]',
919                                     'id=' || lineitem
920                                 ) as t(id int,t text,v text)
921                     )x
922         LOOP
923             RETURN NEXT lida;
924         END LOOP;
925     END LOOP;
926
927     RETURN;
928 END;
929 $$ LANGUAGE PLPGSQL;
930
931 CREATE TYPE acq.flat_lineitem_detail AS (lineitem int, holding int, attr text, data text);
932 CREATE OR REPLACE FUNCTION acq.extract_provider_holding_data ( lineitem_i int ) RETURNS SETOF acq.flat_lineitem_detail AS $$
933 DECLARE
934     prov_i  INT;
935     tag_t   TEXT;
936     lida    acq.flat_lineitem_detail%ROWTYPE;
937 BEGIN
938     SELECT provider INTO prov_i FROM acq.lineitem WHERE id = lineitem_i;
939     IF NOT FOUND THEN RETURN; END IF;
940
941     SELECT holding_tag INTO tag_t FROM acq.provider WHERE id = prov_i;
942     IF NOT FOUND OR tag_t IS NULL THEN RETURN; END IF;
943
944     FOR lida IN
945         SELECT  lineitem_i,
946                 h.holding,
947                 a.name,
948                 h.data
949           FROM  acq.extract_holding_attr_table( lineitem_i, tag_t ) h
950                 JOIN acq.provider_holding_subfield_map a USING (subfield)
951           WHERE a.provider = prov_i
952     LOOP
953         RETURN NEXT lida;
954     END LOOP;
955
956     RETURN;
957 END;
958 $$ LANGUAGE PLPGSQL;
959
960 -- select * from acq.extract_provider_holding_data(699);
961
962 CREATE OR REPLACE FUNCTION public.extract_acq_marc_field ( BIGINT, TEXT, TEXT) RETURNS TEXT AS $$
963         SELECT public.extract_marc_field('acq.lineitem', $1, $2, $3);
964 $$ LANGUAGE SQL;
965
966 /*
967 CREATE OR REPLACE FUNCTION public.extract_bib_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
968         SELECT public.extract_marc_field('biblio.record_entry', $1, $2);
969 $$ LANGUAGE SQL;
970
971 CREATE OR REPLACE FUNCTION public.extract_authority_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
972         SELECT public.extract_marc_field('authority.record_entry', $1, $2);
973 $$ LANGUAGE SQL;
974 */
975 -- For example:
976 -- INSERT INTO acq.lineitem_provider_attr_definition ( provider, code, description, xpath ) VALUES (1,'price','Price','//*[@tag="020" or @tag="022"]/*[@code="a"][1]');
977
978 /*
979 Suggested vendor fields:
980         vendor_price
981         vendor_currency
982         vendor_avail
983         vendor_po
984         vendor_identifier
985 */
986
987 CREATE OR REPLACE FUNCTION public.ingest_acq_marc ( ) RETURNS TRIGGER AS $function$
988 DECLARE
989         value           TEXT;
990         atype           TEXT;
991         prov            INT;
992         pos             INT;
993         adef            RECORD;
994         xpath_string    TEXT;
995 BEGIN
996         FOR adef IN SELECT *,tableoid FROM acq.lineitem_attr_definition LOOP
997
998                 SELECT relname::TEXT INTO atype FROM pg_class WHERE oid = adef.tableoid;
999
1000                 IF (atype NOT IN ('lineitem_usr_attr_definition','lineitem_local_attr_definition')) THEN
1001                         IF (atype = 'lineitem_provider_attr_definition') THEN
1002                                 SELECT provider INTO prov FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
1003                                 CONTINUE WHEN NEW.provider IS NULL OR prov <> NEW.provider;
1004                         END IF;
1005                         
1006                         IF (atype = 'lineitem_provider_attr_definition') THEN
1007                                 SELECT xpath INTO xpath_string FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
1008                         ELSIF (atype = 'lineitem_marc_attr_definition') THEN
1009                                 SELECT xpath INTO xpath_string FROM acq.lineitem_marc_attr_definition WHERE id = adef.id;
1010                         ELSIF (atype = 'lineitem_generated_attr_definition') THEN
1011                                 SELECT xpath INTO xpath_string FROM acq.lineitem_generated_attr_definition WHERE id = adef.id;
1012                         END IF;
1013
1014             xpath_string := REGEXP_REPLACE(xpath_string,$re$//?text\(\)$$re$,'');
1015
1016             pos := 1;
1017
1018             LOOP
1019                         SELECT extract_acq_marc_field(id, xpath_string || '[' || pos || ']', adef.remove) INTO value FROM acq.lineitem WHERE id = NEW.id;
1020
1021                         IF (value IS NOT NULL AND value <> '') THEN
1022                                 INSERT INTO acq.lineitem_attr (lineitem, definition, attr_type, attr_name, attr_value)
1023                                         VALUES (NEW.id, adef.id, atype, adef.code, value);
1024                 ELSE
1025                     EXIT;
1026                             END IF;
1027
1028                 pos := pos + 1;
1029             END LOOP;
1030
1031                 END IF;
1032
1033         END LOOP;
1034
1035         RETURN NULL;
1036 END;
1037 $function$ LANGUAGE PLPGSQL;
1038
1039 CREATE OR REPLACE FUNCTION public.cleanup_acq_marc ( ) RETURNS TRIGGER AS $$
1040 BEGIN
1041         IF TG_OP = 'UPDATE' THEN
1042                 DELETE FROM acq.lineitem_attr
1043                         WHERE lineitem = OLD.id AND attr_type IN ('lineitem_provider_attr_definition', 'lineitem_marc_attr_definition','lineitem_generated_attr_definition');
1044                 RETURN NEW;
1045         ELSE
1046                 DELETE FROM acq.lineitem_attr WHERE lineitem = OLD.id;
1047                 RETURN OLD;
1048         END IF;
1049 END;
1050 $$ LANGUAGE PLPGSQL;
1051
1052 CREATE TRIGGER cleanup_lineitem_trigger
1053         BEFORE UPDATE OR DELETE ON acq.lineitem
1054         FOR EACH ROW EXECUTE PROCEDURE public.cleanup_acq_marc();
1055
1056 CREATE TRIGGER ingest_lineitem_trigger
1057         AFTER INSERT OR UPDATE ON acq.lineitem
1058         FOR EACH ROW EXECUTE PROCEDURE public.ingest_acq_marc();
1059
1060 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( from_ex TEXT, to_ex TEXT ) RETURNS NUMERIC AS $$
1061 DECLARE
1062     rat NUMERIC;
1063 BEGIN
1064     IF from_ex = to_ex THEN
1065         RETURN 1.0;
1066     END IF;
1067
1068     SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = from_ex AND to_currency = to_ex;
1069
1070     IF FOUND THEN
1071         RETURN rat;
1072     ELSE
1073         SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = to_ex AND to_currency = from_ex;
1074         IF FOUND THEN
1075             RETURN 1.0/rat;
1076         END IF;
1077     END IF;
1078
1079     RETURN NULL;
1080
1081 END;
1082 $$ LANGUAGE PLPGSQL;
1083
1084 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( TEXT, TEXT, NUMERIC ) RETURNS NUMERIC AS $$
1085     SELECT $3 * acq.exchange_ratio($1, $2);
1086 $$ LANGUAGE SQL;
1087
1088 CREATE OR REPLACE FUNCTION acq.find_bad_fy()
1089 /*
1090         Examine the acq.fiscal_year table, comparing successive years.
1091         Report any inconsistencies, i.e. years that overlap, have gaps
1092     between them, or are out of sequence.
1093 */
1094 RETURNS SETOF RECORD AS $$
1095 DECLARE
1096         first_row  BOOLEAN;
1097         curr_year  RECORD;
1098         prev_year  RECORD;
1099         return_rec RECORD;
1100 BEGIN
1101         first_row := true;
1102         FOR curr_year in
1103                 SELECT
1104                         id,
1105                         calendar,
1106                         year,
1107                         year_begin,
1108                         year_end
1109                 FROM
1110                         acq.fiscal_year
1111                 ORDER BY
1112                         calendar,
1113                         year_begin
1114         LOOP
1115                 --
1116                 IF first_row THEN
1117                         first_row := FALSE;
1118                 ELSIF curr_year.calendar    = prev_year.calendar THEN
1119                         IF curr_year.year_begin > prev_year.year_end THEN
1120                                 -- This ugly kludge works around the fact that older
1121                                 -- versions of PostgreSQL don't support RETURN QUERY SELECT
1122                                 FOR return_rec IN SELECT
1123                                         prev_year.id,
1124                                         prev_year.year,
1125                                         'Gap between fiscal years'::TEXT
1126                                 LOOP
1127                                         RETURN NEXT return_rec;
1128                                 END LOOP;
1129                         ELSIF curr_year.year_begin < prev_year.year_end THEN
1130                                 FOR return_rec IN SELECT
1131                                         prev_year.id,
1132                                         prev_year.year,
1133                                         'Overlapping fiscal years'::TEXT
1134                                 LOOP
1135                                         RETURN NEXT return_rec;
1136                                 END LOOP;
1137                         ELSIF curr_year.year < prev_year.year THEN
1138                                 FOR return_rec IN SELECT
1139                                         prev_year.id,
1140                                         prev_year.year,
1141                                         'Fiscal years out of order'::TEXT
1142                                 LOOP
1143                                         RETURN NEXT return_rec;
1144                                 END LOOP;
1145                         END IF;
1146                 END IF;
1147                 --
1148                 prev_year := curr_year;
1149         END LOOP;
1150         --
1151         RETURN;
1152 END;
1153 $$ LANGUAGE plpgsql;
1154
1155 CREATE OR REPLACE FUNCTION acq.transfer_fund(
1156         old_fund   IN INT,
1157         old_amount IN NUMERIC,     -- in currency of old fund
1158         new_fund   IN INT,
1159         new_amount IN NUMERIC,     -- in currency of new fund
1160         user_id    IN INT,
1161         xfer_note  IN TEXT         -- to be recorded in acq.fund_transfer
1162         -- ,funding_source_in IN INT  -- if user wants to specify a funding source (see notes)
1163 ) RETURNS VOID AS $$
1164 /* -------------------------------------------------------------------------------
1165
1166 Function to transfer money from one fund to another.
1167
1168 A transfer is represented as a pair of entries in acq.fund_allocation, with a
1169 negative amount for the old (losing) fund and a positive amount for the new
1170 (gaining) fund.  In some cases there may be more than one such pair of entries
1171 in order to pull the money from different funding sources, or more specifically
1172 from different funding source credits.  For each such pair there is also an
1173 entry in acq.fund_transfer.
1174
1175 Since funding_source is a non-nullable column in acq.fund_allocation, we must
1176 choose a funding source for the transferred money to come from.  This choice
1177 must meet two constraints, so far as possible:
1178
1179 1. The amount transferred from a given funding source must not exceed the
1180 amount allocated to the old fund by the funding source.  To that end we
1181 compare the amount being transferred to the amount allocated.
1182
1183 2. We shouldn't transfer money that has already been spent or encumbered, as
1184 defined by the funding attribution process.  We attribute expenses to the
1185 oldest funding source credits first.  In order to avoid transferring that
1186 attributed money, we reverse the priority, transferring from the newest funding
1187 source credits first.  There can be no guarantee that this approach will
1188 avoid overcommitting a fund, but no other approach can do any better.
1189
1190 In this context the age of a funding source credit is defined by the
1191 deadline_date for credits with deadline_dates, and by the effective_date for
1192 credits without deadline_dates, with the proviso that credits with deadline_dates
1193 are all considered "older" than those without.
1194
1195 ----------
1196
1197 In the signature for this function, there is one last parameter commented out,
1198 named "funding_source_in".  Correspondingly, the WHERE clause for the query
1199 driving the main loop has an OR clause commented out, which references the
1200 funding_source_in parameter.
1201
1202 If these lines are uncommented, this function will allow the user optionally to
1203 restrict a fund transfer to a specified funding source.  If the source
1204 parameter is left NULL, then there will be no such restriction.
1205
1206 ------------------------------------------------------------------------------- */ 
1207 DECLARE
1208         same_currency      BOOLEAN;
1209         currency_ratio     NUMERIC;
1210         old_fund_currency  TEXT;
1211         old_remaining      NUMERIC;  -- in currency of old fund
1212         new_fund_currency  TEXT;
1213         new_fund_active    BOOLEAN;
1214         new_remaining      NUMERIC;  -- in currency of new fund
1215         curr_old_amt       NUMERIC;  -- in currency of old fund
1216         curr_new_amt       NUMERIC;  -- in currency of new fund
1217         source_addition    NUMERIC;  -- in currency of funding source
1218         source_deduction   NUMERIC;  -- in currency of funding source
1219         orig_allocated_amt NUMERIC;  -- in currency of funding source
1220         allocated_amt      NUMERIC;  -- in currency of fund
1221         source             RECORD;
1222 BEGIN
1223         --
1224         -- Sanity checks
1225         --
1226         IF old_fund IS NULL THEN
1227                 RAISE EXCEPTION 'acq.transfer_fund: old fund id is NULL';
1228         END IF;
1229         --
1230         IF old_amount IS NULL THEN
1231                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
1232         END IF;
1233         --
1234         -- The new fund and its amount must be both NULL or both not NULL.
1235         --
1236         IF new_fund IS NOT NULL AND new_amount IS NULL THEN
1237                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer to receiving fund is NULL';
1238         END IF;
1239         --
1240         IF new_fund IS NULL AND new_amount IS NOT NULL THEN
1241                 RAISE EXCEPTION 'acq.transfer_fund: receiving fund is NULL, its amount is not NULL';
1242         END IF;
1243         --
1244         IF user_id IS NULL THEN
1245                 RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
1246         END IF;
1247         --
1248         -- Initialize the amounts to be transferred, each denominated
1249         -- in the currency of its respective fund.  They will be
1250         -- reduced on each iteration of the loop.
1251         --
1252         old_remaining := old_amount;
1253         new_remaining := new_amount;
1254         --
1255         -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
1256         --      old_amount, old_fund, new_amount, new_fund;
1257         --
1258         -- Get the currency types of the old and new funds.
1259         --
1260         SELECT
1261                 currency_type
1262         INTO
1263                 old_fund_currency
1264         FROM
1265                 acq.fund
1266         WHERE
1267                 id = old_fund;
1268         --
1269         IF old_fund_currency IS NULL THEN
1270                 RAISE EXCEPTION 'acq.transfer_fund: old fund id % is not defined', old_fund;
1271         END IF;
1272         --
1273         IF new_fund IS NOT NULL THEN
1274                 SELECT
1275                         currency_type,
1276                         active
1277                 INTO
1278                         new_fund_currency,
1279                         new_fund_active
1280                 FROM
1281                         acq.fund
1282                 WHERE
1283                         id = new_fund;
1284                 --
1285                 IF new_fund_currency IS NULL THEN
1286                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is not defined', new_fund;
1287                 ELSIF NOT new_fund_active THEN
1288                         --
1289                         -- No point in putting money into a fund from whence you can't spend it
1290                         --
1291                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is inactive', new_fund;
1292                 END IF;
1293                 --
1294                 IF new_amount = old_amount THEN
1295                         same_currency := true;
1296                         currency_ratio := 1;
1297                 ELSE
1298                         --
1299                         -- We'll have to translate currency between funds.  We presume that
1300                         -- the calling code has already applied an appropriate exchange rate,
1301                         -- so we'll apply the same conversion to each sub-transfer.
1302                         --
1303                         same_currency := false;
1304                         currency_ratio := new_amount / old_amount;
1305                 END IF;
1306         END IF;
1307         --
1308         -- Identify the funding source(s) from which we want to transfer the money.
1309         -- The principle is that we want to transfer the newest money first, because
1310         -- we spend the oldest money first.  The priority for spending is defined
1311         -- by a sort of the view acq.ordered_funding_source_credit.
1312         --
1313         FOR source in
1314                 SELECT
1315                         ofsc.id,
1316                         ofsc.funding_source,
1317                         ofsc.amount,
1318                         ofsc.amount * acq.exchange_ratio( fs.currency_type, old_fund_currency )
1319                                 AS converted_amt,
1320                         fs.currency_type
1321                 FROM
1322                         acq.ordered_funding_source_credit AS ofsc,
1323                         acq.funding_source fs
1324                 WHERE
1325                         ofsc.funding_source = fs.id
1326                         and ofsc.funding_source IN
1327                         (
1328                                 SELECT funding_source
1329                                 FROM acq.fund_allocation
1330                                 WHERE fund = old_fund
1331                         )
1332                         -- and
1333                         -- (
1334                         --      ofsc.funding_source = funding_source_in
1335                         --      OR funding_source_in IS NULL
1336                         -- )
1337                 ORDER BY
1338                         ofsc.sort_priority desc,
1339                         ofsc.sort_date desc,
1340                         ofsc.id desc
1341         LOOP
1342                 --
1343                 -- Determine how much money the old fund got from this funding source,
1344                 -- denominated in the currency types of the source and of the fund.
1345                 -- This result may reflect transfers from previous iterations.
1346                 --
1347                 SELECT
1348                         COALESCE( sum( amount ), 0 ),
1349                         COALESCE( sum( amount )
1350                                 * acq.exchange_ratio( source.currency_type, old_fund_currency ), 0 )
1351                 INTO
1352                         orig_allocated_amt,     -- in currency of the source
1353                         allocated_amt           -- in currency of the old fund
1354                 FROM
1355                         acq.fund_allocation
1356                 WHERE
1357                         fund = old_fund
1358                         and funding_source = source.funding_source;
1359                 --      
1360                 -- Determine how much to transfer from this credit, in the currency
1361                 -- of the fund.   Begin with the amount remaining to be attributed:
1362                 --
1363                 curr_old_amt := old_remaining;
1364                 --
1365                 -- Can't attribute more than was allocated from the fund:
1366                 --
1367                 IF curr_old_amt > allocated_amt THEN
1368                         curr_old_amt := allocated_amt;
1369                 END IF;
1370                 --
1371                 -- Can't attribute more than the amount of the current credit:
1372                 --
1373                 IF curr_old_amt > source.converted_amt THEN
1374                         curr_old_amt := source.converted_amt;
1375                 END IF;
1376                 --
1377                 curr_old_amt := trunc( curr_old_amt, 2 );
1378                 --
1379                 old_remaining := old_remaining - curr_old_amt;
1380                 --
1381                 -- Determine the amount to be deducted, if any,
1382                 -- from the old allocation.
1383                 --
1384                 IF old_remaining > 0 THEN
1385                         --
1386                         -- In this case we're using the whole allocation, so use that
1387                         -- amount directly instead of applying a currency translation
1388                         -- and thereby inviting round-off errors.
1389                         --
1390                         source_deduction := - orig_allocated_amt;
1391                 ELSE 
1392                         source_deduction := trunc(
1393                                 ( - curr_old_amt ) *
1394                                         acq.exchange_ratio( old_fund_currency, source.currency_type ),
1395                                 2 );
1396                 END IF;
1397                 --
1398                 IF source_deduction <> 0 THEN
1399                         --
1400                         -- Insert negative allocation for old fund in fund_allocation,
1401                         -- converted into the currency of the funding source
1402                         --
1403                         INSERT INTO acq.fund_allocation (
1404                                 funding_source,
1405                                 fund,
1406                                 amount,
1407                                 allocator,
1408                                 note
1409                         ) VALUES (
1410                                 source.funding_source,
1411                                 old_fund,
1412                                 source_deduction,
1413                                 user_id,
1414                                 'Transfer to fund ' || new_fund
1415                         );
1416                 END IF;
1417                 --
1418                 IF new_fund IS NOT NULL THEN
1419                         --
1420                         -- Determine how much to add to the new fund, in
1421                         -- its currency, and how much remains to be added:
1422                         --
1423                         IF same_currency THEN
1424                                 curr_new_amt := curr_old_amt;
1425                         ELSE
1426                                 IF old_remaining = 0 THEN
1427                                         --
1428                                         -- This is the last iteration, so nothing should be left
1429                                         --
1430                                         curr_new_amt := new_remaining;
1431                                         new_remaining := 0;
1432                                 ELSE
1433                                         curr_new_amt := trunc( curr_old_amt * currency_ratio, 2 );
1434                                         new_remaining := new_remaining - curr_new_amt;
1435                                 END IF;
1436                         END IF;
1437                         --
1438                         -- Determine how much to add, if any,
1439                         -- to the new fund's allocation.
1440                         --
1441                         IF old_remaining > 0 THEN
1442                                 --
1443                                 -- In this case we're using the whole allocation, so use that amount
1444                                 -- amount directly instead of applying a currency translation and
1445                                 -- thereby inviting round-off errors.
1446                                 --
1447                                 source_addition := orig_allocated_amt;
1448                         ELSIF source.currency_type = old_fund_currency THEN
1449                                 --
1450                                 -- In this case we don't need a round trip currency translation,
1451                                 -- thereby inviting round-off errors:
1452                                 --
1453                                 source_addition := curr_old_amt;
1454                         ELSE 
1455                                 source_addition := trunc(
1456                                         curr_new_amt *
1457                                                 acq.exchange_ratio( new_fund_currency, source.currency_type ),
1458                                         2 );
1459                         END IF;
1460                         --
1461                         IF source_addition <> 0 THEN
1462                                 --
1463                                 -- Insert positive allocation for new fund in fund_allocation,
1464                                 -- converted to the currency of the founding source
1465                                 --
1466                                 INSERT INTO acq.fund_allocation (
1467                                         funding_source,
1468                                         fund,
1469                                         amount,
1470                                         allocator,
1471                                         note
1472                                 ) VALUES (
1473                                         source.funding_source,
1474                                         new_fund,
1475                                         source_addition,
1476                                         user_id,
1477                                         'Transfer from fund ' || old_fund
1478                                 );
1479                         END IF;
1480                 END IF;
1481                 --
1482                 IF trunc( curr_old_amt, 2 ) <> 0
1483                 OR trunc( curr_new_amt, 2 ) <> 0 THEN
1484                         --
1485                         -- Insert row in fund_transfer, using amounts in the currency of the funds
1486                         --
1487                         INSERT INTO acq.fund_transfer (
1488                                 src_fund,
1489                                 src_amount,
1490                                 dest_fund,
1491                                 dest_amount,
1492                                 transfer_user,
1493                                 note,
1494                                 funding_source_credit
1495                         ) VALUES (
1496                                 old_fund,
1497                                 trunc( curr_old_amt, 2 ),
1498                                 new_fund,
1499                                 trunc( curr_new_amt, 2 ),
1500                                 user_id,
1501                                 xfer_note,
1502                                 source.id
1503                         );
1504                 END IF;
1505                 --
1506                 if old_remaining <= 0 THEN
1507                         EXIT;                   -- Nothing more to be transferred
1508                 END IF;
1509         END LOOP;
1510 END;
1511 $$ LANGUAGE plpgsql;
1512
1513 CREATE OR REPLACE FUNCTION acq.attribute_debits() RETURNS VOID AS $$
1514 /*
1515 Function to attribute expenditures and encumbrances to funding source credits,
1516 and thereby to funding sources.
1517
1518 Read the debits in chonological order, attributing each one to one or
1519 more funding source credits.  Constraints:
1520
1521 1. Don't attribute more to a credit than the amount of the credit.
1522
1523 2. For a given fund, don't attribute more to a funding source than the
1524 source has allocated to that fund.
1525
1526 3. Attribute debits to credits with deadlines before attributing them to
1527 credits without deadlines.  Otherwise attribute to the earliest credits
1528 first, based on the deadline date when present, or on the effective date
1529 when there is no deadline.  Use funding_source_credit.id as a tie-breaker.
1530 This ordering is defined by an ORDER BY clause on the view
1531 acq.ordered_funding_source_credit.
1532
1533 Start by truncating the table acq.debit_attribution.  Then insert a row
1534 into that table for each attribution.  If a debit cannot be fully
1535 attributed, insert a row for the unattributable balance, with the 
1536 funding_source_credit and credit_amount columns NULL.
1537 */
1538 DECLARE
1539         curr_fund_source_bal RECORD;
1540         seqno                INT;     -- sequence num for credits applicable to a fund
1541         fund_credit          RECORD;  -- current row in temp t_fund_credit table
1542         fc                   RECORD;  -- used for loading t_fund_credit table
1543         sc                   RECORD;  -- used for loading t_fund_credit table
1544         --
1545         -- Used exclusively in the main loop:
1546         --
1547         deb                 RECORD;   -- current row from acq.fund_debit table
1548         curr_credit_bal     RECORD;   -- current row from temp t_credit table
1549         debit_balance       NUMERIC;  -- amount left to attribute for current debit
1550         conv_debit_balance  NUMERIC;  -- debit balance in currency of the fund
1551         attr_amount         NUMERIC;  -- amount being attributed, in currency of debit
1552         conv_attr_amount    NUMERIC;  -- amount being attributed, in currency of source
1553         conv_cred_balance   NUMERIC;  -- credit_balance in the currency of the fund
1554         conv_alloc_balance  NUMERIC;  -- allocated balance in the currency of the fund
1555         attrib_count        INT;      -- populates id of acq.debit_attribution
1556 BEGIN
1557         --
1558         -- Load a temporary table.  For each combination of fund and funding source,
1559         -- load an entry with the total amount allocated to that fund by that source.
1560         -- This sum may reflect transfers as well as original allocations.  We will
1561         -- reduce this balance whenever we attribute debits to it.
1562         --
1563         CREATE TEMP TABLE t_fund_source_bal
1564         ON COMMIT DROP AS
1565                 SELECT
1566                         fund AS fund,
1567                         funding_source AS source,
1568                         sum( amount ) AS balance
1569                 FROM
1570                         acq.fund_allocation
1571                 GROUP BY
1572                         fund,
1573                         funding_source
1574                 HAVING
1575                         sum( amount ) > 0;
1576         --
1577         CREATE INDEX t_fund_source_bal_idx
1578                 ON t_fund_source_bal( fund, source );
1579         -------------------------------------------------------------------------------
1580         --
1581         -- Load another temporary table.  For each fund, load zero or more
1582         -- funding source credits from which that fund can get money.
1583         --
1584         CREATE TEMP TABLE t_fund_credit (
1585                 fund        INT,
1586                 seq         INT,
1587                 credit      INT
1588         ) ON COMMIT DROP;
1589         --
1590         FOR fc IN
1591                 SELECT DISTINCT fund
1592                 FROM acq.fund_allocation
1593                 ORDER BY fund
1594         LOOP                  -- Loop over the funds
1595                 seqno := 1;
1596                 FOR sc IN
1597                         SELECT
1598                                 ofsc.id
1599                         FROM
1600                                 acq.ordered_funding_source_credit AS ofsc
1601                         WHERE
1602                                 ofsc.funding_source IN
1603                                 (
1604                                         SELECT funding_source
1605                                         FROM acq.fund_allocation
1606                                         WHERE fund = fc.fund
1607                                 )
1608                 ORDER BY
1609                     ofsc.sort_priority,
1610                     ofsc.sort_date,
1611                     ofsc.id
1612                 LOOP                        -- Add each credit to the list
1613                         INSERT INTO t_fund_credit (
1614                                 fund,
1615                                 seq,
1616                                 credit
1617                         ) VALUES (
1618                                 fc.fund,
1619                                 seqno,
1620                                 sc.id
1621                         );
1622                         --RAISE NOTICE 'Fund % credit %', fc.fund, sc.id;
1623                         seqno := seqno + 1;
1624                 END LOOP;     -- Loop over credits for a given fund
1625         END LOOP;         -- Loop over funds
1626         --
1627         CREATE INDEX t_fund_credit_idx
1628                 ON t_fund_credit( fund, seq );
1629         -------------------------------------------------------------------------------
1630         --
1631         -- Load yet another temporary table.  This one is a list of funding source
1632         -- credits, with their balances.  We shall reduce those balances as we
1633         -- attribute debits to them.
1634         --
1635         CREATE TEMP TABLE t_credit
1636         ON COMMIT DROP AS
1637         SELECT
1638             fsc.id AS credit,
1639             fsc.funding_source AS source,
1640             fsc.amount AS balance,
1641             fs.currency_type AS currency_type
1642         FROM
1643             acq.funding_source_credit AS fsc,
1644             acq.funding_source fs
1645         WHERE
1646             fsc.funding_source = fs.id
1647                         AND fsc.amount > 0;
1648         --
1649         CREATE INDEX t_credit_idx
1650                 ON t_credit( credit );
1651         --
1652         -------------------------------------------------------------------------------
1653         --
1654         -- Now that we have loaded the lookup tables: loop through the debits,
1655         -- attributing each one to one or more funding source credits.
1656         -- 
1657         truncate table acq.debit_attribution;
1658         --
1659         attrib_count := 0;
1660         FOR deb in
1661                 SELECT
1662                         fd.id,
1663                         fd.fund,
1664                         fd.amount,
1665                         f.currency_type,
1666                         fd.encumbrance
1667                 FROM
1668                         acq.fund_debit fd,
1669                         acq.fund f
1670                 WHERE
1671                         fd.fund = f.id
1672                 ORDER BY
1673                         fd.id
1674         LOOP
1675                 --RAISE NOTICE 'Debit %, fund %', deb.id, deb.fund;
1676                 --
1677                 debit_balance := deb.amount;
1678                 --
1679                 -- Loop over the funding source credits that are eligible
1680                 -- to pay for this debit
1681                 --
1682                 FOR fund_credit IN
1683                         SELECT
1684                                 credit
1685                         FROM
1686                                 t_fund_credit
1687                         WHERE
1688                                 fund = deb.fund
1689                         ORDER BY
1690                                 seq
1691                 LOOP
1692                         --RAISE NOTICE '   Examining credit %', fund_credit.credit;
1693                         --
1694                         -- Look up the balance for this credit.  If it's zero, then
1695                         -- it's not useful, so treat it as if you didn't find it.
1696                         -- (Actually there shouldn't be any zero balances in the table,
1697                         -- but we check just to make sure.)
1698                         --
1699                         SELECT *
1700                         INTO curr_credit_bal
1701                         FROM t_credit
1702                         WHERE
1703                                 credit = fund_credit.credit
1704                                 AND balance > 0;
1705                         --
1706                         IF curr_credit_bal IS NULL THEN
1707                                 --
1708                                 -- This credit is exhausted; try the next one.
1709                                 --
1710                                 CONTINUE;
1711                         END IF;
1712                         --
1713                         --
1714                         -- At this point we have an applicable credit with some money left.
1715                         -- Now see if the relevant funding_source has any money left.
1716                         --
1717                         -- Look up the balance of the allocation for this combination of
1718                         -- fund and source.  If you find such an entry, but it has a zero
1719                         -- balance, then it's not useful, so treat it as unfound.
1720                         -- (Actually there shouldn't be any zero balances in the table,
1721                         -- but we check just to make sure.)
1722                         --
1723                         SELECT *
1724                         INTO curr_fund_source_bal
1725                         FROM t_fund_source_bal
1726                         WHERE
1727                                 fund = deb.fund
1728                                 AND source = curr_credit_bal.source
1729                                 AND balance > 0;
1730                         --
1731                         IF curr_fund_source_bal IS NULL THEN
1732                                 --
1733                                 -- This fund/source doesn't exist or is already exhausted,
1734                                 -- so we can't use this credit.  Go on to the next one.
1735                                 --
1736                                 CONTINUE;
1737                         END IF;
1738                         --
1739                         -- Convert the available balances to the currency of the fund
1740                         --
1741                         conv_alloc_balance := curr_fund_source_bal.balance * acq.exchange_ratio(
1742                                 curr_credit_bal.currency_type, deb.currency_type );
1743                         conv_cred_balance := curr_credit_bal.balance * acq.exchange_ratio(
1744                                 curr_credit_bal.currency_type, deb.currency_type );
1745                         --
1746                         -- Determine how much we can attribute to this credit: the minimum
1747                         -- of the debit amount, the fund/source balance, and the
1748                         -- credit balance
1749                         --
1750                         --RAISE NOTICE '   deb bal %', debit_balance;
1751                         --RAISE NOTICE '      source % balance %', curr_credit_bal.source, conv_alloc_balance;
1752                         --RAISE NOTICE '      credit % balance %', curr_credit_bal.credit, conv_cred_balance;
1753                         --
1754                         conv_attr_amount := NULL;
1755                         attr_amount := debit_balance;
1756                         --
1757                         IF attr_amount > conv_alloc_balance THEN
1758                                 attr_amount := conv_alloc_balance;
1759                                 conv_attr_amount := curr_fund_source_bal.balance;
1760                         END IF;
1761                         IF attr_amount > conv_cred_balance THEN
1762                                 attr_amount := conv_cred_balance;
1763                                 conv_attr_amount := curr_credit_bal.balance;
1764                         END IF;
1765                         --
1766                         -- If we're attributing all of one of the balances, then that's how
1767                         -- much we will deduct from the balances, and we already captured
1768                         -- that amount above.  Otherwise we must convert the amount of the
1769                         -- attribution from the currency of the fund back to the currency of
1770                         -- the funding source.
1771                         --
1772                         IF conv_attr_amount IS NULL THEN
1773                                 conv_attr_amount := attr_amount * acq.exchange_ratio(
1774                                         deb.currency_type, curr_credit_bal.currency_type );
1775                         END IF;
1776                         --
1777                         -- Insert a row to record the attribution
1778                         --
1779                         attrib_count := attrib_count + 1;
1780                         INSERT INTO acq.debit_attribution (
1781                                 id,
1782                                 fund_debit,
1783                                 debit_amount,
1784                                 funding_source_credit,
1785                                 credit_amount
1786                         ) VALUES (
1787                                 attrib_count,
1788                                 deb.id,
1789                                 attr_amount,
1790                                 curr_credit_bal.credit,
1791                                 conv_attr_amount
1792                         );
1793                         --
1794                         -- Subtract the attributed amount from the various balances
1795                         --
1796                         debit_balance := debit_balance - attr_amount;
1797                         curr_fund_source_bal.balance := curr_fund_source_bal.balance - conv_attr_amount;
1798                         --
1799                         IF curr_fund_source_bal.balance <= 0 THEN
1800                                 --
1801                                 -- This allocation is exhausted.  Delete it so
1802                                 -- that we don't waste time looking at it again.
1803                                 --
1804                                 DELETE FROM t_fund_source_bal
1805                                 WHERE
1806                                         fund = curr_fund_source_bal.fund
1807                                         AND source = curr_fund_source_bal.source;
1808                         ELSE
1809                                 UPDATE t_fund_source_bal
1810                                 SET balance = balance - conv_attr_amount
1811                                 WHERE
1812                                         fund = curr_fund_source_bal.fund
1813                                         AND source = curr_fund_source_bal.source;
1814                         END IF;
1815                         --
1816                         IF curr_credit_bal.balance <= 0 THEN
1817                                 --
1818                                 -- This funding source credit is exhausted.  Delete it
1819                                 -- so that we don't waste time looking at it again.
1820                                 --
1821                                 --DELETE FROM t_credit
1822                                 --WHERE
1823                                 --      credit = curr_credit_bal.credit;
1824                                 --
1825                                 DELETE FROM t_fund_credit
1826                                 WHERE
1827                                         credit = curr_credit_bal.credit;
1828                         ELSE
1829                                 UPDATE t_credit
1830                                 SET balance = curr_credit_bal.balance
1831                                 WHERE
1832                                         credit = curr_credit_bal.credit;
1833                         END IF;
1834                         --
1835                         -- Are we done with this debit yet?
1836                         --
1837                         IF debit_balance <= 0 THEN
1838                                 EXIT;       -- We've fully attributed this debit; stop looking at credits.
1839                         END IF;
1840                 END LOOP;       -- End loop over credits
1841                 --
1842                 IF debit_balance <> 0 THEN
1843                         --
1844                         -- We weren't able to attribute this debit, or at least not
1845                         -- all of it.  Insert a row for the unattributed balance.
1846                         --
1847                         attrib_count := attrib_count + 1;
1848                         INSERT INTO acq.debit_attribution (
1849                                 id,
1850                                 fund_debit,
1851                                 debit_amount,
1852                                 funding_source_credit,
1853                                 credit_amount
1854                         ) VALUES (
1855                                 attrib_count,
1856                                 deb.id,
1857                                 debit_balance,
1858                                 NULL,
1859                                 NULL
1860                         );
1861                 END IF;
1862         END LOOP;   -- End of loop over debits
1863 END;
1864 $$ LANGUAGE 'plpgsql';
1865
1866 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_unit(
1867         old_year INTEGER,
1868         user_id INTEGER,
1869         org_unit_id INTEGER
1870 ) RETURNS VOID AS $$
1871 DECLARE
1872 --
1873 new_id      INT;
1874 old_fund    RECORD;
1875 org_found   BOOLEAN;
1876 --
1877 BEGIN
1878         --
1879         -- Sanity checks
1880         --
1881         IF old_year IS NULL THEN
1882                 RAISE EXCEPTION 'Input year argument is NULL';
1883         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1884                 RAISE EXCEPTION 'Input year is out of range';
1885         END IF;
1886         --
1887         IF user_id IS NULL THEN
1888                 RAISE EXCEPTION 'Input user id argument is NULL';
1889         END IF;
1890         --
1891         IF org_unit_id IS NULL THEN
1892                 RAISE EXCEPTION 'Org unit id argument is NULL';
1893         ELSE
1894                 SELECT TRUE INTO org_found
1895                 FROM actor.org_unit
1896                 WHERE id = org_unit_id;
1897                 --
1898                 IF org_found IS NULL THEN
1899                         RAISE EXCEPTION 'Org unit id is invalid';
1900                 END IF;
1901         END IF;
1902         --
1903         -- Loop over the applicable funds
1904         --
1905         FOR old_fund in SELECT * FROM acq.fund
1906         WHERE
1907                 year = old_year
1908                 AND propagate
1909                 AND org = org_unit_id
1910         LOOP
1911                 BEGIN
1912                         INSERT INTO acq.fund (
1913                                 org,
1914                                 name,
1915                                 year,
1916                                 currency_type,
1917                                 code,
1918                                 rollover,
1919                                 propagate,
1920                                 balance_warning_percent,
1921                                 balance_stop_percent
1922                         ) VALUES (
1923                                 old_fund.org,
1924                                 old_fund.name,
1925                                 old_year + 1,
1926                                 old_fund.currency_type,
1927                                 old_fund.code,
1928                                 old_fund.rollover,
1929                                 true,
1930                                 old_fund.balance_warning_percent,
1931                                 old_fund.balance_stop_percent
1932                         )
1933                         RETURNING id INTO new_id;
1934                 EXCEPTION
1935                         WHEN unique_violation THEN
1936                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
1937                                 CONTINUE;
1938                 END;
1939                 --RAISE NOTICE 'Propagating fund % to fund %',
1940                 --      old_fund.code, new_id;
1941         END LOOP;
1942 END;
1943 $$ LANGUAGE plpgsql;
1944
1945 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_tree(
1946         old_year INTEGER,
1947         user_id INTEGER,
1948         org_unit_id INTEGER
1949 ) RETURNS VOID AS $$
1950 DECLARE
1951 --
1952 new_id      INT;
1953 old_fund    RECORD;
1954 org_found   BOOLEAN;
1955 --
1956 BEGIN
1957         --
1958         -- Sanity checks
1959         --
1960         IF old_year IS NULL THEN
1961                 RAISE EXCEPTION 'Input year argument is NULL';
1962         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1963                 RAISE EXCEPTION 'Input year is out of range';
1964         END IF;
1965         --
1966         IF user_id IS NULL THEN
1967                 RAISE EXCEPTION 'Input user id argument is NULL';
1968         END IF;
1969         --
1970         IF org_unit_id IS NULL THEN
1971                 RAISE EXCEPTION 'Org unit id argument is NULL';
1972         ELSE
1973                 SELECT TRUE INTO org_found
1974                 FROM actor.org_unit
1975                 WHERE id = org_unit_id;
1976                 --
1977                 IF org_found IS NULL THEN
1978                         RAISE EXCEPTION 'Org unit id is invalid';
1979                 END IF;
1980         END IF;
1981         --
1982         -- Loop over the applicable funds
1983         --
1984         FOR old_fund in SELECT * FROM acq.fund
1985         WHERE
1986                 year = old_year
1987                 AND propagate
1988                 AND org in (
1989                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
1990                 )
1991         LOOP
1992                 BEGIN
1993                         INSERT INTO acq.fund (
1994                                 org,
1995                                 name,
1996                                 year,
1997                                 currency_type,
1998                                 code,
1999                                 rollover,
2000                                 propagate,
2001                                 balance_warning_percent,
2002                                 balance_stop_percent
2003                         ) VALUES (
2004                                 old_fund.org,
2005                                 old_fund.name,
2006                                 old_year + 1,
2007                                 old_fund.currency_type,
2008                                 old_fund.code,
2009                                 old_fund.rollover,
2010                                 true,
2011                                 old_fund.balance_warning_percent,
2012                                 old_fund.balance_stop_percent
2013                         )
2014                         RETURNING id INTO new_id;
2015                 EXCEPTION
2016                         WHEN unique_violation THEN
2017                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
2018                                 CONTINUE;
2019                 END;
2020                 --RAISE NOTICE 'Propagating fund % to fund %',
2021                 --      old_fund.code, new_id;
2022         END LOOP;
2023 END;
2024 $$ LANGUAGE plpgsql;
2025
2026 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_unit(
2027         old_year INTEGER,
2028         user_id INTEGER,
2029         org_unit_id INTEGER
2030 ) RETURNS VOID AS $$
2031 DECLARE
2032 --
2033 new_fund    INT;
2034 new_year    INT := old_year + 1;
2035 org_found   BOOL;
2036 xfer_amount NUMERIC;
2037 roll_fund   RECORD;
2038 deb         RECORD;
2039 detail      RECORD;
2040 --
2041 BEGIN
2042         --
2043         -- Sanity checks
2044         --
2045         IF old_year IS NULL THEN
2046                 RAISE EXCEPTION 'Input year argument is NULL';
2047     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
2048         RAISE EXCEPTION 'Input year is out of range';
2049         END IF;
2050         --
2051         IF user_id IS NULL THEN
2052                 RAISE EXCEPTION 'Input user id argument is NULL';
2053         END IF;
2054         --
2055         IF org_unit_id IS NULL THEN
2056                 RAISE EXCEPTION 'Org unit id argument is NULL';
2057         ELSE
2058                 --
2059                 -- Validate the org unit
2060                 --
2061                 SELECT TRUE
2062                 INTO org_found
2063                 FROM actor.org_unit
2064                 WHERE id = org_unit_id;
2065                 --
2066                 IF org_found IS NULL THEN
2067                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
2068                 END IF;
2069         END IF;
2070         --
2071         -- Loop over the propagable funds to identify the details
2072         -- from the old fund plus the id of the new one, if it exists.
2073         --
2074         FOR roll_fund in
2075         SELECT
2076             oldf.id AS old_fund,
2077             oldf.org,
2078             oldf.name,
2079             oldf.currency_type,
2080             oldf.code,
2081                 oldf.rollover,
2082             newf.id AS new_fund_id
2083         FROM
2084         acq.fund AS oldf
2085         LEFT JOIN acq.fund AS newf
2086                 ON ( oldf.code = newf.code )
2087         WHERE
2088                     oldf.org = org_unit_id
2089                 and oldf.year = old_year
2090                 and oldf.propagate
2091         and newf.year = new_year
2092         LOOP
2093                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
2094                 --
2095                 IF roll_fund.new_fund_id IS NULL THEN
2096                         --
2097                         -- The old fund hasn't been propagated yet.  Propagate it now.
2098                         --
2099                         INSERT INTO acq.fund (
2100                                 org,
2101                                 name,
2102                                 year,
2103                                 currency_type,
2104                                 code,
2105                                 rollover,
2106                                 propagate,
2107                                 balance_warning_percent,
2108                                 balance_stop_percent
2109                         ) VALUES (
2110                                 roll_fund.org,
2111                                 roll_fund.name,
2112                                 new_year,
2113                                 roll_fund.currency_type,
2114                                 roll_fund.code,
2115                                 true,
2116                                 true,
2117                                 roll_fund.balance_warning_percent,
2118                                 roll_fund.balance_stop_percent
2119                         )
2120                         RETURNING id INTO new_fund;
2121                 ELSE
2122                         new_fund = roll_fund.new_fund_id;
2123                 END IF;
2124                 --
2125                 -- Determine the amount to transfer
2126                 --
2127                 SELECT amount
2128                 INTO xfer_amount
2129                 FROM acq.fund_spent_balance
2130                 WHERE fund = roll_fund.old_fund;
2131                 --
2132                 IF xfer_amount <> 0 THEN
2133                         IF roll_fund.rollover THEN
2134                                 --
2135                                 -- Transfer balance from old fund to new
2136                                 --
2137                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
2138                                 --
2139                                 PERFORM acq.transfer_fund(
2140                                         roll_fund.old_fund,
2141                                         xfer_amount,
2142                                         new_fund,
2143                                         xfer_amount,
2144                                         user_id,
2145                                         'Rollover'
2146                                 );
2147                         ELSE
2148                                 --
2149                                 -- Transfer balance from old fund to the void
2150                                 --
2151                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
2152                                 --
2153                                 PERFORM acq.transfer_fund(
2154                                         roll_fund.old_fund,
2155                                         xfer_amount,
2156                                         NULL,
2157                                         NULL,
2158                                         user_id,
2159                                         'Rollover'
2160                                 );
2161                         END IF;
2162                 END IF;
2163                 --
2164                 IF roll_fund.rollover THEN
2165                         --
2166                         -- Move any lineitems from the old fund to the new one
2167                         -- where the associated debit is an encumbrance.
2168                         --
2169                         -- Any other tables tying expenditure details to funds should
2170                         -- receive similar treatment.  At this writing there are none.
2171                         --
2172                         UPDATE acq.lineitem_detail
2173                         SET fund = new_fund
2174                         WHERE
2175                         fund = roll_fund.old_fund -- this condition may be redundant
2176                         AND fund_debit in
2177                         (
2178                                 SELECT id
2179                                 FROM acq.fund_debit
2180                                 WHERE
2181                                 fund = roll_fund.old_fund
2182                                 AND encumbrance
2183                         );
2184                         --
2185                         -- Move encumbrance debits from the old fund to the new fund
2186                         --
2187                         UPDATE acq.fund_debit
2188                         SET fund = new_fund
2189                         wHERE
2190                                 fund = roll_fund.old_fund
2191                                 AND encumbrance;
2192                 END IF;
2193                 --
2194                 -- Mark old fund as inactive, now that we've closed it
2195                 --
2196                 UPDATE acq.fund
2197                 SET active = FALSE
2198                 WHERE id = roll_fund.old_fund;
2199         END LOOP;
2200 END;
2201 $$ LANGUAGE plpgsql;
2202
2203 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_tree(
2204         old_year INTEGER,
2205         user_id INTEGER,
2206         org_unit_id INTEGER
2207 ) RETURNS VOID AS $$
2208 DECLARE
2209 --
2210 new_fund    INT;
2211 new_year    INT := old_year + 1;
2212 org_found   BOOL;
2213 xfer_amount NUMERIC;
2214 roll_fund   RECORD;
2215 deb         RECORD;
2216 detail      RECORD;
2217 --
2218 BEGIN
2219         --
2220         -- Sanity checks
2221         --
2222         IF old_year IS NULL THEN
2223                 RAISE EXCEPTION 'Input year argument is NULL';
2224     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
2225         RAISE EXCEPTION 'Input year is out of range';
2226         END IF;
2227         --
2228         IF user_id IS NULL THEN
2229                 RAISE EXCEPTION 'Input user id argument is NULL';
2230         END IF;
2231         --
2232         IF org_unit_id IS NULL THEN
2233                 RAISE EXCEPTION 'Org unit id argument is NULL';
2234         ELSE
2235                 --
2236                 -- Validate the org unit
2237                 --
2238                 SELECT TRUE
2239                 INTO org_found
2240                 FROM actor.org_unit
2241                 WHERE id = org_unit_id;
2242                 --
2243                 IF org_found IS NULL THEN
2244                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
2245                 END IF;
2246         END IF;
2247         --
2248         -- Loop over the propagable funds to identify the details
2249         -- from the old fund plus the id of the new one, if it exists.
2250         --
2251         FOR roll_fund in
2252         SELECT
2253             oldf.id AS old_fund,
2254             oldf.org,
2255             oldf.name,
2256             oldf.currency_type,
2257             oldf.code,
2258                 oldf.rollover,
2259             newf.id AS new_fund_id
2260         FROM
2261         acq.fund AS oldf
2262         LEFT JOIN acq.fund AS newf
2263                 ON ( oldf.code = newf.code )
2264         WHERE
2265                     oldf.year = old_year
2266                 AND oldf.propagate
2267         AND newf.year = new_year
2268                 AND oldf.org in (
2269                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
2270                 )
2271         LOOP
2272                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
2273                 --
2274                 IF roll_fund.new_fund_id IS NULL THEN
2275                         --
2276                         -- The old fund hasn't been propagated yet.  Propagate it now.
2277                         --
2278                         INSERT INTO acq.fund (
2279                                 org,
2280                                 name,
2281                                 year,
2282                                 currency_type,
2283                                 code,
2284                                 rollover,
2285                                 propagate,
2286                                 balance_warning_percent,
2287                                 balance_stop_percent
2288                         ) VALUES (
2289                                 roll_fund.org,
2290                                 roll_fund.name,
2291                                 new_year,
2292                                 roll_fund.currency_type,
2293                                 roll_fund.code,
2294                                 true,
2295                                 true,
2296                                 roll_fund.balance_warning_percent,
2297                                 roll_fund.balance_stop_percent
2298                         )
2299                         RETURNING id INTO new_fund;
2300                 ELSE
2301                         new_fund = roll_fund.new_fund_id;
2302                 END IF;
2303                 --
2304                 -- Determine the amount to transfer
2305                 --
2306                 SELECT amount
2307                 INTO xfer_amount
2308                 FROM acq.fund_spent_balance
2309                 WHERE fund = roll_fund.old_fund;
2310                 --
2311                 IF xfer_amount <> 0 THEN
2312                         IF roll_fund.rollover THEN
2313                                 --
2314                                 -- Transfer balance from old fund to new
2315                                 --
2316                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
2317                                 --
2318                                 PERFORM acq.transfer_fund(
2319                                         roll_fund.old_fund,
2320                                         xfer_amount,
2321                                         new_fund,
2322                                         xfer_amount,
2323                                         user_id,
2324                                         'Rollover'
2325                                 );
2326                         ELSE
2327                                 --
2328                                 -- Transfer balance from old fund to the void
2329                                 --
2330                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
2331                                 --
2332                                 PERFORM acq.transfer_fund(
2333                                         roll_fund.old_fund,
2334                                         xfer_amount,
2335                                         NULL,
2336                                         NULL,
2337                                         user_id,
2338                                         'Rollover'
2339                                 );
2340                         END IF;
2341                 END IF;
2342                 --
2343                 IF roll_fund.rollover THEN
2344                         --
2345                         -- Move any lineitems from the old fund to the new one
2346                         -- where the associated debit is an encumbrance.
2347                         --
2348                         -- Any other tables tying expenditure details to funds should
2349                         -- receive similar treatment.  At this writing there are none.
2350                         --
2351                         UPDATE acq.lineitem_detail
2352                         SET fund = new_fund
2353                         WHERE
2354                         fund = roll_fund.old_fund -- this condition may be redundant
2355                         AND fund_debit in
2356                         (
2357                                 SELECT id
2358                                 FROM acq.fund_debit
2359                                 WHERE
2360                                 fund = roll_fund.old_fund
2361                                 AND encumbrance
2362                         );
2363                         --
2364                         -- Move encumbrance debits from the old fund to the new fund
2365                         --
2366                         UPDATE acq.fund_debit
2367                         SET fund = new_fund
2368                         wHERE
2369                                 fund = roll_fund.old_fund
2370                                 AND encumbrance;
2371                 END IF;
2372                 --
2373                 -- Mark old fund as inactive, now that we've closed it
2374                 --
2375                 UPDATE acq.fund
2376                 SET active = FALSE
2377                 WHERE id = roll_fund.old_fund;
2378         END LOOP;
2379 END;
2380 $$ LANGUAGE plpgsql;
2381
2382 CREATE OR REPLACE VIEW acq.funding_source_credit_total AS
2383     SELECT  funding_source,
2384             SUM(amount) AS amount
2385       FROM  acq.funding_source_credit
2386       GROUP BY 1;
2387
2388 CREATE OR REPLACE VIEW acq.funding_source_allocation_total AS
2389     SELECT  funding_source,
2390             SUM(a.amount)::NUMERIC(100,2) AS amount
2391     FROM  acq.fund_allocation a
2392     GROUP BY 1;
2393
2394 CREATE OR REPLACE VIEW acq.funding_source_balance AS
2395     SELECT  COALESCE(c.funding_source, a.funding_source) AS funding_source,
2396             SUM(COALESCE(c.amount,0.0) - COALESCE(a.amount,0.0))::NUMERIC(100,2) AS amount
2397       FROM  acq.funding_source_credit_total c
2398             FULL JOIN acq.funding_source_allocation_total a USING (funding_source)
2399       GROUP BY 1;
2400
2401 CREATE OR REPLACE VIEW acq.fund_allocation_total AS
2402     SELECT  fund,
2403             SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
2404     FROM acq.fund_allocation a
2405          JOIN acq.fund f ON (a.fund = f.id)
2406          JOIN acq.funding_source s ON (a.funding_source = s.id)
2407     GROUP BY 1;
2408
2409 CREATE OR REPLACE VIEW acq.fund_debit_total AS
2410     SELECT  fund.id AS fund,
2411             fund_debit.encumbrance AS encumbrance,
2412                         SUM( COALESCE( fund_debit.amount, 0 ) ) AS amount
2413       FROM acq.fund AS fund
2414             LEFT JOIN acq.fund_debit AS fund_debit
2415                 ON ( fund.id = fund_debit.fund )
2416       GROUP BY 1,2;
2417
2418 CREATE OR REPLACE VIEW acq.fund_encumbrance_total AS
2419     SELECT  fund,
2420             SUM(amount) AS amount
2421       FROM  acq.fund_debit_total
2422       WHERE encumbrance IS TRUE
2423       GROUP BY 1;
2424
2425 CREATE OR REPLACE VIEW acq.fund_spent_total AS
2426     SELECT  fund,
2427             SUM(amount) AS amount
2428       FROM  acq.fund_debit_total
2429       WHERE encumbrance IS FALSE
2430       GROUP BY 1;
2431
2432 CREATE OR REPLACE VIEW acq.fund_combined_balance AS
2433     SELECT  c.fund,
2434             c.amount - COALESCE(d.amount,0.0) AS amount
2435       FROM  acq.fund_allocation_total c
2436             LEFT JOIN acq.fund_debit_total d USING (fund);
2437
2438 CREATE OR REPLACE VIEW acq.fund_spent_balance AS
2439     SELECT  c.fund,
2440             c.amount - COALESCE(d.amount,0.0) AS amount
2441       FROM  acq.fund_allocation_total c
2442             LEFT JOIN acq.fund_spent_total d USING (fund);
2443
2444 -- For each fund: the total allocation from all sources, in the
2445 -- currency of the fund (or 0 if there are no allocations)
2446
2447 CREATE VIEW acq.all_fund_allocation_total AS
2448 SELECT
2449     f.id AS fund,
2450     COALESCE( SUM( a.amount * acq.exchange_ratio(
2451         s.currency_type, f.currency_type))::numeric(100,2), 0 )
2452     AS amount
2453 FROM
2454     acq.fund f
2455         LEFT JOIN acq.fund_allocation a
2456             ON a.fund = f.id
2457         LEFT JOIN acq.funding_source s
2458             ON a.funding_source = s.id
2459 GROUP BY
2460     f.id;
2461
2462 -- For every fund: the total encumbrances (or 0 if none),
2463 -- in the currency of the fund.
2464
2465 CREATE VIEW acq.all_fund_encumbrance_total AS
2466 SELECT
2467         f.id AS fund,
2468         COALESCE( encumb.amount, 0 ) AS amount
2469 FROM
2470         acq.fund AS f
2471                 LEFT JOIN (
2472                         SELECT
2473                                 fund,
2474                                 sum( amount ) AS amount
2475                         FROM
2476                                 acq.fund_debit
2477                         WHERE
2478                                 encumbrance
2479                         GROUP BY fund
2480                 ) AS encumb
2481                         ON f.id = encumb.fund;
2482
2483 -- For every fund: the total spent (or 0 if none),
2484 -- in the currency of the fund.
2485
2486 CREATE VIEW acq.all_fund_spent_total AS
2487 SELECT
2488     f.id AS fund,
2489     COALESCE( spent.amount, 0 ) AS amount
2490 FROM
2491     acq.fund AS f
2492         LEFT JOIN (
2493             SELECT
2494                 fund,
2495                 sum( amount ) AS amount
2496             FROM
2497                 acq.fund_debit
2498             WHERE
2499                 NOT encumbrance
2500             GROUP BY fund
2501         ) AS spent
2502             ON f.id = spent.fund;
2503
2504 -- For each fund: the amount not yet spent, in the currency
2505 -- of the fund.  May include encumbrances.
2506
2507 CREATE VIEW acq.all_fund_spent_balance AS
2508 SELECT
2509         c.fund,
2510         c.amount - d.amount AS amount
2511 FROM acq.all_fund_allocation_total c
2512     LEFT JOIN acq.all_fund_spent_total d USING (fund);
2513
2514 -- For each fund: the amount neither spent nor encumbered,
2515 -- in the currency of the fund
2516
2517 CREATE VIEW acq.all_fund_combined_balance AS
2518 SELECT
2519      a.fund,
2520      a.amount - COALESCE( c.amount, 0 ) AS amount
2521 FROM
2522      acq.all_fund_allocation_total a
2523         LEFT OUTER JOIN (
2524             SELECT
2525                 fund,
2526                 SUM( amount ) AS amount
2527             FROM
2528                 acq.fund_debit
2529             GROUP BY
2530                 fund
2531         ) AS c USING ( fund );
2532
2533 CREATE TABLE acq.claim_type (
2534         id             SERIAL           PRIMARY KEY,
2535         org_unit       INT              NOT NULL REFERENCES actor.org_unit(id)
2536                                                  DEFERRABLE INITIALLY DEFERRED,
2537         code           TEXT             NOT NULL,
2538         description    TEXT             NOT NULL,
2539         CONSTRAINT claim_type_once_per_org UNIQUE ( org_unit, code )
2540 );
2541
2542 CREATE TABLE acq.claim (
2543         id             SERIAL           PRIMARY KEY,
2544         type           INT              NOT NULL REFERENCES acq.claim_type
2545                                                  DEFERRABLE INITIALLY DEFERRED,
2546         lineitem_detail BIGINT          NOT NULL REFERENCES acq.lineitem_detail
2547                                                  DEFERRABLE INITIALLY DEFERRED
2548 );
2549
2550 CREATE INDEX claim_lid_idx ON acq.claim( lineitem_detail );
2551
2552 CREATE TABLE acq.claim_event (
2553         id             BIGSERIAL        PRIMARY KEY,
2554         type           INT              NOT NULL REFERENCES acq.claim_event_type
2555                                                  DEFERRABLE INITIALLY DEFERRED,
2556         claim          SERIAL           NOT NULL REFERENCES acq.claim
2557                                                  DEFERRABLE INITIALLY DEFERRED,
2558         event_date     TIMESTAMPTZ      NOT NULL DEFAULT now(),
2559         creator        INT              NOT NULL REFERENCES actor.usr
2560                                                  DEFERRABLE INITIALLY DEFERRED,
2561         note           TEXT
2562 );
2563
2564 CREATE INDEX claim_event_claim_date_idx ON acq.claim_event( claim, event_date );
2565
2566 COMMIT;