$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;
+
+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 ('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
+ SELECT amount
+ INTO amount_currently_allocated_to_returning_fund
+ FROM acq.fund_combined_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 transferred, each denominated
+ -- in the currency of its respective fund. They will be
+ -- reduced on each iteration of the loop.
+ --
+ current_amount_to_return := amount_to_return;
+ --
+ -- RAISE NOTICE 'Transferring % in fund % to % in fund %',
+ -- old_amount, old_fund, new_amount, new_fund;
+ --
+ -- 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 old_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 oen 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,
+ ofsc.fund_amount,
+ 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.fund_amount THEN
+ current_amount_to_return := source.fund_amount;
+ 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 );
+
+ -- Ensure the addition is less than 0
+ 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
+ ) VALUES (
+ source.funding_source,
+ returning_fund_id,
+ funding_source_credit,
+ user_id,
+ 'Returning funds to the source'
+ );
+ ELSE
+ RAISE EXCEPTION 'funding_source_credit of % is greater than 0', fundingsource_credit;
+ 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 (
+ returing_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 funds_remaining_to_be_returned = 0 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
+) RETURNS VOID AS $$
+DECLARE
+--
+new_fund INT;
+new_year INT := old_year + 1;
+org_found BOOL;
+xfer_amount NUMERIC;
+roll_fund RECORD;
+deb RECORD;
+detail RECORD;
+--
+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;
+ 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.org = org_unit_id
+ and oldf.year = old_year
+ and oldf.propagate
+ and newf.year = new_year
+ 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
+ --
+ SELECT amount
+ INTO xfer_amount
+ FROM acq.fund_spent_balance
+ WHERE fund = roll_fund.old_fund;
+ --
+ IF xfer_amount <> 0 THEN
+ IF 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;
+ --
+ PERFORM acq.transfer_fund(
+ roll_fund.old_fund,
+ xfer_amount,
+ new_fund,
+ xfer_amount,
+ user_id,
+ 'Rollover'
+ );
+ ELSE
+ --
+ -- Returning funds to their source(s)
+ --
+ -- RAISE NOTICE 'Returing % from fund % to its source(s)', xfer_amount, roll_fund.old_fund;
+ --
+ 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;
+ --
+ -- 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;
+
+CREATE OR REPLACE FUNCTION acq.rollover_funds_by_org_tree(
+ old_year INTEGER,
+ user_id INTEGER,
+ org_unit_id INTEGER
+) RETURNS VOID AS $$
+DECLARE
+--
+new_fund INT;
+new_year INT := old_year + 1;
+org_found BOOL;
+xfer_amount NUMERIC;
+roll_fund RECORD;
+deb RECORD;
+detail RECORD;
+--
+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;
+ 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 oldf.org in (
+ SELECT id FROM actor.org_unit_descendants( 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
+ --
+ SELECT amount
+ INTO xfer_amount
+ FROM acq.fund_spent_balance
+ WHERE fund = roll_fund.old_fund;
+ --
+ IF xfer_amount <> 0 THEN
+ IF 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;
+ --
+ PERFORM acq.transfer_fund(
+ roll_fund.old_fund,
+ xfer_amount,
+ new_fund,
+ xfer_amount,
+ user_id,
+ 'Rollover'
+ );
+ ELSE
+ --
+ -- Returning funds to their source(s)
+ --
+ -- RAISE NOTICE 'Returing % from fund % to its source(s)', xfer_amount, roll_fund.old_fund;
+ --
+ 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;
+ --
+ -- 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
+ transferring_funding_source IN INT DEFAULT NULL -- if user wants to
+ -- specify a funding
+ -- source (see notes)
+) 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 old (losing) fund and a positive amount for the new
+(gaining) 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.
+ 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
+ --
+ -- 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;
+
+ --
+ -- 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 THEN
+ -- they are the same currencies, so make amount_to_transfer a positve value
+ amount_to_transfer := amount_to_transfer * -1;
+ ELSE
+ -- 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
+ SELECT
+ ofsc.id,
+ ofsc.funding_source,
+ ofsc.amount,
+ 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,
+ 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
+ amount_allocated_by_funding_source -- in currency of the transferring fund
+ FROM
+ acq.fund_allocation
+ WHERE
+ 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 transferred
+ --
+ current_amount_to_transfer := funds_remaining_to_be_transferred;
+
+ --
+ -- Can't attribute more than was allocated to the fund:
+ --
+ 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 from the funding source:
+ --
+ IF current_amount_to_transfer > source.amount_credited_to_fund THEN
+ current_amount_to_transfer := source.amount_credited_to_fund;
+ END IF;
+ --
+ 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.
+ --
+
+ 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 (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 * 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;
+ --
+ -- 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
+ --
+ 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.
+ --
+ funding_source_debit := trunc(
+ current_amount_to_receive *
+ acq.exchange_ratio( receiving_fund_currency, source.currency_type ),
+ 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 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;
+
+COMMIT;