]> git.evergreen-ils.org Git - working/Evergreen.git/blob - Open-ILS/src/sql/Pg/200.schema.acq.sql
1. Back off the function acq.attribute_debits, along with three
[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.provider (
33     id                  SERIAL  PRIMARY KEY,
34     name                TEXT    NOT NULL,
35     owner               INT     NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
36     currency_type       TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
37     code                TEXT    NOT NULL,
38     holding_tag         TEXT,
39     san                 TEXT,
40     edi_default         INT,          -- REFERENCES acq.edi_account (id) DEFERRABLE INITIALLY DEFERRED
41     CONSTRAINT provider_name_once_per_owner UNIQUE (name,owner),
42         CONSTRAINT code_once_per_owner UNIQUE (code, owner)
43 );
44
45 CREATE TABLE acq.provider_holding_subfield_map (
46     id          SERIAL  PRIMARY KEY,
47     provider    INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
48     name        TEXT    NOT NULL, -- barcode, price, etc
49     subfield    TEXT    NOT NULL,
50     CONSTRAINT name_once_per_provider UNIQUE (provider,name)
51 );
52
53 CREATE TABLE acq.provider_address (
54         id              SERIAL  PRIMARY KEY,
55         valid           BOOL    NOT NULL DEFAULT TRUE,
56         address_type    TEXT,
57     provider    INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
58         street1         TEXT    NOT NULL,
59         street2         TEXT,
60         city            TEXT    NOT NULL,
61         county          TEXT,
62         state           TEXT    NOT NULL,
63         country         TEXT    NOT NULL,
64         post_code       TEXT    NOT NULL
65 );
66
67 CREATE TABLE acq.provider_contact (
68         id              SERIAL  PRIMARY KEY,
69     provider    INT NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
70     name    TEXT NULL NULL,
71     role    TEXT, -- free-form.. e.g. "our sales guy"
72     email   TEXT,
73     phone   TEXT
74 );
75
76 CREATE TABLE acq.provider_contact_address (
77         id                      SERIAL  PRIMARY KEY,
78         valid                   BOOL    NOT NULL DEFAULT TRUE,
79         address_type    TEXT,
80         contact                 INT         NOT NULL REFERENCES acq.provider_contact (id) DEFERRABLE INITIALLY DEFERRED,
81         street1                 TEXT    NOT NULL,
82         street2                 TEXT,
83         city                    TEXT    NOT NULL,
84         county                  TEXT,
85         state                   TEXT    NOT NULL,
86         country                 TEXT    NOT NULL,
87         post_code               TEXT    NOT NULL
88 );
89
90
91 CREATE TABLE acq.funding_source (
92         id              SERIAL  PRIMARY KEY,
93         name            TEXT    NOT NULL,
94         owner           INT     NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
95         currency_type   TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
96         code            TEXT    UNIQUE,
97         CONSTRAINT funding_source_name_once_per_owner UNIQUE (name,owner)
98 );
99
100 CREATE TABLE acq.funding_source_credit (
101         id      SERIAL     PRIMARY KEY,
102         funding_source INT      NOT NULL REFERENCES acq.funding_source (id) DEFERRABLE INITIALLY DEFERRED,
103         amount         NUMERIC  NOT NULL,
104         note           TEXT,
105         deadline_date  TIMESTAMPTZ,
106         effective_date TIMESTAMPTZ NOT NULL default now()
107 );
108
109 CREATE VIEW acq.ordered_funding_source_credit AS
110     SELECT
111         CASE WHEN deadline_date IS NULL THEN
112             2
113         ELSE
114             1
115         END AS sort_priority,
116         CASE WHEN deadline_date IS NULL THEN
117             effective_date
118         ELSE
119             deadline_date
120         END AS sort_date,
121         id,
122         funding_source,
123         amount,
124         note
125     FROM
126         acq.funding_source_credit;
127
128 COMMENT ON VIEW acq.ordered_funding_source_credit IS $$
129 /*
130  * Copyright (C) 2009  Georgia Public Library Service
131  * Scott McKellar <scott@gmail.com>
132  *
133  * The acq.ordered_funding_source_credit view is a prioritized
134  * ordering of funding source credits.  When ordered by the first
135  * three columns, this view defines the order in which the various
136  * credits are to be tapped for spending, subject to the allocations
137  * in the acq.fund_allocation table.
138  *
139  * The first column reflects the principle that we should spend
140  * money with deadlines before spending money without deadlines.
141  *
142  * The second column reflects the principle that we should spend the
143  * oldest money first.  For money with deadlines, that means that we
144  * spend first from the credit with the earliest deadline.  For
145  * money without deadlines, we spend first from the credit with the
146  * earliest effective date.
147  *
148  * The third column is a tie breaker to ensure a consistent
149  * ordering.
150  *
151  * ****
152  *
153  * This program is free software; you can redistribute it and/or
154  * modify it under the terms of the GNU General Public License
155  * as published by the Free Software Foundation; either version 2
156  * of the License, or (at your option) any later version.
157  *
158  * This program is distributed in the hope that it will be useful,
159  * but WITHOUT ANY WARRANTY; without even the implied warranty of
160  * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
161  * GNU General Public License for more details.
162  */
163 $$;
164
165 CREATE TABLE acq.fund (
166     id              SERIAL  PRIMARY KEY,
167     org             INT     NOT NULL REFERENCES actor.org_unit (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
168     name            TEXT    NOT NULL,
169     year            INT     NOT NULL DEFAULT EXTRACT( YEAR FROM NOW() ),
170     currency_type   TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
171     code            TEXT,
172         rollover        BOOL    NOT NULL DEFAULT FALSE,
173         propagate       BOOL    NOT NULL DEFAULT TRUE,
174         active          BOOL    NOT NULL DEFAULT TRUE,
175     CONSTRAINT name_once_per_org_year UNIQUE (org,name,year),
176     CONSTRAINT code_once_per_org_year UNIQUE (org, code, year),
177         CONSTRAINT acq_fund_rollover_implies_propagate CHECK ( propagate OR NOT rollover )
178 );
179
180 CREATE TABLE acq.fund_debit (
181         id                      SERIAL  PRIMARY KEY,
182         fund                    INT     NOT NULL REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
183         origin_amount           NUMERIC NOT NULL,  -- pre-exchange-rate amount
184         origin_currency_type    TEXT    NOT NULL REFERENCES acq.currency_type (code) DEFERRABLE INITIALLY DEFERRED,
185         amount                  NUMERIC NOT NULL,
186         encumbrance             BOOL    NOT NULL DEFAULT TRUE,
187         debit_type              TEXT    NOT NULL,
188         xfer_destination        INT     REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
189         create_time     TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
190 );
191
192 CREATE TABLE acq.fund_allocation (
193     id          SERIAL  PRIMARY KEY,
194     funding_source        INT     NOT NULL REFERENCES acq.funding_source (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
195     fund        INT     NOT NULL REFERENCES acq.fund (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
196     amount      NUMERIC NOT NULL,
197     allocator   INT NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
198     note        TEXT,
199         create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
200 );
201 CREATE INDEX fund_alloc_allocator_idx ON acq.fund_allocation ( allocator );
202
203 CREATE TABLE acq.fund_allocation_percent
204 (
205     id                   SERIAL            PRIMARY KEY,
206     funding_source       INT               NOT NULL REFERENCES acq.funding_source
207                                                DEFERRABLE INITIALLY DEFERRED,
208     org                  INT               NOT NULL REFERENCES actor.org_unit
209                                                DEFERRABLE INITIALLY DEFERRED,
210     fund_code            TEXT,
211     percent              NUMERIC           NOT NULL,
212     allocator            INTEGER           NOT NULL REFERENCES actor.usr
213                                                DEFERRABLE INITIALLY DEFERRED,
214     note                 TEXT,
215     create_time          TIMESTAMPTZ       NOT NULL DEFAULT now(),
216     CONSTRAINT logical_key UNIQUE( funding_source, org, fund_code ),
217     CONSTRAINT percentage_range CHECK( percent >= 0 AND percent <= 100 )
218 );
219
220 -- Trigger function to validate combination of org_unit and fund_code
221
222 CREATE OR REPLACE FUNCTION acq.fund_alloc_percent_val()
223 RETURNS TRIGGER AS $$
224 --
225 DECLARE
226 --
227 dummy int := 0;
228 --
229 BEGIN
230     SELECT
231         1
232     INTO
233         dummy
234     FROM
235         acq.fund
236     WHERE
237         org = NEW.org
238         AND code = NEW.fund_code
239         LIMIT 1;
240     --
241     IF dummy = 1 then
242         RETURN NEW;
243     ELSE
244         RAISE EXCEPTION 'No fund exists for org % and code %', NEW.org, NEW.fund_code;
245     END IF;
246 END;
247 $$ LANGUAGE plpgsql;
248
249 CREATE TRIGGER acq_fund_alloc_percent_val_trig
250     BEFORE INSERT OR UPDATE ON acq.fund_allocation_percent
251     FOR EACH ROW EXECUTE PROCEDURE acq.fund_alloc_percent_val();
252
253 -- To do: trigger to verify that percentages don't add up to more than 100
254
255 CREATE OR REPLACE FUNCTION acq.fap_limit_100()
256 RETURNS TRIGGER AS $$
257 DECLARE
258 --
259 total_percent numeric;
260 --
261 BEGIN
262     SELECT
263         sum( percent )
264     INTO
265         total_percent
266     FROM
267         acq.fund_allocation_percent AS fap
268     WHERE
269         fap.funding_source = NEW.funding_source;
270     --
271     IF total_percent > 100 THEN
272         RAISE EXCEPTION 'Total percentages exceed 100 for funding_source %',
273             NEW.funding_source;
274     ELSE
275         RETURN NEW;
276     END IF;
277 END;
278 $$ LANGUAGE plpgsql;
279
280 CREATE TRIGGER acqfap_limit_100_trig
281     AFTER INSERT OR UPDATE ON acq.fund_allocation_percent
282     FOR EACH ROW EXECUTE PROCEDURE acq.fap_limit_100();
283
284 CREATE TABLE acq.picklist (
285         id              SERIAL                          PRIMARY KEY,
286         owner           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
287         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
288         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
289         org_unit        INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
290         name            TEXT                            NOT NULL,
291         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
292         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
293         CONSTRAINT name_once_per_owner UNIQUE (name,owner)
294 );
295 CREATE INDEX acq_picklist_owner_idx   ON acq.picklist ( owner );
296 CREATE INDEX acq_picklist_creator_idx ON acq.picklist ( creator );
297 CREATE INDEX acq_picklist_editor_idx  ON acq.picklist ( editor );
298
299 CREATE TABLE acq.purchase_order (
300         id              SERIAL                          PRIMARY KEY,
301         owner           INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
302         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
303         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
304         ordering_agency INT                             NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
305         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
306         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
307         provider        INT                             NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
308         state                   TEXT                                    NOT NULL DEFAULT 'new',
309         order_date              TIMESTAMP WITH TIME ZONE,
310         name                    TEXT                                    NOT NULL
311 );
312 CREATE INDEX po_owner_idx ON acq.purchase_order (owner);
313 CREATE INDEX po_provider_idx ON acq.purchase_order (provider);
314 CREATE INDEX po_state_idx ON acq.purchase_order (state);
315 CREATE INDEX po_creator_idx  ON acq.purchase_order ( creator );
316 CREATE INDEX po_editor_idx   ON acq.purchase_order ( editor );
317 CREATE INDEX acq_po_org_name_order_date_idx ON acq.purchase_order( ordering_agency, name, order_date );
318
319 -- The name should default to the id, as text.  We can't reference a column
320 -- in a DEFAULT clause, so we use a trigger:
321
322 CREATE OR REPLACE FUNCTION acq.purchase_order_name_default () RETURNS TRIGGER 
323 AS $$
324 BEGIN
325         IF NEW.name IS NULL THEN
326                 NEW.name := NEW.id::TEXT;
327         END IF;
328
329         RETURN NEW;
330 END;
331 $$ LANGUAGE PLPGSQL;
332
333 CREATE TRIGGER po_name_default_trg
334   BEFORE INSERT OR UPDATE ON acq.purchase_order
335   FOR EACH ROW EXECUTE PROCEDURE acq.purchase_order_name_default ();
336
337 -- The order name should be unique for a given ordering agency on a given order date
338 -- (truncated to midnight), but only where the order_date is not NULL.  Conceptually
339 -- this rule requires a check constraint with a subquery.  However you can't have a
340 -- subquery in a CHECK constraint, so we fake it with a trigger.
341
342 CREATE OR REPLACE FUNCTION acq.po_org_name_date_unique () RETURNS TRIGGER 
343 AS $$
344 DECLARE
345         collision INT;
346 BEGIN
347         --
348         -- If order_date is not null, then make sure we don't have a collision
349         -- on order_date (truncated to day), org, and name
350         --
351         IF NEW.order_date IS NULL THEN
352                 RETURN NEW;
353         END IF;
354         --
355         -- In the WHERE clause, we compare the order_dates without regard to time of day.
356         -- We use a pair of inequalities instead of comparing truncated dates so that the
357         -- query can do an indexed range scan.
358         --
359         SELECT 1 INTO collision
360         FROM acq.purchase_order
361         WHERE
362                 ordering_agency = NEW.ordering_agency
363                 AND name = NEW.name
364                 AND order_date >= date_trunc( 'day', NEW.order_date )
365                 AND order_date <  date_trunc( 'day', NEW.order_date ) + '1 day'::INTERVAL
366                 AND id <> NEW.id;
367         --
368         IF collision IS NULL THEN
369                 -- okay, no collision
370                 RETURN NEW;
371         ELSE
372                 -- collision; nip it in the bud
373                 RAISE EXCEPTION 'Colliding purchase orders: ordering_agency %, date %, name ''%''',
374                         NEW.ordering_agency, NEW.order_date, NEW.name;
375         END IF;
376 END;
377 $$ LANGUAGE PLPGSQL;
378
379 CREATE TRIGGER po_org_name_date_unique_trg
380   BEFORE INSERT OR UPDATE ON acq.purchase_order
381   FOR EACH ROW EXECUTE PROCEDURE acq.po_org_name_date_unique ();
382
383 CREATE TABLE acq.po_note (
384         id              SERIAL                          PRIMARY KEY,
385         purchase_order  INT                             NOT NULL REFERENCES acq.purchase_order (id) DEFERRABLE INITIALLY DEFERRED,
386         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
387         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
388         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
389         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
390         value           TEXT                            NOT NULL
391 );
392 CREATE INDEX po_note_po_idx ON acq.po_note (purchase_order);
393 CREATE INDEX acq_po_note_creator_idx  ON acq.po_note ( creator );
394 CREATE INDEX acq_po_note_editor_idx   ON acq.po_note ( editor );
395
396 CREATE TABLE acq.lineitem (
397         id                  BIGSERIAL                   PRIMARY KEY,
398         creator             INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
399         editor              INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
400         selector            INT                         NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
401         provider            INT                         REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED,
402         purchase_order      INT                         REFERENCES acq.purchase_order (id) DEFERRABLE INITIALLY DEFERRED,
403         picklist            INT                         REFERENCES acq.picklist (id) DEFERRABLE INITIALLY DEFERRED,
404         expected_recv_time  TIMESTAMP WITH TIME ZONE,
405         create_time         TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
406         edit_time           TIMESTAMP WITH TIME ZONE    NOT NULL DEFAULT NOW(),
407         marc                TEXT                        NOT NULL,
408         eg_bib_id           INT                         REFERENCES biblio.record_entry (id) DEFERRABLE INITIALLY DEFERRED,
409         source_label        TEXT,
410         item_count          INT                         NOT NULL DEFAULT 0,
411         state               TEXT                        NOT NULL DEFAULT 'new',
412     CONSTRAINT picklist_or_po CHECK (picklist IS NOT NULL OR purchase_order IS NOT NULL)
413 );
414 CREATE INDEX li_po_idx ON acq.lineitem (purchase_order);
415 CREATE INDEX li_pl_idx ON acq.lineitem (picklist);
416 CREATE INDEX li_creator_idx   ON acq.lineitem ( creator );
417 CREATE INDEX li_editor_idx    ON acq.lineitem ( editor );
418 CREATE INDEX li_selector_idx  ON acq.lineitem ( selector );
419
420 CREATE TABLE acq.lineitem_note (
421         id              SERIAL                          PRIMARY KEY,
422         lineitem        INT                             NOT NULL REFERENCES acq.lineitem (id) DEFERRABLE INITIALLY DEFERRED,
423         creator         INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
424         editor          INT                             NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
425         create_time     TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
426         edit_time       TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
427         value           TEXT                            NOT NULL
428 );
429 CREATE INDEX li_note_li_idx ON acq.lineitem_note (lineitem);
430 CREATE INDEX li_note_creator_idx  ON acq.lineitem_note ( creator );
431 CREATE INDEX li_note_editor_idx   ON acq.lineitem_note ( editor );
432
433 CREATE TABLE acq.lineitem_detail (
434     id          BIGSERIAL       PRIMARY KEY,
435     lineitem    INT         NOT NULL REFERENCES acq.lineitem (id) DEFERRABLE INITIALLY DEFERRED,
436     fund        INT         REFERENCES acq.fund (id) DEFERRABLE INITIALLY DEFERRED,
437     fund_debit  INT         REFERENCES acq.fund_debit (id) DEFERRABLE INITIALLY DEFERRED,
438     eg_copy_id  BIGINT      REFERENCES asset.copy (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
439     barcode     TEXT,
440     cn_label    TEXT,
441     note        TEXT,
442     collection_code TEXT,
443     circ_modifier   TEXT    REFERENCES config.circ_modifier (code) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
444     owning_lib  INT         REFERENCES actor.org_unit (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
445     location    INT         REFERENCES asset.copy_location (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
446     recv_time   TIMESTAMP WITH TIME ZONE
447 );
448
449 CREATE INDEX li_detail_li_idx ON acq.lineitem_detail (lineitem);
450
451 CREATE TABLE acq.lineitem_attr_definition (
452         id              BIGSERIAL       PRIMARY KEY,
453         code            TEXT            NOT NULL,
454         description     TEXT            NOT NULL,
455         remove          TEXT            NOT NULL DEFAULT '',
456         ident           BOOL            NOT NULL DEFAULT FALSE
457 );
458
459 CREATE TABLE acq.lineitem_marc_attr_definition (
460         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
461         xpath           TEXT            NOT NULL
462 ) INHERITS (acq.lineitem_attr_definition);
463
464 CREATE TABLE acq.lineitem_provider_attr_definition (
465         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
466         xpath           TEXT            NOT NULL,
467         provider        INT     NOT NULL REFERENCES acq.provider (id) DEFERRABLE INITIALLY DEFERRED
468 ) INHERITS (acq.lineitem_attr_definition);
469
470 CREATE TABLE acq.lineitem_generated_attr_definition (
471         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
472         xpath           TEXT            NOT NULL
473 ) INHERITS (acq.lineitem_attr_definition);
474
475 CREATE TABLE acq.lineitem_usr_attr_definition (
476         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
477         usr             INT     NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED
478 ) INHERITS (acq.lineitem_attr_definition);
479 CREATE INDEX li_usr_attr_def_usr_idx  ON acq.lineitem_usr_attr_definition ( usr );
480
481 CREATE TABLE acq.lineitem_local_attr_definition (
482         id              BIGINT  PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq')
483 ) INHERITS (acq.lineitem_attr_definition);
484
485 CREATE TABLE acq.lineitem_attr (
486         id              BIGSERIAL       PRIMARY KEY,
487         definition      BIGINT          NOT NULL,
488         lineitem        BIGINT          NOT NULL REFERENCES acq.lineitem (id) DEFERRABLE INITIALLY DEFERRED,
489         attr_type       TEXT            NOT NULL,
490         attr_name       TEXT            NOT NULL,
491         attr_value      TEXT            NOT NULL
492 );
493
494 CREATE INDEX li_attr_li_idx ON acq.lineitem_attr (lineitem);
495 CREATE INDEX li_attr_value_idx ON acq.lineitem_attr (attr_value);
496 CREATE INDEX li_attr_definition_idx ON acq.lineitem_attr (definition);
497
498
499 -- Seed data
500
501
502 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('title','Title of work','//*[@tag="245"]/*[contains("abcmnopr",@code)]');
503 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)]');
504 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('language','Language of work','//*[@tag="240"]/*[@code="l"][1]');
505 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('pagination','Pagination','//*[@tag="300"]/*[@code="a"][1]');
506 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath, remove ) VALUES ('isbn','ISBN','//*[@tag="020"]/*[@code="a"]', $r$(?:-|\s.+$)$r$);
507 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath, remove ) VALUES ('issn','ISSN','//*[@tag="022"]/*[@code="a"]', $r$(?:-|\s.+$)$r$);
508 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('price','Price','//*[@tag="020" or @tag="022"]/*[@code="c"][1]');
509 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('identifier','Identifier','//*[@tag="001"]');
510 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('publisher','Publisher','//*[@tag="260"]/*[@code="b"][1]');
511 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('pubdate','Publication Date','//*[@tag="260"]/*[@code="c"][1]');
512 INSERT INTO acq.lineitem_marc_attr_definition ( code, description, xpath ) VALUES ('edition','Edition','//*[@tag="250"]/*[@code="a"][1]');
513
514 INSERT INTO acq.lineitem_local_attr_definition ( code, description ) VALUES ('estimated_price', 'Estimated Price');
515
516
517 CREATE TABLE acq.distribution_formula (
518         id              SERIAL PRIMARY KEY,
519         owner   INT NOT NULL
520                         REFERENCES actor.org_unit(id) DEFERRABLE INITIALLY DEFERRED,
521         name    TEXT NOT NULL,
522         skip_count      INT NOT NULL DEFAULT 0,
523         CONSTRAINT acqdf_name_once_per_owner UNIQUE (name, owner)
524 );
525
526 CREATE TABLE acq.distribution_formula_entry (
527         id                      SERIAL PRIMARY KEY,
528         formula         INTEGER NOT NULL REFERENCES acq.distribution_formula(id)
529                                 ON DELETE CASCADE
530                                 DEFERRABLE INITIALLY DEFERRED,
531         position        INTEGER NOT NULL,
532         item_count      INTEGER NOT NULL,
533         owning_lib      INTEGER REFERENCES actor.org_unit(id)
534                                 DEFERRABLE INITIALLY DEFERRED,
535         location        INTEGER REFERENCES asset.copy_location(id),
536         CONSTRAINT acqdfe_lib_once_per_formula UNIQUE( formula, position ),
537         CONSTRAINT acqdfe_must_be_somewhere
538                                 CHECK( owning_lib IS NOT NULL OR location IS NOT NULL ) 
539 );
540
541 CREATE TABLE acq.fund_tag (
542         id              SERIAL PRIMARY KEY,
543         owner   INT NOT NULL
544                         REFERENCES actor.org_unit(id) DEFERRABLE INITIALLY DEFERRED,
545         name    TEXT NOT NULL,
546         CONSTRAINT acqft_tag_once_per_owner UNIQUE (name, owner)
547 );
548
549 CREATE TABLE acq.fund_tag_map (
550         id                      SERIAL PRIMARY KEY,
551         fund            INTEGER NOT NULL REFERENCES acq.fund(id)
552                                 DEFERRABLE INITIALLY DEFERRED,
553         tag         INTEGER REFERENCES acq.fund_tag(id)
554                                 ON DELETE CASCADE
555                                 DEFERRABLE INITIALLY DEFERRED,
556         CONSTRAINT acqftm_fund_once_per_tag UNIQUE( fund, tag )
557 );
558
559 CREATE TABLE acq.fund_transfer (
560     id               SERIAL         PRIMARY KEY,
561     src_fund         INT            NOT NULL REFERENCES acq.fund( id )
562                                     DEFERRABLE INITIALLY DEFERRED,
563     src_amount       NUMERIC        NOT NULL,
564     dest_fund        INT            NOT NULL REFERENCES acq.fund( id )
565                                     DEFERRABLE INITIALLY DEFERRED,
566     dest_amount      NUMERIC        NOT NULL,
567     transfer_time    TIMESTAMPTZ    NOT NULL DEFAULT now(),
568     transfer_user    INT            NOT NULL REFERENCES actor.usr( id )
569                                     DEFERRABLE INITIALLY DEFERRED,
570     note             TEXT,
571         funding_source_credit INT       NOT NULL REFERENCES acq.funding_source_credit( id )
572                                     DEFERRABLE INITIALLY DEFERRED
573 );
574
575 CREATE INDEX acqftr_usr_idx
576 ON acq.fund_transfer( transfer_user );
577
578 COMMENT ON TABLE acq.fund_transfer IS $$
579 /*
580  * Copyright (C) 2009  Georgia Public Library Service
581  * Scott McKellar <scott@esilibrary.com>
582  *
583  * Fund Transfer
584  *
585  * Each row represents the transfer of money from a source fund
586  * to a destination fund.  There should be corresponding entries
587  * in acq.fund_allocation.  The purpose of acq.fund_transfer is
588  * to record how much money moved from which fund to which other
589  * fund.
590  *
591  * The presence of two amount fields, rather than one, reflects
592  * the possibility that the two funds are denominated in different
593  * currencies.  If they use the same currency type, the two
594  * amounts should be the same.
595  *
596  * ****
597  *
598  * This program is free software; you can redistribute it and/or
599  * modify it under the terms of the GNU General Public License
600  * as published by the Free Software Foundation; either version 2
601  * of the License, or (at your option) any later version.
602  *
603  * This program is distributed in the hope that it will be useful,
604  * but WITHOUT ANY WARRANTY; without even the implied warranty of
605  * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
606  * GNU General Public License for more details.
607  */
608 $$;
609
610 CREATE TABLE acq.fiscal_calendar (
611         id              SERIAL         PRIMARY KEY,
612         name            TEXT           NOT NULL
613 );
614
615 -- Create a default calendar (though we don't specify its contents). 
616 -- Create a foreign key in actor.org_unit, initially pointing to
617 -- the default calendar.
618
619 INSERT INTO acq.fiscal_calendar (
620     name
621 ) VALUES (
622
623     'Default'
624 );
625
626 ALTER TABLE actor.org_unit
627 ADD COLUMN fiscal_calendar INT NOT NULL
628     REFERENCES acq.fiscal_calendar( id )
629     DEFERRABLE INITIALLY DEFERRED
630     DEFAULT 1;
631
632 CREATE TABLE acq.fiscal_year (
633         id              SERIAL         PRIMARY KEY,
634         calendar        INT            NOT NULL
635                                        REFERENCES acq.fiscal_calendar
636                                        ON DELETE CASCADE
637                                        DEFERRABLE INITIALLY DEFERRED,
638         year            INT            NOT NULL,
639         year_begin      TIMESTAMPTZ    NOT NULL,
640         year_end        TIMESTAMPTZ    NOT NULL,
641         CONSTRAINT acq_fy_logical_key  UNIQUE ( calendar, year ),
642     CONSTRAINT acq_fy_physical_key UNIQUE ( calendar, year_begin )
643 );
644
645 CREATE TABLE acq.edi_account (      -- similar tables can extend remote_account for other parts of EG
646     provider    INT     NOT NULL REFERENCES acq.provider          (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
647     in_dir      TEXT    -- incoming messages dir (probably different than config.remote_account.path, the outgoing dir)
648 ) INHERITS (config.remote_account);
649
650 -- We need a UNIQUE constraint here also, to support the FK from acq.provider.edi_default
651 ALTER TABLE acq.edi_account ADD CONSTRAINT acq_edi_account_id_unique UNIQUE (id);
652
653 -- Note below that the primary key is NOT a SERIAL type.  We will periodically truncate and rebuild
654 -- the table, assigning ids programmatically instead of using a sequence.
655 CREATE TABLE acq.debit_attribution (
656     id                     INT         NOT NULL PRIMARY KEY,
657     fund_debit             INT         NOT NULL
658                                        REFERENCES acq.fund_debit
659                                        DEFERRABLE INITIALLY DEFERRED,
660     debit_amount           NUMERIC     NOT NULL,
661     funding_source_credit  INT         REFERENCES acq.funding_source_credit
662                                        DEFERRABLE INITIALLY DEFERRED,
663     credit_amount          NUMERIC
664 );
665
666 CREATE INDEX acq_attribution_debit_idx
667     ON acq.debit_attribution( fund_debit );
668
669 CREATE INDEX acq_attribution_credit_idx
670     ON acq.debit_attribution( funding_source_credit );
671
672 -- Functions
673
674 CREATE TYPE acq.flat_lineitem_holding_subfield AS (lineitem int, holding int, subfield text, data text);
675 CREATE OR REPLACE FUNCTION acq.extract_holding_attr_table (lineitem int, tag text) RETURNS SETOF acq.flat_lineitem_holding_subfield AS $$
676 DECLARE
677     counter INT;
678     lida    acq.flat_lineitem_holding_subfield%ROWTYPE;
679 BEGIN
680
681     SELECT  COUNT(*) INTO counter
682       FROM  oils_xpath_table(
683                 'id',
684                 'marc',
685                 'acq.lineitem',
686                 '//*[@tag="' || tag || '"]',
687                 'id=' || lineitem
688             ) as t(i int,c text);
689
690     FOR i IN 1 .. counter LOOP
691         FOR lida IN
692             SELECT  * 
693               FROM  (   SELECT  id,i,t,v
694                           FROM  oils_xpath_table(
695                                     'id',
696                                     'marc',
697                                     'acq.lineitem',
698                                     '//*[@tag="' || tag || '"][position()=' || i || ']/*/@code|' ||
699                                         '//*[@tag="' || tag || '"][position()=' || i || ']/*[@code]',
700                                     'id=' || lineitem
701                                 ) as t(id int,t text,v text)
702                     )x
703         LOOP
704             RETURN NEXT lida;
705         END LOOP;
706     END LOOP;
707
708     RETURN;
709 END;
710 $$ LANGUAGE PLPGSQL;
711
712 CREATE TYPE acq.flat_lineitem_detail AS (lineitem int, holding int, attr text, data text);
713 CREATE OR REPLACE FUNCTION acq.extract_provider_holding_data ( lineitem_i int ) RETURNS SETOF acq.flat_lineitem_detail AS $$
714 DECLARE
715     prov_i  INT;
716     tag_t   TEXT;
717     lida    acq.flat_lineitem_detail%ROWTYPE;
718 BEGIN
719     SELECT provider INTO prov_i FROM acq.lineitem WHERE id = lineitem_i;
720     IF NOT FOUND THEN RETURN; END IF;
721
722     SELECT holding_tag INTO tag_t FROM acq.provider WHERE id = prov_i;
723     IF NOT FOUND OR tag_t IS NULL THEN RETURN; END IF;
724
725     FOR lida IN
726         SELECT  lineitem_i,
727                 h.holding,
728                 a.name,
729                 h.data
730           FROM  acq.extract_holding_attr_table( lineitem_i, tag_t ) h
731                 JOIN acq.provider_holding_subfield_map a USING (subfield)
732           WHERE a.provider = prov_i
733     LOOP
734         RETURN NEXT lida;
735     END LOOP;
736
737     RETURN;
738 END;
739 $$ LANGUAGE PLPGSQL;
740
741 -- select * from acq.extract_provider_holding_data(699);
742
743 CREATE OR REPLACE FUNCTION public.extract_acq_marc_field ( BIGINT, TEXT, TEXT) RETURNS TEXT AS $$
744         SELECT public.extract_marc_field('acq.lineitem', $1, $2, $3);
745 $$ LANGUAGE SQL;
746
747 /*
748 CREATE OR REPLACE FUNCTION public.extract_bib_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
749         SELECT public.extract_marc_field('biblio.record_entry', $1, $2);
750 $$ LANGUAGE SQL;
751
752 CREATE OR REPLACE FUNCTION public.extract_authority_marc_field ( BIGINT, TEXT ) RETURNS TEXT AS $$
753         SELECT public.extract_marc_field('authority.record_entry', $1, $2);
754 $$ LANGUAGE SQL;
755 */
756 -- For example:
757 -- INSERT INTO acq.lineitem_provider_attr_definition ( provider, code, description, xpath ) VALUES (1,'price','Price','//*[@tag="020" or @tag="022"]/*[@code="a"][1]');
758
759 /*
760 Suggested vendor fields:
761         vendor_price
762         vendor_currency
763         vendor_avail
764         vendor_po
765         vendor_identifier
766 */
767
768 CREATE OR REPLACE FUNCTION public.ingest_acq_marc ( ) RETURNS TRIGGER AS $$
769 DECLARE
770         value           TEXT;
771         atype           TEXT;
772         prov            INT;
773         adef            RECORD;
774         xpath_string    TEXT;
775 BEGIN
776         FOR adef IN SELECT *,tableoid FROM acq.lineitem_attr_definition LOOP
777
778                 SELECT relname::TEXT INTO atype FROM pg_class WHERE oid = adef.tableoid;
779
780                 IF (atype NOT IN ('lineitem_usr_attr_definition','lineitem_local_attr_definition')) THEN
781                         IF (atype = 'lineitem_provider_attr_definition') THEN
782                                 SELECT provider INTO prov FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
783                                 CONTINUE WHEN NEW.provider IS NULL OR prov <> NEW.provider;
784                         END IF;
785                         
786                         IF (atype = 'lineitem_provider_attr_definition') THEN
787                                 SELECT xpath INTO xpath_string FROM acq.lineitem_provider_attr_definition WHERE id = adef.id;
788                         ELSIF (atype = 'lineitem_marc_attr_definition') THEN
789                                 SELECT xpath INTO xpath_string FROM acq.lineitem_marc_attr_definition WHERE id = adef.id;
790                         ELSIF (atype = 'lineitem_generated_attr_definition') THEN
791                                 SELECT xpath INTO xpath_string FROM acq.lineitem_generated_attr_definition WHERE id = adef.id;
792                         END IF;
793
794                         SELECT extract_acq_marc_field(id, xpath_string, adef.remove) INTO value FROM acq.lineitem WHERE id = NEW.id;
795
796                         IF (value IS NOT NULL AND value <> '') THEN
797                                 INSERT INTO acq.lineitem_attr (lineitem, definition, attr_type, attr_name, attr_value)
798                                         VALUES (NEW.id, adef.id, atype, adef.code, value);
799                         END IF;
800
801                 END IF;
802
803         END LOOP;
804
805         RETURN NULL;
806 END;
807 $$ LANGUAGE PLPGSQL;
808
809 CREATE OR REPLACE FUNCTION public.cleanup_acq_marc ( ) RETURNS TRIGGER AS $$
810 BEGIN
811         IF TG_OP = 'UPDATE' THEN
812                 DELETE FROM acq.lineitem_attr
813                         WHERE lineitem = OLD.id AND attr_type IN ('lineitem_provider_attr_definition', 'lineitem_marc_attr_definition','lineitem_generated_attr_definition');
814                 RETURN NEW;
815         ELSE
816                 DELETE FROM acq.lineitem_attr WHERE lineitem = OLD.id;
817                 RETURN OLD;
818         END IF;
819 END;
820 $$ LANGUAGE PLPGSQL;
821
822 CREATE TRIGGER cleanup_lineitem_trigger
823         BEFORE UPDATE OR DELETE ON acq.lineitem
824         FOR EACH ROW EXECUTE PROCEDURE public.cleanup_acq_marc();
825
826 CREATE TRIGGER ingest_lineitem_trigger
827         AFTER INSERT OR UPDATE ON acq.lineitem
828         FOR EACH ROW EXECUTE PROCEDURE public.ingest_acq_marc();
829
830 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( from_ex TEXT, to_ex TEXT ) RETURNS NUMERIC AS $$
831 DECLARE
832     rat NUMERIC;
833 BEGIN
834     IF from_ex = to_ex THEN
835         RETURN 1.0;
836     END IF;
837
838     SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = from_ex AND to_currency = to_ex;
839
840     IF FOUND THEN
841         RETURN rat;
842     ELSE
843         SELECT ratio INTO rat FROM acq.exchange_rate WHERE from_currency = to_ex AND to_currency = from_ex;
844         IF FOUND THEN
845             RETURN 1.0/rat;
846         END IF;
847     END IF;
848
849     RETURN NULL;
850
851 END;
852 $$ LANGUAGE PLPGSQL;
853
854 CREATE OR REPLACE FUNCTION acq.exchange_ratio ( TEXT, TEXT, NUMERIC ) RETURNS NUMERIC AS $$
855     SELECT $3 * acq.exchange_ratio($1, $2);
856 $$ LANGUAGE SQL;
857
858 CREATE OR REPLACE FUNCTION acq.find_bad_fy()
859 /*
860         Examine the acq.fiscal_year table, comparing successive years.
861         Report any inconsistencies, i.e. years that overlap, have gaps
862     between them, or are out of sequence.
863 */
864 RETURNS SETOF RECORD AS $$
865 DECLARE
866         first_row  BOOLEAN;
867         curr_year  RECORD;
868         prev_year  RECORD;
869         return_rec RECORD;
870 BEGIN
871         first_row := true;
872         FOR curr_year in
873                 SELECT
874                         id,
875                         calendar,
876                         year,
877                         year_begin,
878                         year_end
879                 FROM
880                         acq.fiscal_year
881                 ORDER BY
882                         calendar,
883                         year_begin
884         LOOP
885                 --
886                 IF first_row THEN
887                         first_row := FALSE;
888                 ELSIF curr_year.calendar    = prev_year.calendar THEN
889                         IF curr_year.year_begin > prev_year.year_end THEN
890                                 -- This ugly kludge works around the fact that older
891                                 -- versions of PostgreSQL don't support RETURN QUERY SELECT
892                                 FOR return_rec IN SELECT
893                                         prev_year.id,
894                                         prev_year.year,
895                                         'Gap between fiscal years'::TEXT
896                                 LOOP
897                                         RETURN NEXT return_rec;
898                                 END LOOP;
899                         ELSIF curr_year.year_begin < prev_year.year_end THEN
900                                 FOR return_rec IN SELECT
901                                         prev_year.id,
902                                         prev_year.year,
903                                         'Overlapping fiscal years'::TEXT
904                                 LOOP
905                                         RETURN NEXT return_rec;
906                                 END LOOP;
907                         ELSIF curr_year.year < prev_year.year THEN
908                                 FOR return_rec IN SELECT
909                                         prev_year.id,
910                                         prev_year.year,
911                                         'Fiscal years out of order'::TEXT
912                                 LOOP
913                                         RETURN NEXT return_rec;
914                                 END LOOP;
915                         END IF;
916                 END IF;
917                 --
918                 prev_year := curr_year;
919         END LOOP;
920         --
921         RETURN;
922 END;
923 $$ LANGUAGE plpgsql;
924
925 CREATE OR REPLACE FUNCTION acq.transfer_fund(
926         old_fund   IN INT,
927         old_amount IN NUMERIC,     -- in currency of old fund
928         new_fund   IN INT,
929         new_amount IN NUMERIC,     -- in currency of new fund
930         user_id    IN INT,
931         xfer_note  IN TEXT         -- to be recorded in acq.fund_transfer
932         -- ,funding_source_in IN INT  -- if user wants to specify a funding source (see notes)
933 ) RETURNS VOID AS $$
934 /* -------------------------------------------------------------------------------
935
936 Function to transfer money from one fund to another.
937
938 A transfer is represented as a pair of entries in acq.fund_allocation, with a
939 negative amount for the old (losing) fund and a positive amount for the new
940 (gaining) fund.  In some cases there may be more than one such pair of entries
941 in order to pull the money from different funding sources, or more specifically
942 from different funding source credits.  For each such pair there is also an
943 entry in acq.fund_transfer.
944
945 Since funding_source is a non-nullable column in acq.fund_allocation, we must
946 choose a funding source for the transferred money to come from.  This choice
947 must meet two constraints, so far as possible:
948
949 1. The amount transferred from a given funding source must not exceed the
950 amount allocated to the old fund by the funding source.  To that end we
951 compare the amount being transferred to the amount allocated.
952
953 2. We shouldn't transfer money that has already been spent or encumbered, as
954 defined by the funding attribution process.  We attribute expenses to the
955 oldest funding source credits first.  In order to avoid transferring that
956 attributed money, we reverse the priority, transferring from the newest funding
957 source credits first.  There can be no guarantee that this approach will
958 avoid overcommitting a fund, but no other approach can do any better.
959
960 In this context the age of a funding source credit is defined by the
961 deadline_date for credits with deadline_dates, and by the effective_date for
962 credits without deadline_dates, with the proviso that credits with deadline_dates
963 are all considered "older" than those without.
964
965 ----------
966
967 In the signature for this function, there is one last parameter commented out,
968 named "funding_source_in".  Correspondingly, the WHERE clause for the query
969 driving the main loop has an OR clause commented out, which references the
970 funding_source_in parameter.
971
972 If these lines are uncommented, this function will allow the user optionally to
973 restrict a fund transfer to a specified funding source.  If the source
974 parameter is left NULL, then there will be no such restriction.
975
976 ------------------------------------------------------------------------------- */ 
977 DECLARE
978         same_currency      BOOLEAN;
979         currency_ratio     NUMERIC;
980         old_fund_currency  TEXT;
981         old_remaining      NUMERIC;  -- in currency of old fund
982         new_fund_currency  TEXT;
983         new_fund_active    BOOLEAN;
984         new_remaining      NUMERIC;  -- in currency of new fund
985         curr_old_amt       NUMERIC;  -- in currency of old fund
986         curr_new_amt       NUMERIC;  -- in currency of new fund
987         source_addition    NUMERIC;  -- in currency of funding source
988         source_deduction   NUMERIC;  -- in currency of funding source
989         orig_allocated_amt NUMERIC;  -- in currency of funding source
990         allocated_amt      NUMERIC;  -- in currency of fund
991         source             RECORD;
992 BEGIN
993         --
994         -- Sanity checks
995         --
996         IF old_fund IS NULL THEN
997                 RAISE EXCEPTION 'acq.transfer_fund: old fund id is NULL';
998         END IF;
999         --
1000         IF old_amount IS NULL THEN
1001                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
1002         END IF;
1003         --
1004         -- The new fund and its amount must be both NULL or both not NULL.
1005         --
1006         IF new_fund IS NOT NULL AND new_amount IS NULL THEN
1007                 RAISE EXCEPTION 'acq.transfer_fund: amount to transfer to receiving fund is NULL';
1008         END IF;
1009         --
1010         IF new_fund IS NULL AND new_amount IS NOT NULL THEN
1011                 RAISE EXCEPTION 'acq.transfer_fund: receiving fund is NULL, its amount is not NULL';
1012         END IF;
1013         --
1014         IF user_id IS NULL THEN
1015                 RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
1016         END IF;
1017         --
1018         -- Initialize the amounts to be transferred, each denominated
1019         -- in the currency of its respective fund.  They will be
1020         -- reduced on each iteration of the loop.
1021         --
1022         old_remaining := old_amount;
1023         new_remaining := new_amount;
1024         --
1025         -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
1026         --      old_amount, old_fund, new_amount, new_fund;
1027         --
1028         -- Get the currency types of the old and new funds.
1029         --
1030         SELECT
1031                 currency_type
1032         INTO
1033                 old_fund_currency
1034         FROM
1035                 acq.fund
1036         WHERE
1037                 id = old_fund;
1038         --
1039         IF old_fund_currency IS NULL THEN
1040                 RAISE EXCEPTION 'acq.transfer_fund: old fund id % is not defined', old_fund;
1041         END IF;
1042         --
1043         IF new_fund IS NOT NULL THEN
1044                 SELECT
1045                         currency_type,
1046                         active
1047                 INTO
1048                         new_fund_currency,
1049                         new_fund_active
1050                 FROM
1051                         acq.fund
1052                 WHERE
1053                         id = new_fund;
1054                 --
1055                 IF new_fund_currency IS NULL THEN
1056                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is not defined', new_fund;
1057                 ELSIF NOT new_fund_active THEN
1058                         --
1059                         -- No point in putting money into a fund from whence you can't spend it
1060                         --
1061                         RAISE EXCEPTION 'acq.transfer_fund: new fund id % is inactive', new_fund;
1062                 END IF;
1063                 --
1064                 IF new_amount = old_amount THEN
1065                         same_currency := true;
1066                         currency_ratio := 1;
1067                 ELSE
1068                         --
1069                         -- We'll have to translate currency between funds.  We presume that
1070                         -- the calling code has already applied an appropriate exchange rate,
1071                         -- so we'll apply the same conversion to each sub-transfer.
1072                         --
1073                         same_currency := false;
1074                         currency_ratio := new_amount / old_amount;
1075                 END IF;
1076         END IF;
1077         --
1078         -- Identify the funding source(s) from which we want to transfer the money.
1079         -- The principle is that we want to transfer the newest money first, because
1080         -- we spend the oldest money first.  The priority for spending is defined
1081         -- by a sort of the view acq.ordered_funding_source_credit.
1082         --
1083         FOR source in
1084                 SELECT
1085                         ofsc.id,
1086                         ofsc.funding_source,
1087                         ofsc.amount,
1088                         ofsc.amount * acq.exchange_ratio( fs.currency_type, old_fund_currency )
1089                                 AS converted_amt,
1090                         fs.currency_type
1091                 FROM
1092                         acq.ordered_funding_source_credit AS ofsc,
1093                         acq.funding_source fs
1094                 WHERE
1095                         ofsc.funding_source = fs.id
1096                         and ofsc.funding_source IN
1097                         (
1098                                 SELECT funding_source
1099                                 FROM acq.fund_allocation
1100                                 WHERE fund = old_fund
1101                         )
1102                         -- and
1103                         -- (
1104                         --      ofsc.funding_source = funding_source_in
1105                         --      OR funding_source_in IS NULL
1106                         -- )
1107                 ORDER BY
1108                         ofsc.sort_priority desc,
1109                         ofsc.sort_date desc,
1110                         ofsc.id desc
1111         LOOP
1112                 --
1113                 -- Determine how much money the old fund got from this funding source,
1114                 -- denominated in the currency types of the source and of the fund.
1115                 -- This result may reflect transfers from previous iterations.
1116                 --
1117                 SELECT
1118                         COALESCE( sum( amount ), 0 ),
1119                         COALESCE( sum( amount )
1120                                 * acq.exchange_ratio( source.currency_type, old_fund_currency ), 0 )
1121                 INTO
1122                         orig_allocated_amt,     -- in currency of the source
1123                         allocated_amt           -- in currency of the old fund
1124                 FROM
1125                         acq.fund_allocation
1126                 WHERE
1127                         fund = old_fund
1128                         and funding_source = source.funding_source;
1129                 --      
1130                 -- Determine how much to transfer from this credit, in the currency
1131                 -- of the fund.   Begin with the amount remaining to be attributed:
1132                 --
1133                 curr_old_amt := old_remaining;
1134                 --
1135                 -- Can't attribute more than was allocated from the fund:
1136                 --
1137                 IF curr_old_amt > allocated_amt THEN
1138                         curr_old_amt := allocated_amt;
1139                 END IF;
1140                 --
1141                 -- Can't attribute more than the amount of the current credit:
1142                 --
1143                 IF curr_old_amt > source.converted_amt THEN
1144                         curr_old_amt := source.converted_amt;
1145                 END IF;
1146                 --
1147                 curr_old_amt := trunc( curr_old_amt, 2 );
1148                 --
1149                 old_remaining := old_remaining - curr_old_amt;
1150                 --
1151                 -- Determine the amount to be deducted, if any,
1152                 -- from the old allocation.
1153                 --
1154                 IF old_remaining > 0 THEN
1155                         --
1156                         -- In this case we're using the whole allocation, so use that
1157                         -- amount directly instead of applying a currency translation
1158                         -- and thereby inviting round-off errors.
1159                         --
1160                         source_deduction := - orig_allocated_amt;
1161                 ELSE 
1162                         source_deduction := trunc(
1163                                 ( - curr_old_amt ) *
1164                                         acq.exchange_ratio( old_fund_currency, source.currency_type ),
1165                                 2 );
1166                 END IF;
1167                 --
1168                 IF source_deduction <> 0 THEN
1169                         --
1170                         -- Insert negative allocation for old fund in fund_allocation,
1171                         -- converted into the currency of the funding source
1172                         --
1173                         INSERT INTO acq.fund_allocation (
1174                                 funding_source,
1175                                 fund,
1176                                 amount,
1177                                 allocator,
1178                                 note
1179                         ) VALUES (
1180                                 source.funding_source,
1181                                 old_fund,
1182                                 source_deduction,
1183                                 user_id,
1184                                 'Transfer to fund ' || new_fund
1185                         );
1186                 END IF;
1187                 --
1188                 IF new_fund IS NOT NULL THEN
1189                         --
1190                         -- Determine how much to add to the new fund, in
1191                         -- its currency, and how much remains to be added:
1192                         --
1193                         IF same_currency THEN
1194                                 curr_new_amt := curr_old_amt;
1195                         ELSE
1196                                 IF old_remaining = 0 THEN
1197                                         --
1198                                         -- This is the last iteration, so nothing should be left
1199                                         --
1200                                         curr_new_amt := new_remaining;
1201                                         new_remaining := 0;
1202                                 ELSE
1203                                         curr_new_amt := trunc( curr_old_amt * currency_ratio, 2 );
1204                                         new_remaining := new_remaining - curr_new_amt;
1205                                 END IF;
1206                         END IF;
1207                         --
1208                         -- Determine how much to add, if any,
1209                         -- to the new fund's allocation.
1210                         --
1211                         IF old_remaining > 0 THEN
1212                                 --
1213                                 -- In this case we're using the whole allocation, so use that amount
1214                                 -- amount directly instead of applying a currency translation and
1215                                 -- thereby inviting round-off errors.
1216                                 --
1217                                 source_addition := orig_allocated_amt;
1218                         ELSIF source.currency_type = old_fund_currency THEN
1219                                 --
1220                                 -- In this case we don't need a round trip currency translation,
1221                                 -- thereby inviting round-off errors:
1222                                 --
1223                                 source_addition := curr_old_amt;
1224                         ELSE 
1225                                 source_addition := trunc(
1226                                         curr_new_amt *
1227                                                 acq.exchange_ratio( new_fund_currency, source.currency_type ),
1228                                         2 );
1229                         END IF;
1230                         --
1231                         IF source_addition <> 0 THEN
1232                                 --
1233                                 -- Insert positive allocation for new fund in fund_allocation,
1234                                 -- converted to the currency of the founding source
1235                                 --
1236                                 INSERT INTO acq.fund_allocation (
1237                                         funding_source,
1238                                         fund,
1239                                         amount,
1240                                         allocator,
1241                                         note
1242                                 ) VALUES (
1243                                         source.funding_source,
1244                                         new_fund,
1245                                         source_addition,
1246                                         user_id,
1247                                         'Transfer from fund ' || old_fund
1248                                 );
1249                         END IF;
1250                 END IF;
1251                 --
1252                 IF trunc( curr_old_amt, 2 ) <> 0
1253                 OR trunc( curr_new_amt, 2 ) <> 0 THEN
1254                         --
1255                         -- Insert row in fund_transfer, using amounts in the currency of the funds
1256                         --
1257                         INSERT INTO acq.fund_transfer (
1258                                 src_fund,
1259                                 src_amount,
1260                                 dest_fund,
1261                                 dest_amount,
1262                                 transfer_user,
1263                                 note,
1264                                 funding_source_credit
1265                         ) VALUES (
1266                                 old_fund,
1267                                 trunc( curr_old_amt, 2 ),
1268                                 new_fund,
1269                                 trunc( curr_new_amt, 2 ),
1270                                 user_id,
1271                                 xfer_note,
1272                                 source.id
1273                         );
1274                 END IF;
1275                 --
1276                 if old_remaining <= 0 THEN
1277                         EXIT;                   -- Nothing more to be transferred
1278                 END IF;
1279         END LOOP;
1280 END;
1281 $$ LANGUAGE plpgsql;
1282
1283 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_unit(
1284         old_year INTEGER,
1285         user_id INTEGER,
1286         org_unit_id INTEGER
1287 ) RETURNS VOID AS $$
1288 DECLARE
1289 --
1290 new_id      INT;
1291 old_fund    RECORD;
1292 org_found   BOOLEAN;
1293 --
1294 BEGIN
1295         --
1296         -- Sanity checks
1297         --
1298         IF old_year IS NULL THEN
1299                 RAISE EXCEPTION 'Input year argument is NULL';
1300         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1301                 RAISE EXCEPTION 'Input year is out of range';
1302         END IF;
1303         --
1304         IF user_id IS NULL THEN
1305                 RAISE EXCEPTION 'Input user id argument is NULL';
1306         END IF;
1307         --
1308         IF org_unit_id IS NULL THEN
1309                 RAISE EXCEPTION 'Org unit id argument is NULL';
1310         ELSE
1311                 SELECT TRUE INTO org_found
1312                 FROM actor.org_unit
1313                 WHERE id = org_unit_id;
1314                 --
1315                 IF org_found IS NULL THEN
1316                         RAISE EXCEPTION 'Org unit id is invalid';
1317                 END IF;
1318         END IF;
1319         --
1320         -- Loop over the applicable funds
1321         --
1322         FOR old_fund in SELECT * FROM acq.fund
1323         WHERE
1324                 year = old_year
1325                 AND propagate
1326                 AND org = org_unit_id
1327         LOOP
1328                 BEGIN
1329                         INSERT INTO acq.fund (
1330                                 org,
1331                                 name,
1332                                 year,
1333                                 currency_type,
1334                                 code,
1335                                 rollover,
1336                                 propagate
1337                         ) VALUES (
1338                                 old_fund.org,
1339                                 old_fund.name,
1340                                 old_year + 1,
1341                                 old_fund.currency_type,
1342                                 old_fund.code,
1343                                 old_fund.rollover,
1344                                 true
1345                         )
1346                         RETURNING id INTO new_id;
1347                 EXCEPTION
1348                         WHEN unique_violation THEN
1349                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
1350                                 CONTINUE;
1351                 END;
1352                 --RAISE NOTICE 'Propagating fund % to fund %',
1353                 --      old_fund.code, new_id;
1354         END LOOP;
1355 END;
1356 $$ LANGUAGE plpgsql;
1357
1358 CREATE OR REPLACE FUNCTION acq.propagate_funds_by_org_tree(
1359         old_year INTEGER,
1360         user_id INTEGER,
1361         org_unit_id INTEGER
1362 ) RETURNS VOID AS $$
1363 DECLARE
1364 --
1365 new_id      INT;
1366 old_fund    RECORD;
1367 org_found   BOOLEAN;
1368 --
1369 BEGIN
1370         --
1371         -- Sanity checks
1372         --
1373         IF old_year IS NULL THEN
1374                 RAISE EXCEPTION 'Input year argument is NULL';
1375         ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1376                 RAISE EXCEPTION 'Input year is out of range';
1377         END IF;
1378         --
1379         IF user_id IS NULL THEN
1380                 RAISE EXCEPTION 'Input user id argument is NULL';
1381         END IF;
1382         --
1383         IF org_unit_id IS NULL THEN
1384                 RAISE EXCEPTION 'Org unit id argument is NULL';
1385         ELSE
1386                 SELECT TRUE INTO org_found
1387                 FROM actor.org_unit
1388                 WHERE id = org_unit_id;
1389                 --
1390                 IF org_found IS NULL THEN
1391                         RAISE EXCEPTION 'Org unit id is invalid';
1392                 END IF;
1393         END IF;
1394         --
1395         -- Loop over the applicable funds
1396         --
1397         FOR old_fund in SELECT * FROM acq.fund
1398         WHERE
1399                 year = old_year
1400                 AND propagate
1401                 AND org in (
1402                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
1403                 )
1404         LOOP
1405                 BEGIN
1406                         INSERT INTO acq.fund (
1407                                 org,
1408                                 name,
1409                                 year,
1410                                 currency_type,
1411                                 code,
1412                                 rollover,
1413                                 propagate
1414                         ) VALUES (
1415                                 old_fund.org,
1416                                 old_fund.name,
1417                                 old_year + 1,
1418                                 old_fund.currency_type,
1419                                 old_fund.code,
1420                                 old_fund.rollover,
1421                                 true
1422                         )
1423                         RETURNING id INTO new_id;
1424                 EXCEPTION
1425                         WHEN unique_violation THEN
1426                                 --RAISE NOTICE 'Fund % already propagated', old_fund.id;
1427                                 CONTINUE;
1428                 END;
1429                 --RAISE NOTICE 'Propagating fund % to fund %',
1430                 --      old_fund.code, new_id;
1431         END LOOP;
1432 END;
1433 $$ LANGUAGE plpgsql;
1434
1435 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_unit(
1436         old_year INTEGER,
1437         user_id INTEGER,
1438         org_unit_id INTEGER
1439 ) RETURNS VOID AS $$
1440 DECLARE
1441 --
1442 new_fund    INT;
1443 new_year    INT := old_year + 1;
1444 org_found   BOOL;
1445 xfer_amount NUMERIC;
1446 roll_fund   RECORD;
1447 deb         RECORD;
1448 detail      RECORD;
1449 --
1450 BEGIN
1451         --
1452         -- Sanity checks
1453         --
1454         IF old_year IS NULL THEN
1455                 RAISE EXCEPTION 'Input year argument is NULL';
1456     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1457         RAISE EXCEPTION 'Input year is out of range';
1458         END IF;
1459         --
1460         IF user_id IS NULL THEN
1461                 RAISE EXCEPTION 'Input user id argument is NULL';
1462         END IF;
1463         --
1464         IF org_unit_id IS NULL THEN
1465                 RAISE EXCEPTION 'Org unit id argument is NULL';
1466         ELSE
1467                 --
1468                 -- Validate the org unit
1469                 --
1470                 SELECT TRUE
1471                 INTO org_found
1472                 FROM actor.org_unit
1473                 WHERE id = org_unit_id;
1474                 --
1475                 IF org_found IS NULL THEN
1476                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
1477                 END IF;
1478         END IF;
1479         --
1480         -- Loop over the propagable funds to identify the details
1481         -- from the old fund plus the id of the new one, if it exists.
1482         --
1483         FOR roll_fund in
1484         SELECT
1485             oldf.id AS old_fund,
1486             oldf.org,
1487             oldf.name,
1488             oldf.currency_type,
1489             oldf.code,
1490                 oldf.rollover,
1491             newf.id AS new_fund_id
1492         FROM
1493         acq.fund AS oldf
1494         LEFT JOIN acq.fund AS newf
1495                 ON ( oldf.code = newf.code )
1496         WHERE
1497                     oldf.org = org_unit_id
1498                 and oldf.year = old_year
1499                 and oldf.propagate
1500         and newf.year = new_year
1501         LOOP
1502                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
1503                 --
1504                 IF roll_fund.new_fund_id IS NULL THEN
1505                         --
1506                         -- The old fund hasn't been propagated yet.  Propagate it now.
1507                         --
1508                         INSERT INTO acq.fund (
1509                                 org,
1510                                 name,
1511                                 year,
1512                                 currency_type,
1513                                 code,
1514                                 rollover,
1515                                 propagate
1516                         ) VALUES (
1517                                 roll_fund.org,
1518                                 roll_fund.name,
1519                                 new_year,
1520                                 roll_fund.currency_type,
1521                                 roll_fund.code,
1522                                 true,
1523                                 true
1524                         )
1525                         RETURNING id INTO new_fund;
1526                 ELSE
1527                         new_fund = roll_fund.new_fund_id;
1528                 END IF;
1529                 --
1530                 -- Determine the amount to transfer
1531                 --
1532                 SELECT amount
1533                 INTO xfer_amount
1534                 FROM acq.fund_spent_balance
1535                 WHERE fund = roll_fund.old_fund;
1536                 --
1537                 IF xfer_amount <> 0 THEN
1538                         IF roll_fund.rollover THEN
1539                                 --
1540                                 -- Transfer balance from old fund to new
1541                                 --
1542                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
1543                                 --
1544                                 PERFORM acq.transfer_fund(
1545                                         roll_fund.old_fund,
1546                                         xfer_amount,
1547                                         new_fund,
1548                                         xfer_amount,
1549                                         user_id,
1550                                         'Rollover'
1551                                 );
1552                         ELSE
1553                                 --
1554                                 -- Transfer balance from old fund to the void
1555                                 --
1556                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
1557                                 --
1558                                 PERFORM acq.transfer_fund(
1559                                         roll_fund.old_fund,
1560                                         xfer_amount,
1561                                         NULL,
1562                                         NULL,
1563                                         user_id,
1564                                         'Rollover'
1565                                 );
1566                         END IF;
1567                 END IF;
1568                 --
1569                 IF roll_fund.rollover THEN
1570                         --
1571                         -- Move any lineitems from the old fund to the new one
1572                         -- where the associated debit is an encumbrance.
1573                         --
1574                         -- Any other tables tying expenditure details to funds should
1575                         -- receive similar treatment.  At this writing there are none.
1576                         --
1577                         UPDATE acq.lineitem_detail
1578                         SET fund = new_fund
1579                         WHERE
1580                         fund = roll_fund.old_fund -- this condition may be redundant
1581                         AND fund_debit in
1582                         (
1583                                 SELECT id
1584                                 FROM acq.fund_debit
1585                                 WHERE
1586                                 fund = roll_fund.old_fund
1587                                 AND encumbrance
1588                         );
1589                         --
1590                         -- Move encumbrance debits from the old fund to the new fund
1591                         --
1592                         UPDATE acq.fund_debit
1593                         SET fund = new_fund
1594                         wHERE
1595                                 fund = roll_fund.old_fund
1596                                 AND encumbrance;
1597                 END IF;
1598                 --
1599                 -- Mark old fund as inactive, now that we've closed it
1600                 --
1601                 UPDATE acq.fund
1602                 SET active = FALSE
1603                 WHERE id = roll_fund.old_fund;
1604         END LOOP;
1605 END;
1606 $$ LANGUAGE plpgsql;
1607
1608 CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_tree(
1609         old_year INTEGER,
1610         user_id INTEGER,
1611         org_unit_id INTEGER
1612 ) RETURNS VOID AS $$
1613 DECLARE
1614 --
1615 new_fund    INT;
1616 new_year    INT := old_year + 1;
1617 org_found   BOOL;
1618 xfer_amount NUMERIC;
1619 roll_fund   RECORD;
1620 deb         RECORD;
1621 detail      RECORD;
1622 --
1623 BEGIN
1624         --
1625         -- Sanity checks
1626         --
1627         IF old_year IS NULL THEN
1628                 RAISE EXCEPTION 'Input year argument is NULL';
1629     ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
1630         RAISE EXCEPTION 'Input year is out of range';
1631         END IF;
1632         --
1633         IF user_id IS NULL THEN
1634                 RAISE EXCEPTION 'Input user id argument is NULL';
1635         END IF;
1636         --
1637         IF org_unit_id IS NULL THEN
1638                 RAISE EXCEPTION 'Org unit id argument is NULL';
1639         ELSE
1640                 --
1641                 -- Validate the org unit
1642                 --
1643                 SELECT TRUE
1644                 INTO org_found
1645                 FROM actor.org_unit
1646                 WHERE id = org_unit_id;
1647                 --
1648                 IF org_found IS NULL THEN
1649                         RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
1650                 END IF;
1651         END IF;
1652         --
1653         -- Loop over the propagable funds to identify the details
1654         -- from the old fund plus the id of the new one, if it exists.
1655         --
1656         FOR roll_fund in
1657         SELECT
1658             oldf.id AS old_fund,
1659             oldf.org,
1660             oldf.name,
1661             oldf.currency_type,
1662             oldf.code,
1663                 oldf.rollover,
1664             newf.id AS new_fund_id
1665         FROM
1666         acq.fund AS oldf
1667         LEFT JOIN acq.fund AS newf
1668                 ON ( oldf.code = newf.code )
1669         WHERE
1670                     oldf.year = old_year
1671                 AND oldf.propagate
1672         AND newf.year = new_year
1673                 AND oldf.org in (
1674                         SELECT id FROM actor.org_unit_descendants( org_unit_id )
1675                 )
1676         LOOP
1677                 --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
1678                 --
1679                 IF roll_fund.new_fund_id IS NULL THEN
1680                         --
1681                         -- The old fund hasn't been propagated yet.  Propagate it now.
1682                         --
1683                         INSERT INTO acq.fund (
1684                                 org,
1685                                 name,
1686                                 year,
1687                                 currency_type,
1688                                 code,
1689                                 rollover,
1690                                 propagate
1691                         ) VALUES (
1692                                 roll_fund.org,
1693                                 roll_fund.name,
1694                                 new_year,
1695                                 roll_fund.currency_type,
1696                                 roll_fund.code,
1697                                 true,
1698                                 true
1699                         )
1700                         RETURNING id INTO new_fund;
1701                 ELSE
1702                         new_fund = roll_fund.new_fund_id;
1703                 END IF;
1704                 --
1705                 -- Determine the amount to transfer
1706                 --
1707                 SELECT amount
1708                 INTO xfer_amount
1709                 FROM acq.fund_spent_balance
1710                 WHERE fund = roll_fund.old_fund;
1711                 --
1712                 IF xfer_amount <> 0 THEN
1713                         IF roll_fund.rollover THEN
1714                                 --
1715                                 -- Transfer balance from old fund to new
1716                                 --
1717                                 --RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
1718                                 --
1719                                 PERFORM acq.transfer_fund(
1720                                         roll_fund.old_fund,
1721                                         xfer_amount,
1722                                         new_fund,
1723                                         xfer_amount,
1724                                         user_id,
1725                                         'Rollover'
1726                                 );
1727                         ELSE
1728                                 --
1729                                 -- Transfer balance from old fund to the void
1730                                 --
1731                                 -- RAISE NOTICE 'Transferring % from fund % to the void', xfer_amount, roll_fund.old_fund;
1732                                 --
1733                                 PERFORM acq.transfer_fund(
1734                                         roll_fund.old_fund,
1735                                         xfer_amount,
1736                                         NULL,
1737                                         NULL,
1738                                         user_id,
1739                                         'Rollover'
1740                                 );
1741                         END IF;
1742                 END IF;
1743                 --
1744                 IF roll_fund.rollover THEN
1745                         --
1746                         -- Move any lineitems from the old fund to the new one
1747                         -- where the associated debit is an encumbrance.
1748                         --
1749                         -- Any other tables tying expenditure details to funds should
1750                         -- receive similar treatment.  At this writing there are none.
1751                         --
1752                         UPDATE acq.lineitem_detail
1753                         SET fund = new_fund
1754                         WHERE
1755                         fund = roll_fund.old_fund -- this condition may be redundant
1756                         AND fund_debit in
1757                         (
1758                                 SELECT id
1759                                 FROM acq.fund_debit
1760                                 WHERE
1761                                 fund = roll_fund.old_fund
1762                                 AND encumbrance
1763                         );
1764                         --
1765                         -- Move encumbrance debits from the old fund to the new fund
1766                         --
1767                         UPDATE acq.fund_debit
1768                         SET fund = new_fund
1769                         wHERE
1770                                 fund = roll_fund.old_fund
1771                                 AND encumbrance;
1772                 END IF;
1773                 --
1774                 -- Mark old fund as inactive, now that we've closed it
1775                 --
1776                 UPDATE acq.fund
1777                 SET active = FALSE
1778                 WHERE id = roll_fund.old_fund;
1779         END LOOP;
1780 END;
1781 $$ LANGUAGE plpgsql;
1782
1783 CREATE OR REPLACE VIEW acq.funding_source_credit_total AS
1784     SELECT  funding_source,
1785             SUM(amount) AS amount
1786       FROM  acq.funding_source_credit
1787       GROUP BY 1;
1788
1789 CREATE OR REPLACE VIEW acq.funding_source_allocation_total AS
1790     SELECT  funding_source,
1791             SUM(a.amount)::NUMERIC(100,2) AS amount
1792     FROM  acq.fund_allocation a
1793     GROUP BY 1;
1794
1795 CREATE OR REPLACE VIEW acq.funding_source_balance AS
1796     SELECT  COALESCE(c.funding_source, a.funding_source) AS funding_source,
1797             SUM(COALESCE(c.amount,0.0) - COALESCE(a.amount,0.0))::NUMERIC(100,2) AS amount
1798       FROM  acq.funding_source_credit_total c
1799             FULL JOIN acq.funding_source_allocation_total a USING (funding_source)
1800       GROUP BY 1;
1801
1802 CREATE OR REPLACE VIEW acq.fund_allocation_total AS
1803     SELECT  fund,
1804             SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
1805     FROM acq.fund_allocation a
1806          JOIN acq.fund f ON (a.fund = f.id)
1807          JOIN acq.funding_source s ON (a.funding_source = s.id)
1808     GROUP BY 1;
1809
1810 CREATE OR REPLACE VIEW acq.fund_debit_total AS
1811     SELECT  fund.id AS fund,
1812             fund_debit.encumbrance AS encumbrance,
1813                         SUM( COALESCE( fund_debit.amount, 0 ) ) AS amount
1814       FROM acq.fund AS fund
1815             LEFT JOIN acq.fund_debit AS fund_debit
1816                 ON ( fund.id = fund_debit.fund )
1817       GROUP BY 1,2;
1818
1819 CREATE OR REPLACE VIEW acq.fund_encumbrance_total AS
1820     SELECT  fund,
1821             SUM(amount) AS amount
1822       FROM  acq.fund_debit_total
1823       WHERE encumbrance IS TRUE
1824       GROUP BY 1;
1825
1826 CREATE OR REPLACE VIEW acq.fund_spent_total AS
1827     SELECT  fund,
1828             SUM(amount) AS amount
1829       FROM  acq.fund_debit_total
1830       WHERE encumbrance IS FALSE
1831       GROUP BY 1;
1832
1833 CREATE OR REPLACE VIEW acq.fund_combined_balance AS
1834     SELECT  c.fund,
1835             c.amount - COALESCE(d.amount,0.0) AS amount
1836       FROM  acq.fund_allocation_total c
1837             LEFT JOIN acq.fund_debit_total d USING (fund);
1838
1839 CREATE OR REPLACE VIEW acq.fund_spent_balance AS
1840     SELECT  c.fund,
1841             c.amount - COALESCE(d.amount,0.0) AS amount
1842       FROM  acq.fund_allocation_total c
1843             LEFT JOIN acq.fund_spent_total d USING (fund);
1844
1845 COMMIT;
1846
1847
1848
1849