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