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?
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