Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
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) |
#2
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
=N(CLEAN(IF(ISERROR(SEARCH("WIRE TYPE:WIRE",D25)),"",MID(D25,SEARCH("PMT DET:",D25)+8,5))&IF(ISERROR(SEARCH("WIRE
TYPE:BOOK",D25)),"",MID(D25,SEARCH("REF:",D25)+4,5 )))) -- KL [MVP - Microsoft Excel] RU: http://www.mvps.ru/Program/Default.aspx ES: http://mvp.support.microsoft.com/?LN=es-es EN: http://mvp.support.microsoft.com/?LN=en-us Profile: https://mvp.support.microsoft.com/pr...A-9E6C73C09A36 "Dinesh" wrote in message ... 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) |
#3
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
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 |
#4
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
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 |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Formula to extract a specific word from text string | Excel Worksheet Functions | |||
I need to search for then extract a specific portion of cell data... | Excel Worksheet Functions | |||
Search/Extract Formula | Excel Discussion (Misc queries) | |||
filename search and extract into a cell | Excel Discussion (Misc queries) | |||
formula to extract specific data if match occurs | Excel Worksheet Functions |