Wrox Programmer Forums
Go Back   Wrox Programmer Forums > Microsoft Office > Access and Access VBA > Access VBA
|
Access VBA Discuss using VBA for Access programming.
Welcome to the p2p.wrox.com Forums.

You are currently viewing the Access VBA section of the Wrox Programmer to Programmer discussions. This is a community of software programmers and website developers including Wrox book authors and readers. New member registration was closed in 2019. New posts were shut off and the site was archived into this static format as of October 1, 2020. If you require technical support for a Wrox book please contact http://hub.wiley.com
 
Old March 29th, 2005, 12:31 PM
Authorized User
 
Join Date: Feb 2005
Posts: 10
Thanks: 0
Thanked 0 Times in 0 Posts
Default Extract part of field from inconsistent data

I need to extract a product code from a field, but the data is inconsistent because it has other information in it. A typical field is below:

Partial payment (E21486) for OCR Accounting Level 2 Cert/Dip (OC05LE0A009P) from Angie Smith (0212345)

The product code that I am attempting to extract is the code in the second set of brackets - (OC05LE0A009P) - this will always be in a set of brackets. The fact that the names of the product and the student are always different lengths means that I cannot extract the data using the MID function.

I have tried Microsoft’s website and a couple of other places seeking VBA or perhaps even SQL code, to no avail.

I would be very grateful for any help received.

Kind regards,


Roly
 
Old March 30th, 2005, 08:58 AM
Friend of Wrox
 
Join Date: Jun 2003
Posts: 1,151
Thanks: 2
Thanked 14 Times in 14 Posts
Send a message via ICQ to SerranoG Send a message via AIM to SerranoG
Default

Well, it seems you have three sets of data in parentheses (what you call brackets): E21486, OC05LE0A009P, and 0212345. Isolating the middle one via just looking for () will be hard because you have others.

Questions: Will the product code always have 12 digits? Will it always start with OC0, etc.? Will it always be the second set of codes in ()? Will the sentence you gave as an example always look like that or can the sentence be anything in any order?


Greg Serrano
Michigan Dept. of Environmental Quality, Air Quality Division
 
Old March 30th, 2005, 10:14 AM
Friend of Wrox
 
Join Date: Mar 2004
Posts: 3,069
Thanks: 0
Thanked 10 Times in 10 Posts
Default

Yeah, you want to parse this with regular expression scripting.

If you always have a string that looks like the one above, only the names of the products or student names are different as you say, then you would push the data into an array and then pull out your product code like this:

strData = "Partial payment (E21486) for OCR Accounting Level 2 Cert/Dip (OC05LE0A009P) from Angie Smith (0212345)"

ProductArray = Split(strData, "(")
   strProdCode = ProductArray(2)
   NewArray = Split(strProdCode, ")")
   strProdCode = NewArray(0)

strProdCode would yeild "OC05LE0A009P"

   This is assuming it was always the second set of parens in your strings.

I am sure SerranoG has a more elegant solution. But assuming I could get at the string in each record, and each string had this format, that is how I would do it.




mmcdonal
 
Old March 30th, 2005, 11:46 AM
Friend of Wrox
 
Join Date: Nov 2004
Posts: 1,621
Thanks: 1
Thanked 3 Times in 3 Posts
Default

I believe I would use InStr() to fin the location of the first "(" (iParen1), and the ")" that follows it (iParen2).
If the distance between them was not the right number of characters, strip off the part that has been looked at
Code:
    tmpstrData = Mid$(tmpstrData, iParen2 + 1)
and do the whole thing again with this now-shorter string.
But if the size is right, then extract the data with
Code:
    strProdCode = Mid$(tmpstrData, iParen1 + 1, iParen2 - 1)
 
Old March 31st, 2005, 09:25 AM
Friend of Wrox
 
Join Date: Nov 2004
Posts: 248
Thanks: 0
Thanked 1 Time in 1 Post
Default

Try this:

Code:
ProductCode = Split(  Split(TypicalField,"(")(2)  ,")")(0)
Be care with the Split! If you don't have enough sets of the search values you'll get "Subscript out of range".

The syntax of the split is a bit tricky. Help gives you:

  Split(field,delimiter)

Which makes you think you have to put it into an array. But if you add the index you can pick whatever you want and assign it to a variable:

  Split(Field,Delimiter)(Index)

The internal Split in the code sample gives you everything after the second "(", index (2). The external Split takes that value and drops off the ")" and everything after it.

Randall J Weers
Membership Vice President
Pacific NorthWest Access Developers Group
http://www.pnwadg.org





Similar Threads
Thread Thread Starter Forum Replies Last Post
Extract data from memo field knix2007 Access VBA 7 December 17th, 2007 03:24 PM
Extract part of String carrie09 Access 6 August 24th, 2007 10:04 AM
inconsistent data stealthdevil Access VBA 2 November 10th, 2006 05:03 PM
Inconsistent error when retrieving data from a db darkhalf Classic ASP Databases 2 March 14th, 2004 12:38 PM
A query to extract part of a string RayL Access 3 March 10th, 2004 09:42 AM





Powered by vBulletin®
Copyright ©2000 - 2020, Jelsoft Enterprises Ltd.
Copyright (c) 2020 John Wiley & Sons, Inc.