PRICEFR
Updated 2024-02-29 14:17:56.857000
Syntax
SELECT [westclintech][wct].[PRICEFR](
<@Settlement, datetime,>
,<@Maturity, datetime,>
,<@Rate, float,>
,<@Par, float,>
,<@Yield, float,>
,<@Frequency, float,>
,<@Basis, nvarchar(4000),>
,<@Repayments, nvarchar(max),>)
Description
Use the scalar function PRICEFR to calculate the price from yield 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. The formula for the price of a bond with a forced redemption schedule with more than one period to maturity is:
\rm{PRICE=\frac{P}{P-\Sigma_{j=1}^MFR_j}\times\left[\sum_{k=1}^N\frac{C_k+FR_k}{\left(1+\frac{Y}{F}\right)^{k-1+\frac{DSC}{E}}}-\left(P-\sum_{j=1}^MFR_j\right)\times\frac{R}{F}\times\frac{A}{E}\right]}
Where:A = Number of days from previous coupon date to settlement dateC = Coupon AmountDSC = Number of days from settlement date to the next coupon dateE = Number of days in the current coupon periodF = Number of coupon payments per yearFR = Forced Redemption amountM = Number of forced redemptions on or before the previous coupon dateN = Number of coupons from the settlement to the maturity dateP = Par ValueR = Annual interest rate in decimal terms (10% = 0.10)Y = Annual yield in decimal terms (10% = 0.10)
The coupon payments can vary over the life of the bond as they are affected by the forced redemption schedule. Coupon payments are calculated as
\rm{C_k=\left(P-\sum_{j=1}^{k-1}FR_j\right)\times\frac{R}{F}}
Where:Ck = Coupon payment number kF = Number of coupon payments per yearFR = Forced redemption amountP = Par valueR = Annual rate of interest in decimal terms
If the settlement date is in the final coupon period, then the formula for the calculation of price is:
\rm{PRICE=P\times\left[\frac{1+\frac{R}{F}}{1+\left(\frac{DSR}{E}\times\frac{Y}{F}\right)}-\left(\frac{A}{E}\times\frac{R}{F}\right)\right]}
Where:A = Number of days from previous coupon date to settlement dateDSR = Number of days from settlement date to maturity dateE = Number of days in the current coupon periodF = Number of coupon payments per yearR = Annual interest rate in decimal terms (10% = 0.10)P = Par ValueY = Annual yield in decimal terms (10% = 0.10)
Arguments
@Basis
is the type of day count to use. @Basis is an expression of the character string data type category.
{"columns":[{"field":"@Basis","width":313},{"field":"Day count basis","width":277}],"rows":[{"@Basis":"0 , 'BOND'","Day count basis":"US (NASD) 30/360"},{"@Basis":"1 , 'ACTUAL'","Day count basis":"Actual/Actual"},{"@Basis":"2 , 'A360'","Day count basis":"Actual/360"},{"@Basis":"3 , 'A365'","Day count basis":"Actual/365"},{"@Basis":"4 , '30E/360 (ISDA)' , '30E/360' , 'ISDA' , '30E/360 ISDA' , 'EBOND'","Day count basis":"European 30/360"},{"@Basis":"5 , '30/360' , '30/360 ISDA' , 'GERMAN'","Day count basis":"30/360 ISDA"},{"@Basis":"6 , 'NL/ACT'","Day count basis":"No Leap Year/ACT"},{"@Basis":"7 , 'NL/365'","Day count basis":"No Leap Year /365"},{"@Basis":"8 , 'NL/360'","Day count basis":"No Leap Year /360"},{"@Basis":"9 , 'A/364'","Day count basis":"Actual/364"},{"@Basis":"10 , 'BOND NON-EOM'","Day count basis":"US (NASD) 30/360 non-end-of-month"},{"@Basis":"11 , 'ACTUAL NON-EOM'","Day count basis":"Actual/Actual non-end-of-month"},{"@Basis":"12 , 'A360 NON-EOM'","Day count basis":"Actual/360 non-end-of-month"},{"@Basis":"13 , 'A365 NON-EOM'","Day count basis":"Actual/365 non-end-of-month"},{"@Basis":"14 , '30E/360 NON-EOM' , '30E/360 ICMA NON-EOM' , 'EBOND NON-EOM'","Day count basis":"European 30/360 non-end-of-month"},{"@Basis":"15 , '30/360 NON-EOM' , '30/360 ISDA NON-EOM' , 'GERMAN NON-EOM'","Day count basis":"30/360 ISDA non-end-of-month"},{"@Basis":"16 , 'NL/ACT NON-EOM'","Day count basis":"No Leap Year/ACT non-end-of-month"},{"@Basis":"17 , 'NL/365 NON-EOM'","Day count basis":"No Leap Year/365 non-end-of-month"},{"@Basis":"18 , 'NL/360 NON-EOM'","Day count basis":"No Leap Year/360 non-end-of-month"},{"@Basis":"19 , 'A/364 NON-EOM'","Day count basis":"Actual/364 non-end-of-month"}]}
@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.
@Repayments
a SELECT statement, as a string, which identifies the coupon dates and the forced redemption amounts to be used in the price calculation.
@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.
@Yield
the security’s annual yield. @Yield 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.
@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.
Return Type
float
Remarks
If @Basis is invalid then PRICEFR returns an error.
If @Frequency is invalid then PRICEFR 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.
PRICEFR 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 PRICEFR returns NULL.
Examples
In this example we calculate the price of a bond maturing on 2029-09-15 with the following redemption schedule:
2017-09-25 28.0742021-09-20 32.291896962024-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 yield of 10.75% for settlement on 2014-10-16.
SELECT wct.PRICEFR(
'2014-10-16', --@Settlement
'2025-09-15', --@Maturity
0.1100, --@Rate
100, --@Par
0.1075, --@Yield
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 [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"101.178910626482"}]}
In this example, we eliminate the last row in the @Repayments SQL, demonstrating that PRICEFAR will always force the principal amount at maturity equal to zero.
SELECT wct.PRICEFR(
'2014-10-16', --@Settlement
'2025-09-15', --@Maturity
0.1100, --@Rate
100, --@Par
0.1075, --@Yield
182, --@Frequency
9, --@Basis
'SELECT
*
FROM (VALUES
(''2017,09,25'', 28.074),
(''2021,09,20'', 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"101.178910626482"}]}
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.PRICEFR(
'2014-10-16', --@Settlement
'2025-09-15', --@Maturity
0.1100, --@Rate
100, --@Par
0.1075, --@Yield
182, --@Frequency
9, --@Basis
'SELECT
dt_ppay
,amt_ppay
FROM
#Repayments
WHERE
ISIN = ''' + 'KE3000008130' + '''' --@Repayments
) as [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"101.178910626482"}]}
In this example we calculate the price for multiple securities, all with the same settlement date and yield, 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.PRICEFR(
'2014-10-16', --@Settlement
n.Maturity, --@Maturity
n.Rate, --@Rate
100, --@Par
0.1075, --@Yield
n.Frequency, --@Frequency
n.Basis, --@Basis
'SELECT
dt_ppay
,amt_ppay
FROM
#Repayments
WHERE
ISIN = ''' + cast(n.ISIN as varchar(max)) + '''' --@Repayments
) as [PRICE]
FROM
(
VALUES
('KE1000001637', '2021-02-08', 0.125, 182, 9),
('KE1000001758', '2021-11-22', 0.120, 182, 9),
('KE1000001793', '2018-02-19', 0.120, 182, 9),
('KE1000001954', '2019-08-19', 0.060, 182, 9),
('KE2000002242', '2023-09-19', 0.120, 182, 9),
('KE3000008130', '2025-09-15', 0.110, 182, 9)
) n (ISIN, Maturity, Rate, Frequency, Basis);
This produces the following result.
{"columns":[{"field":"ISIN"},{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"ISIN":"KE1000001637","PRICE":"103.713940670862"},{"ISIN":"KE1000001758","PRICE":"103.185247973971"},{"ISIN":"KE1000001793","PRICE":"102.362895728426"},{"ISIN":"KE1000001954","PRICE":"88.2317399662709"},{"ISIN":"KE2000002242","PRICE":"103.235732864288"},{"ISIN":"KE3000008130","PRICE":"101.178910626482"}]}
In this example we calculate the price of the bond after a redemption has occurred.
SELECT wct.PRICEFR(
'2017-10-01', --@Settlement
'2025-09-15', --@Maturity
0.1100, --@Rate
100, --@Par
0.1075, --@Yield
182, --@Frequency
9, --@Basis
'SELECT
*
FROM (VALUES
(''2017,09,25'', 28.074),
(''2021,09,20'', 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"101.077556509014"}]}
In this example. we calculate the price of the bond in the final coupon period.
SELECT wct.PRICEFR(
'2025-08-15', --@Settlement
'2025-09-15', --@Maturity
0.1100, --@Rate
100, --@Par
0.1075, --@Yield
182, --@Frequency
9, --@Basis
'SELECT
*
FROM (VALUES
(''2017,09,25'', 28.074),
(''2021,09,20'', 32.29189696)
)n(date_cf, amt_cf)' --@Repayments
) as [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"99.9797000808397"}]}
This is an example of a bond paying a coupon semi-annually using the Actual/Actual day-count convention.
SELECT wct.PRICEFR(
'2014-10-16', --@Settlement
'2034-11-01', --@Maturity
0.0475, --@Rate
100, --@Par
0.0400, --@Yield
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 [PRICE];
This produces the following result.
{"columns":[{"field":"PRICE","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"PRICE":"108.753442328922"}]}
See Also
ODDFPRICE - Price of a security with an odd first coupon
ODDLPRICE - Price of a bond with an odd last coupon
OFLPRICE - Price of a security with an odd last coupon.
PRICE - Price of a bond paying regular periodic interest
PRICEDISC - Price of a discount security
PRICEMAT - Price of an interest-at-maturity security
PRICESTEP - Calculate the Price of a security with step-up rates