VBA - Change a line in a code

montecarlo2012

Well-known Member
Joined
Jan 26, 2011
Messages
986
Office Version
  1. 2010
Platform
  1. Windows
Hello.
VBA Code:
Sub forum_Mrexcel()

Dim rngStart As Range, rngData As Range
Dim Diff1 As Long, Diff2 As Long, NoRows As Long, NoCols As Long, i As Long
Dim s As String

Set rngData = Range("B3:G2720")
      NoRows = rngData.Rows.Count
      NoCols = rngData.Columns.Count
                      Diff1 = 6
                      Diff2 = 60
      Set rngStart = Range("I3").Resize(, NoCols)

                   For i = Diff1 To Diff2
                               With rngStart.Offset(, (NoCols + 1) * (i - Diff1)).Resize(NoRows - i)
                                        .Rows(0).Formula = "=SUMPRODUCT(--(" & rngData.Resize(NoRows - i, 1).Address(0, 0) & "=" & .Columns(1).Address(0, 0) & "))"
                                        .Rows(0).Font.Bold = ture
                                        .Formula = "=TRUNC(Average(" & rngData.Resize(i + 1, 1).Address(0, 0) & "))"
                                        s = .Cells(1, 1).Address(0, 0)
                                                With .FormatConditions
                                                        .Delete
                                                        .Add Type:=xlExpression, Formula1:="=" & rngData(1, 1).Address(0, 0) & "=" & s
                                                        .Item(1).Interior.Color = vbYellow
                                                End With
                               End With
                   Next i
End Sub
The code give me all the results on row 2 until the last calculation, and looks like
1617126259063.png

So Visually is difficult to handle, reason why I would like the same results on sheet 2
but as an array form. Something like
1617126561025.png

Please anyway to tell me what line I have to change, or maybe the code entirely,
Thank you for reading this.
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Perhaps:

VBA Code:
Sub forum_Mrexcel()

    Dim rngStart As Range, rngData As Range, Summary As Range
    Dim Diff1 As Long, Diff2 As Long, NoRows As Long, NoCols As Long, i As Long
    Dim s As String
    
    Set rngData = Range("B3:G2720")
    NoRows = rngData.Rows.Count
    NoCols = rngData.Columns.Count
    Diff1 = 6
    Diff2 = 60
    Set rngStart = Range("I3").Resize(, NoCols)
    Set Summary = Worksheets("Sheet2").Range("A1").Resize(, NoCols) 'Adjust Sheet2 and A1 as appropriate

    For i = Diff1 To Diff2
        With rngStart.Offset(, (NoCols + 1) * (i - Diff1)).Resize(NoRows - i)
            .Rows(0).Formula = "=SUMPRODUCT(--(" & rngData.Resize(NoRows - i, 1).Address(0, 0) & "=" & .Columns(1).Address(0, 0) & "))"
            .Rows(0).Font.Bold = True
            .Formula = "=TRUNC(Average(" & rngData.Resize(i + 1, 1).Address(0, 0) & "))"
            Summary.Rows(i + 1 - Diff1).Value = .Rows(0).Value
            s = .Cells(1, 1).Address(0, 0)
            With .FormatConditions
                .Delete
                .Add Type:=xlExpression, Formula1:="=" & rngData(1, 1).Address(0, 0) & "=" & s
                .Item(1).Interior.Color = vbYellow
            End With
        End With
    Next i

End Sub
 
Upvote 0
StephenCrump, Thank you Sir. Great job, work perfect.
If you don't mind Sir, where do you study VBA.
 
Upvote 0

Forum statistics

Threads
1,224,837
Messages
6,181,255
Members
453,028
Latest member
letswriteafairytale

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