How to repeat multiple formulas where only one reference changes

288enzo

Well-known Member
Joined
Feb 8, 2009
Messages
727
Office Version
  1. 2016
Platform
  1. Windows
I have the following when strQtr is 1, I've basically copied the exact same for 2, 3, and 4. The only difference between 1 and the rest is in 1 the column reference K changes in each.
1 = Employees!K$4:K$1000
2 = Employees!L$4:L$1000
3 = Employees!M$4:M$1000
4 = Employees!N$4:N$1000

Is there a more efficient way of doing this without duplicating the following 18 lines of code 3 more times?
VBA Code:
    Select Case strQtr
    Case 1 ' *************************************** 1ST QUARTER
    Range("B2") = "=""Continuous Learning - Q1 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!K$4:K$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!K$4:K$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!K$4:K$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!K$4:K$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!K$4:K$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!K$4:K$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    End Select
    Case 2 ' *************************************** 2ND QUARTER
    Range("B2") = "=""Continuous Learning - Q2 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!L$4:L$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!L$4:L$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!L$4:L$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!L$4:L$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!L$4:L$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!L$4:L$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!L4:L1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!L4:L1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!L4:L1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!L4:L1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!L4:L1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!L4:L1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!L4:L1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!L4:L1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!L4:L1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!L4:L1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!L4:L1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!L4:L1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    End Select
    Case 3 ' *************************************** 3RD QUARTER
    Range("B2") = "=""Continuous Learning - Q3 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!M$4:M$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!M$4:M$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!M$4:M$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!M$4:M$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!M$4:M$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!M$4:M$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!M4:M1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!M4:M1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!M4:M1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!M4:M1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!M4:M1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!M4:M1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!M4:M1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!M4:M1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!M4:M1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!M4:M1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!M4:M1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!M4:M1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    End Select
    Case 4 ' *************************************** 4TH QUARTER
    Range("B2") = "=""Continuous Learning - Q4 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!N$4:N$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!N$4:N$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!N$4:N$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!N$4:N$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!N$4:N$1000,""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!N$4:N$1000,""N/A"",Employees!E$4:E$1000,A5)"
    Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!N4:N1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!N4:N1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!N4:N1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!N4:N1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!N4:N1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!N4:N1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!N4:N1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!N4:N1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!N4:N1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!N4:N1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!N4:N1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!N4:N1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    End Select
    End Select
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
How about:
VBA Code:
    Range("B2") = "=""Continuous Learning - Q1 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select
 
Upvote 0
Just use strQtr as a variable and concatenate the strings:
VBA Code:
Sub dd()

Dim letr As String
letr = Split(Cells(1, strQtr + 10).Address, "$")(1)

Range("B2") = "=""Continuous Learning - Q" & strQtr & " Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"
Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"
Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"

Select Case strArea
    Case 80, 87
        Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
        Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
        Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
    Case 82, 83, 84
        Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select

End Sub
 
Upvote 0
Solution
How about:
VBA Code:
    Range("B2") = "=""Continuous Learning - Q1 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select
OFFSET using strQtr, brilliant! Question, after strQtr you have 997, 0 - what is that doing? Thank you
 
Upvote 0
Just use strQtr as a variable and concatenate the strings:
VBA Code:
Sub dd()

Dim letr As String
letr = Split(Cells(1, strQtr + 10).Address, "$")(1)

Range("B2") = "=""Continuous Learning - Q" & strQtr & " Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"
Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"
Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!" & letr & "$4:" & letr & "$1000,""Y"",Employees!E$4:E$1000,A5)"
Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",Employees!" & letr & "$4:" & letr & "$1000,""N/A"",Employees!E$4:E$1000,A5)"

Select Case strArea
    Case 80, 87
        Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
        Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
        Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""Y"")"
        Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""N/A"")"
    Case 82, 83, 84
        Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
        Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!" & letr & "4:" & letr & "1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select

End Sub
This looks very interesting. Will you please explain Split(Cells(1, strQtr + 10).Address, "$")(1) ? Thank you
 
Upvote 0
Offset formula at excel has this option:
Excel Formula:
=OFFSET(First cell of your range or Index Cell, [rows],[columns],[height],[width])
Index Cell: first cell you offset formula work based on. Here you can use only $J$4 and don't need :$J$1000 .
[rows]: number of rows move to down (positive number) or to up (negative numbers). then if rows is 0 then rows remain 4 and if 2 rows start 4+2=6.
[columns]: same as rows but go right (+) and left (-).
[height]: number of rows at range. Here is 1000 - 4 + 1 ( also count first row) = 997
[width]: number of columns. here only one =1.
 
Upvote 0
Excel Formula:
  Split(Cells(1, strQtr + 10).Address, "$")(1)
Cells(row number, column number).
Then Address create address of range with $ here Create for example,
VBA Code:
Cells(1, 12).Address = $L$1
.
Then Split , split this address by $ sign. And (1) shows we need first part that here is L then Column is L
 
Upvote 0
How about:
VBA Code:
    Range("B2") = "=""Continuous Learning - Q1 Update ""& TEXT(TODAY(),""dddd, mmmm d, yyyy"")"
    Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("J5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
    Range("N5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),""N/A"",Employees!E$4:E$1000,A5)"
Select Case strArea
    Case 80, 87
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",Employees!K4:K1000,""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select
After running your code, the formula in F5 is
Excel Formula:
=COUNTIFS(Employees!H$4:H$1000,"SA",OFFSET(Employees!J$4:J$1000,0,strQtr,997,1),"Y",Employees!E$4:E$1000,A5)
What did I do wrong?

I made a slight change to the VBA
VBA Code:
Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4:J$1000,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
The result was
Excel Formula:
=COUNTIFS(Employees!H$4:H$1000,"SA",OFFSET(Employees!J$4:J$1000,0,4,997,1),"Y",Employees!E$4:E$1000,A5)
Am I getting close?
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,324
Members
452,635
Latest member
laura12345

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