Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server cash flow schedule for stepped-rate bonds


STEPCF

Updated: 30 June 2016


Use the table-valued function STEPCF to return the cash flows of a stepped-rate bond. Stepped-rate bonds have different interest rates for different coupon periods and may even have a zero-rate period, usually at the commencement of the bond.
The first row in the resultant table is dated with settlement date passed into the function and is for the amount of the accrued interest. All the remaining rows are dated for the subsequent coupon dates and the amounts are the coupon amount. The row for the maturity date includes the coupon amount and the redemption amount.
The resultant table also includes the discount factor for each period as well as the discounted cash flow value for each period. The sum of the discounted cash flow values across all the periods is equal to the clean price of the bond.
Syntax
SELECT * FROM [wct].[STEPCF](
  <@Settlement, datetime,>
 ,<@Maturity, datetime,>
 ,<@Steps, nvarchar(max),>
 ,<@Yield, float,>
 ,<@Redemption, float,>
 ,<@Frequency, float,>
 ,<@Basis, nvarchar(4000),>
 ,<@Issue, datetime,>
 ,<@FirstCoupon, datetime,>
 ,<@LastCoupon, datetime,>)
Arguments
@Settlement
the settlement date of the bond. @Settlement is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@Maturity
the maturity date of the bond. @Maturity is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@Steps
an SQL statement which when executed will return the dates and rates associated with the step periods. The dates are the beginning of the coupon period is which the rate becomes effective. The rate are the annual coupon rates.
@Yield
the bond’s yield. @Yield is an expression of type float or of a type that can be implicitly converted to float.
@Redemption
the bond’s redemption value. Since the coupon amounts are calculation using a face amount of 100 the redemption value should be entered in relation to a 100 face value. @Redemption is an expression of type float or of a type that can be implicitly converted to float.
@Frequency
the number of coupon payments per year. For annual payments, @Frequency = 1; for semi-annual, @Frequency = 2; for quarterly, @Frequency = 4; for bi-monthly, @Frequency = 6; for monthly, @Frequency = 12. For bonds with @Basis = 'A/364' or 9, you can enter 364 for payments made every 52 weeks, 182 for payments made every 26 weeks, 91 for payments made every 13 weeks, 28 for payments made every 4 weeks, 14 for payments made every 2 weeks, and 7 for weekly payments. @Frequency is an expression of type float or of a type that can be implicitly converted to float.
@Basis
is the type of day count to use. @Basis is an expression of the character string data type category.

@Basis
Day count basis
0, 'BOND'
US (NASD) 30/360
1, 'ACTUAL'
Actual/Actual
2, 'A360'
Actual/360
3, 'A365'
Actual/365
4, '30E/360 (ISDA)', '30E/360', 'ISDA', '30E/360 ISDA', 'EBOND'
European 30/360
5, '30/360', '30/360 ISDA', 'GERMAN'
30/360 ISDA
6, 'NL/ACT'
No Leap Year/ACT
7, 'NL/365'
No Leap Year /365
8, 'NL/360'
No Leap Year /360
9, 'A/365'
Actual/364
10, 'BOND NON-EOM'
US (NASD) 30/360 non-end-of-month
11, 'ACTUAL NON-EOM'
Actual/Actual non-end-of-month
12, 'A360 NON-EOM'
Actual/360 non-end-of-month
13, 'A365 NON-EOM'
Actual/365 non-end-of-month
14, '30E/360 NON-EOM', '30E/360 ICMA NON-EOM', 'EBOND NON-EOM'
European 30/360 non-end-of-month
15, '30/360 NON-EOM', '30/360 ISDA NON-EOM', 'GERMAN NON-EOM'
30/360 ISDA non-end-of-month
16, 'NL/ACT NON-EOM'
No Leap Year/ACT non-end-of-month
17, 'NL/365 NON-EOM'
No Leap Year/365 non-end-of-month
18, 'NL/360 NON-EOM'
No Leap Year/360 non-end-of-month
19, 'A/365 NON-EOM'
Actual/364 non-end-of-month

@Issue
the issue date of the bond; the date from which the bond starts accruing interest. @Issue is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@FirstCoupon
the first coupon date of the bond. The period from the issue date until the first coupon date defines the odd interest period. All subsequent coupon dates are assumed to occur at regular periodic intervals as defined by @Frequency. @FirstCoupon is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@LastCoupon
the last coupon date of the bond prior to the maturity. The period from the last interest date until the maturity date defines the odd interest period. All coupon dates from @FirstCoupon to @LastCoupon are assumed to occur at regular periodic intervals as defined by @Frequency. @LastCoupon is an expression that returns a datetime or smalldatetime value, or a character string in date format.
Return Type
RETURNS TABLE (
       [date_pmt] [datetime] NULL,
       [amt_cashflow] [float] NULL,
       [N] [float] NULL,
       [PVF] [float] NULL,
       [PVCF] [float] NULL,
       [cumPVCF] [float] NULL
)

Column
Description
date_pmt
Date of the cash flow.
amt_cashflow
Amount of the cash flow.
N
Number of coupons from the settlement date to date_pmt.
PVF
Present value factor
PVCF
Present value of the cash flow; PVF * amt_cashflow.
cumPVCF
Sum of the PVCF.

Remarks
·         If @Settlement is NULL then @Settlement = GETDATE().
·         If @Step is NULL or returns no rows then0 is used.
·         If @Redemption is NULL then @Redemption = 100.
·         If @Frequency is NULL then @Frequency = 2.
·         If @Basis is NULL then @Basis = 1.
·         If @Maturity <= @Settlement then no rows are returned.
·         If @Frequency invalid STEPCF returns an error.
·         If @Basis invalid (see above list), STEPCF returns an error.
·         If @Maturity is NULL then no rows are returned.
·         To calculate the cash flows for a bond paying regular periodic interest just enter @Maturity and @Settlement.
·         To calculate the cash flows for bond with an odd first coupon where the settlement date is before the first coupon date, enter @Issue, @FirstCoupon, @Settlement, and @Maturity. If the settlement date is on or after the first coupon date just enter @Maturity and @Settlement.
·         To calculate the cash flows for a bond with an odd last coupon enter @LastCoupon, @Settlement, and @Maturity.
·         To calculate the cash flows for bond with an odd first coupon and an odd last coupon where the settlement date is before the first coupon date, enter @Issue, @FirstCoupon, @LastCoupon, @Settlement, and @Maturity. If the settlement date is on or after the first coupon date just enter @LastCoupon, @Maturity and @Settlement.
·         Available in XLeratorDB / financial 2008 only
Examples

Example #1
In this example we generate the cash flows for bond maturing on 2034-06-15. The settlement date is 2014-05-01, the yield is 2.76%. The coupon is paid twice-yearly, the redemption value is 100 and the day-count convention is actual/actual. The step-rate schedule is passed in using a derived table.
SELECT
   *
FROM
   wct.STEPCF(
        '2014-05-01' --@Settlement
       ,'2034-06-15' --@Maturity
       ,'SELECT
          *
        FROM (VALUES
          (''2029-12-15''' + ', .015),
          (''2024-12-15''' + ', .014),
          (''2020-12-15''' + ', .013),
          (''2016-12-15''' + ', .012),
          (''2012-12-15''' + ', .011)
          )n(date_step, rate_step)'      --@Step
       ,0.0276       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

Example #2
In this example we use the same data but select the step rate data from a temporary table rather than a derived table.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2029-12-15', .015),
   ('2024-12-15', .014),
   ('2020-12-15', .013),
   ('2016-12-15', .012),
   ('2012-12-15', .011)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2014-05-01' --@Settlement
       ,'2034-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.0276       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

Example #3
In this example, we have a bond with zero first step.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2040-12-15', .018),
   ('2036-12-15', .017),
   ('2032-12-15', .016),
   ('2028-12-15', .015),
   ('2024-12-15', .014)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2016-07-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.0290       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

Example #4
In this example we use the same bond but the settlement is in the final coupon period.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2040-12-15', .018),
   ('2036-12-15', .017),
   ('2032-12-15', .016),
   ('2028-12-15', .015),
   ('2024-12-15', .014)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2044-04-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.0290       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

Example #5
In this example we have a bond with an odd first coupon period.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2040-12-15', .018),
   ('2035-12-15', .016),
   ('2030-12-15', .015),
   ('2025-12-15', .014),
   ('2020-12-15', .013),
   ('2015-12-01', .012)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2016-04-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.03125      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2015-12-01' --@Issue
       ,'2016-06-15' --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

Example #6
In this example we have a bond with an odd last coupon period.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2040-12-01', .018),
   ('2035-12-01', .016),
   ('2030-12-01', .015),
   ('2025-12-01', .014),
   ('2020-12-01', .013),
   ('2015-12-01', .012)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2016-04-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.02125      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,'2043-12-01' --@LastCoupon
       )
This produces the following result.

Example #7
In this example we have a bond with odd first coupon and an odd last coupon period.
SELECT
   *
INTO
   #t
FROM (VALUES
   ('2040-12-01', .018),
   ('2035-12-01', .016),
   ('2030-12-01', .015),
   ('2025-12-01', .014),
   ('2020-12-01', .013),
   ('2015-12-01', .012)
   )n(date_step, rate_step)
 
 
SELECT
   *
FROM
   wct.STEPCF(
        '2016-04-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,'SELECT * FROM #t' --@Step
       ,0.02125      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2015-11-14' --@Issue
       ,'2016-06-01' --@FirstCoupon
       ,'2043-12-01' --@LastCoupon
       )
This produces the following result.

 

See Also

 



Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service