Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server duration function for odd first coupon bonds


OFCDURATION

Updated: 31 May 2014


Use OFCDURATION to calculate the duration for a bond that has an odd first coupon. The duration is calculated as the first derivative of the price of the bond with respect to yield multiplied by -1, divided by the dirty price of the bond multiplied by 1 plus the yield divided by the frequency.

XLeratorDB formula for the OFCDURATION SQL Server function - Duration of a bond with an odd first coupon
Syntax
SELECT [wctFinancial].[wct].[OFCDURATION](
  <@Settlement, datetime,>
 ,<@Maturity, datetime,>
 ,<@IssueDate, datetime,>
 ,<@FirstCouponDate, datetime,>
 ,<@Rate, float,>
 ,<@Yld, 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. 
@IssueDate
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. 
@FirstCouponDate
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. @FirstCouponDate 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.
@Yld
the yield for the maturity date passed into the function. @Yld is an expression of type float or of a type that can be implicitly converted to float.
@Redemption
the redemption value of the bond assuming a par value of 100. @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
float
Remarks
·         If @Maturity <= @Settlement 0 is returned.
·         If @Settlement is NULL, @Settlement = GETDATE()
·         If @Rate is NULL, @Rate = 0
·         If @Yld is NULL, @Yld = 0
·         If @Frequency is NULL, @Frequency = 2
·         If @Basis is NULL, @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 OFCDURATION returns an error.
·         If @Basis is invalid (see above list), OFCDURATION returns an error.
·         @Rate is entered as a decimal value; 1.0% = 0.01
·         @Yld is entered as a decimal value; 1.0% = 0.01
·         If @Maturity is NULL an error will be returned.
·         If @IssueDate is NULL an error will be returned.
·         If @FirstCouponDate is NULL an error will be returned.
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
   wct.OFCDURATION(
      '2014-05-01',     --@Settlement
      '2034-06-15',     --@Maturity
      '2014-05-01',     --@Issue
      '2014-06-15',     --@FirstCoupon
      0.025,            --@Rate
      0.0276,           --@Yield
      100,              --@Redemption
      2,                --@Frequency
      1                 --@Basis
      ) as OFCDURATION

This produces the following result.
           OFCDURATION
----------------------
      15.8299356059947


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
   wct.OFCDURATION(
      '2014-05-01',     --@Settlement
      '2034-06-15',     --@Maturity
      '2014-05-01',     --@Issue
      '2014-12-15',     --@FirstCoupon
      0.025,            --@Rate
      0.0276,           --@Yield
      100,              --@Redemption
      2,                --@Frequency
      1                 --@Basis
      ) as OFCDURATION

This produces the following result.
           OFCDURATION
----------------------
      15.8322039377803
 


Here we calculate the duration of a bond with an odd short first coupon with semi-annual coupons payable on March 30th and September 30th.
SELECT
   wct.OFCDURATION(
      '2014-03-15',     --@Settlement
      '2034-09-30',     --@Maturity
      '2014-03-01',     --@Issue
      '2014-03-30',     --@FirstCoupon
      0.0257,           --@Rate
      0.0269,           --@Yield
      100,              --@Redemption
      2,                --@Frequency
      11                --@Basis
      ) as OFCDURATION

This produces the following result.
           OFCDURATION
----------------------
      16.0189868270306


In this example we know the price of the bond (99.9875), but not the yield.
SELECT
   wct.OFCDURATION(
      '2014-05-28',     --@Settlement
      '2034-11-30',     --@Maturity
      '2014-05-01',     --@Issue
      '2014-11-30',     --@FirstCoupon
      0.0225,           --@Rate
      wct.ODDFYIELD(
         '2014-05-28', 
         '2034-11-30', 
         '2014-05-01', 
         '2014-11-30', 
         0.0225,             
         99.875,
         100,                
         2,                  
         5                   
         ),             --@Yield
      100,              --@Redemption
      2,                --@Frequency
      5                 --@Basis
   ) as OFCDURATION

This produces the following result.
           OFCDURATION
----------------------
      16.5080153658638


This is an example of a bond paying interest every 26 weeks.
SELECT
   wct.OFCDURATION(
      '2014-10-04',     --@Settlement
      '2029-12-12',     --@Maturity
      '2014-03-26',     --@Issue
      '2014-12-31',     --@FirstCoupon
      0.1250,           --@Rate
      0.1100,           --@Yield
      100,              --@Redemption
      182,              --@Frequency
      9                 --@Basis
      ) as OFCDURATION
 
This produces the following result.
            OFCDURATION
----------------------
      7.13014172616553

 

See Also

 



Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service