all_fund_allocation_total
all_fund_encumbrance_total
all_fund_spent_total
all_fund_spent_balance
all_fund_combined_balance
These views are similar to the correspondingly named views without the
"all_" prefix (i.e. acq.fund_allocation_total, etc) except that the
return a row for every fund in acq.fund, even if the fund is not
represented in acq.fund_debit or acq.fund_allocation.
M Open-ILS/src/sql/Pg/200.schema.acq.sql
M Open-ILS/src/sql/Pg/002.schema.config.sql
A Open-ILS/src/sql/Pg/upgrade/0173.schema.acq.all-fund-views.sql
M Open-ILS/examples/fm_IDL.xml
git-svn-id: svn://svn.open-ils.org/ILS/trunk@15642
dcc99617-32d9-48b4-a31d-
7c20da2025e4
</links>
</class>
+ <class id="acqafat" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::all_fund_allocation_total" oils_persist:readonly="true" oils_persist:tablename="acq.all_fund_allocation_total" reporter:label="All Fund Allocation Total">
+ <fields oils_persist:primary="fund">
+ <field reporter:label="Fund ID" name="fund" reporter:datatype="link" />
+ <field reporter:label="Total Allocation Amount" name="amount" reporter:datatype="money" />
+ </fields>
+ <links>
+ <link field="fund" reltype="has_a" key="id" map="" class="acqf"/>
+ </links>
+ </class>
+
+ <class id="acqafet" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::all_fund_encumbrance_total" oils_persist:readonly="true" oils_persist:tablename="acq.all_fund_encumbrance_total" reporter:label="All Fund Encumbrance Total">
+ <fields oils_persist:primary="fund">
+ <field reporter:label="Fund ID" name="fund" reporter:datatype="link" />
+ <field reporter:label="Total Encumbered Amount" name="amount" reporter:datatype="money" />
+ </fields>
+ <links>
+ <link field="fund" reltype="has_a" key="id" map="" class="acqf"/>
+ </links>
+ </class>
+
+ <class id="acqafst" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::all_fund_spent_total" oils_persist:readonly="true" oils_persist:tablename="acq.all_fund_spent_total" reporter:label="All Fund Spent Total">
+ <fields oils_persist:primary="fund">
+ <field reporter:label="Fund ID" name="fund" reporter:datatype="link" />
+ <field reporter:label="Total Spent Amount" name="amount" reporter:datatype="money" />
+ </fields>
+ <links>
+ <link field="fund" reltype="has_a" key="id" map="" class="acqf"/>
+ </links>
+ </class>
+
+ <class id="acqafsb" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::all_fund_spent_balance" oils_persist:readonly="true" oils_persist:tablename="acq.all_fund_spent_balance" reporter:label="All Fund Spent Balance">
+ <fields oils_persist:primary="fund">
+ <field reporter:label="Fund ID" name="fund" reporter:datatype="link" />
+ <field reporter:label="Total Spent Balance" name="amount" reporter:datatype="money" />
+ </fields>
+ <links>
+ <link field="fund" reltype="has_a" key="id" map="" class="acqf"/>
+ </links>
+ </class>
+
+ <class id="acqafcb" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::all_fund_combined_balance" oils_persist:readonly="true" oils_persist:tablename="acq.all_fund_combined_balance" reporter:label="All Fund Combined Total">
+ <fields oils_persist:primary="fund">
+ <field reporter:label="Fund ID" name="fund" reporter:datatype="link" />
+ <field reporter:label="Total Combined Balance" name="amount" reporter:datatype="money" />
+ </fields>
+ <links>
+ <link field="fund" reltype="has_a" key="id" map="" class="acqf"/>
+ </links>
+ </class>
+
<class id="acqfsrcct" controller="open-ils.cstore open-ils.reporter-store" oils_obj:fieldmapper="acq::funding_source_credit_total" oils_persist:readonly="true" oils_persist:tablename="acq.funding_source_credit_total" reporter:label="Total Credit to Funding Source">
<fields oils_persist:primary="funding_source">
<field reporter:label="Funding Source" name="funding_source" reporter:datatype="link" />
install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-INSERT INTO config.upgrade_log (version) VALUES ('0172'); -- Scott McKellar
+INSERT INTO config.upgrade_log (version) VALUES ('0173'); -- Scott McKellar
CREATE TABLE config.bib_source (
id SERIAL PRIMARY KEY,
FROM acq.fund_allocation_total c
LEFT JOIN acq.fund_spent_total d USING (fund);
+-- For each fund: the total allocation from all sources, in the
+-- currency of the fund (or 0 if there are no allocations)
+
+CREATE VIEW acq.all_fund_allocation_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( SUM( a.amount * acq.exchange_ratio(
+ s.currency_type, f.currency_type))::numeric(100,2), 0 )
+ AS amount
+FROM
+ acq.fund f
+ LEFT JOIN acq.fund_allocation a
+ ON a.fund = f.id
+ LEFT JOIN acq.funding_source s
+ ON a.funding_source = s.id
+GROUP BY
+ f.id;
+
+-- For every fund: the total encumbrances (or 0 if none),
+-- in the currency of the fund.
+
+CREATE VIEW acq.all_fund_encumbrance_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( encumb.amount, 0 ) AS amount
+FROM
+ acq.fund AS f
+ LEFT JOIN (
+ SELECT
+ fund,
+ sum( amount ) AS amount
+ FROM
+ acq.fund_debit
+ WHERE
+ encumbrance
+ GROUP BY fund
+ ) AS encumb
+ ON f.id = encumb.fund;
+
+-- For every fund: the total spent (or 0 if none),
+-- in the currency of the fund.
+
+CREATE VIEW acq.all_fund_spent_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( spent.amount, 0 ) AS amount
+FROM
+ acq.fund AS f
+ LEFT JOIN (
+ SELECT
+ fund,
+ sum( amount ) AS amount
+ FROM
+ acq.fund_debit
+ WHERE
+ NOT encumbrance
+ GROUP BY fund
+ ) AS spent
+ ON f.id = spent.fund;
+
+-- For each fund: the amount not yet spent, in the currency
+-- of the fund. May include encumbrances.
+
+CREATE VIEW acq.all_fund_spent_balance AS
+SELECT
+ c.fund,
+ c.amount - d.amount AS amount
+FROM acq.all_fund_allocation_total c
+ LEFT JOIN acq.all_fund_spent_total d USING (fund);
+
+-- For each fund: the amount neither spent nor encumbered,
+-- in the currency of the fund
+
+CREATE VIEW acq.all_fund_combined_balance AS
+SELECT
+ a.fund,
+ a.amount - COALESCE( c.amount, 0 ) AS amount
+FROM
+ acq.all_fund_allocation_total a
+ LEFT OUTER JOIN (
+ SELECT
+ fund,
+ SUM( amount ) AS amount
+ FROM
+ acq.fund_debit
+ GROUP BY
+ fund
+ ) AS c USING ( fund );
+
COMMIT;
--- /dev/null
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0173'); -- Scott McKellar
+
+-- For each fund: the total allocation from all sources, in the
+-- currency of the fund (or 0 if there are no allocations)
+
+CREATE VIEW acq.all_fund_allocation_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( SUM( a.amount * acq.exchange_ratio(
+ s.currency_type, f.currency_type))::numeric(100,2), 0 )
+ AS amount
+FROM
+ acq.fund f
+ LEFT JOIN acq.fund_allocation a
+ ON a.fund = f.id
+ LEFT JOIN acq.funding_source s
+ ON a.funding_source = s.id
+GROUP BY
+ f.id;
+
+-- For every fund: the total encumbrances (or 0 if none),
+-- in the currency of the fund.
+
+CREATE VIEW acq.all_fund_encumbrance_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( encumb.amount, 0 ) AS amount
+FROM
+ acq.fund AS f
+ LEFT JOIN (
+ SELECT
+ fund,
+ sum( amount ) AS amount
+ FROM
+ acq.fund_debit
+ WHERE
+ encumbrance
+ GROUP BY fund
+ ) AS encumb
+ ON f.id = encumb.fund;
+
+-- For every fund: the total spent (or 0 if none),
+-- in the currency of the fund.
+
+CREATE VIEW acq.all_fund_spent_total AS
+SELECT
+ f.id AS fund,
+ COALESCE( spent.amount, 0 ) AS amount
+FROM
+ acq.fund AS f
+ LEFT JOIN (
+ SELECT
+ fund,
+ sum( amount ) AS amount
+ FROM
+ acq.fund_debit
+ WHERE
+ NOT encumbrance
+ GROUP BY fund
+ ) AS spent
+ ON f.id = spent.fund;
+
+-- For each fund: the amount not yet spent, in the currency
+-- of the fund. May include encumbrances.
+
+CREATE VIEW acq.all_fund_spent_balance AS
+SELECT
+ c.fund,
+ c.amount - d.amount AS amount
+FROM acq.all_fund_allocation_total c
+ LEFT JOIN acq.all_fund_spent_total d USING (fund);
+
+-- For each fund: the amount neither spent nor encumbered,
+-- in the currency of the fund
+
+CREATE VIEW acq.all_fund_combined_balance AS
+SELECT
+ a.fund,
+ a.amount - COALESCE( c.amount, 0 ) AS amount
+FROM
+ acq.all_fund_allocation_total a
+ LEFT OUTER JOIN (
+ SELECT
+ fund,
+ SUM( amount ) AS amount
+ FROM
+ acq.fund_debit
+ GROUP BY
+ fund
+ ) AS c USING ( fund );
+
+COMMIT;