Delete all cells NOT containing specific data within a column selection

MikeJHHT

New Member
Joined
Jan 8, 2020
Messages
39
Office Version
  1. 365
Platform
  1. Windows
Columns D to H have a variety of of cell data
I only want to keep cells in those columns that contain FH
The remaining cells in those columns can be blank.
Is this possible?
Bin Numbers
B13-6A(6)FH-6D-01-03(2)FH-6D-04-03(8)R7-1-B2(6)SP-SP-18(3)
B13-6A(2)FH-6D-02-03(2)SP-SP-36(1)
B7-1C(14)FH-1E-04-02(8)FH-CG-01(4)R7-2-B2(60)SP-HV-2F(7)
B14-5A(7)FH-2F-06-01(5)
B14-5B(14)FH-1C-03-02(10)
B13-7A(36)FH-1C-04-01(14)SP-SP-05(16)
B6-1C(21)FH-2D-01-04(1)
B15-6A(5)FH-1H-05-02(3)SP-SP-12(8)
B15-6A(4)FH-1H-03-03(2)
B15-6A(7)FH-4C-02-02(6)SP-SP-37(12)
B15-2A(9)FH-LSE-03-01(40)FH-LSE-03-03(88)FH-LSE-04-02(36)FH-LSE-04-03(87)
B13-3A(21)FH-6B-04-03(44)FH-LSE-04-01(13)R9-5-D1(44)R9-5-D2(44)
B13-1A(196)FH-1C-01-02(194)Freight Line(2304)Mezz(2478)SP-S-07(1840)
B18-14-A1(94)FH-LSF-02(184)SP-LSB-09(68)
B18-11-A1(84)FH-LSW-08(54)SP-LSF-08(217)
FH-LSF-03(76)SP-LSF-09(98)
B18-9-A1(19)FH-LSW-07(44)SP-LSB-05(50)
B18-1-A1(96)FH-LSW-03(54)Line Sets(149)SP-LSF-15(29)
FH-LSE-01-01(3)Line Sets(1)
B14-1A(360)FH-1D-01-01(166)FH-5A-03-03(284)Freight Line(292)SP-SP-42(400)
B14-1A(379)FH-1C-01-01(333)FH-6A-01-01(289)Freight Line(2730)SP-SP-39(717)
FH-2E-01-02(1)R3-2-A1(5)SP-SP-48(2)
B17-3A(11)FH-1E-01-01(2)FH-5B-04-01(1)FH-5B-04-03(10)FH-5C-04-01(12)
FH-4D-02-02(4)R3-1-A2(4)SP-SP-57(5)
B14-2A(55)FH-1E-01-01(17)FH-6C-02-04(37)SP-SP-10(27)
B14-2A(58)FH-2E-03-04(26)Mezz(91)R3-2-C2(20)SP-SP-18(30)
B14-3A(49)FH-1F-05-01(23)FH-1H-02-01(8)FH-1H-06-03(67)SP-SP-07(14)
FH-CG-05(8)SP-HV-4C(4)SV-CG-01(28)
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Will the FH always be the 1st 2 characters?
 
Upvote 0
Like this

VBA Code:
Sub jec()
 With Range("D1", Cells(Rows.Count, 4).End(xlUp)).Resize(, 5)
   .Value = Evaluate(Replace("if(countifs(@@,@@,@@,""*FH*"")>0,@@,"""")", "@@", .Address))
 End With
End Sub

or

VBA Code:
Sub jecx()
Range("D1", Cells(Rows.Count, 4).End(xlUp)).Resize(, 5).Name = "ar"
[ar] = [if(countifs(ar,ar,ar,"*FH*"),ar,"")]
End Sub
 
Upvote 0
If it is always the 1st 2 characters then try
VBA Code:
With Range("D2:H" & Range("D" & Rows.Count).End(xlUp).Row)
   .Value = Evaluate(Replace("If(left(@,2)=""FH"",@,"""")", "@", .Address))
End With
 
Upvote 0
That worked, ok follow up question,
what would i add to that code if i wanted to exend the columns, go past H, would i change the 4?
 
Upvote 0
In my version you could resize more:
Range("D1", Cells(Rows.Count, 4).End(xlUp)).Resize(, 8).Name = "ar"

Fluff's version:
Range("D2:L" & Range("D" & Rows.Count).End(xlUp).Row)
 
Last edited:
Upvote 0
With the code I supplied, just change the H to whatever your last column should be.
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,217
Members
453,024
Latest member
Wingit77

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