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 12»»

Rand() function error Expand / Collapse
Author
Message
Posted Sunday, March 1, 2009 5:57 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, December 8, 2011 8:19 AM
Points: 3, Visits: 35
CREATE FUNCTION ufntGenerateRandValue
(
@minValue int,
@maxValue int
)
RETURNS int
AS
BEGIN
DECLARE @randNumber int

Set @randNumber = Cast(RAND() * @maxValue + @minValue AS INT)
RETURN @randNumber;

END
GO

This function compiles without error but when I tried to run it I got the following errors:
Invalid use of side-effecting or time-dependent operator in 'rand' within a function.

Please help me figure it out
Thank you.
Post #666309
Posted Sunday, March 1, 2009 6:57 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:18 PM
Points: 36,938, Visits: 31,441
There is no need for the RBAR of a function to generate random integer values. The only reason you think so is because you found out that RAND returns the same number throughout a given single select. The following code produces 500 random integers from 10 to 100 across many rows in a single return as an example...

DECLARE @MinValue INT , @MaxValue INT  , @Quantity INT
SELECT @MinValue = 10, @MaxValue = 100, @Quantity = 500

SELECT TOP (@Quantity)
ABS(CHECKSUM(NEWID()))%(@MaxValue-@MinValue+1)+@MinValue
FROM Master.sys.SysColumns sc1



--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #666322
Posted Monday, March 2, 2009 4:52 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, August 7, 2014 6:48 PM
Points: 459, Visits: 183
you are not allowed to use the RAND() function inside UDF function. To call the value of this function create a view with the single statement select RAND()
And then call that view inside your function.
Post #666477
Posted Monday, March 2, 2009 5:34 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:18 PM
Points: 36,938, Visits: 31,441
mverma4you (3/2/2009)
you are not allowed to use the RAND() function inside UDF function. To call the value of this function create a view with the single statement select RAND()
And then call that view inside your function.


And you still end up with a RBAR solution that way... Don't use RAND to generate random numbers... it just doesn't work the right way in T-SQL.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #666499
Posted Monday, March 2, 2009 2:21 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Sunday, April 27, 2014 6:26 AM
Points: 1,521, Visits: 3,036
So what's wrong with RAND(), you may be wondering? As Jeff notes, the RAND (and also the NEWID) functions are deliberately designed to be invoked a single time in a call, even if referenced multiple times. In SQL 2000, each reference produced a different result as the function would be evaluated again for each reference. This was a deliberate design decision at Microsoft.

An interesting discussion on this topic was posted by Itzik Ben-Gan at http://www.sqlmag.com/Article/ArticleID/97032/sql_server_97032.html
Post #666905
Posted Monday, March 2, 2009 5:46 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:18 PM
Points: 36,938, Visits: 31,441
john.arnott (3/2/2009)
So what's wrong with RAND(), you may be wondering? As Jeff notes, the RAND (and also the NEWID) functions are deliberately designed to be invoked a single time in a call, even if referenced multiple times. In SQL 2000, each reference produced a different result as the function would be evaluated again for each reference. This was a deliberate design decision at Microsoft.

An interesting discussion on this topic was posted by Itzik Ben-Gan at http://www.sqlmag.com/Article/ArticleID/97032/sql_server_97032.html


Ah... but that's not true for NEWID() which will give you a different return for every row generated by a SELECT. The code I provided above is proof of that.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #666984
Posted Tuesday, March 3, 2009 10:43 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Sunday, April 27, 2014 6:26 AM
Points: 1,521, Visits: 3,036
Jeff Moden (3/2/2009)[hr
Ah... but that's not true for NEWID() which will give you a different return for every row generated by a SELECT. The code I provided above is proof of that.


Thank you, Jeff. I went back to the Ben-Gan article and now realize that it addresses the behavior of RAND or NEWID when assigned in a table expression, such as a sub-query. In that regard, the two functions both now behave the same in providing a consistent result when referenced multiple times. This code gives you the same "rnd" three times and the same "nid" three times in SQL2005, but according to Ben-Gan, would give possibly different values for "rnd" and "nid" under SQL 2000.
select rnd, rnd, rnd, nid, nid, nid
from (select rand() as rnd
,abs(checksum(newid()))%100 + 1 as nid
) as d;

rnd rnd rnd nid nid nid
---------------------- ---------------------- ---------------------- ----------- ----------- -----------
0.455575000804869 0.455575000804869 0.455575000804869 54 54 54

The article did not mention the difference between RAND and NEWID that you've pointed out. By comparison, here are two queries with sample output. In the first, both RAND and NEWID return new values for each reference. In the second, they behave differently, a distinction not made clear in BOL's "Behavior Change" table or in Ben-Gan's article. That non-intuitive difference is probably reason enough to shove RAND to the back of the shelf and always use NEWID.
select	 abs(checksum(newid()))%10 + 1 as nid1
,abs(checksum(newid()))%10 + 1 as nid2
,abs(checksum(newid()))%10 + 1 as nid3
,abs(checksum(newid()))%10 + 1 as nid4
,cast(rand()*10 as int)%10 + 1 as rnd1
,cast(rand()*10 as int)%10 + 1 as rnd2
,cast(rand()*10 as int)%10 + 1 as rnd3
,cast(rand()*10 as int)%10 + 1 as rnd4

nid1 nid2 nid3 nid4 rnd1 rnd2 rnd3 rnd4
----------- ----------- ----------- ----------- ----------- ----------- ----------- -----------
8 10 6 4 2 3 10 7

DECLARE @MinValue INT , @MaxValue INT  , @Quantity INT
SELECT @MinValue = 10, @MaxValue = 100, @Quantity = 10

SELECT TOP (@Quantity)
cast(rand()*(@MaxValue-@MinValue+1) as int)%(@MaxValue-@MinValue+1)+@MinValue as ConstRand
,ABS(CHECKSUM(NEWID()))%(@MaxValue-@MinValue+1)+@MinValue as NotConstNewID
FROM Master.sys.SysColumns sc1

ConstRand NotConstNewID
----------- -------------
88 64
88 59
88 76
88 11
88 41
88 38
88 26
88 63
88 89
88 53

Post #667499
Posted Tuesday, March 3, 2009 4:40 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:18 PM
Points: 36,938, Visits: 31,441
john.arnott (3/3/2009)
In that regard, the two functions both now behave the same in providing a consistent result when referenced multiple times.


Of course it will... they've used the same GUID 3 times for the same row... the following should make it crystal clear for any who are still in doubt...

 SELECT GETDATE() AS [GETDATE() (Always Same)],
RAND() AS [RAND() (Always Same)],
NEWID() AS [NEWID() (NEVER Same)]
FROM Master..spt_Values
WHERE Type = 'P'
AND Number < 10

The article did not mention the difference between RAND and NEWID that you've pointed out. By comparison, here are two queries with sample output. In the first, both RAND and NEWID return new values for each reference. In the second, they behave differently, a distinction not made clear in BOL's "Behavior Change" table or in Ben-Gan's article. That non-intuitive difference is probably reason enough to shove RAND to the back of the shelf and always use NEWID.


Heh... once converted to VARBINARY or some such, you can even used NEWID() as a seed for RAND if it's more intuitive. But, beware... Peter Larson, Matt Miller, and Michael Valentine Jones, I have all done some pretty good testing on it... the methods of using NEWID() with CHECKSUM are quite a bit faster than the VARBINARY conversion and RAND().

I agree... knowing it's extreme limitations, I don't even bother with RAND() except in the rarest of cases.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #667757
Posted Monday, February 15, 2010 12:23 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, June 17, 2013 9:13 PM
Points: 21, Visits: 69
is this a better choice guys? RAND(checksum(newid())) ?

perhaps because it increases randomness by not allowing dupes between negatives and positives? Perhaps also because none of us really knows if the combo of newid and checksim is as random as rand?
Post #865669
Posted Monday, February 15, 2010 2:01 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:18 PM
Points: 36,938, Visits: 31,441
stan.teitelbaum (2/15/2010)
is this a better choice guys? RAND(checksum(newid())) ?

perhaps because it increases randomness by not allowing dupes between negatives and positives? Perhaps also because none of us really knows if the combo of newid and checksim is as random as rand?


But it doesn't increase randomness... first, CHECKSUM doesn't do anything to prevent negative numbers (which is actually "more random" than just a positive set of numbers). Second, RAND in SQL server isn't random between rows in a set based result set... RAND requires a random seed for each row or you're relegated to a single row.

As a side bar, it's documented in BOL that NEWID() will return a random GUID that also happens to be unique from a given server.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #865709
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse