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