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