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