OFCFACTORS
Updated: 31 May 2014
Use the table-valued function OFCFACTORS to return the components used in the calculation of price and yield for a bond with an odd first coupon. OFCFACTORS supports odd first coupon bonds with up to 2 quasi-coupon periods.
Syntax
SELECT * FROM [wctFinancial].[wct].[OFCFACTORS](
<@Settlement, datetime,>
,<@Maturity, datetime,>
,<@Issue, datetime,>
,<@FirstCoupon, datetime,>
,<@Rate, float,>
,<@Price, float,>
,<@Yield, float,>
,<@Redemption, float,>
,<@Frequency, float,>
,<@Basis, nvarchar(4000),>)
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.
@Issue
the issue date of the security; the date from which the security 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 security. 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. @First_coupon 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.
@Price
the price of the bond. @Price is an expression of type float or of a type that can be implicitly converted to float.
@Yield
the security’s annual yield. @Yld is an expression of type float or of a type that can be implicitly converted to float.
@Redemption
the security’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 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
|
Return Type
RETURNS TABLE (
[E] [float] NULL,
[DSC] [float] NULL,
[N] [int] NULL,
[NCF] [int] NULL,
[A1] [float] NULL,
[DFC1] [float] NULL,
[NLF1] [float] NULL,
[A2] [float] NULL,
[DFC2] [float] NULL,
[NLF2] [float] NULL,
[Nqf] [float] NULL,
[quasistart] [datetime] NULL,
[quasicoup] [datetime] NULL,
[C] [float] NULL,
[FC] [float] NULL,
[P] [float] NULL,
[AI] [float] NULL,
[Y] [float] NULL
)
Column
|
Description
|
E
|
Number of coupon days in the quasi-coupon period in which the settlement date falls.
|
DSC
|
Number of days from the settlement date to the next quasi-coupon date.
|
N
|
Number of coupons between the first coupon date and the maturity date.
|
NCF
|
Number of quasi-coupon periods in the odd period (1 or 2).
|
A1
|
Number of accrued days in the first quasi-coupon period.
|
DFC1
|
Number of accrued days from the issue date to the next quasi-coupon date.
|
NLF1
|
Normal length of the first quasi-coupon period.
|
A2
|
Number of accrued days in the second quasi-coupon period.
|
DFC2
|
Number of accrued days from the quasicoup date to to the first coupon date.
|
NLF2
|
Normal length of the period from the quasicoup date to the first coupon date.
|
Nqf
|
Number of whole coupons between the settlement date and the first coupon date.
|
quasistart
|
Implied previous coupon date with respect to the issue date.
|
quasicoup
|
Implied next coupon date with respect to the issue date when NCF = 2.
|
C
|
Coupon amount
|
FC
|
First coupon amount
|
P
|
Price. If @Yield is NOT NULL then P is calculated from the inputs otherwise P is the value entered in @Price.
|
AI
|
Accrued interest as of the settlement date.
|
Y
|
Yield. If @Yield is NOT NULL then Y is the value entered in @Yield otherwise Y is calculated from the inputs.
|
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 = 0.
· If @Frequency is any number other than 1, 2, 4, 6 or 12, or for @Basis = 'A/364' any number other than 1, 2, 4, 6, or 12 as well as 7, 14, 28, 91, 182, or 364 OFCFACTORS returns an error.
· If @Basis invalid (see above list), OFCFACTORS returns an error.
· If @Maturity is NULL then an error is returned.
· If @Issue is NULL then an error is returned.
· If @FirstCoupon is NULL then an error is returned.
· If @Settlement >= @FirstCoupon then nothing is returned.
· The first quasi-coupon period is always the quasi-coupon period in which the issue date occurs.
· The previous coupon date for the first quasi-coupon period is calculated using @Frequency, @Basis, and @Maturity. This is the value returned in quasistart.
· If there is only one quasi-coupon period then quasicoup is NULL. Otherwise the preivous coupon date for the second quasi-coupon period is calculated using @Frequency, @Basis, and @Maturity.
· If there are 2 quasi-coupon periods then DFC2 = NLF2.
Examples
This bond has an odd short first coupon (meaning that the first coupon period is shorter than a normal coupon period) and settles on the issue date.
SELECT
*
FROM
wct.OFCFACTORS(
'2014-05-01', --@Settlement
'2034-06-15', --@Maturity
'2014-05-01', --@Issue
'2014-06-15', --@FirstCoupon
0.025, --@Rate
NULL, --@Price
0.0276, --@Yield
100, --@Redemption
2, --@Frequency
1 --@Basis
)
This produces the following result (which has been reformatted for ease of viewing).
E
|
DSC
|
N
|
NCF
|
A1
|
DFC1
|
NLF1
|
A2
|
DFC2
|
NLF2
|
Nqf
|
182
|
45
|
40
|
1
|
0
|
45
|
NULL
|
NULL
|
NULL
|
NULL
|
0
|
quasistart
|
quasicoup
|
C
|
FC
|
P
|
AI
|
Y
|
12/15/2013
|
NULL
|
1.25
|
0.309065934
|
96.00756311
|
0
|
0.0276
|
This bond has odd long first coupon (meaning that the first coupon period is longer than a normal coupon period) and settles on the issue date.
SELECT
*
FROM
wct.OFCFACTORS(
'2014-05-01', --@Settlement
'2034-06-15', --@Maturity
'2014-05-01', --@Issue
'2014-12-15', --@FirstCoupon
0.025, --@Rate
NULL, --@Price
0.0276, --@Yield
100, --@Redemption
2, --@Frequency
1 --@Basis
)
This produces the following result (which has been reformatted for ease of viewing).
E
|
DSC
|
N
|
NCF
|
A1
|
DFC1
|
NLF1
|
A2
|
DFC2
|
NLF2
|
Nqf
|
182
|
45
|
39
|
2
|
0
|
45
|
182
|
0
|
183
|
183
|
1
|
quasistart
|
quasicoup
|
C
|
FC
|
P
|
AI
|
Y
|
12/15/2013
|
6/15/2014
|
1.25
|
1.559065934
|
96.00337029
|
0
|
0.0276
|
Here we calculate the factors for a bond with an odd long first coupon with semi-annual coupons payable on March 30th and September 30th.
SELECT
*
FROM
wct.OFCFACTORS(
'2014-09-15', --@Settlement
'2034-09-30', --@Maturity
'2014-03-01', --@Issue
'2014-09-30', --@FirstCoupon
0.0257, --@Rate
98.116208, --@Price
NULL, --@Yield
100, --@Redemption
2, --@Frequency
11 --@Basis
)
This produces the following result.
E
|
DSC
|
N
|
NCF
|
A1
|
DFC1
|
NLF1
|
A2
|
DFC2
|
NLF2
|
Nqf
|
184
|
15
|
40
|
2
|
29
|
29
|
181
|
169
|
184
|
184
|
0
|
quasistart
|
quasicoup
|
C
|
FC
|
P
|
AI
|
Y
|
9/30/2013
|
3/30/2014
|
1.285
|
1.490883978
|
98.116208
|
1.3861285431
|
0.02692185
|
Here's an example with a negative yield.
SELECT
*
FROM wct.OFCFACTORS(
'2014-03-15', --@Settlement
'2024-09-30', --@Maturity
'2014-03-01', --@Issue
'2014-03-30', --@FirstCoupon
0.0157, --@Rate
NULL, --@Price
-0.00235, --@Yield
100, --@Redemption
2, --@Frequency
10 --@Basis
)
This produces the following result.
E
|
DSC
|
N
|
NCF
|
A1
|
DFC1
|
NLF1
|
A2
|
DFC2
|
NLF2
|
Nqf
|
180
|
15
|
21
|
1
|
14
|
29
|
NULL
|
NULL
|
NULL
|
NULL
|
0
|
quasistart
|
quasicoup
|
C
|
FC
|
P
|
AI
|
Y
|
9/30/2013
|
NULL
|
0.79
|
0.126472222
|
119.2767915
|
0
|
-0.00235
|
This is an example of a bond paying interest every 26 weeks.
SELECT
*
FROM
wct.OFCFACTORS(
'2014-10-04', --@Settlement
'2029-12-12', --@Maturity
'2014-03-26', --@Issue
'2014-12-31', --@FirstCoupon
0.1250, --@Rate
NULL, --@Price
0.1100, --@Yield
100, --@Redemption
182, --@Frequency
9 --@Basis
)
This produces the following result.
E
|
DSC
|
N
|
NCF
|
A1
|
DFC1
|
NLF1
|
A2
|
DFC2
|
NLF2
|
Nqf
|
182
|
88
|
30
|
2
|
98
|
98
|
182
|
94
|
182
|
182
|
0
|
quasistart
|
quasicoup
|
C
|
FC
|
P
|
AI
|
Y
|
2014-01-01
|
2014-07-02
|
6.25
|
9.615384615
|
110.8424329
|
6.593406593
|
0.11
|
See Also