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