Help shortening a VBA code

Mav93

Board Regular
Joined
Feb 21, 2005
Messages
107
Hi everybody,

I'm pretty new at VBA and I'm not really sure how to group things so that the code can be shortened. As of right now I get an error saying that my procedure is to long. What I'm trying to do is count the number of times that a certain word appears in cell range D11: D24 and insert the total into cell T78
Thanks in advance for any help

Code:
If Sheets("sheet metal take off").Range("D11") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D12") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D13") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D14") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D15") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D16") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D17") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D18") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D19") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D20") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D21") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D22") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D23") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
    If Sheets("sheet metal take off").Range("D24") = "Cap flashing" Then
        Sheets("sheet metal take off").Range("T73").Value = 1 + Sheets("sheet metal take off").Range("T73").Value
    Else
        Sheets("sheet metal take off").Range("T73").Value = 0 + Sheets("sheet metal take off").Range("T73").Value
    End If
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Try this...

Code:
Sub Test()

Dim i As Integer
With Sheets("sheet metal take off")

For i = 11 To 24
If .Range("D" & i).Value = "Cap flashing" Then
        .Range("T73") = 1 + .Range("T73")
     End If
    Next
    End With
End Sub
 
Upvote 0
Try this as well.
Code:
With Sheets("sheet metal take off")
    .Range("T73").Value = .Range("T73").Value + Application.WorksheetFunction.CountIf(.Range("D11:D24"), "Cap flashing")
End With
 
Upvote 0
Thanks eveybody for the help both codes work great, it's always good to learn a new way of doing thing it's just one less question I have to bother this board with.

Thanks again
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,211
Members
448,554
Latest member
Gleisner2

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