May 11, 2010 at 10:26 am
Hello All,
Is there any way to calculate XIRR in SQL server using T-SQL.
Kindly suggest.
Thankx
May 11, 2010 at 10:46 am
That the good one!
There are no such thing in SQL!
You can code it yourself if you wish and have time to do so (you will need to find good algorithm first).
Or use XLeratorDB product from http://www.westclintech.com, if you really need it and have some money to spend 🙂
May 11, 2010 at 11:48 am
can any one give me best algorithm for the same, so i can go ahead with development.
If sample code provided then its save my time.
Thankx
May 11, 2010 at 11:51 am
a quick google search on XIRR turned up this:
http://forums.databasejournal.com/showthread.php?t=46094
-- Cory
May 11, 2010 at 3:18 pm
OK,
Here we are:
1. We create a sample table
create table txns
(
PmtAmount money
,PmtDate Datetime
)
insert into txns
select -2750,'20080205'
union select 1000,'20080705'
union select 2000,'20090105'
2. Then we calculate your XIRR as per Excel (almost):
DECLARE @nGuessRate NUMERIC(18,10)
SET @nGuessRate= 0.1 -- 10% - as per Excel XIRR default
DECLARE @dtFirstPmtDate DATETIME
DECLARE @nRateChangeNUMERIC(18,10)
DECLARE @nResidual NUMERIC(18,10)
DECLARE @nPrevResidual NUMERIC(18,10)
DECLARE @nXIRR NUMERIC(18,10)
SET @nRateChange = 0.1 -- starting point of the rate change
SELECT @dtFirstPmtDate=MIN(PmtDate) FROM txns
SELECT @nResidual = 10
,@nPrevResidual = 1
,@nXIRR = @nGuessRate
DECLARE @nIteration SMALLINT
SET @nIteration = 0 -- 100 is a maximum number of calc. iterations as per Excel XIRR
WHILE @nIteration < 100 AND ABS((@nPrevResidual - @nResidual) / @nPrevResidual) > 1.0/POWER(10,8)
BEGIN
SET @nPrevResidual = @nResidual
SET @nResidual = 0
SELECT @nResidual = @nResidual + PmtAmount/ POWER((1.0+@nGuessRate),(DATEDIFF(d,@dtFirstPmtDate,PmtDate)/365.0))
FROM txns
SET @nXIRR = @nGuessRate
IF @nResidual >= 0
BEGIN
SET @nGuessRate = @nGuessRate + @nRateChange
END
ELSE
BEGIN
SET @nRateChange = @nRateChange / 2
SET @nGuessRate = @nGuessRate - @nRateChange
END
SET @nIteration = @nIteration + 1
END
-- Calculation result
SELECT @nXIRR AS XIRR
Now, you can wrap it into stored proc or sql function.
Remember to check that your payment range contains at least one negative and one positive payment, otherwise you should return some error, check Excel XIRR documentation for other error conditions if any.
BUT! It may not be what you want. You most likely want XIRR to be an aggregate function. You cannot implement it in T-SQL, but you can do it in .NET as CLR function. Or, buy the product I have told you about in the previous post.
I might write some article about it if I have spare time...
Good Luck
May 11, 2010 at 10:27 pm
ok Elutin
Thanx four your help
January 31, 2011 at 11:34 pm
thanx ...but the xirr value is not marching with MS Excel 🙁
February 13, 2014 at 11:03 am
An XIRR is just a function name in Excel, it is actually an IRR calculation when the timings for the cash flows are given using a date schedule. This then leads to discounting of the cash flows at the actual time period as opposed to periodic time periods in IRR calculation
There are more than one way to define the XIRR equation and there are scores of ways of finding the roots of this equation that results in one or more IRR values
My personal favorite algo to find roots of a given function is the popular Newton-Raphson method that was named after the two mathematicians who independently discovered this method independent of each other about more than two centuries ago. One is the famous inventor of modern day Calculus the English mathematician Sir Isaac Newton (whom it seem was Knighted by the King of England thus the title "Sir" is referenced. The other one is Joseph Raphson, I am not sure of his national origin but it sounds like an American name so who knows I didn't look it up
Code may not always return an XIRR in such a case use a Guess rate other than the last one tried. In other case a Division by zero may be encountered when the differential is zero.
CREATE TYPE dbo.MyXirrTable AS TABLE
(
theValue DECIMAL(19, 9) NOT NULL,
theDate DATETIME NOT NULL
)
GO
CREATE FUNCTION dbo.XIRR
(
@Sample MyXirrTable READONLY,
@Rate DECIMAL(19, 9) = 0.1
)
RETURNS DECIMAL(38, 9)
AS
BEGIN
DECLARE @X DECIMAL(19, 9) = 0.0,
@X0 DECIMAL(19, 9) = 0.1,
@f DECIMAL(19, 9) = 0.0,
@fbar DECIMAL(19, 9) = 0.0,
@i TINYINT = 0,
IF @Rate IS NULL
SET @Rate = 0.1
SET @X0 = @Rate
WHILE @i < 100
BEGIN
SELECT @f = 0.0,
@fbar = 0.0
SELECT @f = @f + theValue * POWER(1 + @X0, (-theDelta / 365.0E)),
@fbar = @fbar - theDelta / 365.0E * theValue * POWER(1 + @X0, (-theDelta / 365.0E - 1))
FROM (
SELECT theValue,
DATEDIFF(DAY, MIN(theDate) OVER (), theDate) AS theDelta
FROM @Sample
) AS d
IF @fbar = 0
RETURN NULL
SET @X = @X0 - @f / @fbar
If ABS(@X - @X0) < 0.00000001
RETURN @X
SET @X0 = @X
SET @i += 1
END
RETURN NULL
END
GO
The above code is based on financial functions found in this JavaScript library tadJS[/url] that itself is based upon tadXL
February 17, 2014 at 5:59 pm
The Newton-Raphson approach to finding roots can also be done in an rCTE:
Exploring Recursive CTEs by Example [/url]
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
April 22, 2014 at 10:34 am
I've been using this and it works great but it doesn't work if the XIRR is negative, did you ever modify this code to handle that?
April 22, 2014 at 10:49 am
I got it to work using a guess rate of -.9
June 15, 2018 at 9:08 am
This was removed by the editor as SPAM
June 19, 2018 at 12:54 pm
bobthefinancialengineer - Thursday, February 13, 2014 11:03 AMAn XIRR is just a function name in Excel, it is actually an IRR calculation when the timings for the cash flows are given using a date schedule. This then leads to discounting of the cash flows at the actual time period as opposed to periodic time periods in IRR calculationThere are more than one way to define the XIRR equation and there are scores of ways of finding the roots of this equation that results in one or more IRR valuesMy personal favorite algo to find roots of a given function is the popular Newton-Raphson method that was named after the two mathematicians who independently discovered this method independent of each other about more than two centuries ago. One is the famous inventor of modern day Calculus the English mathematician Sir Isaac Newton (whom it seem was Knighted by the King of England thus the title "Sir" is referenced. The other one is Joseph Raphson, I am not sure of his national origin but it sounds like an American name so who knows I didn't look it upCode may not always return an XIRR in such a case use a Guess rate other than the last one tried. In other case a Division by zero may be encountered when the differential is zero.CREATE TYPE dbo.MyXirrTable AS TABLE ( theValue DECIMAL(19, 9) NOT NULL, theDate DATETIME NOT NULL )GOCREATE FUNCTION dbo.XIRR(@Sample MyXirrTable READONLY,@Rate DECIMAL(19, 9) = 0.1)RETURNS DECIMAL(38, 9)ASBEGINDECLARE @X DECIMAL(19, 9) = 0.0, @X0 DECIMAL(19, 9) = 0.1, @f DECIMAL(19, 9) = 0.0, @fbar DECIMAL(19, 9) = 0.0, @i TINYINT = 0,IF @Rate IS NULL SET @Rate = 0.1SET @X0 = @RateWHILE @i < 100 BEGIN SELECT @f = 0.0, @fbar = 0.0 SELECT @f = @f + theValue * POWER(1 + @X0, (-theDelta / 365.0E)), @fbar = @fbar - theDelta / 365.0E * theValue * POWER(1 + @X0, (-theDelta / 365.0E - 1)) FROM ( SELECT theValue, DATEDIFF(DAY, MIN(theDate) OVER (), theDate) AS theDelta FROM @Sample ) AS d IF @fbar = 0 RETURN NULL SET @X = @X0 - @f / @fbar If ABS(@X - @X0) < 0.00000001 RETURN @X SET @X0 = @X SET @i += 1 END RETURN NULLENDGO
The above code is based on financial functions found in this JavaScript library tadJS[/url] that itself is based upon tadXL
Thank you so very much for sharing this info.
This post is about 4 years old. Wondering if you have to modify this code any further? I am looking to implement XIRR in Sql server too.
June 19, 2018 at 12:56 pm
kayla_wilde - Tuesday, April 22, 2014 10:49 AMI got it to work using a guess rate of -.9
Have you made default rate as -0.9 or pass rate as parameter based on the need? Can you please explain?
Thank you.
April 11, 2023 at 4:04 pm
The code works great, however, I don't understand how the residuals are calculated. In the statement below why the residual is not the sum of the discounted cash flows:
SELECT @nResidual = @nResidual + PmtAmount/ POWER((1.0+@nGuessRate),(DATEDIFF(d,@dtFirstPmtDate,PmtDate)/365.0))
i.e. the following:
SELECT @nResidual = SUM (@nResidual + PmtAmount/ POWER((1.0+@nGuessRate),(DATEDIFF(d,@dtFirstPmtDate,PmtDate)/365.0)) )
In this example the subquery generates 3 records. Not sure which one of the records triggers the while loop. But with a sum statement the residual the the discounted cash flow. Interestingly, both statements (with and without the sum) produce the correct answer???
Your view is much appreciated.
Viewing 15 posts - 1 through 14 (of 14 total)
You must be logged in to reply to this topic. Login to reply