Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server bond cash flow schedule


BONDCF

Updated: 31 October 2014


Use the table-valued function BONDCF to return the cash flows of a bond with regular periodic coupon payments. BONDCF also supports odd first and odd last coupon bonds with up to 2 quasi-coupon periods each.
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 will 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].[BONDCF](
  <@Settlement, datetime,>
 ,<@Maturity, datetime,>
 ,<@Rate, float,>
 ,<@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. 
@Rate
the bond’s annual coupon rate. @Rate is an expression of type float or of a type that can be implicitly converted to float.
@Yield
the bond’s annual 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 per 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/365
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/365 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 @Rate is NULL then @Rate = 0.
·         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 BONDCF returns an error.
·         If @Basis invalid (see above list), BONDCF 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.
Examples
In this example we generate the cash flows for bond which pays regular period interest and is maturing on 2034-06-15. The settlement date is 2014-05-01, the yield is 2.76%, the coupon rate is 2.50%, the redemption value is 100, the coupon is paid twice-yearly and the day-count convention is actual/actual.
SELECT
   *
FROM
   wct.BONDCF(
        '2014-05-01' --@Settlement
       ,'2034-06-15' --@Maturity
       ,0.025        --@Rate
       ,0.0276       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result (which has been reformatted for ease of viewing).

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2014-05-01
-0.940934066
0
1
-0.940934066
-0.940934066
2014-06-15
1.25
0.247252747
0.996616976
1.245771221
0.304837155
2014-12-15
1.25
1.247252747
0.983050874
1.228813593
1.533650748
2015-06-15
1.25
2.247252747
0.969669436
1.212086795
2.745737543
2015-12-15
1.25
3.247252747
0.956470148
1.195587685
3.941325228
2016-06-15
1.25
4.247252747
0.943450531
1.179313164
5.120638392
2016-12-15
1.25
5.247252747
0.930608139
1.163260173
6.283898565
2017-06-15
1.25
6.247252747
0.917940559
1.147425698
7.431324263
2017-12-15
1.25
7.247252747
0.905445412
1.131806765
8.563131028
2018-06-15
1.25
8.247252747
0.893120351
1.116400439
9.679531467
2018-12-15
1.25
9.247252747
0.880963061
1.101203826
10.78073529
2019-06-15
1.25
10.24725275
0.868971258
1.086214072
11.86694937
2019-12-15
1.25
11.24725275
0.857142689
1.071428361
12.93837773
2020-06-15
1.25
12.24725275
0.845475132
1.056843915
13.99522164
2020-12-15
1.25
13.24725275
0.833966395
1.042457994
15.03767964
2021-06-15
1.25
14.24725275
0.822614318
1.028267897
16.06594753
2021-12-15
1.25
15.24725275
0.811416767
1.014270958
17.08021849
2022-06-15
1.25
16.24725275
0.800371638
1.000464547
18.08068304
2022-12-15
1.25
17.24725275
0.789476857
0.986846072
19.06752911
2023-06-15
1.25
18.24725275
0.778730378
0.973412973
20.04094208
2023-12-15
1.25
19.24725275
0.768130182
0.960162727
21.00110481
2024-06-15
1.25
20.24725275
0.757674277
0.947092846
21.94819766
2024-12-15
1.25
21.24725275
0.747360699
0.934200874
22.88239853
2025-06-15
1.25
22.24725275
0.737187511
0.921484389
23.80388292
2025-12-15
1.25
23.24725275
0.727152803
0.908941003
24.71282392
2026-06-15
1.25
24.24725275
0.717254688
0.89656836
25.60939228
2026-12-15
1.25
25.24725275
0.707491308
0.884364135
26.49375642
2027-06-15
1.25
26.24725275
0.697860828
0.872326035
27.36608245
2027-12-15
1.25
27.24725275
0.688361441
0.860451801
28.22653425
2028-06-15
1.25
28.24725275
0.67899136
0.8487392
29.07527345
2028-12-15
1.25
29.24725275
0.669748826
0.837186032
29.91245948
2029-06-15
1.25
30.24725275
0.660632103
0.825790129
30.73824961
2029-12-15
1.25
31.24725275
0.651639478
0.814549348
31.55279896
2030-06-15
1.25
32.24725275
0.642769262
0.803461578
32.35626054
2030-12-15
1.25
33.24725275
0.634019789
0.792524737
33.14878527
2031-06-15
1.25
34.24725275
0.625389415
0.781736769
33.93052204
2031-12-15
1.25
35.24725275
0.616876519
0.771095649
34.70161769
2032-06-15
1.25
36.24725275
0.608479502
0.760599378
35.46221707
2032-12-15
1.25
37.24725275
0.600196787
0.750245983
36.21246305
2033-06-15
1.25
38.24725275
0.592026816
0.740033521
36.95249657
2033-12-15
1.25
39.24725275
0.583968057
0.729960072
37.68245665
2034-06-15
101.25
40.24725275
0.576018995
58.32192326
96.00437991

 
In this example we generate the cash flows for a zero-coupon bond
SELECT
   *
FROM
   wct.BONDCF(
        '2014-05-01' --@Settlement
       ,'2044-06-15' --@Maturity
       ,0.0000       --@Rate
       ,0.0301       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
WHERE
   amt_cashflow != 0
This produces the following result.

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2044-06-15
100
60.24725275
0.406583576
40.65835761
40.65835761

In this example we generate the cash flow of a bond paying regular periodic interest settling in the final coupon period.
SELECT
   *
FROM
   wct.BONDCF(
        '2014-05-01' --@Settlement
       ,'2014-07-15' --@Maturity
       ,0.0190       --@Rate
       ,0.0005       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,0            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2014-05-01
-0.559444444
0
1
-0.559444444
-0.559444444
2014-07-15
100.95
0.411111111
0.999897233
100.9396256
100.3801812

Here we generate the cash flows for a bond paying regular periodic interest which matures on the 30th of September 2034, with semi-annual coupons payable on March 30th and September 30th.
SELECT
   *
FROM
   wct.BONDCF(
        '2014-05-01' --@Settlement
       ,'2034-09-30' --@Maturity
       ,0.0257       --@Rate
       ,0.0269       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,11           --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2014-05-01
-0.223478261
0
1
-0.223478261
-0.223478261
2014-09-30
1.285
0.826086957
0.98902387
1.270895673
1.047417412
2015-03-30
1.285
1.826086957
0.975898041
1.254028983
2.301446395
2015-09-30
1.285
2.826086957
0.962946412
1.237386139
3.538832534
2016-03-30
1.285
3.826086957
0.95016667
1.220964171
4.759796706
2016-09-30
1.285
4.826086957
0.937556535
1.204760147
5.964556853
2017-03-30
1.285
5.826086957
0.925113755
1.188771175
7.153328028
2017-09-30
1.285
6.826086957
0.912836109
1.1729944
8.326322428
2018-03-30
1.285
7.826086957
0.900721406
1.157427007
9.483749435
2018-09-30
1.285
8.826086957
0.888767484
1.142066216
10.62581565
2019-03-30
1.285
9.826086957
0.876972207
1.126909287
11.75272494
2019-09-30
1.285
10.82608696
0.865333472
1.111953512
12.86467845
2020-03-30
1.285
11.82608696
0.853849201
1.097196223
13.96187467
2020-09-30
1.285
12.82608696
0.842517342
1.082634785
15.04450946
2021-03-30
1.285
13.82608696
0.831335875
1.068266599
16.11277606
2021-09-30
1.285
14.82608696
0.820302802
1.054089101
17.16686516
2022-03-30
1.285
15.82608696
0.809416155
1.040099759
18.20696492
2022-09-30
1.285
16.82608696
0.79867399
1.026296077
19.23326099
2023-03-30
1.285
17.82608696
0.788074389
1.01267559
20.24593658
2023-09-30
1.285
18.82608696
0.777615461
0.999235868
21.24517245
2024-03-30
1.285
19.82608696
0.767295339
0.98597451
22.23114696
2024-09-30
1.285
20.82608696
0.75711218
0.972889151
23.20403611
2025-03-30
1.285
21.82608696
0.747064167
0.959977455
24.16401357
2025-09-30
1.285
22.82608696
0.737149506
0.947237115
25.11125068
2026-03-30
1.285
23.82608696
0.727366428
0.93466586
26.04591654
2026-09-30
1.285
24.82608696
0.717713185
0.922261443
26.96817798
2027-03-30
1.285
25.82608696
0.708188056
0.910021652
27.87819964
2027-09-30
1.285
26.82608696
0.698789339
0.897944301
28.77614394
2028-03-30
1.285
27.82608696
0.689515358
0.886027235
29.66217117
2028-09-30
1.285
28.82608696
0.680364456
0.874268326
30.5364395
2029-03-30
1.285
29.82608696
0.671335
0.862665475
31.39910497
2029-09-30
1.285
30.82608696
0.662425379
0.851216612
32.25032158
2030-03-30
1.285
31.82608696
0.653634001
0.839919692
33.09024128
2030-09-30
1.285
32.82608696
0.644959299
0.828772699
33.91901398
2031-03-30
1.285
33.82608696
0.636399723
0.817773644
34.73678762
2031-09-30
1.285
34.82608696
0.627953745
0.806920562
35.54370818
2032-03-30
1.285
35.82608696
0.619619858
0.796211517
36.3399197
2032-09-30
1.285
36.82608696
0.611396574
0.785644597
37.1255643
2033-03-30
1.285
37.82608696
0.603282425
0.775217916
37.90078221
2033-09-30
1.285
38.82608696
0.595275963
0.764929613
38.66571182
2034-03-30
1.285
39.82608696
0.587375759
0.754777851
39.42048968
2034-09-30
101.285
40.82608696
0.579580403
58.70280112
98.12329079

Here's an example with a negative yield.
SELECT
   *
FROM
   wct.BONDCF(
        '2014-05-01' --@Settlement
       ,'2014-09-30' --@Maturity
       ,0.0257       --@Rate
       ,-0.046219    --@Yield
       ,98           --@Redemption
       ,2            --@Frequency
       ,0            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2014-05-01
-0.221305556
0
1
-0.221305556
-0.221305556
2014-09-30
99.285
0.827777778
1.019502606
101.2213163
101.0000107

This is an example of bond paying interest every 26 weeks.
SELECT
   *
FROM
   wct.BONDCF(
        '2014-10-01' --@Settlement
       ,'2023-03-13' --@Maturity
       ,0.1250       --@Rate
       ,0.1100       --@Yield
       ,100          --@Redemption
       ,182          --@Frequency
       ,9            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,NULL         --@LastCoupon
       )
This produces the following result.

date_pmt
amt_cashflow
N
PVF
PVCF
cumPVCF
2014-10-01
-0.309065934
0
1
-0.309065934
-0.309065934
2015-03-23
6.25
0.950549451
0.950380216
5.939876353
5.630810419
2015-09-21
6.25
1.950549451
0.900834328
5.630214553
11.26102497
2016-03-21
6.25
2.950549451
0.853871401
5.336696258
16.59772123
2016-09-19
6.25
3.950549451
0.809356779
5.058479866
21.6562011
2017-03-20
6.25
4.950549451
0.767162823
4.794767645
26.45096874
2017-09-18
6.25
5.950549451
0.727168553
4.544803455
30.9957722
2018-03-19
6.25
6.950549451
0.689259292
4.307870574
35.30364277
2018-09-17
6.25
7.950549451
0.653326343
4.083289643
39.38693241
2019-03-18
6.25
8.950549451
0.619266676
3.870416724
43.25734914
2019-09-16
6.25
9.950549451
0.586982631
3.668641444
46.92599058
2020-03-16
6.25
10.95054945
0.556381641
3.477385255
50.40337584
2020-09-14
6.25
11.95054945
0.527375963
3.296099768
53.6994756
2021-03-15
6.25
12.95054945
0.499882429
3.124265183
56.82374079
2021-09-13
6.25
13.95054945
0.473822208
2.961388799
59.78512959
2022-03-14
6.25
14.95054945
0.449120576
2.807003601
62.59213319
2022-09-12
6.25
15.95054945
0.425706707
2.66066692
65.25280011
2023-03-13