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