• ChrisM@Work (4/30/2013)


    todd.ayers (4/30/2013)


    I am trying to create a random number generator that would populate a number between 8-48 to 9 different lanes with the only criteria being that each lane number cannot be within 5 of any lane within 3 spaces of it. So what I mean is if lane 4 has a number of 30 then lane 1-2-3 and lane 5-6-7 cannot be within 5 of lane 4's number. Hope this makes sense and any help would be sincerely appreciated....

    No problem. Folks here love this sort of question! Here's a solution for openers:

    ;WITH SemiRandomNumbers AS (

    SELECT Lane = 8 + ABS(CHECKSUM(NEWID()))%41

    FROM syscolumns a

    )

    SELECT *

    FROM (SELECT ID = 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) s

    CROSS APPLY (

    SELECT TOP 1 Lane1 = Lane FROM SemiRandomNumbers --ORDER BY (SELECT NULL)

    ) l1

    CROSS APPLY (

    SELECT TOP 1 Lane2 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l1.Lane1-5 AND l1.Lane1+5)

    ) l2

    CROSS APPLY (

    SELECT TOP 1 Lane3 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l1.Lane1-5 AND l1.Lane1+5)

    AND NOT (r.Lane BETWEEN l2.Lane2-5 AND l2.Lane2+5)

    ) l3

    CROSS APPLY (

    SELECT TOP 1 Lane4 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l1.Lane1-5 AND l1.Lane1+5)

    AND NOT (r.Lane BETWEEN l2.Lane2-5 AND l2.Lane2+5)

    AND NOT (r.Lane BETWEEN l3.Lane3-5 AND l3.Lane3+5)

    ) l4

    CROSS APPLY (

    SELECT TOP 1 Lane5 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l2.Lane2-5 AND l2.Lane2+5)

    AND NOT (r.Lane BETWEEN l3.Lane3-5 AND l3.Lane3+5)

    AND NOT (r.Lane BETWEEN l4.Lane4-5 AND l4.Lane4+5)

    ) l5

    CROSS APPLY (

    SELECT TOP 1 Lane6 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l3.Lane3-5 AND l3.Lane3+5)

    AND NOT (r.Lane BETWEEN l4.Lane4-5 AND l4.Lane4+5)

    AND NOT (r.Lane BETWEEN l5.Lane5-5 AND l5.Lane5+5)

    ) l6

    CROSS APPLY (

    SELECT TOP 1 Lane7 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l4.Lane4-5 AND l4.Lane4+5)

    AND NOT (r.Lane BETWEEN l5.Lane5-5 AND l5.Lane5+5)

    AND NOT (r.Lane BETWEEN l6.Lane6-5 AND l6.Lane6+5)

    ) l7

    CROSS APPLY (

    SELECT TOP 1 Lane8 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l5.Lane5-5 AND l5.Lane5+5)

    AND NOT (r.Lane BETWEEN l6.Lane6-5 AND l6.Lane6+5)

    AND NOT (r.Lane BETWEEN l7.Lane7-5 AND l7.Lane7+5)

    ) l8

    CROSS APPLY (

    SELECT TOP 1 Lane9 = Lane FROM SemiRandomNumbers r

    WHERE NOT (r.Lane BETWEEN l6.Lane6-5 AND l6.Lane6+5)

    AND NOT (r.Lane BETWEEN l7.Lane7-5 AND l7.Lane7+5)

    AND NOT (r.Lane BETWEEN l8.Lane8-5 AND l8.Lane8+5)

    ) l9

    That is a brilliant solution Chris!

    And here I thought when I pulled up this thread I could make a shameless plug for my random numbers article (in my signature).

    Thanks by the way for the nice plug in your signature for my rCTEs article.


    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