Logo

RANDNORMAL

Updated 2023-10-18 16:12:50.517000

Syntax

SELECT * FROM [westclintech].[wct].[RANDNORMAL](
  <@Rows, int,>
 ,<@mu, float,>
 ,<@sigma, float,>)

Description

Use the table-valued function RANDNORMAL to generate a sequence of random numbers from the normal distribution with mean @mu and standard deviation @sigma.

Arguments

@mu

the mean of the distribution. @mu must be of the type float or of a type that implicitly converts to float.

@Rows

the number of rows to generate. @Rows must be of the type int or of a type that implicitly converts to int.

@sigma

the standard deviation of the distribution. @sigma must be of the type float or of a type that implicitly converts to float.

Return Type

table

{"columns": [{"field": "colName", "headerName": "Name", "header": "name"}, {"field": "colDatatype", "headerName": "Type", "header": "type"}, {"field": "colDesc", "headerName": "Description", "header": "description", "minWidth": 1000}], "rows": [{"id": "3ccfaea6-7d1f-4710-ad15-70f9fb718df6", "colName": "Seq", "colDatatype": "int", "colDesc": "A monotonically increasing sequence number"}, {"id": "a0fa1812-de37-451f-b941-d3164e86d01a", "colName": "X", "colDatatype": "float", "colDesc": "The random variable"}]}

Remarks

@sigma must be greater than zero.

If @mu is NULL then @mu is set to zero.

If @sigma is NULL then @sigma is set to 1.

If @Rows is less than 1 then no rows are returned.

Examples

In this example we create a sequence 1,000,000 truncated random numbers from a standard normal distribution and COUNT the results. Elementary statistics leads us to expect the results to be distributed approximately like this:

{"columns":[{"field":"X","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"COUNT","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"X":"-4","COUNT":"31"},{"X":"-3","COUNT":"1318"},{"X":"-2","COUNT":"21400"},{"X":"-1","COUNT":"135905"},{"X":"0","COUNT":"682689"},{"X":"1","COUNT":"135905"},{"X":"2","COUNT":"21400"},{"X":"3","COUNT":"1318"},{"X":"4","COUNT":"31"}]}
SELECT X,

       COUNT(*) as [COUNT]

FROM

(

    SELECT wct.TRUNC(x, 0) as x

    FROM wct.RANDNORMAL(   1000000, --@Rows

                           NULL,    --@mu

                           NULL     --@sigma

                       )

) n

GROUP BY X

ORDER BY 1;

This produces the following result. Your results will be different.

{"columns":[{"field":"X","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"COUNT","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"X":"-5","COUNT":"1"},{"X":"-4","COUNT":"30"},{"X":"-3","COUNT":"1307"},{"X":"-2","COUNT":"21510"},{"X":"-1","COUNT":"135616"},{"X":"0","COUNT":"683067"},{"X":"1","COUNT":"135698"},{"X":"2","COUNT":"21408"},{"X":"3","COUNT":"1322"},{"X":"4","COUNT":"41"}]}

In this example we generate 1,000,000 random numbers from a normal distribution with a mean of 100 and a standard deviation of 15. We calculate the mean, standard deviation, skewness, and excess kurtosis from the resultant table and compare those values to the expected values for the distribution.

DECLARE @size as int = 1000000;
DECLARE @mu as float = 100;
DECLARE @sigma as float = 15;
DECLARE @mean as float = @mu;
DECLARE @var as float = POWER(@mu, 2);
DECLARE @stdev as float = @sigma;
DECLARE @skew as float = 0;
DECLARE @kurt as float = 0;
 
SELECT
   stat,
   [RANDNORMAL],
   [EXPECTED]
FROM (
   SELECT
      x.*
   FROM (
      SELECT
         AVG(x) as mean_NORMAL,
         STDEVP(x) as stdev_NORMAL,
         wct.SKEWNESS_P(x) as skew_NORMAL,
         wct.KURTOSIS_P(x) as kurt_NORMAL
      FROM
         wct.RANDNORMAL(@size,@mu,@sigma)
      )n
   CROSS APPLY(
      VALUES
         ('RANDNORMAL','avg', mean_NORMAL),
         ('RANDNORMAL','stdev', stdev_NORMAL),
         ('RANDNORMAL','skew', skew_NORMAL),
         ('RANDNORMAL','kurt', kurt_NORMAL),
         ('EXPECTED','avg',@mean),
         ('EXPECTED','stdev',@stdev),
         ('EXPECTED','skew',@skew),
         ('EXPECTED','kurt',@kurt)
      )x(fn_name,stat,val_stat)    
   )d
PIVOT(sum(val_stat) FOR fn_name in([RANDNORMAL],[EXPECTED])) P;

This produces the following result (your result will be different).

{"columns":[{"field":"stat"},{"field":"RANDNORMAL","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"EXPECTED","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"}],"rows":[{"stat":"avg","RANDNORMAL":"99.9969298163252","EXPECTED":"100"},{"stat":"kurt","RANDNORMAL":"-0.00220295058182929","EXPECTED":"0"},{"stat":"skew","RANDNORMAL":"0.000405814354994069","EXPECTED":"0"},{"stat":"stdev","RANDNORMAL":"15.0098425595394","EXPECTED":"15"}]}

See Also

NORMINV - Inverse of the normal distribution

NORMSINV - Inverse of the standard normal distribution

RANDBETA - Random numbers from a beta distribution

RANDBINOM - Random numbers from a binomial distribution

RANDCAUCHY - Random numbers from a Cauchy distribution

RANDCHISQ - Random numbers from a chi-squared distribution

RANDEXP - Random numbers from an exponential distribution

RANDFDIST - Random numbers from an F-distribution

RANDGAMMA - Random numbers from a gamma distribution

RANDLAPLACE - Random numbers from a LaPlace distribution

RANDLOGISTIC - Random numbers from a logistic distribution

RANDPOISSON - Random numbers from a Poisson distribution

RANDSNORMAL - Random numbers from the standard normal distribution

RANDTDIST - Random numbers from Student's t distribution

RANDWEIBULL - Generate a sequence of random numbers from w Weibull distribution with parameters shape (?) and scale (?).