I am not sure how much of this rewrite is correct.
I believe I identified a number of places where currency conversions
were missing. As well, I have cut out some IF branches.
My comments are verbose at the moment to help me figure out what is
going on.
I have also added a second function acq.current_fund_allocation, which
returns the total amount of money allocated to the current fund.
This allows the acq.transfer_fund to determine if it is trying to
transfer more money than is currently available.
A few more sanity checks have also been added. And, the currency
conversion is done strictly from the database now. It seems
inconsistent to me to convert between old_fund and new_fund according to
a rate defined outside of this funciton but to convert between the funds
and the funding sources with values from acq.exchange_rate
(sitka) [RT18248] Working on getting rollover to work
In the process of figuring out how to make rollover work with my
modified transfer_fund function.
Need to print out the values trying to be transferred back to the
funding source via RAISE EXCEPTION
(sitka) [RT18248] Fixing asq.transfer_fund function
The function has to be broken up into parts. One for transfering funds
and one for returning funds to funding sources. This work so far has
created the code for transfering between funds. The acq.fund_allocation
table needs to be updated to have fund_amount and conversion_ratio
fields added. fund_amount will allow the funds to display their total
without fluctuating depending on the worth of the funding source
currency and conversion ratio is good to have for accounting purposes.
(sitka) [RT18248]
Fixed transfer_fund. It was using an amount to return to the funding
source based on the amount allocated by the funding source. But, it was
converting this amount to the currency of the fund. So, if the exchange
rate changes, then athe amount allocated to the fund will change for the
transfer when it should stay constant.
To do this, we add a fund_amount field to the acq.fund_allocation table.
This amount is stored in the curecny of the fund, which will allow us to
determine how much money is in a fund even when the exchange rates
change.
This commit also adds the fuction acq.return_funds_to_source. This is
used when funds are returned to a funding source without then
transferring them to another fund. This can happen when rolling over
acqusitions at year end depending on the options chosen.
(sitka) [RT18248] Added updates for rollover functions
Added updates for the acq.rollover_funds_by_org_unit and
acq.rollover_funds_by_org_tree functions, so they use the new
acq.return_funds_to_source function when appropriate.
As well, aded a commented out DROP line to remove the old version of the
acq.transfer_fund function.
(sitka) [RT18248] Tracked down all old transfer_fund references
This code modifies the upgrade to the acq.rollover_by_org_unit and
acq.rollover_by_org_tree to use acq.return_funds_to_source rather than
acq.transfer_fund. As well, it modifies all old versions of transfer
fund because the new version has new parameters.
(sitka) [RT18248] Fixing stuff via pgTap
A number of syntax errors presented themselves when using pgTap to test
the changes. These have been fixed.
(sitka) [RT18248] Fixing rollover
The transfer_fund function needed and still needs work. But, the
current version is working. It needs to be modified, so we can tell the
difference between potential transfers and real transfers.
The rollover_funds_by_org_tree function needed to be updated to use the
spent total when doing year end and only transferring encumbered funds.
By using the spent total, it now returns that amount to the funding
source. We do not use the combined total because that includes the
encumbered funds and we want those to stay with the current fund so the
library can choose to move them manually to the new fund if the
encumberance is set to rollover, or do something else with them if they
are set to stay.
(sitka) [RT18248] Fixed acq.fund_transfer error
Updated the pgTap test to work with the acq.fund_transfer changes.
Tracked down an error in acq.fund_transfer. In the case where the
transferring and receiving currencies are the same, the
inverted_conversion_ratio was not being set to 1, which meant it had a
NULL value. This was causing the amount_credited to the funding_source
to be seen as NULL, which was breaking the transfer in the case where
the fund currenices are the same.
(sitka) [RT18248] Fixing acq.return_funds_to_source
Started to write a pgTap test for acq.return_funds_to_source. It is
breaking currently because of an 'input of anonymous composite types is
not implemented' error.
When I reloaded the acq.return_funds_to_source file into dev4's
database, I got an error about a RAISE NOTICE that was using variables
that were no longer in use such as old_fund. Once this was fixed, it
appears that roll over is now working (minus the weird rounding). I
need to verify that this is the case. As well the balances do not show
as negative for 2014 even though the encumberances are being
transferred. Need to figure out why that is.
(sitka) [RT18248] Update to acq.fund_allocation_total
acq.fund_allocation_total was returning NULL values when there were no
funds allocated by a source to a fund. This causes a bug when
calculating balances. For instance, acq.fund_combined_balance would
subtract debits from the fund allocations, but, because
acq.fund_allocation_total would return a NULL value, this would result
in the balance being reported as 0. This was apparent when looking at
the new funds after rolling over an Org Unit's funds. In those cases,
encumbrances existed in the new funds, but the balances were being
reported as 0.
(sitka) [RT18248] Fixed pgTab for acq.return_funds_to_source
The pgTap test now works with acq.return_funds_to_source. There was an
error input of anonymous composite types is not implemented, which was
causing trouble. It was a result of trying to use ARRAY_AGG with
different column names. The inner SELECT was using one name (amount),
and the outer SELECT was using a different name (return_amount).
Maybe, the types are defined by looking up the name of the column within
pg's internal state, so using different names causes a problem?
(sitka) [RT18248] Fixed allocation total bug
The current code was modifying the acq.fund_allocation.fund_amount,
which is being used to determine if the amount being returned to a fund
is greater than the amount that was originally allocated to the fund.
However, when funds are transferred, the allocations are changed, and
this interferres with determining if the amount being returned is
greater that the amount allocated. This fix stores the values allocated
for each fund in a two dimensional array. The indexes are the fund id
and the funding credit id. This allows the code to determine everytime
through the LOOP if each amount beging transferred is greater than the
amount allocated.
(sitka) [RT18248] Fixing year end rollover
This commit uses spent_balance instead combined_balance to determine if
the amount to be returned in return_funds_to_source is more than the
amount allocated to the source.
As well, the rollover now returns the spent balance when transferring
and returning funds.
Signed-off-by: Liam Whalen <liam.whalen@bc.libraries.coop>
(sitka) [RT18248] Added new fields to acq.fund_allocation
Added fund_amount NUMERIC and allocation to acq.fund_allocation NUMERIC.
Signed-off-by: Liam Whalen <liam.whalen@bc.libraries.coop>
(sitka) [RT18248] Added acq.fund_allocation trigger
This trigger UPDATEs acq.fund_allocation.fund_amount and
acq.fund_allocation.conversion_ratio when a new entry is INSERTed into
the the acq.fund_allocation table.
If the amount being inserted is postiive then is converts from the
funding source currency to the fund currency because the amount is being
allocated to the fund. If the amount being inserted is negative then it
converts from the fund currency to the funding source currency because
the amount is being returned to the funding source.
$e->json_query({
from => [
'acq.transfer_fund',
- $ofund_id, $ofund_amount, $dfund_id, $dfund_amount, $e->requestor->id, $note
+ $ofund_id, $ofund_amount, $dfund_id, $e->requestor->id, $note
]
});
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION acq.transfer_fund(
- old_fund IN INT,
- old_amount IN NUMERIC, -- in currency of old fund
- new_fund IN INT,
- new_amount IN NUMERIC, -- in currency of new fund
- user_id IN INT,
- xfer_note IN TEXT -- to be recorded in acq.fund_transfer
- -- ,funding_source_in IN INT -- if user wants to specify a funding source (see notes)
+ transferring_fund_id IN INT,
+ amount_to_transfer IN NUMERIC, -- in currency of
+ -- transferring fund
+ receiving_fund_id IN INT,
+ user_id IN INT, -- user initiating
+ -- the transfer
+ xfer_note IN TEXT, -- to be recorded in
+ -- acq.fund_transfer
+ transferring_funding_source IN INT DEFAULT NULL -- if user wants to
+ -- specify a funding
+ -- source (see notes)
) RETURNS VOID AS $$
/* -------------------------------------------------------------------------------
----------
In the signature for this function, there is one last parameter commented out,
-named "funding_source_in". Correspondingly, the WHERE clause for the query
+named "transferring_funding_source". Correspondingly, the WHERE clause for the query
driving the main loop has an OR clause commented out, which references the
-funding_source_in parameter.
+transferring_funding_source parameter.
If these lines are uncommented, this function will allow the user optionally to
restrict a fund transfer to a specified funding source. If the source
------------------------------------------------------------------------------- */
DECLARE
- same_currency BOOLEAN;
- currency_ratio NUMERIC;
- old_fund_currency TEXT;
- old_remaining NUMERIC; -- in currency of old fund
- new_fund_currency TEXT;
- new_fund_active BOOLEAN;
- new_remaining NUMERIC; -- in currency of new fund
- curr_old_amt NUMERIC; -- in currency of old fund
- curr_new_amt NUMERIC; -- in currency of new fund
- source_addition NUMERIC; -- in currency of funding source
- source_deduction NUMERIC; -- in currency of funding source
- orig_allocated_amt NUMERIC; -- in currency of funding source
- allocated_amt NUMERIC; -- in currency of fund
- source RECORD;
+ -- are the transferring and receiving funds the same currency?
+ same_currency BOOLEAN;
+
+ -- The ratio between the transferring fund and the receiving
+ -- fund. Other ratios may be needed due to other currencies
+ -- in the funding sources.
+ currency_ratio NUMERIC;
+
+ transferring_fund_currency TEXT;
+
+ -- kept in the currency of transferring fund
+ funds_remaining_to_be_transferred NUMERIC;
+
+ -- the transferring fund must be active if the amount to
+ -- transfer isnegative because it will have to accept funds
+ transferring_fund_active BOOLEAN;
+
+ receiving_fund_currency TEXT;
+
+ -- kept in currency of recieving fund
+ funds_remaining_to_be_received NUMERIC;
+
+ -- the receiving fund must be active to accept funds
+ receiving_fund_active BOOLEAN;
+
+ -- kept in currency of transferring fund
+ current_amount_to_transfer NUMERIC;
+
+ -- in currency of recevinig fund
+ current_amount_to_receive NUMERIC;
+
+ -- in currency of funding source
+ funding_source_credit NUMERIC;
+
+ -- Ratio between the transferring fund and the source
+ source_credit_conversion_ratio NUMERIC;
+
+ -- in currency of funding source
+ funding_source_debit NUMERIC;
+
+ -- Ratio between the receiving fund and the source
+ source_debit_conversion_ratio NUMERIC;
+
+ -- kept in currency of transferring fund
+ amount_allocated_by_funding_source NUMERIC;
+
+ -- kept in currency of transferring fund
+ amount_currently_allocated_to_transferring_fund NUMERIC;
+
+ -- a JOIN of acq.funding_source and
+ -- acq.ordered_funding_source_credit
+ source RECORD;
+
+ -- Used to swap funds when a negative amount is supplied
+ -- to amount_to_transfer
+ temp_fund_id INTEGER;
+
+ -- Used to sawp currencies when a negative amount is
+ -- supplied to amount_to_transfer
+ temp_currency TEXT;
BEGIN
--
- -- Sanity checks
- --
- IF old_fund IS NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: old fund id is NULL';
- END IF;
+ -- We need to lock this table because the exchange rates could be modifed
+ -- while we are doing a transfer, which would create unpredictable results
--
- IF old_amount IS NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
- END IF;
+ LOCK acq.exchange_rate
+ IN EXCLUSIVE MODE;
+
--
- -- The new fund and its amount must be both NULL or both not NULL.
+ -- Sanity checks
--
- IF new_fund IS NOT NULL AND new_amount IS NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: amount to transfer to receiving fund is NULL';
+ IF transferring_fund_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: transferring fund id is NULL';
END IF;
--
- IF new_fund IS NULL AND new_amount IS NOT NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: receiving fund is NULL, its amount is not NULL';
+ IF receiving_fund_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: recieving fund id is NULL';
END IF;
--
- IF user_id IS NULL THEN
+ IF amount_to_transfer IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
+ END IF;
+ --
+ IF user_id IS NULL THEN
RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
END IF;
+ --
+ IF amount_to_transfer = 0 THEN
+ RAISE EXCEPTION 'acq.transfer_fund amount to transfer is 0';
+ END IF;
+
--
- -- Initialize the amounts to be transferred, each denominated
- -- in the currency of its respective fund. They will be
- -- reduced on each iteration of the loop.
+ -- Get the currency and active status of the transferring fund
--
- old_remaining := old_amount;
- new_remaining := new_amount;
+ SELECT
+ currency_type,
+ active
+ INTO
+ transferring_fund_currency,
+ transferring_fund_active
+ FROM
+ acq.fund
+ WHERE
+ id = transferring_fund_id;
--
- -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
- -- old_amount, old_fund, new_amount, new_fund;
+ IF transferring_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: transferring fund currency is not defined for fund id: %', transferring_fund_id;
+ END IF;
--
- -- Get the currency types of the old and new funds.
+ -- Get the currency and active status of the receiving fund
--
SELECT
- currency_type
+ currency_type,
+ active
INTO
- old_fund_currency
+ receiving_fund_currency,
+ receiving_fund_active
FROM
acq.fund
WHERE
- id = old_fund;
+ id = receiving_fund_id;
--
- IF old_fund_currency IS NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: old fund id % is not defined', old_fund;
+ IF receiving_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: receiving fund currency is not defined for fund id: %', receiving_fund_id;
END IF;
--
- IF new_fund IS NOT NULL THEN
- SELECT
- currency_type,
- active
- INTO
- new_fund_currency,
- new_fund_active
- FROM
- acq.fund
- WHERE
- id = new_fund;
+ -- If the amount to transfer is negative then swap the transferring and
+ -- receiving funds
+ --
+ IF amount_to_transfer < 0 THEN
+ --
+ -- Because the amount is negative, we need to check if the transferring
+ -- fund is active, so we do not transfer to an inactive transferring fund
--
- IF new_fund_currency IS NULL THEN
- RAISE EXCEPTION 'acq.transfer_fund: new fund id % is not defined', new_fund;
- ELSIF NOT new_fund_active THEN
+ IF NOT transferring_fund_active THEN
--
-- No point in putting money into a fund from whence you can't spend it
--
- RAISE EXCEPTION 'acq.transfer_fund: new fund id % is inactive', new_fund;
+ RAISE EXCEPTION 'acq.transfer_fund: Amount to transfer is negative, and transferring fund id % is inactive', transferring_fund_id;
END IF;
- --
- IF new_amount = old_amount THEN
- same_currency := true;
- currency_ratio := 1;
+
+ IF transferring_fund_crrency = receiving_fund_currecy THEN
+ -- they are the same currencies, so make amount_to_transfer a positve value
+ amount_to_transfer := amount_to_transfer * -1;
ELSE
- --
- -- We'll have to translate currency between funds. We presume that
- -- the calling code has already applied an appropriate exchange rate,
- -- so we'll apply the same conversion to each sub-transfer.
- --
- same_currency := false;
- currency_ratio := new_amount / old_amount;
+ -- turn the amount to transfer into a positive value and
+ -- convert the funds amount to transfer from
+ -- the currency of the transferring fund into the currecny of
+ -- the receiving fund
+ amount_to_transfer := trunc( amount_to_transfer *
+ acq.exchange_ratio(transferring_fund_currency, receiving_fund_currency), 2 ) * -1;
END IF;
+
+ temp_fund_id := transferring_fund_id;
+ temp_currency := transferring_fund_currency;
+ transferring_fund_id := receiving_fund_id;
+ transferring_fund_currency := receiving_fund_currency;
+ receiving_fund_id := temp_fund_id;
+ receiving_fund_currency := temp_currency;
+ ELSIF NOT receiving_fund_active THEN
+ -- We need to check this after a possible swap and not before
+ -- because it is ok to transfer from an inactive fund, so
+ -- the fact that receiving fund has not been swapped means
+ -- we can now check to make sure it is active
+ --
+ -- No point in putting money into a fund from whence you can't spend it
+ --
+ RAISE EXCEPTION 'acq.transfer_fund: receiving fund id % is inactive', receiving_fund_id;
+ END IF;
+
+ -- ensure there is enough money in the fund to cover the amount to transfer
+ -- we do this after checking if we need to swap funds to ensure we are
+ -- checking the correct fund for the necessary funds to transfer
+ SELECT amount
+ INTO amount_currently_allocated_to_transferring_fund
+ FROM acq.fund_combined_balance
+ WHERE fund = transferring_fund_id;
+
+ -- Ensure there is enough money left in this fund to fulfill the transfer
+ IF amount_to_transfer >= amount_currently_allocated_to_transferring_fund THEN
+ RAISE EXCEPTION 'Cannot transfer more money than is currently allocted to the fund. fund id: % has % allocated to it, and acq.transfer_fund is trying to debit it for %',
+ transferring_fund_id, amount_currently_allocated_to_transferring_fund, amount_to_transfer;
+ END IF;
+
+ --
+ -- Initialize the amounts to be transferred, each denominated
+ -- in the currency of its respective fund. They will be
+ -- reduced on each iteration of the loop.
+ --
+ funds_remaining_to_be_transferred := amount_to_transfer;
+ --
+ RAISE NOTICE 'Transferring % in fund % to fund %',
+ amount_to_transfer, transferring_fund_id, receiving_fund_id;
+ --
+ IF transferring_fund_currency = receiving_fund_currency THEN
+ same_currency := true;
+ currency_ratio := 1;
+ funds_remaining_to_be_received := funds_remaining_to_be_transferred;
+ ELSE
+ --
+ -- We'll have to translate currency between funds.
+ -- In this version we are only using the value to be transfered
+ -- from the old fund. We will convert in this funciton
+ --
+ same_currency := false;
+ currency_ratio := acq.exchange_ratio(transferring_fund_currency, receiving_fund_currency);
+ funds_remaining_to_be_received := trunc( funds_remaining_to_be_transferred * currency_ratio, 2 );
END IF;
+
--
-- Identify the funding source(s) from which we want to transfer the money.
-- The principle is that we want to transfer the newest money first, because
-- we spend the oldest money first. The priority for spending is defined
-- by a sort of the view acq.ordered_funding_source_credit.
--
- FOR source in
+
+ FOR source IN
SELECT
ofsc.id,
ofsc.funding_source,
ofsc.amount,
- ofsc.amount * acq.exchange_ratio( fs.currency_type, old_fund_currency )
- AS converted_amt,
+ ofsc.amount * acq.exchange_ratio(fs.currency_type, transferring_fund_currency)
+ AS amount_credited_to_fund,
fs.currency_type
FROM
acq.ordered_funding_source_credit AS ofsc,
(
SELECT funding_source
FROM acq.fund_allocation
- WHERE fund = old_fund
+ WHERE fund = transferring_fund_id
+ )
+ and
+ (
+ ofsc.funding_source = transferring_funding_source
+ OR transferring_funding_source IS NULL
)
- -- and
- -- (
- -- ofsc.funding_source = funding_source_in
- -- OR funding_source_in IS NULL
- -- )
ORDER BY
ofsc.sort_priority desc,
ofsc.sort_date desc,
ofsc.id desc
LOOP
--
- -- Determine how much money the old fund got from this funding source,
- -- denominated in the currency types of the source and of the fund.
- -- This result may reflect transfers from previous iterations.
+ -- Determine total amount of credits that this funding source has give this fund
+ -- Denominated in the currency types of the transferring fund.
+ -- Because we need to look at specific allocations,
+ -- this result may reflect transfers from previous iterations.
--
SELECT
- COALESCE( sum( amount ), 0 ),
- COALESCE( sum( amount )
- * acq.exchange_ratio( source.currency_type, old_fund_currency ), 0 )
+ COALESCE( sum( fund_amount ), 0 )
INTO
- orig_allocated_amt, -- in currency of the source
- allocated_amt -- in currency of the old fund
+ amount_allocated_by_funding_source -- in currency of the transferring fund
FROM
acq.fund_allocation
WHERE
- fund = old_fund
+ fund = transferring_fund_id
and funding_source = source.funding_source;
--
-- Determine how much to transfer from this credit, in the currency
- -- of the fund. Begin with the amount remaining to be attributed:
+ -- of the fund. Begin with the amount remaining to be transferred
--
- curr_old_amt := old_remaining;
+ current_amount_to_transfer := funds_remaining_to_be_transferred;
+
--
- -- Can't attribute more than was allocated from the fund:
+ -- Can't attribute more than was allocated to the fund:
--
- IF curr_old_amt > allocated_amt THEN
- curr_old_amt := allocated_amt;
+ IF current_amount_to_transfer > amount_allocated_by_funding_source THEN
+ current_amount_to_transfer := amount_allocated_by_funding_source;
END IF;
--
- -- Can't attribute more than the amount of the current credit:
+ -- Can't attribute more than the amount of the current credit from the funding source:
--
- IF curr_old_amt > source.converted_amt THEN
- curr_old_amt := source.converted_amt;
+ IF current_amount_to_transfer > source.amount_credited_to_fund THEN
+ current_amount_to_transfer := source.amount_credited_to_fund;
END IF;
--
- curr_old_amt := trunc( curr_old_amt, 2 );
+ current_amount_to_transfer := trunc( current_amount_to_transfer, 2 );
--
- old_remaining := old_remaining - curr_old_amt;
+ -- At some point funds_remaining_to_be_transferred value WILL become 0
+ -- because current_amount_to_transfer is set to funds_remaining_to_be_transferred above
+ -- and it is never increased above that.
--
- -- Determine the amount to be deducted, if any,
- -- from the old allocation.
+ funds_remaining_to_be_transferred := funds_remaining_to_be_transferred - current_amount_to_transfer;
+
--
- IF old_remaining > 0 THEN
- --
- -- In this case we're using the whole allocation, so use that
- -- amount directly instead of applying a currency translation
- -- and thereby inviting round-off errors.
- --
- source_deduction := - orig_allocated_amt;
- ELSE
- source_deduction := trunc(
- ( - curr_old_amt ) *
- acq.exchange_ratio( old_fund_currency, source.currency_type ),
- 2 );
- END IF;
+ -- Determine the amount to be credited, if any,
+ -- to the funding source.
--
- IF source_deduction <> 0 THEN
+
+ --
+ -- Either the entire amount is being deducted (the case where current_amount_to_transfer
+ -- is less than the
+ -- amount_allocated_by_funding_source and source.amount_credited_to_fund), we're
+ -- are deducting the whole allocation from the current funding source credit,
+ -- or we are deducting the amount allocated in this single unding source credit if it is
+ -- less than the original amount of the credit (due to previous debits).
+ -- In all these cases these values are represented by current_amount_to_transfer.
+ -- We need to convert the amount into the source.currency_type regardless of the
+ -- condiitons above because we are deducting from the source not the fund.
+ --
+
+ source_credit_conversion_ratio := acq.exchange_ratio( transferring_fund_currency, source.currency_type );
+ funding_source_credit := trunc(
+ ( - current_amount_to_transfer ) *
+ source_credit_conversion_ratio,
+ 2 );
+
+ -- Ensure the credit is less than or equal to 0
+ -- We insert the case where it is equal to 0 because
+ -- there may be a need for a corresponding 0 entry in acq.fund_transfer,
+ -- which is INSERTed near the end of this function.
+
+ -- transfering a negative amount from a fund is the same as
+ -- crediting it back to the funding source, which must
+ -- happen before the amount is transferred to the receiving fund
+ IF funding_source_credit <= 0 THEN
--
- -- Insert negative allocation for old fund in fund_allocation,
+ -- Insert negative (or 0) allocation for old fund in fund_allocation,
-- converted into the currency of the funding source
--
INSERT INTO acq.fund_allocation (
fund,
amount,
allocator,
- note
+ note,
+ conversion_ratio,
+ fund_amount
) VALUES (
source.funding_source,
- old_fund,
- source_deduction,
+ transferring_fund_id,
+ funding_source_credit,
user_id,
- 'Transfer to fund ' || new_fund
+ 'Transfer to fund ' || receiving_fund_id,
+ source_credit_conversion_ratio,
+ (current_amount_to_transfer * -1)
);
+ ELSE
+ RAISE EXCEPTION 'funding_source_credit of % is greater than 0', funding_source_credit;
END IF;
--
- IF new_fund IS NOT NULL THEN
- --
- -- Determine how much to add to the new fund, in
- -- its currency, and how much remains to be added:
- --
- IF same_currency THEN
- curr_new_amt := curr_old_amt;
+ --
+ -- Determine how much to add to the receiving fund, in
+ -- its currency, and how much remains to be added:
+ --
+ IF same_currency THEN
+ current_amount_to_receive := current_amount_to_transfer;
+ ELSE
+ -- If there are not funds left to be transferred then
+ -- transfer the remaining funds to be recieved from the
+ -- funding source. In this instance, conversion rates
+ -- have resulted in us transferring more out than we transferred
+ -- back in
+ IF funds_remaining_to_be_transferred = 0 THEN
+ current_amount_to_receive := funds_remaining_to_be_received;
+ funds_remaining_to_be_received := 0;
ELSE
- IF old_remaining = 0 THEN
- --
- -- This is the last iteration, so nothing should be left
- --
- curr_new_amt := new_remaining;
- new_remaining := 0;
- ELSE
- curr_new_amt := trunc( curr_old_amt * currency_ratio, 2 );
- new_remaining := new_remaining - curr_new_amt;
+ -- set the amount to recieve to be the amount to transfer converted into
+ -- the currenty of the receiving fund
+ current_amount_to_receive := trunc( current_amount_to_transfer * currency_ratio, 2 );
+ funds_remaining_to_be_received := funds_remaining_to_be_received - current_amount_to_receive;
+
+ --
+ -- It may be that the amount to be transfered to the new
+ -- fund becomes less than 0
+ -- a loop before funds_remaining_to_be_transferred becomes 0
+ -- I am not positive if this is possible, but
+ -- it is good to guard against it.
+ --
+ IF funds_remaining_to_be_received < 0 THEN
+ funds_remaining_to_be_received := 0;
END IF;
END IF;
+ END IF;
+
+ --
+ -- Determine how much to add, if any,
+ -- to the receiving fund's allocation.
+ --
+
+ IF source.currency_type = receiving_fund_currency THEN
+ source_debit_conversion_ratio = 1;
--
- -- Determine how much to add, if any,
- -- to the new fund's allocation.
+ -- In this case we don't need a round trip currency translation,
+ -- because current_amount_to_receive is either in the same currency as the transferring fund
+ -- so it does not need to be converted, or it has been converted in the IF
+ -- block above this either through multiplication via the currency_ratio
+ -- of via assignment of funds_remaining_to_be_received which is in the denomination of the
+ -- receiving currency
--
- IF old_remaining > 0 THEN
- --
- -- In this case we're using the whole allocation, so use that amount
- -- amount directly instead of applying a currency translation and
- -- thereby inviting round-off errors.
- --
- source_addition := orig_allocated_amt;
- ELSIF source.currency_type = old_fund_currency THEN
- --
- -- In this case we don't need a round trip currency translation,
- -- thereby inviting round-off errors:
- --
- source_addition := curr_old_amt;
- ELSE
- source_addition := trunc(
- curr_new_amt *
- acq.exchange_ratio( new_fund_currency, source.currency_type ),
- 2 );
- END IF;
+ funding_source_debit := current_amount_to_receive;
+ ELSE
+ source_debit_conversion_ratio := acq.exchange_ratio( transferring_fund_currency, source.currency_type );
+ --
+ -- Otherwise, we need to convert the amount being added
+ -- from the source to the new fund
+ -- into the currency of the source.
--
- IF source_addition <> 0 THEN
- --
- -- Insert positive allocation for new fund in fund_allocation,
- -- converted to the currency of the founding source
- --
- INSERT INTO acq.fund_allocation (
- funding_source,
- fund,
- amount,
- allocator,
- note
- ) VALUES (
- source.funding_source,
- new_fund,
- source_addition,
- user_id,
- 'Transfer from fund ' || old_fund
- );
- END IF;
+ funding_source_debit := trunc(
+ current_amount_to_receive *
+ acq.exchange_ratio( receiving_fund_currency, source.currency_type ),
+ 2 );
END IF;
--
- IF trunc( curr_old_amt, 2 ) <> 0
- OR trunc( curr_new_amt, 2 ) <> 0 THEN
+ -- Ensure the debit is greater than or equal to 0
+ -- Similar to funding_source_credit there may be a corresponding
+ -- entry in acq.fund_transfer.
+ --
+ IF funding_source_debit >= 0 THEN
+ --
+ -- Insert positive allocation (or 0) for new fund in fund_allocation,
+ -- converted to the currency of the founding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note,
+ conversion_ratio,
+ fund_amount
+ ) VALUES (
+ source.funding_source,
+ receiving_fund_id,
+ funding_source_debit,
+ user_id,
+ 'Transfer from fund ' || transferring_fund_id,
+ source_debit_conversion_ratio,
+ current_amount_to_receive
+ );
+ ELSE
+ RAISE EXCEPTION 'acq.fund_transfer: funding_source_debit % is less than 0', funding_source_debit;
+ END IF;
+ --
+ -- Either of these can be greater than 0.
+ -- current_amount_to_transfer is the value to be transferred. current_amount_to_receive is that
+ -- value converted into the new funds currency
+ -- If the entire amount can be taken from a single source credit. Then
+ -- this is a simple calculation.
+ -- Otherwise, current_amount_to_transfer is set to the amount left in funds_remaining_to_be_transferred
+ -- after a loop or the values in the current funding source credit.
+ -- And, current_amount_to_receive is set to the converted amount from current_amount_to_transfer.
+ -- Finally, once funds_remaining_to_be_transferred = 0 curr_new_amount is set to funds_remaining_to_be_received,
+ -- and new remaining will be 0 after that. Because funds_remaining_to_be_received
+ -- is only calculated once (after that it is only debited), this should
+ -- ensure that they both arrive at 0 together
+ -- There may be some conversion issues that make this not true, but I
+ -- cannot think of any at the moment. The code needs further examination.
+ IF trunc( current_amount_to_transfer, 2 ) > 0
+ OR trunc( current_amount_to_receive, 2 ) > 0 THEN
--
-- Insert row in fund_transfer, using amounts in the currency of the funds
--
note,
funding_source_credit
) VALUES (
- old_fund,
- trunc( curr_old_amt, 2 ),
- new_fund,
- trunc( curr_new_amt, 2 ),
+ transferring_fund_id,
+ trunc( current_amount_to_transfer, 2 ),
+ receiving_fund_id,
+ trunc( current_amount_to_receive, 2 ),
user_id,
xfer_note,
source.id
);
END IF;
--
- if old_remaining <= 0 THEN
+ -- It should be impossible for funds_remaining_to_be_transferred to be less than 0.
+ --
+ IF funds_remaining_to_be_transferred = 0 THEN
EXIT; -- Nothing more to be transferred
+ ELSIF funds_remaining_to_be_transferred < 0 THEN
+ RAISE EXCEPTION 'acq.transfer_fund: funds_remaining_to_be_transferred is less thant 0: % FIND OUT WHY',
+ funds_remaining_to_be_transferred;
END IF;
END LOOP;
+
+ --
+ -- This should not be possible any more, but we can leave it in just in case there
+ -- is a case that has not been thought of.
+ --
+ IF funds_remaining_to_be_transferred > 0 THEN
+ RAISE EXCEPTION 'not all of funds_remaining_to_be_transferred were transfered. There must not have been enough funds in the funding sources';
+ END IF;
END;
$$ LANGUAGE plpgsql;
--- /dev/null
+BEGIN;
+
+SELECT plan(2);
+
+INSERT INTO acq.funding_source (name, owner, currency_type, code)
+ VALUES ('FS1', 1, 'USD', 'FS1');
+
+INSERT INTO acq.funding_source_credit (funding_source, amount, deadline_date )
+VALUES
+ (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ 300,
+ NOW() + '1 DAY'::INTERVAL
+ ), (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ 500,
+ NULL -- no deadline_date ensures this credit will be used first
+ -- for transfers, giving us a predictable (testable) outcome.
+ );
+
+INSERT INTO acq.fund (org, name, year, currency_type, active) VALUES
+ (1, 'F1', '2014', 'USD', TRUE),
+ (1, 'F2', '2014', 'USD', TRUE);
+
+-- LP#800478
+-- allocation must exceed transfer amount but be less than total credits
+INSERT INTO acq.fund_allocation
+ (funding_source, fund, amount, fund_amount, allocator, note)
+VALUES (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ (SELECT id FROM acq.fund WHERE name = 'F1'),
+ 700 , 700, 1, 'test'
+);
+
+-- LP#800478
+-- transfer amount must exceed any one funding source credit but be less
+-- than the allocation amount
+SELECT acq.transfer_fund(
+ (SELECT id FROM acq.fund WHERE name = 'F1'), 600::NUMERIC,
+ (SELECT id FROM acq.fund WHERE name = 'F2'), 1, 'test'::TEXT, 600::NUMERIC
+);
+
+-- fund transfer should show 600 moved between funds
+-- 500 from the 500 credit, 100 from the 300 credit
+SELECT is(
+ (
+ SELECT ARRAY_AGG(dest_amount) FROM (
+ SELECT dest_amount FROM acq.fund_transfer
+ WHERE
+ src_fund = (SELECT id FROM acq.fund WHERE name = 'F1') AND
+ dest_fund = (SELECT id FROM acq.fund WHERE name = 'F2')
+ ORDER BY dest_amount
+ ) dest_amount
+ ),
+ '{100.00,500.00}',
+ 'Transfer amount should be 100 and 500'
+);
+
+-- destination fund should have a 600 allocation
+SELECT is(
+ (
+ SELECT ARRAY_AGG(amount) FROM (
+ SELECT amount FROM acq.fund_allocation
+ WHERE
+ funding_source =
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1') AND
+ fund = (SELECT id FROM acq.fund WHERE name = 'F2')
+ ORDER BY amount
+ ) amount
+ ),
+ '{100.00,500.00}',
+ 'Allocation amount should be 100 and 500'
+);
+
+ROLLBACK;
--- /dev/null
+BEGIN;
+
+SELECT plan(2);
+
+INSERT INTO acq.funding_source (name, owner, currency_type, code)
+ VALUES ('FS1', 1, 'USD', 'FS1');
+
+INSERT INTO acq.funding_source_credit (funding_source, amount, deadline_date )
+VALUES
+ (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ 300,
+ NOW() + '1 DAY'::INTERVAL
+ ), (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ 500,
+ NULL -- no deadline_date ensures this credit will be used first
+ -- for transfers, giving us a predictable (testable) outcome.
+ );
+
+INSERT INTO acq.fund (org, name, year, currency_type, active) VALUES
+ (1, 'F1', '2014', 'USD', TRUE);
+
+-- LP#800478
+-- allocation must exceed transfer amount but be less than total credits
+INSERT INTO acq.fund_allocation
+ (funding_source, fund, amount, fund_amount, allocator, note)
+VALUES (
+ (SELECT id FROM acq.funding_source WHERE name = 'FS1'),
+ (SELECT id FROM acq.fund WHERE name = 'F1'),
+ 700 , 700, 1, 'test'
+);
+
+-- LP#800478
+-- transfer amount must exceed any one funding source credit but be less
+-- than the allocation amount
+SELECT acq.return_funds_to_source(
+ (SELECT id FROM acq.fund WHERE name = 'F1'), 600::NUMERIC,
+ 1, 'test'::TEXT
+);
+
+-- acq.fund_allocation should show 500 and 100 returned to funding source
+SELECT is(
+ (
+ SELECT ARRAY_AGG(amount) FROM (
+ SELECT amount FROM acq.fund_allocation
+ WHERE
+ funding_source = (SELECT id FROM acq.funding_source WHERE name = 'FS1') AND
+ fund = (SELECT id FROM acq.fund WHERE name = 'F1')
+ ORDER BY amount
+ ) AS amount
+ ),
+ '{-500.00,-100.00,700}',
+ 'Should have returned 100 and 500 to the funding source, with an inital credit of 700'
+);
+
+SELECT is(
+ (
+ SELECT ARRAY_AGG(src_amount)
+ FROM acq.fund_transfer
+ WHERE src_fund = (SELECT id FROM acq.fund WHERE name = 'F1')
+ ),
+ '{500.00,100.00}',
+ 'Two fund transfer: 500.00 and 100.00'
+);
+
+ROLLBACK;
--- /dev/null
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('XXXX');
+
+-- We need to use CASCADE to remove acq.fund_combined_balance and acq.fund_spent_balance
+
+DROP VIEW acq.fund_allocation_total CASCADE;
+
+-- Recreate the acq.fund_allocation_total, so that funds without allocations are given a total
+-- of 0.00
+
+CREATE OR REPLACE VIEW acq.fund_allocation_total AS
+ SELECT af.id AS fund,
+ COALESCE(sum(afa.amount * acq.exchange_ratio(COALESCE(afs.currency_type, 'USD'), COALESCE(af.currency_type, 'USD')))::numeric(100,2), 0.00) AS amount
+ FROM acq.fund_allocation AS afa
+ RIGHT JOIN acq.fund AS af ON afa.fund = af.id
+ LEFT JOIN acq.funding_source AS afs ON afa.funding_source = afs.id
+ GROUP BY af.id;
+
+-- Recreate the VIEWs that are dependant upon acq.fund_allocation_total
+
+CREATE OR REPLACE VIEW acq.fund_combined_balance AS
+ SELECT c.fund,
+ c.amount - COALESCE(d.amount, 0.0) AS amount
+ FROM acq.fund_allocation_total c
+ LEFT JOIN acq.fund_debit_total d USING (fund);
+
+CREATE OR REPLACE VIEW acq.fund_spent_balance AS
+ SELECT c.fund,
+ c.amount - COALESCE(d.amount,0.0) AS amount
+ FROM acq.fund_allocation_total c
+ LEFT JOIN acq.fund_spent_total d USING (fund);
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('XXXX');
+
+ALTER TABLE acq.fund_allocation
+ADD fund_amount NUMERIC;
+
+ALTER TABLE acq.fund_allocation
+ADD conversion_ratio NUMERIC;
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('XXXX');
+
+CREATE OR REPLACE FUNCTION acq.current_fund_allocation(
+ fund_to_total IN INT,
+ funding_source_in IN INT DEFAULT NULL -- if user wants to specify a funding source (see notes)
+) RETURNS NUMERIC $$
+/* -------------------------------------------------------------------------------
+
+Function calculates how much money is currently allocated to a fund
+------------------------------------------------------------------------------- */
+DECLARE
+ total_amount NUMERIC;
+ fund_currency TEXT;
+BEGIN
+ --
+ -- Identify the funding source(s) from which we want to get a total of
+ -- the current allocated amount
+ --
+
+ -- Get the currency type
+ SELECT currency_type
+ INTO fund_currency
+ FROM acq.fund
+ WHERE id = fund_to_total;
+
+ FOR source in
+ SELECT
+ ofsc.id,
+ ofsc.funding_source,
+ ofsc.amount,
+ ofsc.amount * acq.exchange_ratio( fs.currency_type, fund_currency )
+ AS converted_amt,
+ fs.currency_type
+ FROM
+ acq.ordered_funding_source_credit AS ofsc,
+ acq.funding_source fs
+ WHERE
+ ofsc.funding_source = fs.id
+ and ofsc.funding_source IN
+ (
+ SELECT funding_source
+ FROM acq.fund_allocation
+ WHERE fund = fund_to_total
+ )
+ and
+ (
+ ofsc.funding_source = funding_source_in
+ OR funding_source_in IS NULL
+ )
+ ORDER BY
+ ofsc.sort_priority desc,
+ ofsc.sort_date desc,
+ ofsc.id desc
+ LOOP
+ --
+ -- Determine how much money is allocated to this fund
+ SELECT
+ COALESCE( sum( amount )
+ * acq.exchange_ratio( source.currency_type, fund_currency ), 0 )
+ INTO
+ allocated_amt -- in currency of the fund
+ FROM
+ acq.fund_allocation
+ WHERE
+ fund = fund_to_total
+ and funding_source = source.funding_source;
+ --
+ -- Total the allocations
+ --
+ total_amount := total_amount + allocated_amt;
+ END LOOP;
+
+ RETURN total_amount;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('XXXX');
+
+CREATE OR REPLACE FUNCTION acq.insert_fund_allocation_fund_amount() RETURNS TRIGGER AS $$
+/* -------------------------------------------------------------------------------
+
+Calculates the fund_amount from the values in acq.fund_allocation.amount,
+acq.fund_allocation.funding_source, acq.fund_allocation.fund and acq.fund.currency_type
+------------------------------------------------------------------------------- */
+DECLARE calculated_conversion_ratio NUMERIC;
+
+BEGIN
+
+ IF NEW.amount < 0 THEN
+ SELECT acq.exchange_ratio((SELECT currency_type FROM acq.fund WHERE id = NEW.fund),
+ (SELECT currency_type FROM acq.funding_source WHERE id = NEW.funding_source)
+ )
+ INTO calculated_conversion_ratio;
+ ELSE
+ SELECT acq.exchange_ratio((SELECT currency_type FROM acq.funding_source WHERE id = NEW.funding_source),
+ (SELECT currency_type FROM acq.fund WHERE id = NEW.fund)
+ )
+ INTO calculated_conversion_ratio;
+ END IF;
+
+ UPDATE acq.fund_allocation
+ SET fund_amount = trunc((NEW.amount * calculated_conversion_ratio), 2)
+ WHERE fund = NEW.fund AND id = NEW.id;
+
+ UPDATE acq.fund_allocation
+ SET conversion_ratio = calculated_conversion_ratio
+ WHERE fund = NEW.fund AND id = NEW.id;
+
+ RETURN NEW;
+
+END;
+$$ LANGUAGE PLPGSQL;
+
+DROP TRIGGER acq_insert_fund_allocation_fund_amount ON acq.fund_allocation;
+
+CREATE TRIGGER acq_insert_fund_allocation_fund_amount
+ AFTER INSERT ON acq.fund_allocation
+ FOR EACH ROW
+ EXECUTE PROCEDURE acq.insert_fund_allocation_fund_amount();
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+--INSERT INTO config.upgrade_log (version) VALUES ('0147'); -- Scott M
+
+CREATE OR REPLACE FUNCTION acq.return_funds_to_source(
+ returning_fund_id IN INT,
+ amount_to_return IN NUMERIC, -- in currency of returning
+ -- fund
+ user_id IN INT,
+ xfer_note IN TEXT, -- to be recorded in
+ -- acq.fund_transfer
+ return_funding_source IN INT DEFAULT NULL -- if user wants to specify a
+ -- funding source (see notes)
+) RETURNS VOID AS $$
+/* -------------------------------------------------------------------------------
+
+Function to return funds from a fund to a funding source or funding sources..
+
+A return is represented as a single entry in acq.fund_allocation, with a
+negative amount for the fund being debited.
+In some cases there may be more than one such pair of entries
+In order to pull the money from different funding sources, or more specifically
+from different funding source credits. For each return there is also an
+entry in acq.fund_transfer.
+
+Since funding_source is a non-nullable column in acq.fund_allocation, we must
+choose a funding source for the returning money to return to. This choice
+must meet two constraints, so far as possible:
+
+1. The amount returned to a given funding source must not exceed the
+amount allocated to the returning fund by the funding source. To that end we
+compare the amount being returned to the amount allocated.
+
+2. We shouldn't return money that has already been spent or encumbered, as
+defined by the funding attribution process. We attribute expenses to the
+oldest funding source credits first. In order to avoid returning that
+attributed money, we reverse the priority, returning from the newest funding
+source credits first. There can be no guarantee that this approach will
+avoid over returning from a fund, but no other approach can do any better.
+
+In this context the age of a funding source credit is defined by the
+deadline_date for credits with deadline_dates, and by the effective_date for
+credits without deadline_dates, with the proviso that credits with deadline_dates
+are all considered "older" than those without.
+
+----------
+
+In the signature for this function, there is one last parameter commented out,
+named "return_funding_soruce". Correspondingly, the WHERE clause for the query
+driving the main loop has an OR clause commented out, which references the
+funding_source_in parameter.
+
+If these lines are uncommented, this function will allow the user optionally to
+restrict a fund return to a specified funding source. If the source
+parameter is left NULL, then there will be no such restriction.
+
+TODO: Need to lock the acq.currency_rate table while this function is being
+executed. Otherwise, the amount in new_amount may be less than an amount deducted
+if the currencies in the table fluctuate to a large degree while this is running.
+
+------------------------------------------------------------------------------- */
+DECLARE
+
+ returning_fund_currency TEXT;
+
+ -- kept in the currency of return fund
+ funds_remaining_to_be_returned NUMERIC;
+
+ -- kept in currency of return fund
+ current_amount_to_return NUMERIC;
+
+ -- in currency of funding source
+ funding_source_credit NUMERIC;
+
+ -- kept in currency of returning fund
+ amount_allocated_by_funding_source NUMERIC;
+
+ -- kept in currency of returning fund
+ amount_currently_allocated_to_returning_fund NUMERIC;
+
+ -- a JOIN of acq.funding_source and acq.ordered_funding_source_credit
+ source RECORD;
+
+BEGIN
+ --
+ -- We need to lock this table because the exchange rates could be modifed
+ -- while we are doing a transfer, which would create unpredictable results
+ --
+ LOCK acq.exchange_rate
+ IN EXCLUSIVE MODE;
+ --
+ -- Sanity checks
+ --
+ IF returning_fund_id IS NULL THEN
+ RAISE EXCEPTION 'acq.return_funds_to_source: returning fund id is NULL';
+ END IF;
+ --
+ IF amount_to_return IS NULL THEN
+ RAISE EXCEPTION 'acq.return_funds_to_soruce: amount to return is NULL';
+ END IF;
+ --
+ IF user_id IS NULL THEN
+ RAISE EXCEPTION 'acq.return_funds_to_source: user id is NULL';
+ END IF;
+ --
+ IF amount_to_return = 0 THEN
+ RAISE EXCEPTION 'acq.return_funds_to_source amount to return is 0';
+ END IF;
+
+ -- Ensure there is enough money in the fund to cover the amount to return
+ -- We are returning the balance plus any funds currently encumbered
+ -- So we use the Spent Balance because it includes the Total Encumbered
+ -- as well as the the Total Spent
+ SELECT amount
+ INTO amount_currently_allocated_to_returning_fund
+ FROM acq.fund_spent_balance
+ WHERE fund = returning_fund_id;
+
+ IF amount_to_return > amount_currently_allocated_to_returning_fund THEN
+ RAISE EXCEPTION 'Cannot return more money than is currently allocted to the fund. fund id: % has % allocated to it, and the acq.return_funds_to_source is trying to debit it for %', returning_fund_id, amount_currently_allocated_to_returning_fund, amount_to_return;
+ END IF;
+
+ --
+ -- Initialize the amounts to be returned, each denominated
+ -- in the currency of its respective fund. They will be
+ -- reduced on each iteration of the loop.
+ --
+ funds_remaining_to_be_returned := amount_to_return;
+ --
+ RAISE NOTICE 'Returning % in fund % to its soruce(s)',
+ amount_to_return, returning_fund_id;
+ --
+ -- Get the currency types of the old and new funds.
+ --
+ SELECT
+ currency_type
+ INTO
+ returning_fund_currency
+ FROM
+ acq.fund
+ WHERE
+ id = returning_fund_id;
+ --
+ IF returning_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.return_funds_to_source: old fund currency is not defined for fund id: %', returning_fund_id;
+ END IF;
+ --
+ -- Identify the funding source(s) from which we want to transfer the money.
+ -- The principle is that we want to transfer the newest money first, because
+ -- we spend the oldest money first. The priority for spending is defined
+ -- by a sort of the view acq.ordered_funding_source_credit.
+ --
+
+ -- There is no guarantee that the currency types in the funding source will be one of
+ -- the two types passed in to this function. This needs to be fixed.
+
+ -- Add code to determine if there are enough funds left in the fund to transfer the
+ -- amount requested.
+ FOR source IN
+ SELECT
+ ofsc.id,
+ ofsc.funding_source,
+ ofsc.amount * acq.exchange_ratio(fs.currency_type, returning_fund_currency)
+ AS amount_credited_to_fund,
+ -- We store the amount to retreive when amount_to_receive IS NOT NULL and the
+ -- fs.currency_type is the same currency as the amount to receive. We use the
+ -- inverted_conversion_ratio because we are concerned with having the amount in
+ -- the currency of the returning fund. The AS amount_credited_to_fund value is
+ -- converted using the source to returning fund currencies.
+ fs.currency_type
+ FROM
+ acq.ordered_funding_source_credit AS ofsc,
+ acq.funding_source fs
+ WHERE
+ ofsc.funding_source = fs.id
+ AND ofsc.funding_source IN
+ (
+ SELECT funding_source
+ FROM acq.fund_allocation
+ WHERE fund = returning_fund_id
+ )
+ AND
+ (
+ ofsc.funding_source = return_funding_source
+ OR return_funding_source IS NULL
+ )
+ ORDER BY
+ ofsc.sort_priority DESC,
+ ofsc.sort_date DESC,
+ ofsc.id DESC
+ LOOP
+ --
+ -- Determine how much money the returning fund got from this funding source,
+ -- denominated in the currency types of the fund.
+ -- This result may reflect transfers from previous iterations.
+ --
+ SELECT
+ COALESCE( sum( fund_amount ), 0 )
+ INTO
+ amount_allocated_by_funding_source -- in currency of the returning fund
+ FROM
+ acq.fund_allocation
+ WHERE
+ fund = returning_fund_id
+ AND funding_source = source.funding_source;
+ --
+ -- Determine how much to transfer from this credit, in the currency
+ -- of the fund. Begin with the amount remaining to be attributed:
+ --
+ current_amount_to_return := funds_remaining_to_be_returned;
+
+ --
+ -- Can't attribute more than was allocated to the fund:
+ --
+ IF current_amount_to_return > amount_allocated_by_funding_source THEN
+ current_amount_to_return := amount_allocated_by_funding_source;
+ END IF;
+ --
+ -- Can't attribute more than the amount of the current credit from the funding source:
+ --
+ IF current_amount_to_return > source.amount_credited_to_fund THEN
+ current_amount_to_return := source.amount_credited_to_fund;
+ END IF;
+ --
+ current_amount_to_return := trunc( current_amount_to_return, 2 );
+ --
+ -- At some point old_remaining value WILL become 0
+ -- because curr_old_amt is set to old_remaining above
+ -- and it is never increased above that.
+ --
+ funds_remaining_to_be_returned := funds_remaining_to_be_returned - current_amount_to_return;
+
+ --
+ -- Determine the amount to be deducted, if any,
+ -- from the old allocation.
+ --
+
+ --
+ -- Either the entire amount is being credited (the case where
+ -- current_amount_to_return is less than the
+ -- amount_allocated_by_funding_soruce and source.fund_amount), and we're using the whole allocation
+ -- from the current
+ -- funding source credit, or the amount left allocated in this funding
+ -- source credit if it is
+ -- less than the original amount of the credit (due to previous debits), so
+ -- use that amount
+ -- directly. In all these cases these values are represented by current_amount_to_return.
+ -- We need to translate the amount into the source.currency_type regardless of the
+ -- condiitons above because we are crediting to the source not the fund.
+ --
+
+ funding_source_credit := trunc(
+ ( - current_amount_to_return ) *
+ acq.exchange_ratio( returning_fund_currency, source.currency_type ),
+ 2 );
+
+ IF returning_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'returning_fund_currency IS NULL';
+ END IF;
+
+ IF current_amount_to_return IS NULL THEN
+ RAISE EXCEPTION 'current_amount_to_return IS NULL % - %', amount_allocated_by_funding_source, source.amount_credited_to_fund;
+ END IF;
+ -- Ensure the addition is less than 0
+ RAISE NOTICE 'funding_source_credit: %', funding_source_credit;
+ IF funding_source_credit < 0 THEN
+ --
+ -- Insert negative allocation for old fund in fund_allocation,
+ -- converted into the currency of the funding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note,
+ fund_amount
+ ) VALUES (
+ source.funding_source,
+ returning_fund_id,
+ funding_source_credit,
+ user_id,
+ 'Returning funds to the source',
+ (current_amount_to_return * -1)
+ );
+ ELSE
+ -- RAISE EXCEPTION 'funding_source_credit of % is greater than 0: % -- %', funding_source_credit, current_amount_to_return, funds_remaining_to_be_returned;
+ EXIT;
+ END IF;
+ --
+ IF trunc( current_amount_to_return, 2 ) > 0 THEN
+ --
+ -- Insert row in fund_transfer, using amounts in the currency of the funds
+ --
+ INSERT INTO acq.fund_transfer (
+ src_fund,
+ src_amount,
+ dest_fund,
+ dest_amount,
+ transfer_user,
+ note,
+ funding_source_credit
+ ) VALUES (
+ returning_fund_id,
+ trunc( current_amount_to_return, 2 ),
+ NULL,
+ NULL,
+ user_id,
+ xfer_note,
+ source.id
+ );
+ END IF;
+ --
+ -- It should be impossible for old_remaining to be less than 0.
+ --
+ IF trunc(funds_remaining_to_be_returned, 2) = 0.00 THEN
+ EXIT; -- Nothing more to be transferred
+ END IF;
+ END LOOP;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+-- INSERT INTO config.upgrade_log (version) VALUES ('XXXX');
+
+CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_unit( old_year INTEGER, user_id INTEGER, org_unit_id INTEGER, encumb_only BOOL DEFAULT FALSE ) RETURNS VOID AS $$
+ SELECT acq.rollover_funds_by_org_tree( $1, $2, $3, $4, FALSE );
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_tree(
+ old_year INTEGER,
+ user_id INTEGER,
+ org_unit_id INTEGER,
+ encumb_only BOOL DEFAULT FALSE,
+ include_desc BOOL DEFAULT TRUE
+) RETURNS VOID AS $$
+DECLARE
+--
+new_fund INT;
+new_year INT := old_year + 1;
+org_found BOOL;
+perm_ous BOOL;
+xfer_amount NUMERIC := 0;
+roll_fund RECORD;
+deb RECORD;
+detail RECORD;
+roll_distrib_forms BOOL;
+--
+BEGIN
+ --
+ -- Sanity checks
+ --
+ IF old_year IS NULL THEN
+ RAISE EXCEPTION 'Input year argument is NULL';
+ ELSIF old_year NOT BETWEEN 2008 and 2200 THEN
+ RAISE EXCEPTION 'Input year is out of range';
+ END IF;
+ --
+ IF user_id IS NULL THEN
+ RAISE EXCEPTION 'Input user id argument is NULL';
+ END IF;
+ --
+ IF org_unit_id IS NULL THEN
+ RAISE EXCEPTION 'Org unit id argument is NULL';
+ ELSE
+ --
+ -- Validate the org unit
+ --
+ SELECT TRUE
+ INTO org_found
+ FROM actor.org_unit
+ WHERE id = org_unit_id;
+ --
+ IF org_found IS NULL THEN
+ RAISE EXCEPTION 'Org unit id % is invalid', org_unit_id;
+ ELSIF encumb_only THEN
+ SELECT INTO perm_ous value::BOOL FROM
+ actor.org_unit_ancestor_setting(
+ 'acq.fund.allow_rollover_without_money', org_unit_id
+ );
+ IF NOT FOUND OR NOT perm_ous THEN
+ RAISE EXCEPTION 'Encumbrance-only rollover not permitted at org %', org_unit_id;
+ END IF;
+ END IF;
+ END IF;
+ --
+ -- Loop over the propagable funds to identify the details
+ -- from the old fund plus the id of the new one, if it exists.
+ --
+ FOR roll_fund in
+ SELECT
+ oldf.id AS old_fund,
+ oldf.org,
+ oldf.name,
+ oldf.currency_type,
+ oldf.code,
+ oldf.rollover,
+ newf.id AS new_fund_id
+ FROM
+ acq.fund AS oldf
+ LEFT JOIN acq.fund AS newf
+ ON ( oldf.code = newf.code )
+ WHERE
+ oldf.year = old_year
+ AND oldf.propagate
+ AND newf.year = new_year
+ AND ( ( include_desc AND oldf.org IN ( SELECT id FROM actor.org_unit_descendants( org_unit_id ) ) )
+ OR (NOT include_desc AND oldf.org = org_unit_id ) )
+ LOOP
+ --
+ --RAISE NOTICE 'Processing fund %', roll_fund.old_fund;
+ --
+ IF roll_fund.new_fund_id IS NULL THEN
+ --
+ -- The old fund hasn't been propagated yet. Propagate it now.
+ --
+ INSERT INTO acq.fund (
+ org,
+ name,
+ year,
+ currency_type,
+ code,
+ rollover,
+ propagate,
+ balance_warning_percent,
+ balance_stop_percent
+ ) VALUES (
+ roll_fund.org,
+ roll_fund.name,
+ new_year,
+ roll_fund.currency_type,
+ roll_fund.code,
+ true,
+ true,
+ roll_fund.balance_warning_percent,
+ roll_fund.balance_stop_percent
+ )
+ RETURNING id INTO new_fund;
+ ELSE
+ new_fund = roll_fund.new_fund_id;
+ END IF;
+ --
+ --
+ -- Determine the amount to transfer or return
+ --
+ SELECT amount
+ INTO xfer_amount
+ FROM acq.fund_spent_balance
+ WHERE fund = roll_fund.old_fund;
+
+ IF NOT encumb_only AND roll_fund.rollover THEN
+ -- Transfer balance from old fund to new
+ --
+ -- RAISE NOTICE 'Transferring % from fund % to %', xfer_amount, roll_fund.old_fund, new_fund;
+ --
+ IF xfer_amount > 0 THEN
+ PERFORM acq.transfer_fund(
+ roll_fund.old_fund,
+ xfer_amount,
+ new_fund,
+ user_id,
+ 'Rollover',
+ xfer_amount,
+ NULL,
+ TRUE
+ );
+ END IF;
+ ELSE
+ --
+ -- Transfer balance from old fund to the void
+ --
+ -- RAISE NOTICE 'Returning % from fund % to its source(s)', xfer_amount, roll_fund.old_fund;
+ --
+ IF xfer_amount > 0 THEN
+ PERFORM acq.return_funds_to_source(
+ roll_fund.old_fund,
+ xfer_amount,
+ user_id,
+ 'Rollover - return funds to source'
+ );
+ END IF;
+ END IF;
+ --
+ IF roll_fund.rollover THEN
+ --
+ -- Move any lineitems from the old fund to the new one
+ -- where the associated debit is an encumbrance.
+ --
+ -- Any other tables tying expenditure details to funds should
+ -- receive similar treatment. At this writing there are none.
+ --
+ UPDATE acq.lineitem_detail
+ SET fund = new_fund
+ WHERE
+ fund = roll_fund.old_fund -- this condition may be redundant
+ AND fund_debit IN
+ (
+ SELECT id
+ FROM acq.fund_debit
+ WHERE
+ fund = roll_fund.old_fund
+ AND encumbrance
+ );
+ --
+ -- Move encumbrance debits from the old fund to the new fund
+ --
+ UPDATE acq.fund_debit
+ SET fund = new_fund
+ wHERE
+ fund = roll_fund.old_fund
+ AND encumbrance;
+ END IF;
+
+ -- Rollover distribution formulae funds
+ SELECT INTO roll_distrib_forms value::BOOL FROM
+ actor.org_unit_ancestor_setting(
+ 'acq.fund.rollover_distrib_forms', org_unit_id
+ );
+
+ IF roll_distrib_forms THEN
+ UPDATE acq.distribution_formula_entry
+ SET fund = roll_fund.new_fund_id
+ WHERE fund = roll_fund.old_fund;
+ END IF;
+
+ --
+ -- Mark old fund as inactive, now that we've closed it
+ --
+ UPDATE acq.fund
+ SET active = FALSE
+ WHERE id = roll_fund.old_fund;
+ END LOOP;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMIT;
--- /dev/null
+BEGIN;
+
+-- INSERT INTO config.upgrade_log (version) VALUES ('0147'); -- Scott McKellar
+
+-- DROP FUNCTION acq.transfer_fund (INT, NUMERIC, INT, NUMERIC, INT, TEXT);
+
+CREATE OR REPLACE FUNCTION acq.transfer_fund(
+ transferring_fund_id IN INT,
+ amount_to_transfer IN NUMERIC, -- in currency of
+ -- transferring fund
+ receiving_fund_id IN INT,
+ user_id IN INT, -- user initiating
+ -- the transfer
+ xfer_note IN TEXT, -- to be recorded in
+ -- acq.fund_transfer
+ amount_to_receive IN NUMERIC DEFAULT NULL,-- in currency of
+ -- receiving fund
+ -- It can be null in
+ -- cases where the
+ -- amount to transfer
+ -- will be calculated
+ -- within the function
+ transferring_funding_source IN INT DEFAULT NULL, -- if user wants to
+ -- specify a funding
+ -- source (see notes)
+ rollover_transfer IN BOOLEAN DEFAULT FALSE-- If true, then
+ -- we make sure the
+ -- amount being
+ -- transferred is not
+ -- greater than the
+ -- spent balance as
+ -- oposed to the
+ -- combined balacne
+) RETURNS VOID AS $$
+/* -------------------------------------------------------------------------------
+
+Function to transfer money from one fund to another.
+
+A transfer is represented as a pair of entries in acq.fund_allocation, with a
+negative amount for the transferring fund and a positive amount for the
+receiving fund. In some cases there may be more than one such pair of entries
+in order to pull the money from different funding sources, or more specifically
+from different funding source credits. For each such pair there is also an
+entry in acq.fund_transfer.
+
+Since funding_source is a non-nullable column in acq.fund_allocation, we must
+choose a funding source for the transferred money to come from. This choice
+must meet two constraints, so far as possible:
+
+1. The amount transferred from a given funding source must not exceed the
+amount allocated to the old fund by the funding source. To that end we
+compare the amount being transferred to the amount allocated.
+
+2. We shouldn't transfer money that has already been spent or encumbered, as
+defined by the funding attribution process. We attribute expenses to the
+oldest funding source credits first. In order to avoid transferring that
+attributed money, we reverse the priority, transferring from the newest funding
+source credits first. There can be no guarantee that this approach will
+avoid overcommitting a fund, but no other approach can do any better.
+
+In this context the age of a funding source credit is defined by the
+deadline_date for credits with deadline_dates, and by the effective_date for
+credits without deadline_dates, with the proviso that credits with deadline_dates
+are all considered "older" than those without.
+
+----------
+
+In the signature for this function, there is one last parameter commented out,
+named "transferring_funding_source". Correspondingly, the WHERE clause for the query
+driving the main loop has an OR clause commented out, which references the
+transferring_funding_source parameter.
+
+If these lines are uncommented, this function will allow the user optionally to
+restrict a fund transfer to a specified funding source. If the source
+parameter is left NULL, then there will be no such restriction.
+
+------------------------------------------------------------------------------- */
+DECLARE
+ -- are the transferring and receiving funds the same currency?
+ same_currency BOOLEAN;
+
+ -- The ratio between the transferring fund and the receiving
+ -- fund. Other ratios may be needed due to other currencies
+ -- in the funding sources.
+ conversion_ratio NUMERIC;
+
+ -- The ratio between the receiving fund and the transferring
+ -- fund. Other ratios may be needed due to other currencies
+ -- in the funding sources.
+ inverted_conversion_ratio NUMERIC;
+
+ transferring_fund_currency TEXT;
+
+ -- kept in the currency of transferring fund
+ funds_remaining_to_be_transferred NUMERIC;
+
+ -- the transferring fund must be active if the amount to
+ -- transfer isnegative because it will have to accept funds
+ transferring_fund_active BOOLEAN;
+
+ receiving_fund_currency TEXT;
+
+ -- kept in currency of recieving fund
+ funds_remaining_to_be_received NUMERIC;
+
+ -- the receiving fund must be active to accept funds
+ receiving_fund_active BOOLEAN;
+
+ -- kept in currency of transferring fund
+ current_amount_to_transfer NUMERIC;
+
+ -- in currency of recevinig fund
+ current_amount_to_receive NUMERIC;
+
+ -- in currency of funding source
+ funding_source_credit NUMERIC;
+
+ -- Ratio between the transferring fund and the source
+ source_credit_conversion_ratio NUMERIC;
+
+ -- in currency of funding source
+ funding_source_debit NUMERIC;
+
+ -- Ratio between the receiving fund and the source
+ source_debit_conversion_ratio NUMERIC;
+
+ -- kept in currency of transferring fund
+ amount_allocated_by_funding_source NUMERIC;
+
+ -- kept in currency of the transferring fund
+ amount_credited NUMERIC;
+
+ -- kept in currency of transferring fund
+ amount_currently_allocated_to_transferring_fund NUMERIC;
+
+ -- a JOIN of acq.funding_source and
+ -- acq.ordered_funding_source_credit
+ source RECORD;
+
+ -- Used to swap funds when a negative amount is supplied
+ -- to amount_to_transfer
+ temp_fund_id INTEGER;
+
+ -- Used to sawp currencies when a negative amount is
+ -- supplied to amount_to_transfer
+ temp_currency TEXT;
+
+ -- Used to swap the amount to transfer when negative
+ -- amounts are supplied to amount_to_transfer and
+ -- amount_to_receive
+ temp_amount NUMERIC;
+
+ -- Keeps track of the amount allocated by each funding
+ -- source credit, so that the totals are not changed
+ -- when the code modifies allocations when moving
+ -- money between funds
+ fund_allocation_total NUMERIC[][];
+BEGIN
+ --
+ -- We need to lock this table because the exchange rates could be modifed
+ -- while we are doing a transfer, which would create unpredictable results
+ --
+ LOCK acq.exchange_rate
+ IN EXCLUSIVE MODE;
+
+ --
+ -- Sanity checks
+ --
+ IF transferring_fund_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: transferring fund id is NULL';
+ END IF;
+ --
+ IF receiving_fund_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: recieving fund id is NULL';
+ END IF;
+ --
+ IF amount_to_transfer IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: amount to transfer is NULL';
+ END IF;
+ --
+ IF user_id IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: user id is NULL';
+ END IF;
+ --
+ IF amount_to_transfer = 0 THEN
+ RAISE EXCEPTION 'acq.transfer_fund amount to transfer is 0';
+ END IF;
+
+ IF amount_to_receive IS NOT NULL THEN
+ IF (amount_to_transfer > 0 AND amount_to_receive < 0) OR
+ (amount_to_transfer < 0 AND amount_to_receive > 0) THEN
+ RAISE EXCEPTION 'acq.transfer_fund amount to transfer (%) and amount to receive (%) do not have the same sign', amount_to_transfer, amount_to_receive;
+ END IF;
+ END IF;
+ --
+ -- Get the currency and active status of the transferring fund
+ --
+ SELECT
+ currency_type,
+ active
+ INTO
+ transferring_fund_currency,
+ transferring_fund_active
+ FROM
+ acq.fund
+ WHERE
+ id = transferring_fund_id;
+ --
+ IF transferring_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: transferring fund currency is not defined for fund id: %', transferring_fund_id;
+ END IF;
+ --
+ -- Get the currency and active status of the receiving fund
+ --
+ SELECT
+ currency_type,
+ active
+ INTO
+ receiving_fund_currency,
+ receiving_fund_active
+ FROM
+ acq.fund
+ WHERE
+ id = receiving_fund_id;
+ --
+ IF receiving_fund_currency IS NULL THEN
+ RAISE EXCEPTION 'acq.transfer_fund: receiving fund currency is not defined for fund id: %', receiving_fund_id;
+ END IF;
+ --
+ -- If the amount to transfer is negative then swap the transferring and
+ -- receiving funds
+ --
+ IF amount_to_transfer < 0 THEN
+ --
+ -- Because the amount is negative, we need to check if the transferring
+ -- fund is active, so we do not transfer to an inactive transferring fund
+ --
+ IF NOT transferring_fund_active THEN
+ --
+ -- No point in putting money into a fund from whence you can't spend it
+ --
+ RAISE EXCEPTION 'acq.transfer_fund: Amount to transfer is negative, and transferring fund id % is inactive', transferring_fund_id;
+ END IF;
+
+ IF (transferring_fund_crrency != receiving_fund_currecy) AND
+ (amount_to_recevie IS NULL) THEN
+ -- convert the funds amount to transfer from
+ -- the currency of the transferring fund into the currecny of
+ -- the receiving fund. Only do this if there is no value in
+ -- in amount_to_receive
+ amount_to_transfer := trunc( amount_to_transfer *
+ acq.exchange_ratio(transferring_fund_currency, receiving_fund_currency), 2 );
+ END IF;
+
+ -- make the amount to transfer, and conditionally the amount to recieve, positive
+ amount_to_transfer := amount_to_transfer * -1;
+
+ IF amount_to_receive IS NOT NULL THEN
+ amount_to_receive := amount_to_receive * -1;
+ END IF;
+
+ temp_fund_id := transferring_fund_id;
+ temp_currency := transferring_fund_currency;
+ temp_amount = amount_to_transfer;
+ transferring_fund_id := receiving_fund_id;
+ transferring_fund_currency := receiving_fund_currency;
+ amount_to_transfer = amount_to_receive;
+ receiving_fund_id := temp_fund_id;
+ receiving_fund_currency := temp_currency;
+ amount_to_receive = temp_amount;
+ ELSIF NOT receiving_fund_active THEN
+ -- We need to check this after a possible swap and not before
+ -- because it is ok to transfer from an inactive fund, so
+ -- the fact that receiving fund has not been swapped means
+ -- we can now check to make sure it is active
+ --
+ -- No point in putting money into a fund from whence you can't spend it
+ --
+ RAISE EXCEPTION 'acq.transfer_fund: receiving fund id % is inactive', receiving_fund_id;
+ END IF;
+
+ -- RAISE EXCEPTION 'acq.transfer_fund test';
+
+ -- ensure there is enough money in the fund to cover the amount to transfer
+ -- we do this after checking if we need to swap funds to ensure we are
+ -- checking the correct fund for the necessary funds to transfer
+ -- If this is a rollover transfer then we check against the spent balance
+ -- which will be higher because it does not contain the encubmerance total.
+ -- Otherwise, makes sure we do not spend encumbered funds
+ IF rollover_transfer THEN
+ SELECT amount
+ INTO amount_currently_allocated_to_transferring_fund
+ FROM acq.fund_spent_balance
+ WHERE fund = transferring_fund_id;
+ ELSE
+ SELECT amount
+ INTO amount_currently_allocated_to_transferring_fund
+ FROM acq.fund_combined_balance
+ WHERE fund = transferring_fund_id;
+ END IF;
+
+ -- Ensure there is enough money left in this fund to fulfill the transfer
+ IF amount_to_transfer > amount_currently_allocated_to_transferring_fund THEN
+ RAISE EXCEPTION 'Cannot transfer more money than is currently allocted to the fund. fund id: % has % allocated to it, and acq.transfer_fund is trying to debit it for %',
+ transferring_fund_id, amount_currently_allocated_to_transferring_fund, amount_to_transfer;
+ END IF;
+
+ --
+ -- Initialize the amounts to be transferred, each denominated
+ -- in the currency of its respective fund. They will be
+ -- reduced on each iteration of the loop.
+ --
+ funds_remaining_to_be_transferred := amount_to_transfer;
+ --
+ RAISE NOTICE 'Transferring % in fund % to fund %',
+ amount_to_transfer, transferring_fund_id, receiving_fund_id;
+ --
+ IF transferring_fund_currency = receiving_fund_currency THEN
+ same_currency := true;
+ conversion_ratio := 1;
+ inverted_conversion_ratio := 1;
+ funds_remaining_to_be_received := funds_remaining_to_be_transferred;
+ ELSE
+ --
+ -- We'll have to translate currency between funds.
+ -- In this version we are only using the value to be transfered
+ -- from the old fund. We will convert in this funciton
+ --
+ same_currency := false;
+
+ IF amount_to_receive IS NULL THEN
+ conversion_ratio := acq.exchange_ratio(transferring_fund_currency, receiving_fund_currency);
+ -- This is not needed yet, but I am setting it here because it can be calculated, which
+ -- ensures that if the case where amount_to_receive is NULl requires the inversted_conversion_ratio
+ -- then it will be set.e
+ inverted_conversion_ratio = acq.exchange_ratio(receiving_fund_currency, transferring_fund_currency);
+ ELSE
+ -- Because amount_to_receive has been speficied we will
+ -- use whatever conversion ratio the system making this call used
+ -- to calculate the amount_to_receive
+ conversion_ratio := amount_to_receive/amount_to_trasnfer;
+ inverted_conversion_ratio = amount_to_transfer/amount_to_receive;
+ END IF;
+
+ funds_remaining_to_be_received := trunc( funds_remaining_to_be_transferred * conversion_ratio, 2 );
+ END IF;
+
+ --
+ -- Identify the funding source(s) from which we want to transfer the money.
+ -- The principle is that we want to transfer the newest money first, because
+ -- we spend the oldest money first. The priority for spending is defined
+ -- by a sort of the view acq.ordered_funding_source_credit.
+ --
+
+ FOR source IN
+ SELECT
+ ofsc.id,
+ ofsc.funding_source,
+ ofsc.amount,
+ ofsc.amount * acq.exchange_ratio(fs.currency_type, transferring_fund_currency)
+ AS amount_credited_to_fund,
+ -- We store the amount to retreive when amount_to_receive IS NOT NULL and the
+ -- fs.currency_type is the same currency as the amount to receive. We use the
+ -- inverted_conversion_ratio because we are concerned with having the amount in
+ -- the currency of the transferring fund. The AS amount_credited_to_fund value is
+ -- converted using the source to transferring currencies. However, if the soure
+ -- is the same currency as the receiving currency, then we need to calculate this
+ -- using the inversion of the ratio used to convert the currencies when the
+ -- amount_to_receive is specified.
+ ofsc.amount * inverted_conversion_ratio AS amount_credited_to_fund_at_supplied_ratio,
+ fs.currency_type
+ FROM
+ acq.ordered_funding_source_credit AS ofsc,
+ acq.funding_source fs
+ WHERE
+ ofsc.funding_source = fs.id
+ AND ofsc.funding_source IN
+ (
+ SELECT funding_source
+ FROM acq.fund_allocation
+ WHERE fund = transferring_fund_id
+ )
+ AND
+ (
+ ofsc.funding_source = transferring_funding_source
+ OR transferring_funding_source IS NULL
+ )
+ ORDER BY
+ ofsc.sort_priority DESC,
+ ofsc.sort_date DESC,
+ ofsc.id DESC
+ LOOP
+ --
+ -- Determine total amount of credits that this funding source has give this fund
+ -- Denominated in the currency types of the transferring fund.
+ -- Because we need to look at specific allocations,
+ -- this result may reflect transfers from previous iterations.
+ --
+ SELECT
+ COALESCE( sum( fund_amount ), 0 )
+ INTO
+ -- in currency of the transferring fund
+ amount_allocated_by_funding_source
+ FROM
+ acq.fund_allocation
+ WHERE
+ fund = transferring_fund_id
+ AND funding_source = source.funding_source;
+
+ IF fund_allocation_total[transferring_fund_id][source.funding_source] IS NULL THEN
+ fund_allocation_total[transferring_fund_id][source.funding_source] = amount_allocated_by_funding_source;
+ END IF;
+ --
+ -- Determine how much to transfer from this credit, in the currency
+ -- of the fund. Begin with the amount remaining to be transferred
+ --
+ current_amount_to_transfer := funds_remaining_to_be_transferred;
+
+ -- RAISE NOTICE 'current_amount_to_transfer: %', current_amount_to_transfer;
+
+ --
+ -- Can't attribute more than was allocated to the fund:
+ --
+
+ IF current_amount_to_transfer > fund_allocation_total[transferring_fund_id][source.funding_source] THEN
+ current_amount_to_transfer := amount_allocated_by_funding_source;
+ END IF;
+
+ -- RAISE NOTICE 'current_amount_to_transfer after checking amount allocated to the fund: %', current_amount_to_transfer;
+ --
+ -- Can't attribute more than the amount of the current credit from the funding source:
+ --
+
+ -- RAISE NOTICE 'transferring_fund_currency: %', transferring_fund_currency;
+ -- RAISE NOTICE 'source.currency_type: %', source.currency_type;
+ -- RAISE NOTICE 'amount_to_receive: %', amount_to_receive;
+
+ IF (transferring_fund_currency = source.currency_type) AND
+ (amount_to_receive IS NOT NULL) THEN
+ -- RAISE NOTICE 'source.amount_credited_to_fund_at_supplied_ratio: %', source.amount_credited_to_fund_at_supplied_ratio;
+ amount_credited = source.amount_credited_to_fund_at_supplied_ratio;
+ ELSE
+ amount_credited = source.amount_credited_to_fund;
+ END IF;
+
+ -- RAISE NOTICE 'amount_credited: %', amount_credited;
+
+ IF (current_amount_to_transfer > amount_credited) THEN
+ current_amount_to_transfer := amount_credited;
+ END IF;
+
+ -- RAISE NOTICE 'current_amount_to_transfer after checking amount of the current funding credit: %', current_amount_to_transfer;
+
+ --
+ current_amount_to_transfer := trunc( current_amount_to_transfer, 2 );
+ --
+ -- At some point funds_remaining_to_be_transferred value WILL become 0
+ -- because current_amount_to_transfer is set to funds_remaining_to_be_transferred above
+ -- and it is never increased above that.
+ --
+ funds_remaining_to_be_transferred := funds_remaining_to_be_transferred - current_amount_to_transfer;
+
+ --
+ -- Determine the amount to be credited, if any,
+ -- to the funding source.
+ --
+
+ --
+ -- Either the entire amount is being deducted (the case where current_amount_to_transfer
+ -- is less than the
+ -- amount_allocated_by_funding_source and source.amount_credited_to_fund), we're
+ -- are deducting the whole allocation from the current funding source credit,
+ -- or we are deducting the amount allocated in this single unding source credit if it is
+ -- less than the original amount of the credit (due to previous debits).
+ -- In all these cases these values are represented by current_amount_to_transfer.
+ -- We need to convert the amount into the source.currency_type regardless of the
+ -- condiitons above because we are deducting from the source not the fund.
+ --
+
+ IF (amount_to_receive IS NULL) AND (receiving_fund_currency != source.currency_type) THEN
+ source_credit_conversion_ratio := acq.exchange_ratio( transferring_fund_currency, source.currency_type );
+ ELSE
+ -- use the calculated ratio when the amount_to_receive is specified
+ source_credit_conversion_ratio := conversion_ratio;
+ END IF;
+
+ funding_source_credit := trunc(
+ ( - current_amount_to_transfer ) *
+ source_credit_conversion_ratio,
+ 2 );
+
+ -- Ensure the credit is less than or equal to 0
+ -- We insert the case where it is equal to 0 because
+ -- there may be a need for a corresponding 0 entry in acq.fund_transfer,
+ -- which is INSERTed near the end of this function.
+
+ -- transfering a negative amount from a fund is the same as
+ -- crediting it back to the funding source, which must
+ -- happen before the amount is transferred to the receiving fund
+ IF funding_source_credit <= 0 THEN
+ --
+ -- Insert negative (or 0) allocation for old fund in fund_allocation,
+ -- converted into the currency of the funding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note,
+ conversion_ratio,
+ fund_amount
+ ) VALUES (
+ source.funding_source,
+ transferring_fund_id,
+ funding_source_credit,
+ user_id,
+ 'Transfer to fund ' || receiving_fund_id,
+ source_credit_conversion_ratio,
+ (current_amount_to_transfer * -1)
+ );
+ ELSE
+ RAISE EXCEPTION 'funding_source_credit of % is greater than 0', funding_source_credit;
+ END IF;
+ --
+ --
+ -- Determine how much to add to the receiving fund, in
+ -- its currency, and how much remains to be added:
+ --
+ IF same_currency THEN
+ current_amount_to_receive := current_amount_to_transfer;
+ ELSE
+ -- If there are not funds left to be transferred then
+ -- transfer the remaining funds to be recieved from the
+ -- funding source. In this instance, conversion rates
+ -- have resulted in us transferring more out than we transferred
+ -- back in
+ IF funds_remaining_to_be_transferred = 0 THEN
+ current_amount_to_receive := funds_remaining_to_be_received;
+ funds_remaining_to_be_received := 0;
+ ELSE
+ -- set the amount to recieve to be the amount to transfer converted into
+ -- the currenty of the receiving fund
+ current_amount_to_receive := trunc( current_amount_to_transfer * conversion_ratio, 2 );
+ funds_remaining_to_be_received := funds_remaining_to_be_received - current_amount_to_receive;
+
+ --
+ -- It may be that the amount to be transfered to the new
+ -- fund becomes less than 0
+ -- a loop before funds_remaining_to_be_transferred becomes 0
+ -- I am not positive if this is possible, but
+ -- it is good to guard against it.
+ --
+ IF funds_remaining_to_be_received < 0 THEN
+ funds_remaining_to_be_received := 0;
+ END IF;
+ END IF;
+ END IF;
+
+ --
+ -- Determine how much to add, if any,
+ -- to the receiving fund's allocation.
+ --
+
+ IF source.currency_type = receiving_fund_currency THEN
+ source_debit_conversion_ratio = 1;
+ --
+ -- In this case we don't need a round trip currency translation,
+ -- because current_amount_to_receive is either in the same currency as the transferring fund
+ -- so it does not need to be converted, or it has been converted in the IF
+ -- block above this either through multiplication via the conversion_ratio
+ -- of via assignment of funds_remaining_to_be_received which is in the denomination of the
+ -- receiving currency
+ --
+ funding_source_debit := current_amount_to_receive;
+ ELSE
+
+ IF (amount_to_receive IS NULL) AND (trasnferring_fund_currency != source.currency_type) THEN
+ source_debit_conversion_ratio := acq.exchange_ratio( receiving_fund_currency, source.currency_type );
+ ELSE
+ -- Need to use the inverted_conversion_ratio variable when
+ -- there is an amount_to_receive passed in
+ source_debit_conversion_ratio := inverted_conversion_ratio;
+ END IF;
+
+ funding_source_debit := trunc(
+ current_amount_to_receive * source_debit_conversion_ratio, 2 );
+ END IF;
+ --
+ -- Ensure the debit is greater than or equal to 0
+ -- Similar to funding_source_credit there may be a corresponding
+ -- entry in acq.fund_transfer.
+ --
+ IF funding_source_debit >= 0 THEN
+ --
+ -- Insert positive allocation (or 0) for new fund in fund_allocation,
+ -- converted to the currency of the founding source
+ --
+ INSERT INTO acq.fund_allocation (
+ funding_source,
+ fund,
+ amount,
+ allocator,
+ note,
+ conversion_ratio,
+ fund_amount
+ ) VALUES (
+ source.funding_source,
+ receiving_fund_id,
+ funding_source_debit,
+ user_id,
+ 'Transfer from fund ' || transferring_fund_id,
+ source_debit_conversion_ratio,
+ current_amount_to_receive
+ );
+ ELSE
+ RAISE EXCEPTION 'acq.fund_transfer: funding_source_debit % is less than 0', funding_source_debit;
+ END IF;
+ --
+ -- Either of these can be greater than 0.
+ -- current_amount_to_transfer is the value to be transferred. current_amount_to_receive is that
+ -- value converted into the new funds currency
+ -- If the entire amount can be taken from a single source credit. Then
+ -- this is a simple calculation.
+ -- Otherwise, current_amount_to_transfer is set to the amount left in funds_remaining_to_be_transferred
+ -- after a loop or the values in the current funding source credit.
+ -- And, current_amount_to_receive is set to the converted amount from current_amount_to_transfer.
+ -- Finally, once funds_remaining_to_be_transferred = 0 curr_new_amount is set to funds_remaining_to_be_received,
+ -- and new remaining will be 0 after that. Because funds_remaining_to_be_received
+ -- is only calculated once (after that it is only debited), this should
+ -- ensure that they both arrive at 0 together
+ -- There may be some conversion issues that make this not true, but I
+ -- cannot think of any at the moment. The code needs further examination.
+ IF trunc( current_amount_to_transfer, 2 ) > 0
+ OR trunc( current_amount_to_receive, 2 ) > 0 THEN
+ --
+ -- Insert row in fund_transfer, using amounts in the currency of the funds
+ --
+ INSERT INTO acq.fund_transfer (
+ src_fund,
+ src_amount,
+ dest_fund,
+ dest_amount,
+ transfer_user,
+ note,
+ funding_source_credit
+ ) VALUES (
+ transferring_fund_id,
+ trunc( current_amount_to_transfer, 2 ),
+ receiving_fund_id,
+ trunc( current_amount_to_receive, 2 ),
+ user_id,
+ xfer_note,
+ source.id
+ );
+ END IF;
+ --
+ -- It should be impossible for funds_remaining_to_be_transferred to be less than 0.
+ --
+ IF funds_remaining_to_be_transferred = 0 THEN
+ EXIT; -- Nothing more to be transferred
+ ELSIF funds_remaining_to_be_transferred < 0 THEN
+ RAISE EXCEPTION 'acq.transfer_fund: funds_remaining_to_be_transferred is less thant 0: % FIND OUT WHY',
+ funds_remaining_to_be_transferred;
+ END IF;
+ END LOOP;
+
+ --
+ -- This should not be possible any more, but we can leave it in just in case there
+ -- is a case that has not been thought of.
+ --
+ IF trunc(funds_remaining_to_be_transferred, 2) > 0 THEN
+ RAISE EXCEPTION 'not all of funds_remaining_to_be_transferred were transfered. There must not have been enough funds in the funding sources';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMIT;