Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Generating a set of semi-random numbers


Generating a set of semi-random numbers

Author
Message
pietlinden
pietlinden
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2181 Visits: 12522
I can generate random numbers just fine using NewID(). I got it from SqlAuthority.com, works a charm.

I am generating numbers between 1 and 5. If I just use NewID() or similar, I will likely get an even spread of values, which I don't want. Instead, I wanted the frequency to decrease as the number increased. So for example, I would have a spread like this (for example):

(1 indicates a mild symptom, 5 indicates a fatality)
1 - 40%
2 - 25%
3 - 20%
4 - 14%
5 - 1%

I was playing around with generating numbers and using something like 6-(Power(randomNum,CAST(1/6) AS DECIMAL())
and then using FLOOR or CEILING to round up or down as necessary. The catch is that I'm trying to avoid using a cursor for all of the data generation. I may have to for the patients, and then loop until the code generates a grade 5, because that indicates a fatality. At that point, I would "deactivate" the patient so no more cycles would be run.

Is this a sane way to do this, or am I missing something obvious? (Sorry, I would read Ken Henderson's advice in Guru's Guide, but it's at home and I'm not.)

Thanks!
Pieter
TheSQLGuru
TheSQLGuru
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5963 Visits: 8312
How about something like this? You can do a table of numbers to generate a set of them with the required distribution.

DECLARE @i float = RAND(CHECKSUM(NEWID()))

SELECT CASE WHEN @i <= 0.4 THEN 1
WHEN @i > 0.4 AND @i <= 0.65 THEN 2
WHEN @i > 0.65 AND @i <= 0.85 THEN 3
WHEN @i > 0.85 AND @i <= 0.99 THEN 4
WHEN @i > 0.99 THEN 5
END

Best,

Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru at GMail
pietlinden
pietlinden
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2181 Visits: 12522
I think that will work. I knew I had to be making it waaay harder than it really was.

Thanks!
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45121 Visits: 39919
Please post the link that you mentioned so others can see what you have seen. Thanks.

If you want to generate a million rows of sample data using those ratios, you could do the following. This takes about 1-1/2 seconds to gen a table with a million rows in it.

WITH
cteGenMillionNumbers AS
(
SELECT TOP 1000000
N = ABS(CHECKSUM(NEWID()))%100+1
FROM sys.all_columns ac1
CROSS JOIN sys.all_columns ac2
)
SELECT SomeID= IDENTITY(INT,1,1),
Grade = CASE
WHEN N BETWEEN 1 AND 40 THEN 1
WHEN N BETWEEN 41 AND 65 THEN 2
WHEN N BETWEEN 66 AND 85 THEN 3
WHEN N BETWEEN 86 AND 99 THEN 4
WHEN N = 100 THEN 5
ELSE 0 --will never happen but I do these types of safety checks
END
INTO #MyHead
FROM cteGenMillionNumbers
;



--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4255 Visits: 6431
Jeff's way is probably faster, but I have a general purpose function called RN_MULTINOMIAL that you can use for this.

See the 2nd article linked in my signature.


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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search