Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server dirty PRICE from yield function


DIRTYPRICE

Updated: 10 November 2014


Use the scalar function DIRTYPRICE to calculate the dirty price of a bond. The dirty price of a bond is the discounted cash flow value of all the remaining coupons plus the discounted cash flow value of the redemption amount. This is equivalent to the clean price of the bond plus the accrued interest.
You can use DIRTYPRICE for bonds that pay regular period interest, bonds with an odd first coupon period, bonds with an odd last coupon period, and bonds with both an odd first and an odd last coupon period.
Syntax
SELECT [wct].[DIRTYPRICE](
  <@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/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

@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
float
Remarks
·         If @Settlement is NULL then @Settlement = GETDATE().
·         If @Rate is NULL then @Rate = 0.
·         If @Yield is NULL then @Yield = 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 DIRTYPRICE returns an error.
·         If @Basis invalid (see above list), DIRTYPRICE returns an error.
·         If @Maturity is NULL then @Maturity = GETDATE().
·         To calculate the dirty price for a bond paying regular periodic interest just enter @Maturity and @Settlement.
·         To calculate the dirty price 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 dirty price for a bond with an odd last coupon enter @LastCoupon, @Settlement, and @Maturity.
·         To calculate the dirty price 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 calculate the dirty price 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
   wct.DIRTYPRICE(
        '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
       ) as PRICE
This produces the following result.
PRICE
----------------------
96.9453139716364
 


Using the same bond information, we compare the clean price, dirty price, and accrued interest.
SELECT
   [DIRTY PRICE]
   ,P
   ,AI
   ,P + AI as [P + AI]
FROM (
   SELECT
       wct.DIRTYPRICE(
           '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
          ) as [DIRTY PRICE]
       ,wct.PRICE(
           '2014-05-01'    --@Settlement
          ,'2034-06-15'    --@Maturity
          ,0.025           --@Rate
          ,0.0276          --@Yield
          ,100             --@Redemption
          ,2               --@Frequency
          ,1) as P
       ,wct.BONDINT(
           '2014-05-01'    --@Settlement
          ,'2034-06-15'    --@Maturity
          ,0.025           --@Rate
          ,100             --@Par
          ,2               --@Frequency
          ,1) as AI
   )n
 
This produces the following result.
DIRTY PRICE            P                      AI                     P + AI
---------------------- ---------------------- ---------------------- ----------------------
96.9453139716364       96.0043799057024       0.940934065934066      96.9453139716364
 
You can use the DIRTYPRICE and BONDINT functions together to calculate the clean price when interim rounding is required. In this example, the price is calculated by round the discounted cash flow values to 4 decimal place and the accrued interest to 4 decimal places. We compare that to the result returned by the PRICE function rounded to 4 decimal places.
SELECT
   ROUND(
       wct.DIRTYPRICE(
           '2014-10-31'    --@Settlement
          ,'2015-05-18'    --@Maturity
          ,0.0695          --@Rate
          ,0.1140          --@Yield
          ,100             --@Redemption
          ,182             --@Frequency
          ,9               --@Basis
          ,NULL            --@Issue
          ,NULL            --@FirstCoupon
          ,NULL            --@LastCoupon
       ), 4)
   -ROUND(
       wct.BONDINT(
           '2014-10-31'    --@Settlement
          ,'2015-05-18'    --@Maturity
          ,0.0695          --@Rate
          ,100             --@Par
          ,182             --@Frequency
          ,9               --@Basis
       ), 4) as PRICE
   ,ROUND(
       wct.PRICE(
           '2014-10-31'    --@Settlement
          ,'2015-05-18'    --@Maturity
          ,0.0695          --@Rate
          ,0.1140          --@Yield
          ,100             --@Redemption
          ,182             --@Frequency
          ,9               --@Basis
       ), 4) as P
 
This produces the following result.
PRICE                  P
---------------------- ----------------------
97.6961                97.696


Here's an example of a bond with odd short first coupon settling on the issue date of the bond.
SELECT
   wct.DIRTYPRICE(
        '2014-05-01' --@Settlement
       ,'2034-06-15' --@Maturity
       ,0.0250       --@Rate
       ,0.0276       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2014-05-01' --@Issue
       ,'2014-06-15' --@FirstCoupon
       ,NULL         --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
96.0075631077824
 
This is a bond with an odd long first coupon, also settling on the issue date.
SELECT
   wct.DIRTYPRICE(
        '2014-05-01' --@Settlement
       ,'2034-06-15' --@Maturity
       ,0.0250       --@Rate
       ,0.0276       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2014-05-01' --@Issue
       ,'2014-12-15' --@FirstCoupon
       ,NULL         --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
96.0033702877755


This is a bond with an odd short last coupon settling in the last coupon period.
SELECT
   wct.DIRTYPRICE(
        '2014-10-01' --@Settlement
       ,'2014-12-15' --@Maturity
       ,0.0225       --@Rate
       ,0.0010       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,'2014-09-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
100.544776634675
 
This is a bond with an odd long last coupon settling in the final period.
SELECT
   wct.DIRTYPRICE(
        '2014-10-01' --@Settlement
       ,'2014-12-15' --@Maturity
       ,0.0225       --@Rate
       ,0.0010       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,'2014-03-15' --@LastCoupon
   ) as PRICE
This produces the following result.

 

PRICE
----------------------
101.669543602845


This is a bond with an odd short last coupon settling before the last coupon date.
SELECT
   wct.DIRTYPRICE(
        '2014-10-01' --@Settlement
       ,'2034-12-15' --@Maturity
       ,0.0425       --@Rate
       ,0.0400       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,'2034-09-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
103.63108323254


This is a bond with an odd long last coupon settling before the last coupon date.
SELECT
   wct.DIRTYPRICE(
        '2014-10-01' --@Settlement
       ,'2034-12-15' --@Maturity
       ,0.0425       --@Rate
       ,0.0400       --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,NULL         --@Issue
       ,NULL         --@FirstCoupon
       ,'2034-03-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
103.621532475367


This is a bond with an odd long first coupon and an odd long last coupon.
SELECT
   wct.DIRTYPRICE(
        '2013-03-04' --@Settlement
       ,'2022-11-28' --@Maturity
       ,0.03125      --@Rate
       ,0.02875      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2012-06-07' --@Issue
       ,'2013-03-15' --@FirstCoupon
       ,'2022-03-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
104.420159644839


This is a bond with an odd long first coupon and an odd short last coupon.
SELECT
   wct.DIRTYPRICE(
        '2013-03-04' --@Settlement
       ,'2022-04-28' --@Maturity
       ,0.03125      --@Rate
       ,0.02875      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2012-06-07' --@Issue
       ,'2013-03-15' --@FirstCoupon
       ,'2022-03-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
104.315730975387


This is a bond with an odd short first coupon and an odd long last coupon.
SELECT
   wct.DIRTYPRICE(
        '2013-03-04' --@Settlement
       ,'2022-11-28' --@Maturity
       ,0.03125      --@Rate
       ,0.02875      --@Yield
       ,100          --@Redemption
       ,2            --@Frequency
       ,1            --@Basis
       ,'2012-12-07' --@Issue
       ,'2013-03-15' --@FirstCoupon
       ,'2022-03-15' --@LastCoupon
   ) as PRICE
This produces the following result.
PRICE
----------------------
102.855826827035

 

See Also

 



Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service