Generating a set of semi-random numbers

  • 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

  • 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 on googles mail service

  • I think that will work. I knew I had to be making it waaay harder than it really was.

    Thanks!

  • 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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply