FIND function using a Define Name range

MsLeFox2017

New Member
Joined
Oct 23, 2017
Messages
5
Hi,

I'm using the below formula to extract data (equipment number) with a hyphen. For example, cell contains:

V-1770A BLAST/PAINT EXTERNAL SURFACE (#17337C)

the formula:

=TRIM(MID(SUBSTITUTE(E3080," ",REPT(" ",99)),MAX(1,FIND("V-",SUBSTITUTE(E3080," ",REPT(" ",99)))-50),99))

returns the results:

V-1770A

The formula works great, but I have to change the FIND find_text parameter (V- or I- or E- or C- or T-) each time the equipment number changes in the cell line. Examples of various cell data lines:

I-1602 A/B "DRYER" DEMO SCAFFOLD # 2080 (#17324A)
E-1403 "IN/OUTLET VALVE " DEMO SCAFFOLD #2076 (#17324A)
C-1407 "INSPECTION WINDOWS" REPLACE METAL/SEALANT (#17324B)
T-1311C "ROOF TOP NOZZLES" CLEAN/PAINT (#17324C)
V-1770A BLAST/PAINT EXTERNAL SURFACE (#17337C)

No matter where the information is on the line the formula works, but I have to edit the formula each time the equipment letter changes. I've tried using a Define Name table in the FIND find_text parameter, but that does not work. Returns #VALUE .

Any suggestions or help would be greatly appreciated.
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Thanks for the reply. The current formula searches and finds the name anywhere in the cell for any length. Items bolded in the examples below is what needs extracting.

Examples:

C-1407 "INSPECTION WINDOWS" REPLACE METAL/SEALANT (#17324B)
"ROOF TOP NOZZLES" CLEAN/PAINT T-1311C (#17324C)
BLAST/PAINT V-1770A EXTERNAL SURFACE (#17337C)[TABLE="width: 555"]
<tbody>[TR]
[TD]T/A - T-1335 INTERNAL CLEANING (#17324D)[/TD]
[/TR]
[TR]
[TD]P-1353 "VALVES/PIPING" REMOVE & REPLACE INSULATION/METAL (#17324B)[/TD]
[/TR]
[TR]
[TD]T/A - T-1345A "NOZZLES" INSTALL PLASTIC PROTETION (#17324B)[TABLE="width: 555"]
<tbody>[TR]
[TD]"PSF DISK" SF-1160 REPLACE HEAT TRACING & INSULATION BLANKETS (#17324B)[/TD]
[/TR]
</tbody><colgroup><col></colgroup>[/TABLE]
[/TD]
[/TR]
</tbody><colgroup><col></colgroup>[/TABLE]

I'm not sure as to where your suggestion would be placed in this formula:

=TRIM(MID(SUBSTITUTE(E3080," ",REPT(" ",99)),MAX(1,FIND("V-",SUBSTITUTE(E3080," ",REPT(" ",99)))-50),99))
where "V-" is the FIND find_text being changed each time a different piece of equipment is named.

The Define Name range I've tried to use is:

=TRIM(MID(SUBSTITUTE(E3080," ",REPT(" ",99)),MAX(1,FIND(Equip_Lookup,SUBSTITUTE(E3080," ",REPT(" ",99)))-50),99))
[TABLE="width: 86"]
<tbody>[TR]
[TD]Equip_Lookup [/TD]
[/TR]
[TR]
[TD]C-[/TD]
[/TR]
[TR]
[TD]D-[/TD]
[/TR]
[TR]
[TD]DV-[/TD]
[/TR]
[TR]
[TD]F-[/TD]
[/TR]
[TR]
[TD]FI-C[/TD]
[/TR]
[TR]
[TD]FV-[/TD]
[/TR]
[TR]
[TD]LG-[/TD]
[/TR]
[TR]
[TD]LS-[/TD]
[/TR]
[TR]
[TD]LSHH-[/TD]
[/TR]
[TR]
[TD]LV-[/TD]
[/TR]
[TR]
[TD]ME-[/TD]
[/TR]
[TR]
[TD]OV-[/TD]
[/TR]
[TR]
[TD]P-[/TD]
[/TR]
[TR]
[TD]PSE-[/TD]
[/TR]
[TR]
[TD]PSV-[/TD]
[/TR]
[TR]
[TD]PV-[/TD]
[/TR]
[TR]
[TD]R-[/TD]
[/TR]
[TR]
[TD]SD-[/TD]
[/TR]
[TR]
[TD]T-[/TD]
[/TR]
[TR]
[TD]TCV-[/TD]
[/TR]
[TR]
[TD]TV-[/TD]
[/TR]
[TR]
[TD]V-[/TD]
[/TR]
[TR]
[TD]VB-[/TD]
[/TR]
[TR]
[TD]VJ-[/TD]
[/TR]
</tbody><colgroup><col></colgroup>[/TABLE]
 
Upvote 0
What is the expected result for the last example?
SF-
is not present in Equip_lookup, but F- is.

M.
 
Upvote 0
I'm still building the Equip_Lookup table. SF- and F- are two different types of equipment names. Thanks for asking.
 
Upvote 0
I'm still building the Equip_Lookup table. SF- and F- are two different types of equipment names. Thanks for asking.

Also, if there are characters before the search characters, those characters will be picked up as well. But, they would still be different records.
 
Upvote 0
I'm still building the Equip_Lookup table. SF- and F- are two different types of equipment names. Thanks for asking.

Ok, so assuming the last example should return an error ("Not Found"), until SF- is included in the named range, maybe something like that


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
Text​
[/td][td]
Result​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
C-1407 "INSPECTION WINDOWS" REPLACE METAL/SEALANT (#17324B)​
[/td][td]
C-1407​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
"ROOF TOP NOZZLES" CLEAN/PAINT T-1311C (#17324C)​
[/td][td]
T-1311C​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
BLAST/PAINT V-1770A EXTERNAL SURFACE (#17337C)​
[/td][td]
V-1770A​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
T/A - T-1335 INTERNAL CLEANING (#17324D)​
[/td][td]
T-1335​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
P-1353 "VALVES/PIPING" REMOVE & REPLACE INSULATION/METAL (#17324B)​
[/td][td]
P-1353​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
T/A - T-1345A "NOZZLES" INSTALL PLASTIC PROTETION (#17324B)​
[/td][td]
T-1345A​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td]
"PSF DISK" SF-1160 REPLACE HEAT TRACING & INSULATION BLANKETS (#17324B)​
[/td][td]
Not Found​
[/td][/tr]
[/table]


Formula in B2 copied down
=IFERROR(TRIM(MID(SUBSTITUTE(A2," ",REPT(" ",99)),MAX(1,FIND(" "&LOOKUP(9.99E+307,SEARCH(Equip_Lookup,A2),Equip_Lookup)," "&SUBSTITUTE(A2," ",REPT(" ",99)))-50),99)),"Not Found")

Observe i substituted in your formula
TRIM(MID(SUBSTITUTE(E3080," ",REPT(" ",99)),MAX(1,FIND(Equip_Lookup,SUBSTITUTE(E3080," ",REPT(" ",99)))-50),99))

Equip_Lookup by LOOKUP(9.99E+307,SEARCH(Equip_Lookup,A2),Equip_Lookup)

and added a space before this LOOKUP, and another space before SUBSTITUTE (to avoid that the equipment whose prefix is F- is found in SF-)

Hope this helps

M.
 
Upvote 0
It's very very long :)

=IF(LEFT(IF(LEN(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))))>=IFERROR(SEARCH(" ?-",A1),SEARCH("?-",A1)),SUBSTITUTE(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),LEFT(A1,-2-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),""),SUBSTITUTE(LEFT(A1,-1-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),""))&MID(A1,FIND("-",A1),FIND(" ",A1,FIND("-",A1))-FIND("-",A1)),3)="T/A",TRIM(MID(IF(LEN(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))))>=IFERROR(SEARCH(" ?-",A1),SEARCH("?-",A1)),SUBSTITUTE(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),LEFT(A1,-2-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),""),SUBSTITUTE(LEFT(A1,-1-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),""))&MID(A1,FIND("-",A1),FIND(" ",A1,FIND("-",A1))-FIND("-",A1)),6,LEN(IF(LEN(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))))>=IFERROR(SEARCH(" ?-",A1),SEARCH("?-",A1)),SUBSTITUTE(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),LEFT(A1,-2-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),""),SUBSTITUTE(LEFT(A1,-1-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),""))&MID(A1,FIND("-",A1),FIND(" ",A1,FIND("-",A1))-FIND("-",A1)))-5)),IF(LEN(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))))>=IFERROR(SEARCH(" ?-",A1),SEARCH("?-",A1)),SUBSTITUTE(LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),LEFT(A1,-2-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),""),SUBSTITUTE(LEFT(A1,-1-LOOKUP(,-FIND("-",A1,ROW($1:$99)))),LEFT(A1,IFERROR(SEARCH(" ??-",A1),SEARCH("?-",A1))),""))&MID(A1,FIND("-",A1),FIND(" ",A1,FIND("-",A1))-FIND("-",A1)))
 
Upvote 0
@Marcelo Branco

:) Thank you. After researching the LOOKUP(9.99E+307... (BigNum) setting, I modified the formula, made adjustments to my lookup table, and it now works for what I need.:)

Final formula:
=IFERROR(TRIM(MID(SUBSTITUTE(E2993," ",REPT(" ",99)),MAX(1,FIND(LOOKUP(9.99E+307,SEARCH(Equip_Lookup,E2993),Equip_Lookup),SUBSTITUTE(E2993," ",REPT(" ",99)))-50),99))," ")

where the Define Name range (Equip_Lookup) had to be exact (no blank lines), with the specific search values. There are other cells which hold data with hyphens that were not valid elements of my search.

Should there be a new entry for the range, it must be inserted into the range, or added at the end, sorted, and the range size adjusted using Name Manager.

Again, thank you for your brilliance!
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,249
Members
452,623
Latest member
Techenthusiast

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