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