combine a formula with VBA to generate random numbers

MattLevand

New Member
Joined
May 22, 2021
Messages
1
Office Version
  1. 2013
Platform
  1. Windows
I'm generating a random number in Cell AI5 between 2.5 and 6.0 if data is entered in Cell X5 using the formula =IF(X5>1,2.5+3.5*RAND(),""). Then i drag this down a spread sheet 365 cells for the entire year. Instead of changing the cell to a string everytime it generates a number (to keep the number from changing) couldn't i call a macro that generates my random number only if data is entered in Cell X5? (Cell X5 is always a whole number if it is entered) Or is there any other better way...
Thanks,

Matt
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
@MattLevand Welcome to MrExcel
I'm assuming you generate 356 new numbers each time X5 changes?
If so then try this code in the Worksheet code pane of the vba editor.
It will automatically react to changes in cell X5

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Cells.Count > 1 Then Exit Sub
If Not Intersect(Target, Range("X5")) Is Nothing And Target > 1 Then
With Range("A15:A379")
.Formula = "=IF($X$5>1,2.5+3.5*RAND(),"""")"
.Value = .Value
End With
End If


End Sub

Hope that helps.
 
Upvote 0
Solution
Another option
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   If Not Intersect(Target, Range("X5:X370")) Is Nothing Then
      Target.Offset(, 11).Value = Evaluate("if(" & Target.Address & ">1,2.5+3.5*rand(),"""")")
   End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,872
Messages
6,122,026
Members
449,061
Latest member
TheRealJoaquin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top