Logo

CDRCashflowIRR

Updated 2023-10-10 15:11:25.397000

Syntax

SELECT [westclintech].[wct].[CDRCashflowIRR](
  <@PV, float,>
 ,<@PrinAmt, float,>
 ,<@InterestRate, float,>
 ,<@NumPmts, int,>
 ,<@LastPmtNum, int,>
 ,<@PmtPerYr, int,>
 ,<@LSRatesQuery, nvarchar(max),>
 ,<@CPRRatesQuery, nvarchar(max),>
 ,<@CDRRatesQuery, nvarchar(max),>
 ,<@InterestOnly, bit,>
 ,<@PrinPaymentMultiple, int,>
 ,<@FirstPrinPayNo, int,>
 ,<@PmtPayPct, float,>)

Description

Use the scalar function CDRCashFlowIRR to calculate the internal rate of return on cash flows produced using the CDRCASHFLOW inputs. CDRCashFlowIRR just returns the internal rate of return; if you want to explicitly produce the cash flows, use the CDRCASHFLOW table-valued function.

Arguments

@InterestRate

the annual rate of interest used to calculate the periodic payment. @InterestRate is an expression of type float or of a type that can be implicitly converted to float.

@CDRRatesQuery

a SELECT statement, as a string, which returns the month and default rate to be used in the calculation of the default amounts. @CDRRatesQuery should return 2 columns, month and rate, where 1% = .01.

@FirstPrinPayNo

the payment number of the first principal payment. @FirstPrinPayNo is an expression of type int or of a type that can be implicitly converted to int.

@PmtPerYr

the number of payments per year. @PmtPerYr is an expression of type int or of a type that can be implicitly converted to int.

@PmtPayPct

a fixed percentage which is applied to the projected principal balance to calculate the projected principal payment. @PmtPayPct is of a type float or of a type that can be implicitly converted to float.

@CPRRatesQuery

a SELECT statement, as a string, which returns the month and prepayment rates to be used in the calculation of the principal prepayments. @CPRratesQuery should return 2 columns, month and rate, where 1% = .01.

@NumPmts

the number of periods to be used in the calculation of the periodic payment. @NumPmts is an expression of type int or of a type that can be implicitly converted to int.

@PrinAmt

the principal amount to be amortized. @PrinAmt is an expression of type float or of a type that can be implicitly converted to float.

@LastPmtNum

the number of the last payment. Use @LastPmtNum for case where the number of payments for the annuity calculation is different than the actual number of payments, For example, an annuity based on 300 monthly payment which will be paid off at the end of 120 months. @LastPmtNum is an expression of type int or of a type that can be implicitly converted to int.

@InterestOnly

a bit value, which when true, identifies that the principal amount is scheduled to be repaid at the end of the loan.

@LSRatesQuery

a SELECT statement, as a string, which returns the month and loss severity rates to be used in the calculation of the loss severity amounts. @LSRatesQuery should return 2 columns, month and rate, where 1% = .01.

@PrinPaymentMultiple

the ratio of the frequency of the interest payments to the frequency of the interest payments. For example, a loan with monthly payments of interest and quarterly payments of principal would have a @PrinPaymentMultiple of 3. @PrinPaymentMultiple is an expression of type int or of a type that can be implicitly converted to int.

@PV

the present value of the cash flows. @PV is an expression of type float or of a type that can be implicitly converted to float.

Return Type

float

Remarks

If @FirstPrinPayNo is NULL then @FirstPrinPayNo = 1.

If @PrinAmt is NULL then @PrinAmt = 0.

If @InterestRate is NULL then @InterestRate = 0.

If @NumPmts is NULL then @NumPmts = 0.

If @LastPmtNum is NULL then @LastPmtNum = @NumPmts.

If @InterestOnly is NULL then @InterestOnly = FALSE.

If @PrinPaymentMultiple is NULL then @PrinPaymentMultiple = 1.

If @FirstPrinPayNo is NULL then @FirstPrinPayNo = @PrinPaymentMultiple.

If @NumPmts < 1 then no rows are returned.

If @PrinPaymentMultiple < 1 then no rows are returned.

If @FirstPrinPayNo < 1 then no rows are returned.

@PmtPerYr must be 1, 2, 3, 4, 6, or 12.

If @LSRatesQuery returns NULL or no rows then LS is set to zero.

If @CDRRatesQuery returns NULL or no rows then CDR is set to zero.

If @CPRRatesQuery returns NULL or no rows then CPR is set to zero.

Examples

Use the following CPR rates, which have been inserted into the #cpr table, for all of the examples.

SELECT *

INTO #cpr

FROM

(

    VALUES

        (1, 0.002),

        (25, 0.012),

        (61, 0.02),

        (181, 0.06)

) n (mth, rate);

Use the following CDR rates, which have been inserted into the #cdr table, for all of the examples.

SELECT *

INTO #cdr

FROM

(

    VALUES

        (1, 0.1),

        (61, 0.08),

        (181, 0.05)

) n (mth, rate);

Use the following Loss Severity rates, which have been inserted into the #ls table, for all the examples.

SELECT *

INTO #ls

FROM

(

    VALUES

        (1, 0.15),

        (91, 0.16),

        (181, 0.14),

        (271, 0.17),

        (361, 0.13)

) n (mth, rate);

Example #1

In this example we calculate the internal rate of return for a 100,000,000 loan with a 5% interest rate over 360 months using the data from the #ls, #cpr, and #cdr tables without modification.

SELECT wct.CDRCashflowIRR(   99000000,             --@PV

                             100000000,            --@PrinAmt

                             0.05,                 --@InterestRate

                             360,                  --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             NULL,                 --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0376982870781803"}]}

Example #2

In this example, we have a 10-year, 20,000,000 loan, with monthly payments calculated as though it were a 25-year loan.

SELECT wct.CDRCashflowIRR(   19800000,             --@PV

                             20000000,             --@PrinAmt

                             0.05,                 --@InterestRate

                             300,                  --@NumPmts

                             120,                  --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             NULL,                 --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0374349466658168"}]}

Example #3

In this example we have a 10-year, 25,000,000 interest-only loan with quarterly payments.

SELECT wct.CDRCashflowIRR(   24750000,             --@PV

                             25000000,             --@PrinAmt

                             0.04,                 --@InterestRate

                             40,                   --@NumPmts

                             NULL,                 --@LastPmtNum

                             4,                    --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             'True',               --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0269904195295865"}]}

Example #4

In this example we have a 10,000,000 loan with monthly payments of interest and quarterly payments of principal. The loan matures in 120 months.

SELECT wct.CDRCashflowIRR(   9900000,              --@PV

                             10000000,             --@PrinAmt

                             0.06,                 --@InterestRate

                             120,                  --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             NULL,                 --@InterestOnly

                             3,                    --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0482871473290531"}]}

Example #5

This example uses the same loan as the previous loan, 1 month later.

SELECT wct.CDRCashflowIRR(   9900000,              --@PV

                             10000000,             --@PrinAmt

                             0.06,                 --@InterestRate

                             119,                  --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             NULL,                 --@InterestOnly

                             3,                    --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.04828729633226"}]}

Example #6

This is an interest-only loan.

SELECT wct.CDRCashflowIRR(   49500,                --@PV

                             50000,                --@PrinAmt

                             .05,                  --@InterestRate

                             36,                   --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             'TRUE',               --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0386001717747222"}]}

Example #7

In this loan the principal payment is a fixed percentage of the outstanding principal.

SELECT wct.CDRCashflowIRR(   990000,               --@PV

                             1000000,              --@PrinAmt

                             .18,                  --@InterestRate

                             24,                   --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             NULL,                 --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             NULL,                 --@FirstPrinPayNo

                             0.0100                --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.182579923578976"}]}

Example #8

In this example we have a 30-year loan with interest-only payments for the first 7 years and fully-amortizing payments thereafter.

SELECT wct.CDRCashflowIRR(   495000,               --@PV

                             500000,               --@PrinAmt

                             .05,                  --@InterestRate

                             360,                  --@NumPmts

                             NULL,                 --@LastPmtNum

                             12,                   --@PmtPerYr

                             'SELECT * FROM #ls',  --@LSRatesQuery

                             'SELECT * FROM #cpr', --@CPRRatesQuery

                             'SELECT * FROM #cdr', --@CDRRatesQuery

                             'False',              --@InterestOnly

                             NULL,                 --@PrinPaymentMultiple

                             85,                   --@FirstPrinPayNo

                             NULL                  --@PmtPayPct

                         ) as IRR;

This produces the following result.

{"columns":[{"field":"IRR","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"IRR":"0.0376595537169337"}]}

See Also

AMORTIZECASHFLOWS - Discounted cash flow schedule

IRR - Internal rate of return for irregular periodic cash flows

MIRR - Modified internal rate of return for periodic irregular cash flows

XIRR - Internal rate of return for irregular cash flows

XIRR30360 - Internal rate of return for irregular cash flows using a 30/360 day-count convention

XIRRT - Internal rate of return for cash flows discounted using XNPVT

XMIRR - Calculate the modified internal rate of return, where positive and negative cash flows are financed at different rates and where the cash flows occur irregularly and are specified by date.