VBA - Delete cells with a specific value

shebe228

New Member
Joined
Sep 28, 2017
Messages
46
I have some sample data below and I want to write a code that will delete anything in a specific range of columns if it has a specific parameter in the AC column.


For example, if "REMOVE" is in AC2 and AC3, I want to delete cells V2:AC3 and shift the remaining data up. The amount of rows will vary, but the "REMOVE" tag will always be at the most top rows of the spreadsheet. This particular report spans 52 tabs at this time so I will loop through all worksheets.


[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]S[/TD]
[TD]T[/TD]
[TD]U[/TD]
[TD]V[/TD]
[TD]W[/TD]
[TD]X[/TD]
[TD]Y[/TD]
[TD]Z[/TD]
[TD]AA[/TD]
[TD]AB[/TD]
[TD]AC[/TD]
[TD]AD[/TD]
[TD]AE[/TD]
[TD]AF[/TD]
[TD]AG[/TD]
[TD]AH[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]State[/TD]
[TD]TIN[/TD]
[TD]BC[/TD]
[TD]Allwd[/TD]
[TD]Cntr[/TD]
[TD]Dbblr[/TD]
[TD]Activity[/TD]
[TD]Bad TINS[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[TD]x[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]MS[/TD]
[TD]5546868[/TD]
[TD]23[/TD]
[TD]400[/TD]
[TD]Matt[/TD]
[TD]Declined[/TD]
[TD]6/1/18[/TD]
[TD]REMOVE[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]TN[/TD]
[TD]4654654[/TD]
[TD]58[/TD]
[TD]4654[/TD]
[TD]James[/TD]
[TD]Successful[/TD]
[TD]8/2/18[/TD]
[TD]REMOVE[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]CA[/TD]
[TD]8978793[/TD]
[TD]100[/TD]
[TD]873[/TD]
[TD]Bob[/TD]
[TD]Successful[/TD]
[TD]7/15/18[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]FL[/TD]
[TD]7352421[/TD]
[TD]586[/TD]
[TD]7352[/TD]
[TD]Emily[/TD]
[TD]None[/TD]
[TD]8/7/18[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]TN[/TD]
[TD]5646451[/TD]
[TD]987[/TD]
[TD]3215[/TD]
[TD]Sue[/TD]
[TD]Initial[/TD]
[TD]2/8/17[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 

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:
Sub Test()


'Loop through each Sheet and check AC for "REMOVE"
For i = 1 To Sheets.Count
Sheets(i).Activate


'Set the range to check - based on last row in column W
myRange = Cells(Rows.Count, 23).End(xlUp).Row


'Loop through the sheet and look for rows to delete
For x = 2 To myRange
    If Range("AC" & x).Value = "REMOVE" Then
        ' Note this is deleting and shifting up Rows A-V and AC onward remain unchanged
        Range("V" & x & ":AC" & x).Delete xlShiftUp
        x = x - 1
    End If
Next x


Next i


End Sub
 
Last edited:
Upvote 0
Are you sure you only want to remove a certain range and not the entire row ??
Deleting ranges can really mess up data if you get it wrong !!
This will remove the entire row if "'REMOVE" is in col AC of each sheet
Code:
Sub MM1()
dim ws as worksheet
For ws = 1 To Sheets.Count
Sheets(ws).Activate
    With Columns("AC")
        .AutoFilter field:=1, Criteria1:="REMOVE"
        .SpecialCells(xlCellTypeVisible).EntireRow.Delete
        .AutoFilter
    End With
Next ws
End Sub
 
Upvote 0
Are you sure you only want to remove a certain range and not the entire row ??
Deleting ranges can really mess up data if you get it wrong !!



I definitely just want to delete the range. Each sheet has multiple "tables" (not actual excel tables) that feed into two other workbooks with 8 pivot tables referencing each tab. This worksheet has about 50 tabs for each client so it's a lot going on. ? Its something I've built over the last year and a half making tweaks as I go so its definitely not the most efficient strategy, but I dont have the time (or will!!) to start over.

I pull the client reports separate and run macros on them before dumping them into the giant workbook. So it wouldn't be the end of the world if something messed up because it's fairly easy to recreate (and have learned the hard way to save in multiple places after each step!). Thanks for your help!!
 
Upvote 0
Not sure whether column AC might contain formulas that result in REMOVE or "", but just in case this has a built-in mechanism in case that is the case. Otherwise with the (xlUp) approach more rows than expected could get removed.
Test in a copy of your workbook

Code:
Sub Delete_Ranges()
  Dim ws As Worksheet
  Dim RemCount As Long
  
  For Each ws In Worksheets
    RemCount = WorksheetFunction.CountIf(Intersect(ws.UsedRange, ws.Columns("AC")), "REMOVE")
    If RemCount > 0 Then ws.Range("V2:AC" & RemCount + 1).Delete Shift:=xlUp
  Next ws
End Sub
 
Upvote 0
not sure whether column ac might contain formulas that result in remove or "", but just in case this has a built-in mechanism in case that is the case. Otherwise with the (xlup) approach more rows than expected could get removed.
Test in a copy of your workbook

Code:
sub delete_ranges()
  dim ws as worksheet
  dim remcount as long
  
  for each ws in worksheets
    remcount = worksheetfunction.countif(intersect(ws.usedrange, ws.columns("ac")), "remove")
    if remcount > 0 then ws.range("v2:ac" & remcount + 1).delete shift:=xlup
  next ws
end sub






this works perfectly!!!!!!!! :) thank you!!!!!!!!!!!!!!!!!!!!!!!!!!
 
Upvote 0

Forum statistics

Threads
1,223,907
Messages
6,175,301
Members
452,633
Latest member
DougMo

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