Logo

CDRCashflowDCF

Updated 2023-10-10 15:10:21.817000

Syntax

SELECT [westclintech].[wct].[CDRCashflowDCF](
  <@DiscRate, 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 CDRCASHFLOWDCF to return the discounted cash flow value for a loan with a fixed periodic payment with Conditional Prepayment Rates (CPR) and Constant Default Rates (CDR) applied.

Arguments

@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.

@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.

@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.

@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.

@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.

@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.

@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.

@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.

@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.

@DiscRate

The discount rate to be applied to the cash flows. @DiscRate is an expression of type float or of a type that can be 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.

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 discounted cash flow value of 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. The discount rate is 3.596%.

SELECT wct.CDRCashflowDCF(   0.0377,               --@DiscRate
                             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 DCF;

This produces the following result.

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

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. The discount rate is 3.532%.

SELECT wct.CDRCashflowDCF(   0.03744,              --@DiscRate
                             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 DCF;

This produces the following result.

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

Example #3

In this example we have a 10-year, 25,000,000 interest-only loan with quarterly payments. The discount rate is 2.479%.

SELECT wct.CDRCashflowDCF(   0.02699,              --@DiscRate
                             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 DCF;

This produces the following result.

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

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. The discount rate is 4.513%.

SELECT wct.CDRCashflowDCF(   0.04829,              --@DiscRate
                             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 DCF;

This produces the following result.

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

Example #5

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

SELECT wct.CDRCashflowDCF(   0.048287,             --@DiscRate
                             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 DCF;

This produces the following result.

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

Example #6

This is an interest-only loan. The discount rate is 3.472%.

SELECT wct.CDRCashflowDCF(   0.0386,               --@DiscRate
                             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 DCF;

This produces the following result.

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

Example #7

In this loan the principal payment is a fixed percentage of the outstanding principal. The discount rate is 17.601%.

SELECT wct.CDRCashflowDCF(   0.18258,              --@DiscRate
                             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 DCF;

This produces the following result.

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

Example #8

In this example we have a 30-year loan where the payments are interest-only for the first seven years and fully-amortizing thereafter. The discount rate is 3.604%.

SELECT wct.CDRCashflowDCF(   0.03766,              --@DiscRate
                             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 DCF;

This produces the following result.

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

See Also

EFV - Calculate the future value of a cash flow between two periods.

ENPV - Net Present Value for irregular periodic cash flows

EPV - Calculate the discounted value of a cash flow between two periods.

NFV - Calculate the net future value of an investment based on a series of periodic cash flows and a rate.

NPV - Net Present Value for irregular periodic cash flows using the Excel definition

XDCF - Discounted cash flow value

XFV - Calculate the future value of a cash flow between two dates.

XNFV - Net Future Value for irregular cash flows

XNPV - Net Present Value for irregular cash flows

XNPV30360 - Net Present Value for irregular cash flows using a 30/360 day-count convention

XNPVT - Calculate the net present value for a series of cash flows with irregular time periods—cash flows of varying amount occurring at various points in time.

XPV - Calculate the discounted value of a cash flow between two dates.