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