VBA Apply to all sheets in workbook

jamescooper

Well-known Member
Joined
Sep 8, 2014
Messages
834
Trying to get the code below to apply to all unhidden worksheets, it only appears to apply it to the selected sheet at present. Any ideas please?

Many thanks.

Code:
Public Sub Template()

Dim ws As Worksheet
Dim strFormulaPart1 As String
Dim strFormulaPart2 As String
Dim strFormulaPart3 As String
Dim strFormulaPart4 As String
    
    For Each ws In ActiveWorkbook.Worksheets
    
    Range("P1").Value = "Sectional Time Rating"
    Range("Q1").Value = "Full Time Rating"
    Range("P2").FormulaR1C1 = "=IFERROR(IF(IF(OR(RC[-6]=0,TRIM(RC[-6])=""""),"""",VLOOKUP(VLOOKUP(TRIM(RC[-12]),'Track Records'!R2C19:R50C20,2,FALSE)&"" ""&TRIM(RC[-9]),'Track Records'!R2C12:R500C16,5,FALSE)/RC[-6])*100>100,"""",VLOOKUP(VLOOKUP(TRIM(RC[-12]),'Track Records'!R2C19:R50C20,2,FALSE)&"" ""&TRIM(RC[-9]),'Track Records'!R2C12:R500C16,5,FALSE)/RC[-6])*100,"""")"
    Range("P2").AutoFill Destination:=Range("P2:P" & Range("A" & Rows.Count).End(xlUp).Row)
    Range("Q2").FormulaR1C1 = "=IFERROR(IF(IF(OR(RC[-6]=0,TRIM(RC[-6])=""""),"""",VLOOKUP(VLOOKUP(TRIM(RC[-13]),'Track Records'!R2C19:R50C20,2,FALSE)&"" ""&TRIM(RC[-10]),'Track Records'!R2C12:R500C16,4,FALSE)/RC[-6])*100>100,"""",VLOOKUP(VLOOKUP(TRIM(RC[-13]),'Track Records'!R2C19:R50C20,2,FALSE)&"" ""&TRIM(RC[-10]),'Track Records'!R2C12:R500C16,4,FALSE)/RC[-6])*100,"""")"
    Range("Q2").AutoFill Destination:=Range("Q2:Q" & Range("A" & Rows.Count).End(xlUp).Row)
    Range("T1").Value = "Sectional"
    Range("V1").Value = "Full Time"
    Range("S2").Value = "Trap #"
    Range("T2").Value = "Form: Moving Avg (Last 5)"
    Range("U2").Value = "Rank"
    Range("V2").Value = "Form: Moving Avg (Last 5)"
    Range("W2").Value = "Rank"
    Range("Y2").Value = "Rank Total"
    Range("Z2").Value = "Fractional Chance"
    Range("AB2").Value = "Event"
    Range("AC2").Value = "Trap #"
    Range("AD2").Value = "Dog"
    Range("AE2").Value = "Odds"
    Range("S3").Value = "1"
    Range("S4").Value = "2"
    Range("S5").Value = "3"
    Range("S6").Value = "4"
    Range("S7").Value = "5"
    Range("S8").Value = "6"
    Range("S10").Value = "1"
    Range("S11").Value = "2"
    Range("S12").Value = "3"
    Range("S13").Value = "4"
    Range("S14").Value = "5"
    Range("S15").Value = "6"
    Range("AC2").Value = "Trap #"
    Range("AC3").Value = "1"
    Range("AC4").Value = "2"
    Range("AC5").Value = "3"
    Range("AC6").Value = "4"
    Range("AC7").Value = "5"
    Range("AC8").Value = "6"
    
    strFormulaPart1 = "SMALL(IF(ISNUMBER($P$2:$P$5000),IF($B$2:$B$5000=VALUE(S3),ROW($P$2:$P$5000))),Y_Y_Y)"
    strFormulaPart2 = "MIN(SUM(IF($B$2:$B$5000=VALUE(S3),IF(ISNUMBER($P$2:$P$5000),1))),5)"


    With Range("T10")
        .FormulaArray = "=AVERAGE(IF(ROW($P$2:$P$5000)<=X_X_X,IF($B$2:$B$5000=VALUE(S3),IF(ISNUMBER($P$2:$P$5000),$P$2:$P$5000))))"
        .Replace "X_X_X", strFormulaPart1
        .Replace "Y_Y_Y", strFormulaPart2
    End With
    
    Range("T10").AutoFill Destination:=Range("T10:T" & Range("S" & Rows.Count).End(xlUp).Row)
    
    strFormulaPart3 = "SMALL(IF(ISNUMBER($Q$2:$Q$5000),IF($B$2:$B$5000=VALUE(S3),ROW($Q$2:$Q$5000))),Y_Y_Y)"
    strFormulaPart4 = "MIN(SUM(IF($B$2:$B$5000=VALUE(S3),IF(ISNUMBER($Q$2:$Q$5000),1))),5)"


    With Range("V10")
        .FormulaArray = "=AVERAGE(IF(ROW($Q$2:$Q$5000)<=X_X_X,IF($B$2:$B$5000=VALUE(S3),IF(ISNUMBER($Q$2:$Q$5000),$Q$2:$Q$5000))))"
        .Replace "X_X_X", strFormulaPart1
        .Replace "Y_Y_Y", strFormulaPart2
    End With
    


    Range("V10").AutoFill Destination:=Range("V10:V" & Range("S" & Rows.Count).End(xlUp).Row)
    
    Range("T3").FormulaR1C1 = "=IF(VALUE(LEFT(RIGHT(R[-1]C[-19],4),3))<330,"""",IFERROR(R[7]C,""""))"
    Range("T3").AutoFill Destination:=Range("T3:T8")
    Range("V3").FormulaR1C1 = "=IFERROR(R[7]C,"""")"
    Range("V3").AutoFill Destination:=Range("V3:V8")
    Range("W3").FormulaR1C1 = "=IF(RC[-1]="""","""",RANK(RC[-1],R3C22:R8C22,1)*VLOOKUP(LEFT(R[-1]C[-22],FIND("" "",R[-1]C[-22],1)-1)&"" ""&RIGHT(R[-1]C[-22],4),'Track Records'!R[-2]C:R300C25,3,FALSE))"
    Range("W3").AutoFill Destination:=Range("W3:W" & Range("S" & Rows.Count).End(xlUp).Row)
    Range("Y3").FormulaR1C1 = "=IFERROR(IF(VALUE(LEFT(RIGHT(R[-1]C[-24],4),3))<330,RC[-2],RC[-4]+RC[-2]),2)"
    Range("Y3").AutoFill Destination:=Range("Y3:Y8")
    Range("Z3").FormulaR1C1 = "=IF(RC[-1]="""","""",IFERROR(RC[-1]/SUM(R3C25:R10C25),""""))"
    Range("Z3").AutoFill Destination:=Range("Z3:Z8")
    Range("AB3").FormulaR1C1 = "=IF(RC[1]="""","""",R2C1)"
    Range("AB3").AutoFill Destination:=Range("AB3:AB" & Range("S" & Rows.Count).End(xlUp).Row)
    Range("AD3").FormulaR1C1 = "=IFERROR(VLOOKUP(RC[-11],C2:C5,4,FALSE),"""")"
    Range("AD3").AutoFill Destination:=Range("AD3:AD8")
    Range("AE3").FormulaR1C1 = "=IFERROR(1/RC[-5],"""")"
    Range("AE3").AutoFill Destination:=Range("AE3:AE8")
    
  Next ws
  


End Sub
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Code:
For Each ws In ActiveWorkbook.Worksheets

do stuff

Next ws
This syntax only runs a loop that creates a variable (ws) to represent each sheet during the loop

But each sheet does not become active/selected during the loop.
So lines like this still only refer to the actve sheet, not the sheet specified by the loop.
Range("P1").Value = xxx

You have to add that variable (ws) to those lines (ALL references using Range)
ws.Range("P1").Value = xxx
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,813
Messages
6,121,705
Members
449,048
Latest member
81jamesacct

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