InStr() within a Range, mistmatch error

ilcaa

Well-known Member
Joined
May 25, 2005
Messages
751
Office Version
  1. 365
Platform
  1. Windows
i have a range of rows that contains text. I want to check if a string exists within this range. but i keep getting errors

what is proper syntax?

Rng = Range("a1:a200")

if Instr(Rng, "All Formulas") then
if Instr(Rng.text, "All Formulas") then
if Instr(Rng.value, "All Formulas") then

none work. if i try to print the range i get

Debug.Print (Rng.Text) = Null
Debug.Print (Rng.Value) = type Mismatch
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Try
Code:
For Each c In Rng
If Instr(c, "All Formulas") <> 0 then
 ' do what needs to be done
End If
Next c
 
Last edited:
Upvote 0
If you just want to see if the string occurs anywhere in the range use
Code:
MsgBox IIf(InStr(1, Join(Application.Transpose(Range("A1:A200").Value), "|"), "All Formulas", vbTextCompare) > 0, "yes", "no")
 
Upvote 0
If you just want to see if the string occurs anywhere in the range use
Code:
MsgBox IIf(InStr(1, Join(Application.Transpose(Range("A1:A200").Value), "|"), "All Formulas", vbTextCompare) > 0, "yes", "no")
If that is what the OP wants, then here is another way...
Code:
MsgBox IIf(Application.CountIf(Range("A1:A200"), "*All Formulas*"), "Yes", "No")
 
Upvote 0
If that is what the OP wants, then here is another way...
Code:
MsgBox IIf(Application.CountIf(Range("A1:A200"), "*All Formulas*"), "Yes", "No")

thanks, this seems to be the cleanest and easiest. why the * before and after? indicates wildcard, if text appears before and after??? thanks for the help
 
Upvote 0
why the * before and after? indicates wildcard, if text appears before and after???
Yes, the asterisks allow for there to be text either before or after (or both) the text you are searching for. I did that because you tried to use InStr which allows for text to before or after the text being searched for. If you are looking for the text to be the only text in the cell, then remove the asterisks.
 
Upvote 0

Forum statistics

Threads
1,213,552
Messages
6,114,278
Members
448,559
Latest member
MrPJ_Harper

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