Search for a number in a row

M_Gross

New Member
Joined
May 2, 2018
Messages
12
Hi everyone,

I am struggling in VBA to find those cells in a row that contain a number.

The aim is to find every cell in a certain row with a number in it an delate the whole column.
A further Problem might be that the number is not declared as numeric, but as a text.

Can anyone help me out with this?

Best regards,
Max
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Hi & welcome to MrExcel.
Maybe something like
Code:
Sub Checktext()
   Dim rng As Range
   For Each rng In Range("A3:J3")
      If IsNumeric(rng.Value) Then rng.EntireColumn.Delete
   Next rng
End Sub
 
Upvote 0
Hi everyone,

I am struggling in VBA to find those cells in a row that contain a number.

The aim is to find every cell in a certain row with a number in it an delate the whole column.
A further Problem might be that the number is not declared as numeric, but as a text.
Given that you are going to delete the column whose cells contain numbers, would it be alright to have the code format the cells in than "certain row" as General and convert text numbers to real numbers?

The remaining cells would be formatted as General, but could be converted back to Text if you need it them formatted that way for future use... just let us know

Which "certain row" (or rows) is being examined for having a number in it?
 
Upvote 0
Hi & welcome to MrExcel.
Maybe something like
Code:
Sub Checktext()
   Dim rng As Range
   For Each rng In Range("A3:J3")
      If [B][COLOR="#FF0000"]IsNumeric[/COLOR][/B](rng.Value) Then rng.EntireColumn.Delete
   Next rng
End Sub
[SIZE=4][/SIZE]
From a previous post of mine...

I usually try and steer people away from using IsNumeric to "proof" supposedly numeric text. Consider this (also see note below):

Rich (BB code):
ReturnValue = IsNumeric("($1,23,,3.4,,,5,,E67$)")

Most people would not expect THAT to return True. IsNumeric has some "flaws" in what it considers a proper number and what most programmers are looking for.

I had a short tip published by Pinnacle Publishing in their Visual Basic Developer magazine that covered some of these flaws. Originally, the tip was free to view but is now viewable only by subscribers.. Basically, it said that IsNumeric returned True for things like -- currency symbols being located in front or in back of the number as shown in my example (also applies to plus, minus and blanks too); numbers surrounded by parentheses as shown in my example (some people use these to mark negative numbers); numbers containing any number of commas before a decimal point as shown in my example; numbers in scientific notation (a number followed by an upper or lower case "D" or "E", followed by a number equal to or less than 307 -- the maximum power of 10 in VB); and Octal/Hexadecimal numbers (&H for Hexadecimal, &O or just & in front of the number for Octal).

NOTE:
======
In the above example and in the referenced tip, I refer to $ signs and commas and dots -- these were meant to refer to your currency, thousands separator and decimal point symbols as defined in your local settings -- substitute your local regional symbols for these if appropriate.

As for your question about checking numbers, here are two functions that I have posted in the past for similar questions..... one is for digits only and the other is for "regular" numbers (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

Rich (BB code):
Function IsDigitsOnly(Value As String) As Boolean
    IsDigitsOnly = Len(Value) > 0 And Not Value Like "*[!0-9]*"
End Function

Function IsNumber(ByVal Value As String) As Boolean
    '   Leave the next statement out if you don't
    '   want to provide for plus/minus signs
    If Value Like "[+-]*" Then Value = Mid$(Value, 2)
    IsNumber = Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" And Len(Value) > 0 And Value <> "."
End Function

Here are revisions to the above functions that deal with the local settings for decimal points (and thousand's separators) that are different than used in the US (this code works in the US too, of course).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

I'm not as concerned by the rejection of entries that include one or more thousand's separators, but we can handle this if we don't insist on the thousand's separator being located in the correct positions (in other words, we'll allow the user to include them for their own purposes... we'll just tolerate their presence).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  Dim TS As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Get local setting for thousand's separator
  '   and eliminate them. Remove the next two lines
  '   if you don't want your users being able to
  '   type in the thousands separator at all.
  TS = Mid$(Format$(1000, "#,###"), 2, 1)
  Value = Replace$(Value, TS, "")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function
 
Upvote 0
When I try the script in post 2 it does not delete all the columns it should delete.
Try this:
Code:
Sub MeCheck()
'Modified 5/2/18 11:50 AM EDT   
For i = 10 To 1 Step -1
    If IsNumeric(Cells(3, i)) Then Columns(i).Delete
   Next
End Sub
 
Upvote 0
When I try the script in post 2 it does not delete all the columns it should delete.
You're quite right.

@M_Gross
Please ignore the code in post#2
When deleting columns you need to go right to left, as MAIT has done.
You'll also need to take into account what Rick has said
 
Last edited:
Upvote 0
Solved it this way, thank you for your help :)

NumberCol = .Cells(8, Columns.Count).End(xlToLeft).Column

For i = NumberCol To 1 Step -1
If IsNumeric(.Cells(8, i)) = True Then .Columns(i).Delete
Next i
 
Upvote 0
Solved it this way, thank you for your help :)

NumberCol = .Cells(8, Columns.Count).End(xlToLeft).Column

For i = NumberCol To 1 Step -1
If IsNumeric(.Cells(8, i)) = True Then .Columns(i).Delete
Next i
You did not follow Fluff's advice when he said "You'll also need to take into account what Rick has said".

If you are not sure how to apply what I posted in Message #4 , then just tell us whether your numbers are always whole numbers or if they could be floating point numbers... also, can the numbers be negative... and I will adjust your above code to account for what I posted as it applies to your numbers.
 
Upvote 0
Solved it this way, thank you for your help :)

NumberCol = .Cells(8, Columns.Count).End(xlToLeft).Column

For i = NumberCol To 1 Step -1
If IsNumeric(.Cells(8, i)) = True Then .Columns(i).Delete
Next i
They are always whole numbers, not Floating, not negative.
To implement what I posted in Message #4 above, change the red highlighted line of code above to this...
Code:
[table="width: 500"]
[tr]
	[td]If Len(.Cells(8, i)) > 0 And Not .Cells(8, i) Like "*[!0-9]*" Then .Columns(i).Delete[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,885
Messages
6,175,183
Members
452,615
Latest member
bogeys2birdies

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