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