YIELDFR
Updated: 17 October 2014
Use the scalar function YIELDFR to calculate the yield given price of a bond with a forced redemption schedule where the coupon payment dates occur at regular periods and the redemptions can occur on any coupon date. There is no closed-from solution for the calculation of yield if there is more than one coupon period remaining to maturity. If the settlement date is in the final coupon period, then the formula for the calculation of yield is:
Where:
A
|
=
|
Number of days from previous coupon date to settlement date
|
DSR
|
=
|
Number of days from settlement date to maturity date
|
E
|
=
|
Number of days in the current coupon period
|
F
|
=
|
Number of coupon payments per year
|
R
|
=
|
Annual interest rate in decimal terms (10% = 0.10)
|
Y
|
=
|
Annual yield in decimal terms (10% = 0.10)
|
Price
|
=
|
Clean price of the bond
|
Par
|
=
|
Par value of the bond
|
Syntax
SELECT [wct].[YIELDFR](
<@Settlement, datetime,>
,<@Maturity, datetime,>
,<@Rate, float,>
,<@Par, float,>
,<@Price, float,>
,<@Frequency, float,>
,<@Basis, nvarchar(4000),>
,<@Repayments, nvarchar(max),>)
Arguments
@Settlement
the settlement date of the security. @Settlement is an expression that returns a datetime or smalldatetime value, or a character string in date format.
@Maturity
the maturity date of the security. @Maturity is an expression that returns a datetime or smalldatetime value, or a character string in date format.
@Rate
the security’s annual coupon rate. @Rate is an expression of type float or of a type that can be implicitly converted to float.
@Par
the par value of the security. All forced redemptions are subtracted from the par value on the redemption date and the adjusted balance is used in calculating the subsequent coupon interest. @Par is an expression of type float or of a type that can be implicitly converted to float.
@Price
the clean price of the security. @Price 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 bimonthly @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/364'
|
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/364 NON-EOM'
|
Actual/364 non-end-of-month
|
@Repayments
a SELECT statement, as a string, which identifies the coupon dates and the forced redemption amounts to be used in the price calculation.
Return Type
float
Remarks
· If @Basis is invalid then YIELDFR returns an error.
· If @Frequency is invalid then YIELDFR returns an error.
· If @Maturity < @Settlement then NULL is returned.
· If @Repayments returns no rows then NULL is returned.
· If @Settlement is NULL, @Settlement = GETDATE().
· If @Frequency is NULL, @Frequency = 2.
· If @Basis is NULL, @Basis = 0.
· YIELDFR forces the principal balance of the bond to zero at maturity.
· If @Par is NULL then @Par = 100.
· If @Rate is NULL then @Rate = 0.
· If @Yield is NULL then @Yield = 0.
· If @Maturity is NULL then YIELDFR returns NULL.
Example
In this example we calculate the yield of a bond maturing on 2029-09-15 with the following redemption schedule:
2017-09-25 28.074
2021-09-20 32.29189696
2024-09-15 39.63410304
The bond has an 11.0% coupon rate, pays interest every 182 days using the Actual/364 day-count convention and has a par value or 100. The bond is being purchased at a price of 101.178910626482 for settlement on 2014-10-16.
SELECT
wct.YIELDFR(
'2014-10-16' --@Settlement
,'2025-09-15' --@Maturity
,0.1100 --@Rate
,100 --@Par
,101.17891062648 --@Price
,182 --@Frequency
,9 --@Basis
,'SELECT
*
FROM (VALUES
(''2017,09,25'', 28.074),
(''2021,09,20'', 32.29189696),
(''2025,09,15'', 39.63410304)
)n(date_cf, amt_cf)' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.107499999986335
In this example, we eliminate the last row in the @Repayments SQL, demonstrating that YIELDFR will always force the principal amount at maturity equal to zero.
SELECT
wct.YIELDFR(
'2014-10-16' --@Settlement
,'2025-09-15' --@Maturity
,0.1100 --@Rate
,100 --@Par
,101.17891062648 --@Price
,182 --@Frequency
,9 --@Basis
,'SELECT
*
FROM (VALUES
(''2017,09,25', 28.074),
(''2021,09,20', 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.107499999986335
In this example, we populate a table with forced redemption information for a number of securities and demonstrate how to select that data in the @Repayments SQL.
SELECT
*
INTO
#Repayments
FROM (VALUES
('KE1000001637','16-Feb-15',43.00)
,('KE1000001637','13-Feb-17',22.80)
,('KE1000001637','8-Feb-21',34.20)
,('KE1000001758','30-Nov-2015',48.648)
,('KE1000001758','26-Nov-2018',27.23299264)
,('KE1000001758','22-Nov-2021',24.11900736)
,('KE1000001793','22-Feb-2016',55.17)
,('KE1000001793','19-Feb-2018',44.83)
,('KE1000001954','22-Aug-2016',43.038)
,('KE1000001954','21-Aug-2017',26.53232998)
,('KE1000001954','19-Aug-2019',30.42967002)
,('KE2000002242','28-Sep-2015',44.01)
,('KE2000002242','23-Sep-2019',32.6634462)
,('KE2000002242','18-Sep-2023',23.3265538)
,('KE3000008130','25-Sep-2017',28.074)
,('KE3000008130','20-Sep-2021',32.29189696)
,('KE3000008130','15-Sep-2025',39.63410304)
)n(ISIN, dt_ppay, amt_ppay)
SELECT
wct.YIELDFR(
'2014-10-16' --@Settlement
,'2025-09-15' --@Maturity
,0.1100 --@Rate
,100 --@Par
,101.17891062648 --@Price
,182 --@Frequency
,9 --@Basis
,'SELECT
dt_ppay
,amt_ppay
FROM
#Repayments
WHERE
ISIN = ''' + 'KE3000008130' + '''' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.107499999986335
In this example we calculate the yield for multiple securities, all with the same settlement, pulling the forced redemptions in from a temp table and the rest of the function inputs from a derived table.
SELECT
*
INTO
#Repayments
FROM (VALUES
('KE1000001637','16-Feb-15',43.00)
,('KE1000001637','13-Feb-17',22.80)
,('KE1000001637','8-Feb-21',34.20)
,('KE1000001758','30-Nov-2015',48.648)
,('KE1000001758','26-Nov-2018',27.23299264)
,('KE1000001758','22-Nov-2021',24.11900736)
,('KE1000001793','22-Feb-2016',55.17)
,('KE1000001793','19-Feb-2018',44.83)
,('KE1000001954','22-Aug-2016',43.038)
,('KE1000001954','21-Aug-2017',26.53232998)
,('KE1000001954','19-Aug-2019',30.42967002)
,('KE2000002242','28-Sep-2015',44.01)
,('KE2000002242','23-Sep-2019',32.6634462)
,('KE2000002242','18-Sep-2023',23.3265538)
,('KE3000008130','25-Sep-2017',28.074)
,('KE3000008130','20-Sep-2021',32.29189696)
,('KE3000008130','15-Sep-2025',39.63410304)
)n(ISIN, dt_ppay, amt_ppay)
SELECT
n.ISIN
,wct.YIELDFR(
'2014-10-16' --@Settlement
,n.Maturity --@Maturity
,n.Rate --@Rate
,100 --@Par
,n.Price --@Price
,n.Frequency --@Frequency
,n.Basis --@Basis
,'SELECT
dt_ppay
,amt_ppay
FROM
#Repayments
WHERE
ISIN = ''' + cast(n.ISIN as varchar(max)) + '''' --@Repayments
) as [YIELD]
FROM (VALUES
('KE1000001637','2021-02-08',0.125,182,9,103.713940670862)
,('KE1000001758','2021-11-22',0.120,182,9,103.185247973971)
,('KE1000001793','2018-02-19',0.120,182,9,102.362895728426)
,('KE1000001954','2019-08-19',0.060,182,9,88.2317399662709)
,('KE2000002242','2023-09-19',0.120,182,9,103.235732864288)
,('KE3000008130','2025-09-15',0.110,182,9,101.178910626482)
)n(ISIN,Maturity,Rate,Frequency,Basis,Price)
This produces the following result.
ISIN YIELD
------------ ----------------------
KE1000001637 0.107499999958553
KE1000001758 0.107499999979495
KE1000001793 0.107499999966529
KE1000001954 0.107499999963435
KE2000002242 0.107499999977359
KE3000008130 0.107499999986331
In this example we calculate the yield of the bond after a redemption has occurred.
SELECT
wct.YIELDFR(
'2017-10-01' --@Settlement
,'2025-09-15' --@Maturity
,0.1100 --@Rate
,100 --@Par
,101.077556509014 --@Price
,182 --@Frequency
,9 --@Basis
,'SELECT
*
FROM (VALUES
(wct.CALCDATE(2017,09,25), 28.074),
(wct.CALCDATE(2021,09,20), 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.107499999976386
In this example we calculate the price of the bond in the final coupon period.
SELECT
wct.YIELDFR(
'2025-08-15' --@Settlement
,'2025-09-15' --@Maturity
,0.1100 --@Rate
,100 --@Par
,99.9797000808397 --@Price
,182 --@Frequency
,9 --@Basis
,'SELECT
*
FROM (VALUES
(''2017,09,25', 28.074),
(''2021,09,20', 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.1075
This is an example of a bond paying a coupon semi-annually using the Actual/Actual day-count convention.
SELECT
wct.YIELDFR(
'2014-10-16' --@Settlement
,'2034-11-01' --@Maturity
,0.0475 --@Rate
,100 --@Par
,108.753442328922 --@Price
,2 --@Frequency
,1 --@Basis
,'SELECT
*
FROM (VALUES
(''2026,11,01', 20.000),
(''2028,11,01', 20.000),
(''2030,11,01', 20.000),
(''2032,11,01', 20.000)
)n(date_cf, amt_cf)' --@Repayments
) as [YIELD]
This produces the following result.
YIELD
----------------------
0.0399999999921134
See Also