12 KiB
slug | sidebar_position | sidebar_label |
---|---|---|
/en/sql-reference/functions/random-functions | 51 | Pseudo-Random Numbers |
Functions for Generating Pseudo-Random Numbers
All the functions accept zero arguments or one argument. If an argument is passed, it can be any type, and its value is not used for anything. The only purpose of this argument is to prevent common subexpression elimination, so that two different instances of the same function return different columns with different random numbers.
:::note
Non-cryptographic generators of pseudo-random numbers are used.
:::
rand, rand32
Returns a pseudo-random UInt32 number, evenly distributed among all UInt32-type numbers.
Uses a linear congruential generator.
rand64
Returns a pseudo-random UInt64 number, evenly distributed among all UInt64-type numbers.
Uses a linear congruential generator.
randCanonical
The function generates pseudo random results with independent and identically distributed uniformly distributed values in [0, 1).
Non-deterministic. Return type is Float64.
randConstant
Produces a constant column with a random value.
Syntax
randConstant([x])
Arguments
x
— Expression resulting in any of the supported data types. The resulting value is discarded, but the expression itself if used for bypassing common subexpression elimination if the function is called multiple times in one query. Optional parameter.
Returned value
- Pseudo-random number.
Type: UInt32.
Example
Query:
SELECT rand(), rand(1), rand(number), randConstant(), randConstant(1), randConstant(number)
FROM numbers(3)
Result:
┌─────rand()─┬────rand(1)─┬─rand(number)─┬─randConstant()─┬─randConstant(1)─┬─randConstant(number)─┐
│ 3047369878 │ 4132449925 │ 4044508545 │ 2740811946 │ 4229401477 │ 1924032898 │
│ 2938880146 │ 1267722397 │ 4154983056 │ 2740811946 │ 4229401477 │ 1924032898 │
│ 956619638 │ 4238287282 │ 1104342490 │ 2740811946 │ 4229401477 │ 1924032898 │
└────────────┴────────────┴──────────────┴────────────────┴─────────────────┴──────────────────────┘
Functions for Generating Random Numbers based on Distributions
:::note
These functions are available starting from 22.10.
:::
randUniform
Return random number based on continuous uniform distribution in a specified range from min
to max
.
Syntax
randUniform(min, max)
Arguments
min
-Float64
- min value of the range,max
-Float64
- max value of the range.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randUniform(5.5, 10) FROM numbers(5)
Result:
┌─randUniform(5.5, 10)─┐
│ 8.094978491443102 │
│ 7.3181248914450885 │
│ 7.177741903868262 │
│ 6.483347380953762 │
│ 6.122286382885112 │
└──────────────────────┘
randNormal
Return random number based on normal distribution.
Syntax
randNormal(meam, variance)
Arguments
meam
-Float64
mean value of distribution,variance
-Float64
- variance.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randNormal(10, 2) FROM numbers(5)
Result:
┌──randNormal(10, 2)─┐
│ 13.389228911709653 │
│ 8.622949707401295 │
│ 10.801887062682981 │
│ 4.5220192605895315 │
│ 10.901239123982567 │
└────────────────────┘
randLogNormal
Return random number based on log-normal distribution.
Syntax
randLogNormal(meam, variance)
Arguments
meam
-Float64
mean value of distribution,variance
-Float64
- variance.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randLogNormal(100, 5) FROM numbers(5)
Result:
┌─randLogNormal(100, 5)─┐
│ 1.295699673937363e48 │
│ 9.719869109186684e39 │
│ 6.110868203189557e42 │
│ 9.912675872925529e39 │
│ 2.3564708490552458e42 │
└───────────────────────┘
randBinomial
Return random number based on binomial distribution.
Syntax
randBinomial(experiments, probability)
Arguments
experiments
-UInt64
number of experiments,probability
-Float64
- probability of success in each experiment (values in0...1
range only).
Returned value
- Pseudo-random number.
Type: UInt64.
Example
Query:
SELECT randBinomial(100, .75) FROM numbers(5)
Result:
┌─randBinomial(100, 0.75)─┐
│ 74 │
│ 78 │
│ 76 │
│ 77 │
│ 80 │
└─────────────────────────┘
randNegativeBinomial
Return random number based on negative binomial distribution.
Syntax
randNegativeBinomial(experiments, probability)
Arguments
experiments
-UInt64
number of experiments,probability
-Float64
- probability of failure in each experiment (values in0...1
range only).
Returned value
- Pseudo-random number.
Type: UInt64.
Example
Query:
SELECT randNegativeBinomial(100, .75) FROM numbers(5)
Result:
┌─randNegativeBinomial(100, 0.75)─┐
│ 33 │
│ 32 │
│ 39 │
│ 40 │
│ 50 │
└─────────────────────────────────┘
randPoisson
Return random number based on Poisson distribution.
Syntax
randPoisson(n)
Arguments
n
-UInt64
mean number of occurrences.
Returned value
- Pseudo-random number.
Type: UInt64.
Example
Query:
SELECT randPoisson(10) FROM numbers(5)
Result:
┌─randPoisson(10)─┐
│ 8 │
│ 8 │
│ 7 │
│ 10 │
│ 6 │
└─────────────────┘
randBernoulli
Return random number based on Bernoulli distribution.
Syntax
randBernoulli(probability)
Arguments
probability
-Float64
- probability of success (values in0...1
range only).
Returned value
- Pseudo-random number.
Type: UInt64.
Example
Query:
SELECT randBernoulli(.75) FROM numbers(5)
Result:
┌─randBernoulli(0.75)─┐
│ 1 │
│ 1 │
│ 0 │
│ 1 │
│ 1 │
└─────────────────────┘
randExponential
Return random number based on exponential distribution.
Syntax
randExponential(lambda)
Arguments
lambda
-Float64
lambda value.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randExponential(1/10) FROM numbers(5)
Result:
┌─randExponential(divide(1, 10))─┐
│ 44.71628934340778 │
│ 4.211013337903262 │
│ 10.809402553207766 │
│ 15.63959406553284 │
│ 1.8148392319860158 │
└────────────────────────────────┘
randChiSquared
Return random number based on Chi-square distribution - a distribution of a sum of the squares of k independent standard normal random variables.
Syntax
randChiSquared(degree_of_freedom)
Arguments
degree_of_freedom
-Float64
degree of freedom.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randChiSquared(10) FROM numbers(5)
Result:
┌─randChiSquared(10)─┐
│ 10.015463656521543 │
│ 9.621799919882768 │
│ 2.71785015634699 │
│ 11.128188665931908 │
│ 4.902063104425469 │
└────────────────────┘
randStudentT
Return random number based on Student's t-distribution.
Syntax
randStudentT(degree_of_freedom)
Arguments
degree_of_freedom
-Float64
degree of freedom.
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randStudentT(10) FROM numbers(5)
Result:
┌─────randStudentT(10)─┐
│ 1.2217309938538725 │
│ 1.7941971681200541 │
│ -0.28192176076784664 │
│ 0.2508897721303792 │
│ -2.7858432909761186 │
└──────────────────────┘
randFisherF
Return random number based on F-distribution.
Syntax
randFisherF(d1, d2)
Arguments
d1
-Float64
d1 degree of freedom inX = (S1 / d1) / (S2 / d2)
,d2
-Float64
d2 degree of freedom inX = (S1 / d1) / (S2 / d2)
,
Returned value
- Pseudo-random number.
Type: Float64.
Example
Query:
SELECT randFisherF(10, 3) FROM numbers(5)
Result:
┌──randFisherF(10, 3)─┐
│ 7.286287504216609 │
│ 0.26590779413050386 │
│ 0.22207610901168987 │
│ 0.7953362728449572 │
│ 0.19278885985221572 │
└─────────────────────┘
Random Functions for Working with Strings
randomString
randomFixedString
randomPrintableASCII
randomStringUTF8
fuzzBits
Syntax
fuzzBits([s], [prob])
Inverts bits of s
, each with probability prob
.
Arguments
s
-String
orFixedString
prob
- constantFloat32/64
Returned value Fuzzed string with same as s type.
Example
SELECT fuzzBits(materialize('abacaba'), 0.1)
FROM numbers(3)
Result:
┌─fuzzBits(materialize('abacaba'), 0.1)─┐
│ abaaaja │
│ a*cjab+ │
│ aeca2A │
└───────────────────────────────────────┘