XL: How to Create a List of Unique Random Integers Between Two Given Values

ID: Q151470


The information in this article applies to:
  • Microsoft Excel 98 Macintosh Edition
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a


SUMMARY

In Microsoft Excel, you can write a macro to create a list of unique random integers between two numbers.


MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

http://www.microsoft.com/support/supportnet/overview/overview.asp
The following macro prompts the user for a starting integer and an ending integer, then the macro prompts the user to input the number of random numbers to generate. Next, it lists that number of unique integers on the active worksheet. To create and run the macro, follow these steps:
  1. Type the following code in a module sheet:
    
          Option Explicit
    
          Sub Unique_Numbers()
    
             Dim x As Long, y As Long, z As Long, tempnum As Long
             Dim flag As Boolean
             Dim i As Integer
             Dim foundCell As Range
    
             Application.ScreenUpdating = False
    
             x = Application.InputBox("Enter starting Random Number" _
                , "Random Number Generation", 1, , , , , 1)
             y = Application.InputBox("Enter ending Random Number" _
                , "Random Number Generation", 1000, , , , , 1)
             z = Application.InputBox("How many random numbers would" _
                & "you like to generate (<15000)?" _
                    , "Random Number Generation", 100, , , , , 1)
             If z = 0 Then Exit Sub
    
             If z > 15000 Then z = 15000
    
             If z > y - x + 1 Then
                 MsgBox "You specified more numbers to return than " _
                         & "are possible in the range!"
                 Exit Sub
             End If
    
             Randomize
    
             Cells(1, 1) =  Int((y - x + 1) * Rnd + x)
    
             For i = 2 To z
                 Do
                     flag = False
                     Randomize
                     tempnum = Int((y - x + 1) * Rnd + x)
    
                     Set foundCell = Range("a1", _
                            Range("a1").End(xlDown).Address).Find(tempnum)
                     If Not (foundCell Is Nothing) Then
                         flag = True
                     End If
    
                 Loop Until Not flag
    
                 Cells(i, 1) =  tempnum
    
             Next
    
          End Sub 


  2. Open a blank worksheet.


  3. On the Tools menu, click Macro.

    In Microsoft Excel 97, on the Tools menu, point to Macro, and click Macros.


  4. Click the Unique_Numbers macro, and then click Run.



REFERENCES

For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

Q163435 VBA: Programming Resources for Visual Basic for Applications

Additional query words: XL97

Keywords : kbprg kbdta kbdtacode PgmHowto KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0; winnt:5.0
Platform : MACINTOSH WINDOWS winnt
Issue type : kbhowto


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.