]> git.evergreen-ils.org Git - Evergreen.git/blob - Open-ILS/src/sql/Pg/200.schema.acq.sql
added column to indicate that an invoice is complete/done/closed
[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     complete    BOOL        NOT NULL DEFAULT FALSE,
807     CONSTRAINT  inv_ident_once_per_provider UNIQUE(provider, inv_ident)
808 );
809
810 CREATE TABLE acq.invoice_entry (
811     id              SERIAL      PRIMARY KEY,
812     invoice         INT         NOT NULL REFERENCES acq.invoice (id) ON DELETE CASCADE,
813     purchase_order  INT         REFERENCES acq.purchase_order (id) ON UPDATE CASCADE ON DELETE SET NULL,
814     lineitem        INT         REFERENCES acq.lineitem (id) ON UPDATE CASCADE ON DELETE SET NULL,
815     inv_item_count  INT         NOT NULL, -- How many acqlids did they say they sent
816     phys_item_count INT, -- and how many did staff count
817     note            TEXT,
818     billed_per_item BOOL,
819     cost_billed     NUMERIC(8,2),
820     actual_cost     NUMERIC(8,2),
821         amount_paid     NUMERIC (8,2)
822 );
823
824 CREATE TABLE acq.invoice_item_type (
825     code    TEXT    PRIMARY KEY,
826     name    TEXT    NOT NULL,  -- i18n-ize
827         prorate BOOL    NOT NULL DEFAULT FALSE
828 );
829
830 CREATE TABLE acq.invoice_item ( -- for invoice-only debits: taxes/fees/non-bib items/etc
831     id              SERIAL      PRIMARY KEY,
832     invoice         INT         NOT NULL REFERENCES acq.invoice (id) ON UPDATE CASCADE ON DELETE CASCADE,
833     purchase_order  INT         REFERENCES acq.purchase_order (id) ON UPDATE CASCADE ON DELETE SET NULL,
834     fund_debit      INT         REFERENCES acq.fund_debit (id),
835     inv_item_type   TEXT        NOT NULL REFERENCES acq.invoice_item_type (code),
836     title           TEXT,
837     author          TEXT,
838     note            TEXT,
839     cost_billed     NUMERIC(8,2),
840     actual_cost     NUMERIC(8,2),
841         fund            INT         REFERENCES acq.fund (id)
842                                     DEFERRABLE INITIALLY DEFERRED,
843         amount_paid     NUMERIC (8,2)
844 );
845
846 -- Patron requests
847 CREATE TABLE acq.user_request_type (
848     id      SERIAL  PRIMARY KEY,
849     label   TEXT    NOT NULL UNIQUE -- i18n-ize
850 );
851
852 INSERT INTO acq.user_request_type (id,label) VALUES (1, oils_i18n_gettext('1', 'Books', 'aurt', 'label'));
853 INSERT INTO acq.user_request_type (id,label) VALUES (2, oils_i18n_gettext('2', 'Journal/Magazine & Newspaper Articles', 'aurt', 'label'));
854 INSERT INTO acq.user_request_type (id,label) VALUES (3, oils_i18n_gettext('3', 'Audiobooks', 'aurt', 'label'));
855 INSERT INTO acq.user_request_type (id,label) VALUES (4, oils_i18n_gettext('4', 'Music', 'aurt', 'label'));
856 INSERT INTO acq.user_request_type (id,label) VALUES (5, oils_i18n_gettext('5', 'DVDs', 'aurt', 'label'));
857
858 SELECT SETVAL('acq.user_request_type_id_seq'::TEXT, 6);
859
860 CREATE TABLE acq.user_request (
861     id                  SERIAL  PRIMARY KEY,
862     usr                 INT     NOT NULL REFERENCES actor.usr (id), -- requesting user
863     hold                BOOL    NOT NULL DEFAULT TRUE,
864
865     pickup_lib          INT     NOT NULL REFERENCES actor.org_unit (id), -- pickup lib
866     holdable_formats    TEXT,           -- nullable, for use in hold creation
867     phone_notify        TEXT,
868     email_notify        BOOL    NOT NULL DEFAULT TRUE,
869     lineitem            INT     REFERENCES acq.lineitem (id) ON DELETE CASCADE,
870     eg_bib              BIGINT  REFERENCES biblio.record_entry (id) ON DELETE CASCADE,
871     request_date        TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- when they requested it
872     need_before         TIMESTAMPTZ,    -- don't create holds after this
873     max_fee             TEXT,
874   
875     request_type        INT     NOT NULL REFERENCES acq.user_request_type (id),
876     isxn                TEXT,
877     title               TEXT,
878     volume              TEXT,
879     author              TEXT,
880     article_title       TEXT,
881     article_pages       TEXT,
882     publisher           TEXT,
883     location            TEXT,
884     pubdate             TEXT,
885     mentioned           TEXT,
886     other_info          TEXT,
887         cancel_reason       INT    REFERENCES acq.cancel_reason( id )
888                                    DEFERRABLE INITIALLY DEFERRED
889 );
890
891
892 -- Functions
893
894 CREATE TYPE acq.flat_lineitem_holding_subfield AS (lineitem int, holding int, subfield text, data text);
895 CREATE OR REPLACE FUNCTION acq.extract_holding_attr_table (lineitem int, tag text) RETURNS SETOF acq.flat_lineitem_holding_subfield AS $$
896 DECLARE
897     counter INT;
898     lida    acq.flat_lineitem_holding_subfield%ROWTYPE;
899 BEGIN
900
901     SELECT  COUNT(*) INTO counter
902       FROM  oils_xpath_table(
903                 'id',
904                 'marc',
905                 'acq.lineitem',
906                 '//*[@tag="' || tag || '"]',
907                 'id=' || lineitem
908             ) as t(i int,c text);
909
910     FOR i IN 1 .. counter LOOP
911         FOR lida IN
912             SELECT  * 
913               FROM  (   SELECT  id,i,t,v
914                           FROM  oils_xpath_table(
915                                     'id',
916                                     'marc',
917                                     'acq.lineitem',
918                                     '//*[@tag="' || tag || '"][position()=' || i || ']/*/@code|' ||
919                                         '//*[@tag="' || tag || '"][position()=' || i || ']/*[@code]',
920                                     'id=' || lineitem
921                                 ) as t(id int,t text,v text)
922                     )x
923         LOOP
924             RETURN NEXT lida;
925         END LOOP;
926     END LOOP;
927
928     RETURN;
929 END;
930 $$ LANGUAGE PLPGSQL;
931
932 CREATE TYPE acq.flat_lineitem_detail AS (lineitem int, holding int, attr text, data text);
933 CREATE OR REPLACE FUNCTION acq.extract_provider_holding_data ( lineitem_i int ) RETURNS SETOF acq.flat_lineitem_detail AS $$
934 DECLARE
935     prov_i  INT;
936     tag_t   TEXT;
937     lida    acq.flat_lineitem_detail%ROWTYPE;
938 BEGIN
939     SELECT provider INTO prov_i FROM acq.lineitem WHERE id = lineitem_i;
940     IF NOT FOUND THEN RETURN; END IF;
941
942     SELECT holding_tag INTO tag_t FROM acq.provider WHERE id = prov_i;
943     IF NOT FOUND OR tag_t IS NULL THEN RETURN; END IF;
944
945     FOR lida IN
946         SELECT  lineitem_i,
947                 h.holding,
948                 a.name,
949                 h.data
950           FROM  acq.extract_holding_attr_table( lineitem_i, tag_t ) h
951                 JOIN acq.provider_holding_subfield_map a USING (subfield)
952           WHERE a.provider = prov_i
953     LOOP
954         RETURN NEXT lida;
955     END LOOP;
956
957     RETURN;
958 END;
959 $$ LANGUAGE PLPGSQL;
960
961 -- select * from acq.extract_provider_holding_data(699);
962
963 CREATE OR REPLACE FUNCTION public.extract_acq_marc_field ( BIGINT, TEXT, TEXT) RETURNS TEXT AS $$
964         SELECT public.extract_marc_field('acq.lineitem', $1, $2, $3);
965 $$ LANGUAGE SQL;
966
967 /*
968 CREATE OR REPLACE FUNCTION public.extract_bib_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
969         SELECT public.extract_marc_field('biblio.record_entry', $1, $2);
970 $$ LANGUAGE SQL;
971
972 CREATE OR REPLACE FUNCTION public.extract_authority_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
973         SELECT public.extract_marc_field('authority.record_entry', $1, $2);
974 $$ LANGUAGE SQL;
975 */
976 -- For example:
977 -- INSERT INTO acq.lineitem_provider_attr_definition ( provider, code, description, xpath ) VALUES (1,'price','Price','//*[@tag="020" or @tag="022"]/*[@code="a"][1]');
978
979 /*
980 Suggested vendor fields:
981         vendor_price
982         vendor_currency
983         vendor_avail
984         vendor_po
985         vendor_identifier
986 */
987
988 CREATE OR REPLACE FUNCTION public.ingest_acq_marc ( ) RETURNS TRIGGER AS $function$
989 DECLARE
990         value           TEXT;
991         atype           TEXT;
992         prov            INT;
993         pos             INT;
994         adef            RECORD;
995         xpath_string    TEXT;
996 BEGIN
997         FOR adef IN SELECT *,tableoid FROM acq.lineitem_attr_definition LOOP
998
999                 SELECT relname::TEXT INTO atype FROM pg_class WHERE oid = adef.tableoid;
1000
1001                 IF (atype NOT IN ('lineitem_usr_attr_definition','lineitem_local_attr_definition')) THEN
1002                         IF (atype = 'lineitem_provider_attr_definition') THEN
1003                                 SELECT provider INTO prov FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
1004                                 CONTINUE WHEN NEW.provider IS NULL OR prov <> NEW.provider;
1005                         END IF;
1006                         
1007                         IF (atype = 'lineitem_provider_attr_definition') THEN
1008                                 SELECT xpath INTO xpath_string FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
1009                         ELSIF (atype = 'lineitem_marc_attr_definition') THEN
1010                                 SELECT xpath INTO xpath_string FROM acq.lineitem_marc_attr_definition WHERE id = adef.id;
1011                         ELSIF (atype = 'lineitem_generated_attr_definition') THEN
1012                                 SELECT xpath INTO xpath_string FROM acq.lineitem_generated_attr_definition WHERE id = adef.id;
1013                         END IF;
1014
1015             xpath_string := REGEXP_REPLACE(xpath_string,$re$//?text\(\)$$re$,'');
1016
1017             pos := 1;
1018
1019             LOOP
1020                         SELECT extract_acq_marc_field(id, xpath_string || '[' || pos || ']', adef.remove) INTO value FROM acq.lineitem WHERE id = NEW.id;
1021
1022                         IF (value IS NOT NULL AND value <> '') THEN
1023                                 INSERT INTO acq.lineitem_attr (lineitem, definition, attr_type, attr_name, attr_value)
1024                                         VALUES (NEW.id, adef.id, atype, adef.code, value);
1025                 ELSE
1026                     EXIT;
1027                             END IF;
1028
1029                 pos := pos + 1;
1030             END LOOP;
1031
1032                 END IF;
1033
1034         END LOOP;
1035
1036         RETURN NULL;
1037 END;
1038 $function$ LANGUAGE PLPGSQL;
1039
1040 CREATE OR REPLACE FUNCTION public.cleanup_acq_marc ( ) RETURNS TRIGGER AS $$
1041 BEGIN
1042         IF TG_OP = 'UPDATE' THEN
1043                 DELETE FROM acq.lineitem_attr
1044                         WHERE lineitem = OLD.id AND attr_type IN ('lineitem_provider_attr_definition', 'lineitem_marc_attr_definition','lineitem_generated_attr_definition');
1045                 RETURN NEW;
1046         ELSE
1047                 DELETE FROM acq.lineitem_attr WHERE lineitem = OLD.id;
1048                 RETURN OLD;
1049         END IF;
1050 END;
1051 $$ LANGUAGE PLPGSQL;
1052
1053 CREATE TRIGGER cleanup_lineitem_trigger
1054         BEFORE UPDATE OR DELETE ON acq.lineitem
1055         FOR EACH ROW EXECUTE PROCEDURE public.cleanup_acq_marc();
1056
1057 CREATE TRIGGER ingest_lineitem_trigger
1058         AFTER INSERT OR UPDATE ON acq.lineitem
1059         FOR EACH ROW EXECUTE PROCEDURE public.ingest_acq_marc();
1060
1061 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( from_ex TEXT, to_ex TEXT ) RETURNS NUMERIC AS $$
1062 DECLARE
1063     rat NUMERIC;
1064 BEGIN
1065     IF from_ex = to_ex THEN
1066         RETURN 1.0;
1067     END IF;
1068
1069     SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = from_ex AND to_currency = to_ex;
1070
1071     IF FOUND THEN
1072         RETURN rat;
1073     ELSE
1074         SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = to_ex AND to_currency = from_ex;
1075         IF FOUND THEN
1076             RETURN 1.0/rat;
1077         END IF;
1078     END IF;
1079
1080     RETURN NULL;
1081
1082 END;
1083 $$ LANGUAGE PLPGSQL;
1084
1085 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( TEXT, TEXT, NUMERIC ) RETURNS NUMERIC AS $$
1086     SELECT $3 * acq.exchange_ratio($1, $2);
1087 $$ LANGUAGE SQL;
1088
1089 CREATE OR REPLACE FUNCTION acq.find_bad_fy()
1090 /*
1091         Examine the acq.fiscal_year table, comparing successive years.
1092         Report any inconsistencies, i.e. years that overlap, have gaps
1093     between them, or are out of sequence.
1094 */
1095 RETURNS SETOF RECORD AS $$
1096 DECLARE
1097         first_row  BOOLEAN;
1098         curr_year  RECORD;
1099         prev_year  RECORD;
1100         return_rec RECORD;
1101 BEGIN
1102         first_row := true;
1103         FOR curr_year in
1104                 SELECT
1105                         id,
1106                         calendar,
1107                         year,
1108                         year_begin,
1109                         year_end
1110                 FROM
1111                         acq.fiscal_year
1112                 ORDER BY
1113                         calendar,
1114                         year_begin
1115         LOOP
1116                 --
1117                 IF first_row THEN
1118                         first_row := FALSE;
1119                 ELSIF curr_year.calendar    = prev_year.calendar THEN
1120                         IF curr_year.year_begin > prev_year.year_end THEN
1121                                 -- This ugly kludge works around the fact that older
1122                                 -- versions of PostgreSQL don't support RETURN QUERY SELECT
1123                                 FOR return_rec IN SELECT
1124                                         prev_year.id,
1125                                         prev_year.year,
1126                                         'Gap between fiscal years'::TEXT
1127                                 LOOP
1128                                         RETURN NEXT return_rec;
1129                                 END LOOP;
1130                         ELSIF curr_year.year_begin < prev_year.year_end THEN
1131                                 FOR return_rec IN SELECT
1132                                         prev_year.id,
1133                                         prev_year.year,
1134                                         'Overlapping fiscal years'::TEXT
1135                                 LOOP
1136                                         RETURN NEXT return_rec;
1137                                 END LOOP;
1138                         ELSIF curr_year.year < prev_year.year THEN
1139                                 FOR return_rec IN SELECT
1140                                         prev_year.id,
1141                                         prev_year.year,
1142                                         'Fiscal years out of order'::TEXT
1143                                 LOOP
1144                                         RETURN NEXT return_rec;
1145                                 END LOOP;
1146                         END IF;
1147                 END IF;
1148                 --
1149                 prev_year := curr_year;
1150         END LOOP;
1151         --
1152         RETURN;
1153 END;
1154 $$ LANGUAGE plpgsql;
1155
1156 CREATE OR REPLACE FUNCTION acq.transfer_fund(
1157         old_fund   IN INT,
1158         old_amount IN NUMERIC,     -- in currency of old fund
1159         new_fund   IN INT,
1160         new_amount IN NUMERIC,     -- in currency of new fund
1161         user_id    IN INT,
1162         xfer_note  IN TEXT         -- to be recorded in acq.fund_transfer
1163         -- ,funding_source_in IN INT  -- if user wants to specify a funding source (see notes)
1164 ) RETURNS VOID AS $$
1165 /* -------------------------------------------------------------------------------
1166
1167 Function to transfer money from one fund to another.
1168
1169 A transfer is represented as a pair of entries in acq.fund_allocation, with a
1170 negative amount for the old (losing) fund and a positive amount for the new
1171 (gaining) fund.  In some cases there may be more than one such pair of entries
1172 in order to pull the money from different funding sources, or more specifically
1173 from different funding source credits.  For each such pair there is also an
1174 entry in acq.fund_transfer.
1175
1176 Since funding_source is a non-nullable column in acq.fund_allocation, we must
1177 choose a funding source for the transferred money to come from.  This choice
1178 must meet two constraints, so far as possible:
1179
1180 1. The amount transferred from a given funding source must not exceed the
1181 amount allocated to the old fund by the funding source.  To that end we
1182 compare the amount being transferred to the amount allocated.
1183
1184 2. We shouldn't transfer money that has already been spent or encumbered, as
1185 defined by the funding attribution process.  We attribute expenses to the
1186 oldest funding source credits first.  In order to avoid transferring that
1187 attributed money, we reverse the priority, transferring from the newest funding
1188 source credits first.  There can be no guarantee that this approach will
1189 avoid overcommitting a fund, but no other approach can do any better.
1190
1191 In this context the age of a funding source credit is defined by the
1192 deadline_date for credits with deadline_dates, and by the effective_date for
1193 credits without deadline_dates, with the proviso that credits with deadline_dates
1194 are all considered "older" than those without.
1195
1196 ----------
1197
1198 In the signature for this function, there is one last parameter commented out,
1199 named "funding_source_in".  Correspondingly, the WHERE clause for the query
1200 driving the main loop has an OR clause commented out, which references the
1201 funding_source_in parameter.
1202
1203 If these lines are uncommented, this function will allow the user optionally to
1204 restrict a fund transfer to a specified funding source.  If the source
1205 parameter is left NULL, then there will be no such restriction.
1206
1207 ------------------------------------------------------------------------------- */ 
1208 DECLARE
1209         same_currency      BOOLEAN;
1210         currency_ratio     NUMERIC;
1211         old_fund_currency  TEXT;
1212         old_remaining      NUMERIC;  -- in currency of old fund
1213         new_fund_currency  TEXT;
1214         new_fund_active    BOOLEAN;
1215         new_remaining      NUMERIC;  -- in currency of new fund
1216         curr_old_amt       NUMERIC;  -- in currency of old fund
1217         curr_new_amt       NUMERIC;  -- in currency of new fund
1218         source_addition    NUMERIC;  -- in currency of funding source
1219         source_deduction   NUMERIC;  -- in currency of funding source
1220         orig_allocated_amt NUMERIC;  -- in currency of funding source
1221         allocated_amt      NUMERIC;  -- in currency of fund
1222         source             RECORD;
1223 BEGIN
1224         --
1225         -- Sanity checks
1226         --
1227         IF old_fund IS NULL THEN
1228                 RAISE EXCEPTION 'acq.transfer_fund: old fund id is NULL';
1229         END IF;
1230         --
1231         IF old_amount IS NULL THEN
1232                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
1233         END IF;
1234         --
1235         -- The new fund and its amount must be both NULL or both not NULL.
1236         --
1237         IF new_fund IS NOT NULL AND new_amount IS NULL THEN
1238                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer to receiving fund is NULL';
1239         END IF;
1240         --
1241         IF new_fund IS NULL AND new_amount IS NOT NULL THEN
1242                 RAISE EXCEPTION 'acq.transfer_fund: receiving fund is NULL, its amount is not NULL';
1243         END IF;
1244         --
1245         IF user_id IS NULL THEN
1246                 RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
1247         END IF;
1248         --
1249         -- Initialize the amounts to be transferred, each denominated
1250         -- in the currency of its respective fund.  They will be
1251         -- reduced on each iteration of the loop.
1252         --
1253         old_remaining := old_amount;
1254         new_remaining := new_amount;
1255         --
1256         -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
1257         --      old_amount, old_fund, new_amount, new_fund;
1258         --
1259         -- Get the currency types of the old and new funds.
1260         --
1261         SELECT
1262                 currency_type
1263         INTO
1264                 old_fund_currency
1265         FROM
1266                 acq.fund
1267         WHERE
1268                 id = old_fund;
1269         --
1270         IF old_fund_currency IS NULL THEN
1271                 RAISE EXCEPTION 'acq.transfer_fund: old fund id % is not defined', old_fund;
1272         END IF;
1273         --
1274         IF new_fund IS NOT NULL THEN
1275                 SELECT
1276                         currency_type,
1277                         active
1278                 INTO
1279                         new_fund_currency,
1280                         new_fund_active
1281                 FROM
1282                         acq.fund
1283                 WHERE
1284                         id = new_fund;
1285                 --
1286                 IF new_fund_currency IS NULL THEN
1287                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is not defined', new_fund;
1288                 ELSIF NOT new_fund_active THEN
1289                         --
1290                         -- No point in putting money into a fund from whence you can't spend it
1291                         --
1292                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is inactive', new_fund;
1293                 END IF;
1294                 --
1295                 IF new_amount = old_amount THEN
1296                         same_currency := true;
1297                         currency_ratio := 1;
1298                 ELSE
1299                         --
1300                         -- We'll have to translate currency between funds.  We presume that
1301                         -- the calling code has already applied an appropriate exchange rate,
1302                         -- so we'll apply the same conversion to each sub-transfer.
1303                         --
1304                         same_currency := false;
1305                         currency_ratio := new_amount / old_amount;
1306                 END IF;
1307         END IF;
1308         --
1309         -- Identify the funding source(s) from which we want to transfer the money.
1310         -- The principle is that we want to transfer the newest money first, because
1311         -- we spend the oldest money first.  The priority for spending is defined
1312         -- by a sort of the view acq.ordered_funding_source_credit.
1313         --
1314         FOR source in
1315                 SELECT
1316                         ofsc.id,
1317                         ofsc.funding_source,
1318                         ofsc.amount,
1319                         ofsc.amount * acq.exchange_ratio( fs.currency_type, old_fund_currency )
1320                                 AS converted_amt,
1321                         fs.currency_type
1322                 FROM
1323                         acq.ordered_funding_source_credit AS ofsc,
1324                         acq.funding_source fs
1325                 WHERE
1326                         ofsc.funding_source = fs.id
1327                         and ofsc.funding_source IN
1328                         (
1329                                 SELECT funding_source
1330                                 FROM acq.fund_allocation
1331                                 WHERE fund = old_fund
1332                         )
1333                         -- and
1334                         -- (
1335                         --      ofsc.funding_source = funding_source_in
1336                         --      OR funding_source_in IS NULL
1337                         -- )
1338                 ORDER BY
1339                         ofsc.sort_priority desc,
1340                         ofsc.sort_date desc,
1341                         ofsc.id desc
1342         LOOP
1343                 --
1344                 -- Determine how much money the old fund got from this funding source,
1345                 -- denominated in the currency types of the source and of the fund.
1346                 -- This result may reflect transfers from previous iterations.
1347                 --
1348                 SELECT
1349                         COALESCE( sum( amount ), 0 ),
1350                         COALESCE( sum( amount )
1351                                 * acq.exchange_ratio( source.currency_type, old_fund_currency ), 0 )
1352                 INTO
1353                         orig_allocated_amt,     -- in currency of the source
1354                         allocated_amt           -- in currency of the old fund
1355                 FROM
1356                         acq.fund_allocation
1357                 WHERE
1358                         fund = old_fund
1359                         and funding_source = source.funding_source;
1360                 --      
1361                 -- Determine how much to transfer from this credit, in the currency
1362                 -- of the fund.   Begin with the amount remaining to be attributed:
1363                 --
1364                 curr_old_amt := old_remaining;
1365                 --
1366                 -- Can't attribute more than was allocated from the fund:
1367                 --
1368                 IF curr_old_amt > allocated_amt THEN
1369                         curr_old_amt := allocated_amt;
1370                 END IF;
1371                 --
1372                 -- Can't attribute more than the amount of the current credit:
1373                 --
1374                 IF curr_old_amt > source.converted_amt THEN
1375                         curr_old_amt := source.converted_amt;
1376                 END IF;
1377                 --
1378                 curr_old_amt := trunc( curr_old_amt, 2 );
1379                 --
1380                 old_remaining := old_remaining - curr_old_amt;
1381                 --
1382                 -- Determine the amount to be deducted, if any,
1383                 -- from the old allocation.
1384                 --
1385                 IF old_remaining > 0 THEN
1386                         --
1387                         -- In this case we're using the whole allocation, so use that
1388                         -- amount directly instead of applying a currency translation
1389                         -- and thereby inviting round-off errors.
1390                         --
1391                         source_deduction := - orig_allocated_amt;
1392                 ELSE 
1393                         source_deduction := trunc(
1394                                 ( - curr_old_amt ) *
1395                                         acq.exchange_ratio( old_fund_currency, source.currency_type ),
1396                                 2 );
1397                 END IF;
1398                 --
1399                 IF source_deduction <> 0 THEN
1400                         --
1401                         -- Insert negative allocation for old fund in fund_allocation,
1402                         -- converted into the currency of the funding source
1403                         --
1404                         INSERT INTO acq.fund_allocation (
1405                                 funding_source,
1406                                 fund,
1407                                 amount,
1408                                 allocator,
1409                                 note
1410                         ) VALUES (
1411                                 source.funding_source,
1412                                 old_fund,
1413                                 source_deduction,
1414                                 user_id,
1415                                 'Transfer to fund ' || new_fund
1416                         );
1417                 END IF;
1418                 --
1419                 IF new_fund IS NOT NULL THEN
1420                         --
1421                         -- Determine how much to add to the new fund, in
1422                         -- its currency, and how much remains to be added:
1423                         --
1424                         IF same_currency THEN
1425                                 curr_new_amt := curr_old_amt;
1426                         ELSE
1427                                 IF old_remaining = 0 THEN
1428                                         --
1429                                         -- This is the last iteration, so nothing should be left
1430                                         --
1431                                         curr_new_amt := new_remaining;
1432                                         new_remaining := 0;
1433                                 ELSE
1434                                         curr_new_amt := trunc( curr_old_amt * currency_ratio, 2 );
1435                                         new_remaining := new_remaining - curr_new_amt;
1436                                 END IF;
1437                         END IF;
1438                         --
1439                         -- Determine how much to add, if any,
1440                         -- to the new fund's allocation.
1441                         --
1442                         IF old_remaining > 0 THEN
1443                                 --
1444                                 -- In this case we're using the whole allocation, so use that amount
1445                                 -- amount directly instead of applying a currency translation and
1446                                 -- thereby inviting round-off errors.
1447                                 --
1448                                 source_addition := orig_allocated_amt;
1449                         ELSIF source.currency_type = old_fund_currency THEN
1450                                 --
1451                                 -- In this case we don't need a round trip currency translation,
1452                                 -- thereby inviting round-off errors:
1453                                 --
1454                                 source_addition := curr_old_amt;
1455                         ELSE 
1456                                 source_addition := trunc(
1457                                         curr_new_amt *
1458                                                 acq.exchange_ratio( new_fund_currency, source.currency_type ),
1459                                         2 );
1460                         END IF;
1461                         --
1462                         IF source_addition <> 0 THEN
1463                                 --
1464                                 -- Insert positive allocation for new fund in fund_allocation,
1465                                 -- converted to the currency of the founding source
1466                                 --
1467                                 INSERT INTO acq.fund_allocation (
1468                                         funding_source,
1469                                         fund,
1470                                         amount,
1471                                         allocator,
1472                                         note
1473                                 ) VALUES (
1474                                         source.funding_source,
1475                                         new_fund,
1476                                         source_addition,
1477                                         user_id,
1478                                         'Transfer from fund ' || old_fund
1479                                 );
1480                         END IF;
1481                 END IF;
1482                 --
1483                 IF trunc( curr_old_amt, 2 ) <> 0
1484                 OR trunc( curr_new_amt, 2 ) <> 0 THEN
1485                         --
1486                         -- Insert row in fund_transfer, using amounts in the currency of the funds
1487                         --
1488                         INSERT INTO acq.fund_transfer (
1489                                 src_fund,
1490                                 src_amount,
1491                                 dest_fund,
1492                                 dest_amount,
1493                                 transfer_user,
1494                                 note,
1495                                 funding_source_credit
1496                         ) VALUES (
1497                                 old_fund,
1498                                 trunc( curr_old_amt, 2 ),
1499                                 new_fund,
1500                                 trunc( curr_new_amt, 2 ),
1501                                 user_id,
1502                                 xfer_note,
1503                                 source.id
1504                         );
1505                 END IF;
1506                 --
1507                 if old_remaining <= 0 THEN
1508                         EXIT;                   -- Nothing more to be transferred
1509                 END IF;
1510         END LOOP;
1511 END;
1512 $$ LANGUAGE plpgsql;
1513
1514 CREATE OR REPLACE FUNCTION acq.attribute_debits() RETURNS VOID AS $$
1515 /*
1516 Function to attribute expenditures and encumbrances to funding source credits,
1517 and thereby to funding sources.
1518
1519 Read the debits in chonological order, attributing each one to one or
1520 more funding source credits.  Constraints:
1521
1522 1. Don't attribute more to a credit than the amount of the credit.
1523
1524 2. For a given fund, don't attribute more to a funding source than the
1525 source has allocated to that fund.
1526
1527 3. Attribute debits to credits with deadlines before attributing them to
1528 credits without deadlines.  Otherwise attribute to the earliest credits
1529 first, based on the deadline date when present, or on the effective date
1530 when there is no deadline.  Use funding_source_credit.id as a tie-breaker.
1531 This ordering is defined by an ORDER BY clause on the view
1532 acq.ordered_funding_source_credit.
1533
1534 Start by truncating the table acq.debit_attribution.  Then insert a row
1535 into that table for each attribution.  If a debit cannot be fully
1536 attributed, insert a row for the unattributable balance, with the 
1537 funding_source_credit and credit_amount columns NULL.
1538 */
1539 DECLARE
1540         curr_fund_source_bal RECORD;
1541         seqno                INT;     -- sequence num for credits applicable to a fund
1542         fund_credit          RECORD;  -- current row in temp t_fund_credit table
1543         fc                   RECORD;  -- used for loading t_fund_credit table
1544         sc                   RECORD;  -- used for loading t_fund_credit table
1545         --
1546         -- Used exclusively in the main loop:
1547         --
1548         deb                 RECORD;   -- current row from acq.fund_debit table
1549         curr_credit_bal     RECORD;   -- current row from temp t_credit table
1550         debit_balance       NUMERIC;  -- amount left to attribute for current debit
1551         conv_debit_balance  NUMERIC;  -- debit balance in currency of the fund
1552         attr_amount         NUMERIC;  -- amount being attributed, in currency of debit
1553         conv_attr_amount    NUMERIC;  -- amount being attributed, in currency of source
1554         conv_cred_balance   NUMERIC;  -- credit_balance in the currency of the fund
1555         conv_alloc_balance  NUMERIC;  -- allocated balance in the currency of the fund
1556         attrib_count        INT;      -- populates id of acq.debit_attribution
1557 BEGIN
1558         --
1559         -- Load a temporary table.  For each combination of fund and funding source,
1560         -- load an entry with the total amount allocated to that fund by that source.
1561         -- This sum may reflect transfers as well as original allocations.  We will
1562         -- reduce this balance whenever we attribute debits to it.
1563         --
1564         CREATE TEMP TABLE t_fund_source_bal
1565         ON COMMIT DROP AS
1566                 SELECT
1567                         fund AS fund,
1568                         funding_source AS source,
1569                         sum( amount ) AS balance
1570                 FROM
1571                         acq.fund_allocation
1572                 GROUP BY
1573                         fund,
1574                         funding_source
1575                 HAVING
1576                         sum( amount ) > 0;
1577         --
1578         CREATE INDEX t_fund_source_bal_idx
1579                 ON t_fund_source_bal( fund, source );
1580         -------------------------------------------------------------------------------
1581         --
1582         -- Load another temporary table.  For each fund, load zero or more
1583         -- funding source credits from which that fund can get money.
1584         --
1585         CREATE TEMP TABLE t_fund_credit (
1586                 fund        INT,
1587                 seq         INT,
1588                 credit      INT
1589         ) ON COMMIT DROP;
1590         --
1591         FOR fc IN
1592                 SELECT DISTINCT fund
1593                 FROM acq.fund_allocation
1594                 ORDER BY fund
1595         LOOP                  -- Loop over the funds
1596                 seqno := 1;
1597                 FOR sc IN
1598                         SELECT
1599                                 ofsc.id
1600                         FROM
1601                                 acq.ordered_funding_source_credit AS ofsc
1602                         WHERE
1603                                 ofsc.funding_source IN
1604                                 (
1605                                         SELECT funding_source
1606                                         FROM acq.fund_allocation
1607                                         WHERE fund = fc.fund
1608                                 )
1609                 ORDER BY
1610                     ofsc.sort_priority,
1611                     ofsc.sort_date,
1612                     ofsc.id
1613                 LOOP                        -- Add each credit to the list
1614                         INSERT INTO t_fund_credit (
1615                                 fund,
1616                                 seq,
1617                                 credit
1618                         ) VALUES (
1619                                 fc.fund,
1620                                 seqno,
1621                                 sc.id
1622                         );
1623                         --RAISE NOTICE 'Fund % credit %', fc.fund, sc.id;
1624                         seqno := seqno + 1;
1625                 END LOOP;     -- Loop over credits for a given fund
1626         END LOOP;         -- Loop over funds
1627         --
1628         CREATE INDEX t_fund_credit_idx
1629                 ON t_fund_credit( fund, seq );
1630         -------------------------------------------------------------------------------
1631         --
1632         -- Load yet another temporary table.  This one is a list of funding source
1633         -- credits, with their balances.  We shall reduce those balances as we
1634         -- attribute debits to them.
1635         --
1636         CREATE TEMP TABLE t_credit
1637         ON COMMIT DROP AS
1638         SELECT
1639             fsc.id AS credit,
1640             fsc.funding_source AS source,
1641             fsc.amount AS balance,
1642             fs.currency_type AS currency_type
1643         FROM
1644             acq.funding_source_credit AS fsc,
1645             acq.funding_source fs
1646         WHERE
1647             fsc.funding_source = fs.id
1648                         AND fsc.amount > 0;
1649         --
1650         CREATE INDEX t_credit_idx
1651                 ON t_credit( credit );
1652         --
1653         -------------------------------------------------------------------------------
1654         --
1655         -- Now that we have loaded the lookup tables: loop through the debits,
1656         -- attributing each one to one or more funding source credits.
1657         -- 
1658         truncate table acq.debit_attribution;
1659         --
1660         attrib_count := 0;
1661         FOR deb in
1662                 SELECT
1663                         fd.id,
1664                         fd.fund,
1665                         fd.amount,
1666                         f.currency_type,
1667                         fd.encumbrance
1668                 FROM
1669                         acq.fund_debit fd,
1670                         acq.fund f
1671                 WHERE
1672                         fd.fund = f.id
1673                 ORDER BY
1674                         fd.id
1675         LOOP
1676                 --RAISE NOTICE 'Debit %, fund %', deb.id, deb.fund;
1677                 --
1678                 debit_balance := deb.amount;
1679                 --
1680                 -- Loop over the funding source credits that are eligible
1681                 -- to pay for this debit
1682                 --
1683                 FOR fund_credit IN
1684                         SELECT
1685                                 credit
1686                         FROM
1687                                 t_fund_credit
1688                         WHERE
1689                                 fund = deb.fund
1690                         ORDER BY
1691                                 seq
1692                 LOOP
1693                         --RAISE NOTICE '   Examining credit %', fund_credit.credit;
1694                         --
1695                         -- Look up the balance for this credit.  If it's zero, then
1696                         -- it's not useful, so treat it as if you didn't find it.
1697                         -- (Actually there shouldn't be any zero balances in the table,
1698                         -- but we check just to make sure.)
1699                         --
1700                         SELECT *
1701                         INTO curr_credit_bal
1702                         FROM t_credit
1703                         WHERE
1704                                 credit = fund_credit.credit
1705                                 AND balance > 0;
1706                         --
1707                         IF curr_credit_bal IS NULL THEN
1708                                 --
1709                                 -- This credit is exhausted; try the next one.
1710                                 --
1711                                 CONTINUE;
1712                         END IF;
1713                         --
1714                         --
1715                         -- At this point we have an applicable credit with some money left.
1716                         -- Now see if the relevant funding_source has any money left.
1717                         --
1718                         -- Look up the balance of the allocation for this combination of
1719                         -- fund and source.  If you find such an entry, but it has a zero
1720                         -- balance, then it's not useful, so treat it as unfound.
1721                         -- (Actually there shouldn't be any zero balances in the table,
1722                         -- but we check just to make sure.)
1723                         --
1724                         SELECT *
1725                         INTO curr_fund_source_bal
1726                         FROM t_fund_source_bal
1727                         WHERE
1728                                 fund = deb.fund
1729                                 AND source = curr_credit_bal.source
1730                                 AND balance > 0;
1731                         --
1732                         IF curr_fund_source_bal IS NULL THEN
1733                                 --
1734                                 -- This fund/source doesn't exist or is already exhausted,
1735                                 -- so we can't use this credit.  Go on to the next one.
1736                                 --
1737                                 CONTINUE;
1738                         END IF;
1739                         --
1740                         -- Convert the available balances to the currency of the fund
1741                         --
1742                         conv_alloc_balance := curr_fund_source_bal.balance * acq.exchange_ratio(
1743                                 curr_credit_bal.currency_type, deb.currency_type );
1744                         conv_cred_balance := curr_credit_bal.balance * acq.exchange_ratio(
1745                                 curr_credit_bal.currency_type, deb.currency_type );
1746                         --
1747                         -- Determine how much we can attribute to this credit: the minimum
1748                         -- of the debit amount, the fund/source balance, and the
1749                         -- credit balance
1750                         --
1751                         --RAISE NOTICE '   deb bal %', debit_balance;
1752                         --RAISE NOTICE '      source % balance %', curr_credit_bal.source, conv_alloc_balance;
1753                         --RAISE NOTICE '      credit % balance %', curr_credit_bal.credit, conv_cred_balance;
1754                         --
1755                         conv_attr_amount := NULL;
1756                         attr_amount := debit_balance;
1757                         --
1758                         IF attr_amount > conv_alloc_balance THEN
1759                                 attr_amount := conv_alloc_balance;
1760                                 conv_attr_amount := curr_fund_source_bal.balance;
1761                         END IF;
1762                         IF attr_amount > conv_cred_balance THEN
1763                                 attr_amount := conv_cred_balance;
1764                                 conv_attr_amount := curr_credit_bal.balance;
1765                         END IF;
1766                         --
1767                         -- If we're attributing all of one of the balances, then that's how
1768                         -- much we will deduct from the balances, and we already captured
1769                         -- that amount above.  Otherwise we must convert the amount of the
1770                         -- attribution from the currency of the fund back to the currency of
1771                         -- the funding source.
1772                         --
1773                         IF conv_attr_amount IS NULL THEN
1774                                 conv_attr_amount := attr_amount * acq.exchange_ratio(
1775                                         deb.currency_type, curr_credit_bal.currency_type );
1776                         END IF;
1777                         --
1778                         -- Insert a row to record the attribution
1779                         --
1780                         attrib_count := attrib_count + 1;
1781                         INSERT INTO acq.debit_attribution (
1782                                 id,
1783                                 fund_debit,
1784                                 debit_amount,
1785                                 funding_source_credit,
1786                                 credit_amount
1787                         ) VALUES (
1788                                 attrib_count,
1789                                 deb.id,
1790                                 attr_amount,
1791                                 curr_credit_bal.credit,
1792                                 conv_attr_amount
1793                         );
1794                         --
1795                         -- Subtract the attributed amount from the various balances
1796                         --
1797                         debit_balance := debit_balance - attr_amount;
1798                         curr_fund_source_bal.balance := curr_fund_source_bal.balance - conv_attr_amount;
1799                         --
1800                         IF curr_fund_source_bal.balance <= 0 THEN
1801                                 --
1802                                 -- This allocation is exhausted.  Delete it so
1803                                 -- that we don't waste time looking at it again.
1804                                 --
1805                                 DELETE FROM t_fund_source_bal
1806                                 WHERE
1807                                         fund = curr_fund_source_bal.fund
1808                                         AND source = curr_fund_source_bal.source;
1809                         ELSE
1810                                 UPDATE t_fund_source_bal
1811                                 SET balance = balance - conv_attr_amount
1812                                 WHERE
1813                                         fund = curr_fund_source_bal.fund
1814                                         AND source = curr_fund_source_bal.source;
1815                         END IF;
1816                         --
1817                         IF curr_credit_bal.balance <= 0 THEN
1818                                 --
1819                                 -- This funding source credit is exhausted.  Delete it
1820                                 -- so that we don't waste time looking at it again.
1821                                 --
1822                                 --DELETE FROM t_credit
1823                                 --WHERE
1824                                 --      credit = curr_credit_bal.credit;
1825                                 --
1826                                 DELETE FROM t_fund_credit
1827                                 WHERE
1828                                         credit = curr_credit_bal.credit;
1829                         ELSE
1830                                 UPDATE t_credit
1831                                 SET balance = curr_credit_bal.balance
1832                                 WHERE
1833                                         credit = curr_credit_bal.credit;
1834                         END IF;
1835                         --
1836                         -- Are we done with this debit yet?
1837                         --
1838                         IF debit_balance <= 0 THEN
1839                                 EXIT;       -- We've fully attributed this debit; stop looking at credits.
1840                         END IF;
1841                 END LOOP;       -- End loop over credits
1842                 --
1843                 IF debit_balance <> 0 THEN
1844                         --
1845                         -- We weren't able to attribute this debit, or at least not
1846                         -- all of it.  Insert a row for the unattributed balance.
1847                         --
1848                         attrib_count := attrib_count + 1;
1849                         INSERT INTO acq.debit_attribution (
1850                                 id,
1851                                 fund_debit,
1852                                 debit_amount,
1853                                 funding_source_credit,
1854                                 credit_amount
1855                         ) VALUES (
1856                                 attrib_count,
1857                                 deb.id,
1858                                 debit_balance,
1859                                 NULL,
1860                                 NULL
1861                         );
1862                 END IF;
1863         END LOOP;   -- End of loop over debits
1864 END;
1865 $$ LANGUAGE 'plpgsql';
1866
1867 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_unit(
1868         old_year INTEGER,
1869         user_id INTEGER,
1870         org_unit_id INTEGER
1871 ) RETURNS VOID AS $$
1872 DECLARE
1873 --
1874 new_id      INT;
1875 old_fund    RECORD;
1876 org_found   BOOLEAN;
1877 --
1878 BEGIN
1879         --
1880         -- Sanity checks
1881         --
1882         IF old_year IS NULL THEN
1883                 RAISE EXCEPTION 'Input year argument is NULL';
1884         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1885                 RAISE EXCEPTION 'Input year is out of range';
1886         END IF;
1887         --
1888         IF user_id IS NULL THEN
1889                 RAISE EXCEPTION 'Input user id argument is NULL';
1890         END IF;
1891         --
1892         IF org_unit_id IS NULL THEN
1893                 RAISE EXCEPTION 'Org unit id argument is NULL';
1894         ELSE
1895                 SELECT TRUE INTO org_found
1896                 FROM actor.org_unit
1897                 WHERE id = org_unit_id;
1898                 --
1899                 IF org_found IS NULL THEN
1900                         RAISE EXCEPTION 'Org unit id is invalid';
1901                 END IF;
1902         END IF;
1903         --
1904         -- Loop over the applicable funds
1905         --
1906         FOR old_fund in SELECT * FROM acq.fund
1907         WHERE
1908                 year = old_year
1909                 AND propagate
1910                 AND org = org_unit_id
1911         LOOP
1912                 BEGIN
1913                         INSERT INTO acq.fund (
1914                                 org,
1915                                 name,
1916                                 year,
1917                                 currency_type,
1918                                 code,
1919                                 rollover,
1920                                 propagate,
1921                                 balance_warning_percent,
1922                                 balance_stop_percent
1923                         ) VALUES (
1924                                 old_fund.org,
1925                                 old_fund.name,
1926                                 old_year + 1,
1927                                 old_fund.currency_type,
1928                                 old_fund.code,
1929                                 old_fund.rollover,
1930                                 true,
1931                                 old_fund.balance_warning_percent,
1932                                 old_fund.balance_stop_percent
1933                         )
1934                         RETURNING id INTO new_id;
1935                 EXCEPTION
1936                         WHEN unique_violation THEN
1937                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
1938                                 CONTINUE;
1939                 END;
1940                 --RAISE NOTICE 'Propagating fund % to fund %',
1941                 --      old_fund.code, new_id;
1942         END LOOP;
1943 END;
1944 $$ LANGUAGE plpgsql;
1945
1946 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_tree(
1947         old_year INTEGER,
1948         user_id INTEGER,
1949         org_unit_id INTEGER
1950 ) RETURNS VOID AS $$
1951 DECLARE
1952 --
1953 new_id      INT;
1954 old_fund    RECORD;
1955 org_found   BOOLEAN;
1956 --
1957 BEGIN
1958         --
1959         -- Sanity checks
1960         --
1961         IF old_year IS NULL THEN
1962                 RAISE EXCEPTION 'Input year argument is NULL';
1963         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1964                 RAISE EXCEPTION 'Input year is out of range';
1965         END IF;
1966         --
1967         IF user_id IS NULL THEN
1968                 RAISE EXCEPTION 'Input user id argument is NULL';
1969         END IF;
1970         --
1971         IF org_unit_id IS NULL THEN
1972                 RAISE EXCEPTION 'Org unit id argument is NULL';
1973         ELSE
1974                 SELECT TRUE INTO org_found
1975                 FROM actor.org_unit
1976                 WHERE id = org_unit_id;
1977                 --
1978                 IF org_found IS NULL THEN
1979                         RAISE EXCEPTION 'Org unit id is invalid';
1980                 END IF;
1981         END IF;
1982         --
1983         -- Loop over the applicable funds
1984         --
1985         FOR old_fund in SELECT * FROM acq.fund
1986         WHERE
1987                 year = old_year
1988                 AND propagate
1989                 AND org in (
1990                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
1991                 )
1992         LOOP
1993                 BEGIN
1994                         INSERT INTO acq.fund (
1995                                 org,
1996                                 name,
1997                                 year,
1998                                 currency_type,
1999                                 code,
2000                                 rollover,
2001                                 propagate,
2002                                 balance_warning_percent,
2003                                 balance_stop_percent
2004                         ) VALUES (
2005                                 old_fund.org,
2006                                 old_fund.name,
2007                                 old_year + 1,
2008                                 old_fund.currency_type,
2009                                 old_fund.code,
2010                                 old_fund.rollover,
2011                                 true,
2012                                 old_fund.balance_warning_percent,
2013                                 old_fund.balance_stop_percent
2014                         )
2015                         RETURNING id INTO new_id;
2016                 EXCEPTION
2017                         WHEN unique_violation THEN
2018                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
2019                                 CONTINUE;
2020                 END;
2021                 --RAISE NOTICE 'Propagating fund % to fund %',
2022                 --      old_fund.code, new_id;
2023         END LOOP;
2024 END;
2025 $$ LANGUAGE plpgsql;
2026
2027 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_unit(
2028         old_year INTEGER,
2029         user_id INTEGER,
2030         org_unit_id INTEGER
2031 ) RETURNS VOID AS $$
2032 DECLARE
2033 --
2034 new_fund    INT;
2035 new_year    INT := old_year + 1;
2036 org_found   BOOL;
2037 xfer_amount NUMERIC;
2038 roll_fund   RECORD;
2039 deb         RECORD;
2040 detail      RECORD;
2041 --
2042 BEGIN
2043         --
2044         -- Sanity checks
2045         --
2046         IF old_year IS NULL THEN
2047                 RAISE EXCEPTION 'Input year argument is NULL';
2048     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
2049         RAISE EXCEPTION 'Input year is out of range';
2050         END IF;
2051         --
2052         IF user_id IS NULL THEN
2053                 RAISE EXCEPTION 'Input user id argument is NULL';
2054         END IF;
2055         --
2056         IF org_unit_id IS NULL THEN
2057                 RAISE EXCEPTION 'Org unit id argument is NULL';
2058         ELSE
2059                 --
2060                 -- Validate the org unit
2061                 --
2062                 SELECT TRUE
2063                 INTO org_found
2064                 FROM actor.org_unit
2065                 WHERE id = org_unit_id;
2066                 --
2067                 IF org_found IS NULL THEN
2068                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
2069                 END IF;
2070         END IF;
2071         --
2072         -- Loop over the propagable funds to identify the details
2073         -- from the old fund plus the id of the new one, if it exists.
2074         --
2075         FOR roll_fund in
2076         SELECT
2077             oldf.id AS old_fund,
2078             oldf.org,
2079             oldf.name,
2080             oldf.currency_type,
2081             oldf.code,
2082                 oldf.rollover,
2083             newf.id AS new_fund_id
2084         FROM
2085         acq.fund AS oldf
2086         LEFT JOIN acq.fund AS newf
2087                 ON ( oldf.code = newf.code )
2088         WHERE
2089                     oldf.org = org_unit_id
2090                 and oldf.year = old_year
2091                 and oldf.propagate
2092         and newf.year = new_year
2093         LOOP
2094                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
2095                 --
2096                 IF roll_fund.new_fund_id IS NULL THEN
2097                         --
2098                         -- The old fund hasn't been propagated yet.  Propagate it now.
2099                         --
2100                         INSERT INTO acq.fund (
2101                                 org,
2102                                 name,
2103                                 year,
2104                                 currency_type,
2105                                 code,
2106                                 rollover,
2107                                 propagate,
2108                                 balance_warning_percent,
2109                                 balance_stop_percent
2110                         ) VALUES (
2111                                 roll_fund.org,
2112                                 roll_fund.name,
2113                                 new_year,
2114                                 roll_fund.currency_type,
2115                                 roll_fund.code,
2116                                 true,
2117                                 true,
2118                                 roll_fund.balance_warning_percent,
2119                                 roll_fund.balance_stop_percent
2120                         )
2121                         RETURNING id INTO new_fund;
2122                 ELSE
2123                         new_fund = roll_fund.new_fund_id;
2124                 END IF;
2125                 --
2126                 -- Determine the amount to transfer
2127                 --
2128                 SELECT amount
2129                 INTO xfer_amount
2130                 FROM acq.fund_spent_balance
2131                 WHERE fund = roll_fund.old_fund;
2132                 --
2133                 IF xfer_amount <> 0 THEN
2134                         IF roll_fund.rollover THEN
2135                                 --
2136                                 -- Transfer balance from old fund to new
2137                                 --
2138                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
2139                                 --
2140                                 PERFORM acq.transfer_fund(
2141                                         roll_fund.old_fund,
2142                                         xfer_amount,
2143                                         new_fund,
2144                                         xfer_amount,
2145                                         user_id,
2146                                         'Rollover'
2147                                 );
2148                         ELSE
2149                                 --
2150                                 -- Transfer balance from old fund to the void
2151                                 --
2152                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
2153                                 --
2154                                 PERFORM acq.transfer_fund(
2155                                         roll_fund.old_fund,
2156                                         xfer_amount,
2157                                         NULL,
2158                                         NULL,
2159                                         user_id,
2160                                         'Rollover'
2161                                 );
2162                         END IF;
2163                 END IF;
2164                 --
2165                 IF roll_fund.rollover THEN
2166                         --
2167                         -- Move any lineitems from the old fund to the new one
2168                         -- where the associated debit is an encumbrance.
2169                         --
2170                         -- Any other tables tying expenditure details to funds should
2171                         -- receive similar treatment.  At this writing there are none.
2172                         --
2173                         UPDATE acq.lineitem_detail
2174                         SET fund = new_fund
2175                         WHERE
2176                         fund = roll_fund.old_fund -- this condition may be redundant
2177                         AND fund_debit in
2178                         (
2179                                 SELECT id
2180                                 FROM acq.fund_debit
2181                                 WHERE
2182                                 fund = roll_fund.old_fund
2183                                 AND encumbrance
2184                         );
2185                         --
2186                         -- Move encumbrance debits from the old fund to the new fund
2187                         --
2188                         UPDATE acq.fund_debit
2189                         SET fund = new_fund
2190                         wHERE
2191                                 fund = roll_fund.old_fund
2192                                 AND encumbrance;
2193                 END IF;
2194                 --
2195                 -- Mark old fund as inactive, now that we've closed it
2196                 --
2197                 UPDATE acq.fund
2198                 SET active = FALSE
2199                 WHERE id = roll_fund.old_fund;
2200         END LOOP;
2201 END;
2202 $$ LANGUAGE plpgsql;
2203
2204 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_tree(
2205         old_year INTEGER,
2206         user_id INTEGER,
2207         org_unit_id INTEGER
2208 ) RETURNS VOID AS $$
2209 DECLARE
2210 --
2211 new_fund    INT;
2212 new_year    INT := old_year + 1;
2213 org_found   BOOL;
2214 xfer_amount NUMERIC;
2215 roll_fund   RECORD;
2216 deb         RECORD;
2217 detail      RECORD;
2218 --
2219 BEGIN
2220         --
2221         -- Sanity checks
2222         --
2223         IF old_year IS NULL THEN
2224                 RAISE EXCEPTION 'Input year argument is NULL';
2225     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
2226         RAISE EXCEPTION 'Input year is out of range';
2227         END IF;
2228         --
2229         IF user_id IS NULL THEN
2230                 RAISE EXCEPTION 'Input user id argument is NULL';
2231         END IF;
2232         --
2233         IF org_unit_id IS NULL THEN
2234                 RAISE EXCEPTION 'Org unit id argument is NULL';
2235         ELSE
2236                 --
2237                 -- Validate the org unit
2238                 --
2239                 SELECT TRUE
2240                 INTO org_found
2241                 FROM actor.org_unit
2242                 WHERE id = org_unit_id;
2243                 --
2244                 IF org_found IS NULL THEN
2245                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
2246                 END IF;
2247         END IF;
2248         --
2249         -- Loop over the propagable funds to identify the details
2250         -- from the old fund plus the id of the new one, if it exists.
2251         --
2252         FOR roll_fund in
2253         SELECT
2254             oldf.id AS old_fund,
2255             oldf.org,
2256             oldf.name,
2257             oldf.currency_type,
2258             oldf.code,
2259                 oldf.rollover,
2260             newf.id AS new_fund_id
2261         FROM
2262         acq.fund AS oldf
2263         LEFT JOIN acq.fund AS newf
2264                 ON ( oldf.code = newf.code )
2265         WHERE
2266                     oldf.year = old_year
2267                 AND oldf.propagate
2268         AND newf.year = new_year
2269                 AND oldf.org in (
2270                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
2271                 )
2272         LOOP
2273                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
2274                 --
2275                 IF roll_fund.new_fund_id IS NULL THEN
2276                         --
2277                         -- The old fund hasn't been propagated yet.  Propagate it now.
2278                         --
2279                         INSERT INTO acq.fund (
2280                                 org,
2281                                 name,
2282                                 year,
2283                                 currency_type,
2284                                 code,
2285                                 rollover,
2286                                 propagate,
2287                                 balance_warning_percent,
2288                                 balance_stop_percent
2289                         ) VALUES (
2290                                 roll_fund.org,
2291                                 roll_fund.name,
2292                                 new_year,
2293                                 roll_fund.currency_type,
2294                                 roll_fund.code,
2295                                 true,
2296                                 true,
2297                                 roll_fund.balance_warning_percent,
2298                                 roll_fund.balance_stop_percent
2299                         )
2300                         RETURNING id INTO new_fund;
2301                 ELSE
2302                         new_fund = roll_fund.new_fund_id;
2303                 END IF;
2304                 --
2305                 -- Determine the amount to transfer
2306                 --
2307                 SELECT amount
2308                 INTO xfer_amount
2309                 FROM acq.fund_spent_balance
2310                 WHERE fund = roll_fund.old_fund;
2311                 --
2312                 IF xfer_amount <> 0 THEN
2313                         IF roll_fund.rollover THEN
2314                                 --
2315                                 -- Transfer balance from old fund to new
2316                                 --
2317                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
2318                                 --
2319                                 PERFORM acq.transfer_fund(
2320                                         roll_fund.old_fund,
2321                                         xfer_amount,
2322                                         new_fund,
2323                                         xfer_amount,
2324                                         user_id,
2325                                         'Rollover'
2326                                 );
2327                         ELSE
2328                                 --
2329                                 -- Transfer balance from old fund to the void
2330                                 --
2331                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
2332                                 --
2333                                 PERFORM acq.transfer_fund(
2334                                         roll_fund.old_fund,
2335                                         xfer_amount,
2336                                         NULL,
2337                                         NULL,
2338                                         user_id,
2339                                         'Rollover'
2340                                 );
2341                         END IF;
2342                 END IF;
2343                 --
2344                 IF roll_fund.rollover THEN
2345                         --
2346                         -- Move any lineitems from the old fund to the new one
2347                         -- where the associated debit is an encumbrance.
2348                         --
2349                         -- Any other tables tying expenditure details to funds should
2350                         -- receive similar treatment.  At this writing there are none.
2351                         --
2352                         UPDATE acq.lineitem_detail
2353                         SET fund = new_fund
2354                         WHERE
2355                         fund = roll_fund.old_fund -- this condition may be redundant
2356                         AND fund_debit in
2357                         (
2358                                 SELECT id
2359                                 FROM acq.fund_debit
2360                                 WHERE
2361                                 fund = roll_fund.old_fund
2362                                 AND encumbrance
2363                         );
2364                         --
2365                         -- Move encumbrance debits from the old fund to the new fund
2366                         --
2367                         UPDATE acq.fund_debit
2368                         SET fund = new_fund
2369                         wHERE
2370                                 fund = roll_fund.old_fund
2371                                 AND encumbrance;
2372                 END IF;
2373                 --
2374                 -- Mark old fund as inactive, now that we've closed it
2375                 --
2376                 UPDATE acq.fund
2377                 SET active = FALSE
2378                 WHERE id = roll_fund.old_fund;
2379         END LOOP;
2380 END;
2381 $$ LANGUAGE plpgsql;
2382
2383 CREATE OR REPLACE VIEW acq.funding_source_credit_total AS
2384     SELECT  funding_source,
2385             SUM(amount) AS amount
2386       FROM  acq.funding_source_credit
2387       GROUP BY 1;
2388
2389 CREATE OR REPLACE VIEW acq.funding_source_allocation_total AS
2390     SELECT  funding_source,
2391             SUM(a.amount)::NUMERIC(100,2) AS amount
2392     FROM  acq.fund_allocation a
2393     GROUP BY 1;
2394
2395 CREATE OR REPLACE VIEW acq.funding_source_balance AS
2396     SELECT  COALESCE(c.funding_source, a.funding_source) AS funding_source,
2397             SUM(COALESCE(c.amount,0.0) - COALESCE(a.amount,0.0))::NUMERIC(100,2) AS amount
2398       FROM  acq.funding_source_credit_total c
2399             FULL JOIN acq.funding_source_allocation_total a USING (funding_source)
2400       GROUP BY 1;
2401
2402 CREATE OR REPLACE VIEW acq.fund_allocation_total AS
2403     SELECT  fund,
2404             SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
2405     FROM acq.fund_allocation a
2406          JOIN acq.fund f ON (a.fund = f.id)
2407          JOIN acq.funding_source s ON (a.funding_source = s.id)
2408     GROUP BY 1;
2409
2410 CREATE OR REPLACE VIEW acq.fund_debit_total AS
2411     SELECT  fund.id AS fund,
2412             fund_debit.encumbrance AS encumbrance,
2413                         SUM( COALESCE( fund_debit.amount, 0 ) ) AS amount
2414       FROM acq.fund AS fund
2415             LEFT JOIN acq.fund_debit AS fund_debit
2416                 ON ( fund.id = fund_debit.fund )
2417       GROUP BY 1,2;
2418
2419 CREATE OR REPLACE VIEW acq.fund_encumbrance_total AS
2420     SELECT  fund,
2421             SUM(amount) AS amount
2422       FROM  acq.fund_debit_total
2423       WHERE encumbrance IS TRUE
2424       GROUP BY 1;
2425
2426 CREATE OR REPLACE VIEW acq.fund_spent_total AS
2427     SELECT  fund,
2428             SUM(amount) AS amount
2429       FROM  acq.fund_debit_total
2430       WHERE encumbrance IS FALSE
2431       GROUP BY 1;
2432
2433 CREATE OR REPLACE VIEW acq.fund_combined_balance AS
2434     SELECT  c.fund,
2435             c.amount - COALESCE(d.amount,0.0) AS amount
2436       FROM  acq.fund_allocation_total c
2437             LEFT JOIN acq.fund_debit_total d USING (fund);
2438
2439 CREATE OR REPLACE VIEW acq.fund_spent_balance AS
2440     SELECT  c.fund,
2441             c.amount - COALESCE(d.amount,0.0) AS amount
2442       FROM  acq.fund_allocation_total c
2443             LEFT JOIN acq.fund_spent_total d USING (fund);
2444
2445 -- For each fund: the total allocation from all sources, in the
2446 -- currency of the fund (or 0 if there are no allocations)
2447
2448 CREATE VIEW acq.all_fund_allocation_total AS
2449 SELECT
2450     f.id AS fund,
2451     COALESCE( SUM( a.amount * acq.exchange_ratio(
2452         s.currency_type, f.currency_type))::numeric(100,2), 0 )
2453     AS amount
2454 FROM
2455     acq.fund f
2456         LEFT JOIN acq.fund_allocation a
2457             ON a.fund = f.id
2458         LEFT JOIN acq.funding_source s
2459             ON a.funding_source = s.id
2460 GROUP BY
2461     f.id;
2462
2463 -- For every fund: the total encumbrances (or 0 if none),
2464 -- in the currency of the fund.
2465
2466 CREATE VIEW acq.all_fund_encumbrance_total AS
2467 SELECT
2468         f.id AS fund,
2469         COALESCE( encumb.amount, 0 ) AS amount
2470 FROM
2471         acq.fund AS f
2472                 LEFT JOIN (
2473                         SELECT
2474                                 fund,
2475                                 sum( amount ) AS amount
2476                         FROM
2477                                 acq.fund_debit
2478                         WHERE
2479                                 encumbrance
2480                         GROUP BY fund
2481                 ) AS encumb
2482                         ON f.id = encumb.fund;
2483
2484 -- For every fund: the total spent (or 0 if none),
2485 -- in the currency of the fund.
2486
2487 CREATE VIEW acq.all_fund_spent_total AS
2488 SELECT
2489     f.id AS fund,
2490     COALESCE( spent.amount, 0 ) AS amount
2491 FROM
2492     acq.fund AS f
2493         LEFT JOIN (
2494             SELECT
2495                 fund,
2496                 sum( amount ) AS amount
2497             FROM
2498                 acq.fund_debit
2499             WHERE
2500                 NOT encumbrance
2501             GROUP BY fund
2502         ) AS spent
2503             ON f.id = spent.fund;
2504
2505 -- For each fund: the amount not yet spent, in the currency
2506 -- of the fund.  May include encumbrances.
2507
2508 CREATE VIEW acq.all_fund_spent_balance AS
2509 SELECT
2510         c.fund,
2511         c.amount - d.amount AS amount
2512 FROM acq.all_fund_allocation_total c
2513     LEFT JOIN acq.all_fund_spent_total d USING (fund);
2514
2515 -- For each fund: the amount neither spent nor encumbered,
2516 -- in the currency of the fund
2517
2518 CREATE VIEW acq.all_fund_combined_balance AS
2519 SELECT
2520      a.fund,
2521      a.amount - COALESCE( c.amount, 0 ) AS amount
2522 FROM
2523      acq.all_fund_allocation_total a
2524         LEFT OUTER JOIN (
2525             SELECT
2526                 fund,
2527                 SUM( amount ) AS amount
2528             FROM
2529                 acq.fund_debit
2530             GROUP BY
2531                 fund
2532         ) AS c USING ( fund );
2533
2534 CREATE TABLE acq.claim_type (
2535         id             SERIAL           PRIMARY KEY,
2536         org_unit       INT              NOT NULL REFERENCES actor.org_unit(id)
2537                                                  DEFERRABLE INITIALLY DEFERRED,
2538         code           TEXT             NOT NULL,
2539         description    TEXT             NOT NULL,
2540         CONSTRAINT claim_type_once_per_org UNIQUE ( org_unit, code )
2541 );
2542
2543 CREATE TABLE acq.claim (
2544         id             SERIAL           PRIMARY KEY,
2545         type           INT              NOT NULL REFERENCES acq.claim_type
2546                                                  DEFERRABLE INITIALLY DEFERRED,
2547         lineitem_detail BIGINT          NOT NULL REFERENCES acq.lineitem_detail
2548                                                  DEFERRABLE INITIALLY DEFERRED
2549 );
2550
2551 CREATE INDEX claim_lid_idx ON acq.claim( lineitem_detail );
2552
2553 CREATE TABLE acq.claim_event (
2554         id             BIGSERIAL        PRIMARY KEY,
2555         type           INT              NOT NULL REFERENCES acq.claim_event_type
2556                                                  DEFERRABLE INITIALLY DEFERRED,
2557         claim          SERIAL           NOT NULL REFERENCES acq.claim
2558                                                  DEFERRABLE INITIALLY DEFERRED,
2559         event_date     TIMESTAMPTZ      NOT NULL DEFAULT now(),
2560         creator        INT              NOT NULL REFERENCES actor.usr
2561                                                  DEFERRABLE INITIALLY DEFERRED,
2562         note           TEXT
2563 );
2564
2565 CREATE INDEX claim_event_claim_date_idx ON acq.claim_event( claim, event_date );
2566
2567 COMMIT;