LinkBack Thread Tools Search this Thread Display Modes
Prev Previous Post   Next Post Next
  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 5,651
Default Extract specific value using SEARCH FORMULA

On Fri, 02 Mar 2007 08:17:30 -0500, Ron Rosenfeld
wrote:

On Thu, 1 Mar 2007 16:19:03 -0800, Dinesh
wrote:

Hi,

Below is text and underneath is a formula to extract a number (53625) from
Text after "PMT DET". Since this number is broken down between two rows, it
is not extracting the value as desire and gives "#value! error. How can fix
the formula?

thanks in advance.

Dinesh

Text
"WIRE TYPE:WIRE OUT DATE:060231 TIME:1219 ET
TRN:3001014500160362 SERVICE REF:002067
BNF:DISTRIBUTED SYSTEMS SERVIC ID:ab68068pc
BNF BK:NATIONAL BENN CORP ID:031308784 PMT DET:536
25 KMC-65069 INV a000G5202 0000ab /152
"
Formula
=IF(ISERROR(SEARCH("WIRE TYPE:WIRE",D25)),"",MID(D25,SEARCH("PMT
DET:",D25)+8,5)+0)&IF(ISERROR(SEARCH("WIRE
TYPE:BOOK",D25)),"",MID(D25,SEARCH("REF:",D25)+4 ,5)+0)


If the length of the text will be less than 256 characters, you could download
and install Longre's free and easily distributable morefunc.xll add-in from
http://xcell05.free.fr

and then use this Regular Expression formula:

=IF(REGEX.COMP(A1,"WIRE TYPE:WIRE"),
REGEX.SUBSTITUTE(REGEX.MID(A1,"(?<=PMT DET:)[\d\n]+"),"\n"),"")


--ron


If your text string might be longer than 255 characters, then you can use this
VBA UDF.

To enter the UDF, <alt-F11 opens the VB Editor.
Ensure your project is highlighted in the Project Explorer window, then
Insert/Module and paste the code below into the window that opens.

To use the UDF, in some cell enter the formula:

=PMTDET(cell_ref,"WIRE TYPE:WIRE")

The formula will return the number that exists after the string "PMT DET:" and
ignore any "new line" characters.

If your format is different, the regex might need to be changed a bit to
accomodate.

--------------------------------------------------
Option Explicit

Function PMTDET(str As String, RecType As String) As String
Dim objRegExp As Object
Set objRegExp = CreateObject("VBScript.RegExp")

Dim colMatches As Object
Const sPattern As String = "(PMT DET:)([\d\n]+)"

With objRegExp
.IgnoreCase = False
.Global = True
.Pattern = RecType

If .Test(str) = True Then
.Pattern = sPattern
If .Test(str) = True Then
Set colMatches = .Execute(str)
PMTDET = colMatches(0).submatches(1)
PMTDET = Replace(PMTDET, Chr(10), "")
End If
End If

End With

End Function
============================================
--ron
 
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Formula to extract a specific word from text string Dinesh Excel Worksheet Functions 4 November 3rd 06 08:35 PM
I need to search for then extract a specific portion of cell data... Ken Excel Worksheet Functions 15 September 6th 06 11:53 AM
Search/Extract Formula M Moore Excel Discussion (Misc queries) 5 August 29th 06 04:28 AM
filename search and extract into a cell M John Excel Discussion (Misc queries) 5 April 28th 06 10:11 PM
formula to extract specific data if match occurs jerry Excel Worksheet Functions 2 February 24th 05 11:06 AM


All times are GMT +1. The time now is 12:24 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"