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
 
Yes. my fault. Also can use:
VBA Code:
Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
 
Upvote 0

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Yes. my fault. Also can use:
VBA Code:
Range("F5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
This is the result
Excel Formula:
=COUNTIFS(Employees!H$4:H$1000,"SA",OFFSET(Employees!J$4,0,4,997,1),"Y",Employees!E$4:E$1000,A5)
I was looking up OFFSET to learn a little more, I just can't figure how to use it with a COUNTIFS formula.
Range is a little more straight forward
VBA Code:
Range("A1:A2").Offset(3, 2).Select
Easy enough, but trying to incorporate COUNTIFS and my variable strQtr has become challenging.
Thank you for the help
 
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
Worked perfectly, thank you. I'm going to have to pick it apart to better understand.

Thanks again
 
Upvote 0
Which formula?
what you want for result at formula?
 
Upvote 0
Which formula?
what you want for result at formula?
When strQtr =
1 the formula should be =COUNTIFS(Employees!H$4:H$1000,"SA",Employees!K$4:K$1000,"Y",Employees!E$4:E$1000,A5)
2 the formula should be =COUNTIFS(Employees!H$4:H$1000,"SA",Employees!L$4:L$1000,"Y",Employees!E$4:E$1000,A5)
3 the formula should be =COUNTIFS(Employees!H$4:H$1000,"SA",Employees!M$4:M$1000,"Y",Employees!E$4:E$1000,A5)
4 the formula should be =COUNTIFS(Employees!H$4:H$1000,"SA",Employees!N$4:N$1000,"Y",Employees!E$4:E$1000,A5)

cmowla's code worked right out of the gate, but I do like your idea of OFFSET better because I can wrap my head around it...I just can't get it to work.

Thank you
 
Upvote 0
What is problem with:
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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4,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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4,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
if you want understand how formula work, select cell has formula, then go to Formula tab and Select Evaluate formula then press Evaluate to see step to step how to work formula.
 
Upvote 0
What is problem with:
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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4,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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4,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
if you want understand how formula work, select cell has formula, then go to Formula tab and Select Evaluate formula then press Evaluate to see step to step how to work formula.
As an example in F4 -
=COUNTIFS(Employees!H4:H1000,"SA",Employees!K4:K1000,"Y",Employees!C4:C1000,(RIGHT(A4,3)))
no matter what the strQtr variable is, the outcome is the same.
 
Upvote 0
I don't noticed that before.
Try:
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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("G5") = "=COUNTIFS(Employees!H$4:H$1000,""SA"",OFFSET(Employees!J$4,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,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("K5") = "=COUNTIFS(Employees!H$4:H$1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!E$4:E$1000,A5)"
    Range("O5") = "=COUNTIFS(Employees!H$4:H$1000,""PA"",OFFSET(Employees!J$4,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"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"")"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"")"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"")"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"")"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"")"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"")"
    Case 82, 83, 84
    Range("F4") = "=COUNTIFS(Employees!H4:H1000,""SA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("G4") = "=COUNTIFS(Employees!H4:H1000,""SA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("J4") = "=COUNTIFS(Employees!H4:H1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("K4") = "=COUNTIFS(Employees!H4:H1000,""SV"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("N4") = "=COUNTIFS(Employees!H4:H1000,""PA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""Y"",Employees!C4:C1000,(RIGHT(A4,3)))"
    Range("O4") = "=COUNTIFS(Employees!H4:H1000,""PA"",OFFSET(Employees!J$4,0," & strQtr & ",997,1),""N/A"",Employees!C4:C1000,(RIGHT(A4,3)))"
End Select
 
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