Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Is there an equivalent of Excel's NORMDIST function in SQL Server 2005? Expand / Collapse
Author
Message
Posted Monday, August 9, 2010 7:55 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, January 13, 2015 11:40 AM
Points: 24, Visits: 314
Is there an equivalent of Excel's NORMDIST function in SQL Server 2005?
Post #965963
Posted Monday, August 9, 2010 9:01 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:47 PM
Points: 14,377, Visits: 14,123
Nothing right out of the box that i know of. You will probably have to write your own. (or borrow somebody else's)

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #966025
Posted Friday, August 13, 2010 6:31 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, January 13, 2015 11:40 AM
Points: 24, Visits: 314
If it helps anyone, this is how my function looks like. Thanks again to all who helped me.

CREATE FUNCTION [dbo].[udf_NORMDIST](@value FLOAT,
@mean FLOAT,
@sigma FLOAT,
@cummulative BIT)
RETURNS NUMERIC(28,8)
AS
/****************************************************************************************
NAME: udf_NORMDIST
WRITTEN BY: Tim Pickering
http://www.eggheadcafe.com/software/aspnet/31021839/normdistx-mean-standarddevtrue-in-sql-2005.aspx
DATE: 2010/07/13
PURPOSE: Mimics Excel's Function NORMDIST

Usage: SELECT dbo.udf_NORMDIST(.48321740,0,1,0)
OUTPUT: 0.35498205

REVISION HISTORY

Date Developer Details
2010/08/11 LC Posted Function


*****************************************************************************************/


BEGIN

DECLARE @x FLOAT
DECLARE @z FLOAT
DECLARE @t FLOAT
DECLARE @ans FLOAT
DECLARE @returnvalue FLOAT

SELECT @x = (@value-@mean)/@sigma

IF (@cummulative = 1)
BEGIN

SELECT @z = abs(@x)/sqrt(2.0)
SELECT @t = 1.0/(1.0+0.5*@z)
SELECT @ans = @t*exp(-@z*@z-1.26551223+@t*(1.00002368+@t*(0.37409196+@t*(0.09678418+@t*(-0.18628806+@t*(0.27886807+@t*(-1.13520398+@t*(1.48851587+@t*(-0.82215223+@t*0.17087277)))))))))/2.0

IF (@x <= 0)
SELECT @returnvalue = @ans
ELSE
SELECT @returnvalue = 1-@ans
END
ELSE
BEGIN
SELECT @returnvalue = exp(-@x*@x/2.0)/sqrt(2.0*3.14159265358979)
END


RETURN CAST(@returnvalue AS NUMERIC(28,8))


END
Post #968851
Posted Wednesday, September 12, 2012 8:15 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, September 12, 2012 8:45 PM
Points: 1, Visits: 4
Out of the box there is no equivalent in SQL Server (up to 2012) for NORMDIST.

NORMDIST computes the Normal Distribution PDF (Probability Density Function) when the cumulative parameter is false and the CDF (Cumulative Distribution Function) otherwise.

The PDF can be computed from the definition and is pretty straight forward, the CDF however has no close form and can only be approximated.
I've developed a function for the PDF and a set of functions using different approximations for the CDF.
You can read my analysis in:
http://formaldev.blogspot.com.au/2012/09/T-SQL-NORMDIST-1.html
and either copy paste the ones you want from the posts or get them from the project page for the blog posts at:
https://tsqlnormdist.codeplex.com/
Post #1358295
Posted Tuesday, May 5, 2015 6:15 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Today @ 8:57 PM
Points: 1, Visits: 49
I have been able to use the udf_NORMDIST code to stand in for Excel NORM.DIST (NORMDIST). Thank-you very much for posting it!

The other reference from idea/Forum Newbie points to code for NORM.S.DIST (NORMSDIST in older Excel), it seems to be incorrectly labelled as an equivalent for NORMDIST.

However the value returned when @cummulative is set to false (0) seems to be incorrect with some larger numbers, at least it doesn't line up with Excel.

e.g. I used SELECT dbo.udf_NORMDIST(358, 352.791176470588, 234.354144866830, 0)
Excel gives me 0.001701885, but this function gave me 0.398843752

So I created a replacement for the line that returns a value when not using cumulative

The formula for this change comes from http://stattrek.com/online-calculator/normal.aspx

Normal equation:

The value of the random variable Y is:
Y = { 1/[ σ * sqrt(2π) ] } * e-(x - μ)2/2σ2

where X is a normal random variable,
μ is the mean,
σ is the standard deviation,
π is approximately 3.14159,
and e is approximately 2.71828.

Code change:
-- Incorrect for larger numbers?
--SELECT @returnvalue = exp(-@x*@x/2.0)/sqrt(2.0*3.14159265358979)
-- Correct for any numbers...
SELECT @returnvalue = (1/(@sigma * sqrt(2.0*3.14159265358979))) * exp(-((@value - @mean)*(@value - @mean))/(2*(@sigma*@sigma)))

Also, the precision is not quite right, it needs to be 29,9, not 28,8

Here is a replacement for the function:


CREATE FUNCTION [dbo].[udf_NORMDIST](
@value FLOAT,
@mean FLOAT,
@sigma FLOAT,
@cummulative BIT )

RETURNS NUMERIC( 29,9 )
AS

/****************************************************************************************
NAME: udf_NORMDIST
WRITTEN BY: Tim Pickering
http://www.eggheadcafe.com/software/aspnet/31021839/normdistx-mean-standarddevtrue-in-sql-2005.aspx
DATE: 2010/07/13
PURPOSE: Mimics Excel's Function NORMDIST

Usage: SELECT dbo.udf_NORMDIST(.48321740,0,1,0)
OUTPUT: 0.35498205

REVISION HISTORY

Date Developer Details
2010/08/11 LC Posted Function
*****************************************************************************************/
BEGIN
DECLARE @x FLOAT;
DECLARE @z FLOAT;
DECLARE @t FLOAT;
DECLARE @ans FLOAT;
DECLARE @returnvalue FLOAT;
SELECT @x = (@value - @mean) / @sigma;
IF(@cummulative = 1)
BEGIN
SELECT @z = ABS( @x ) / SQRT( 2.0 );
SELECT @t = 1.0 / (1.0 + 0.5 * @z);
SELECT @ans = @t*exp(-@z*@z-1.26551223+@t*(1.00002368+@t*(0.37409196+@t*(0.09678418+@t*(-0.18628806+@t*(0.27886807+@t*(-1.13520398+@t*(1.48851587+@t*(-0.82215223+@t*0.17087277)))))))))/2.0;
IF(@x <= 0)
SELECT @returnvalue = @ans;
ELSE
SELECT @returnvalue = 1 - @ans;
END;
ELSE
BEGIN
SELECT @returnvalue = (1/(@sigma * SQRT( 2.0 * 3.14159265358979 ))) * EXP(-((@value-@mean)*(@value-@mean)) / (2*(@sigma*@sigma)));
END;
RETURN CAST( @returnvalue AS NUMERIC( 29,9 ));
END;
Post #1682972
Posted Tuesday, May 19, 2015 9:35 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Tuesday, July 28, 2015 5:36 PM
Points: 3,964, Visits: 6,324
Nothing out of the box as stated, but there is this:

Excel in T-SQL Part 2 – The Normal Distribution (NORM.DIST) Density Functions

There are also some links at the end to approximation formulas for the cumulative distribution function. The probability density function is pretty straightforward.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Post #1687103
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse