Help with nested loop

JARichard74

Board Regular
Joined
Dec 16, 2019
Messages
114
Office Version
  1. 365
Platform
  1. Windows
In this case, y=3 and z-1 = 4. What I am trying to do is RANK the numbers in E4:E7 based on the values in E4:E7, then RANK the numbers in E9:E12 based on the values in E9:E12 and then RANK the numbers in E14:E17 based on the values in E14:E17. The code below only puts the formula in F4:F7 and the formula it puts is RANK.EQ($E4,E14:E17,0), RANK.EQ($E5,E14:E17,0), RANK.EQ($E6,E14:E17,0), RANK.EQ($E7,E14:E17,0). Thanks for your help
VBA Code:
For k = 1 To y
    For j = 1 To z - 1
    ThisWorkbook.Worksheets("Rated").Range("F" & j + 3).Formula = "=RANK.EQ($E" & j + 3 & ",E" & k * 5 - 1 & ":E" & k * 5 + 2 & ",0)"
    Next j
Next k
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
try this:
VBA Code:
Sub test1()
y = 3
Z = 5
With Worksheets("Rated")
For k = 1 To y
    For j = 1 To Z - 1
    .Range(.Cells(3 + j + (k - 1) * 5, 7), .Cells(3 + j + (k - 1) * 5, 7)).Formula = "=RANK.EQ($E" & (3 + j + (k - 1) * 5) & ",E" & (k * 5) - 1 & ":E" & (k * 5) + 2 & ",0)"
    Next j
Next k
End With
End Sub
 
Upvote 0
Solution
What about in a single loop like this?

VBA Code:
Sub InsertRankFormulas()
  Dim rA As Range
  
  For Each rA In Worksheets("Rated").Range("E4:E7,E9:E12,E14:E17").Areas
    rA.Offset(, 1).Formula = "=RANK.EQ(" & rA.Cells(1).Address(0, 1) & "," & rA.Address & ",0)"
  Next rA
End Sub
 
Upvote 0
What about in a single loop like this?

VBA Code:
Sub InsertRankFormulas()
  Dim rA As Range
 
  For Each rA In Worksheets("Rated").Range("E4:E7,E9:E12,E14:E17").Areas
    rA.Offset(, 1).Formula = "=RANK.EQ(" & rA.Cells(1).Address(0, 1) & "," & rA.Address & ",0)"
  Next rA
End Sub
.Range(???).Areas - what if I had 8 areas instead of three and what if each area was larger or smaller e.g. E4:E20, E22:E38 etc. I would need the code to be more flexible
 
Upvote 0
try this:
VBA Code:
Sub test1()
y = 3
Z = 5
With Worksheets("Rated")
For k = 1 To y
    For j = 1 To Z - 1
    .Range(.Cells(3 + j + (k - 1) * 5, 7), .Cells(3 + j + (k - 1) * 5, 7)).Formula = "=RANK.EQ($E" & (3 + j + (k - 1) * 5) & ",E" & (k * 5) - 1 & ":E" & (k * 5) + 2 & ",0)"
    Next j
Next k
End With
End Sub
Perfect. I just had to change the 7 to a 6 to put the formula in column F instead of G. Marked as solution. Thanks much
 
Upvote 0
.Range(???).Areas - what if I had 8 areas instead of three and what if each area was larger or smaller e.g. E4:E20, E22:E38 etc. I would need the code to be more flexible
I was just answering the question that you posed. ;)
If you want to go with the double loop that's fine, but you could still do it with a single loop and simple editing of the three 'Const' lines only if the circumstances change.

VBA Code:
Sub InsertRankFormulas_v2()
  Dim i As Long
  Dim Rng As Range
 
  Const sFirstcell As String = "E4" '<- First cell in first range
  Const lRangeRows As Long = 4      '<- Number of rows in each range
  Const lNumRanges As Long = 8      '<- How many ranges
 
  For i = 1 To lNumRanges
    Set Rng = Range(sFirstcell).Offset((i - 1) * (lRangeRows + 1)).Resize(lRangeRows)
    Rng.Offset(, 1).Formula = "=RANK.EQ(" & Rng.Cells(1).Address(0, 1) & "," & Rng.Address & ",0)"
  Next i
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,261
Members
448,558
Latest member
aivin

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