A Microsoft Office (Excel, Word) forum. OfficeFrustration

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » OfficeFrustration forum » Microsoft Excel » General Discussion
Site Map Home Register Authors List Search Today's Posts Mark Forums Read  

pulling out Numbers



 
 
Thread Tools Display Modes
  #11  
Old August 21st, 2007, 07:50 PM posted to microsoft.public.excel.misc
peyman
external usenet poster
 
Posts: 193
Default pulling out Numbers

hi Mike,
the problem is , it removes the zero at the begining of a numbers after
pulling out them,like:
aab0125 turns to 125 instead of 0125

"Mike H" wrote:

Another way.

I'm a bit cofused why the previous method only removed th dash but try this

Sub anotherway()
For Each cell In Selection
For a = 1 To Len(cell)
Select Case Mid(cell, a, 1)
Case "0" To "9"
newstring = newstring & Mid(cell, a, 1)
End Select
Next a
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next cell
End Sub

Mike

"peyman" wrote:

hi Mike,
it just removes dash "-" from string!! not letters.

"Mike H" wrote:

With a macro:-

Sub removeletters()
For Each cell In Selection
For a = 1 To Len(cell)
If Asc(Mid(cell, a, 1)) 47 And Asc(Mid(cell, a, 1)) 59 Or _
Asc(Mid(cell, a, 1)) 64 And Asc(Mid(cell, a, 1)) 91 Then _
newstring = newstring & Mid(cell, a, 1)
Next
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next
End Sub

Select the cells to convert and run this

Mike

"peyman" wrote:

hi,
how can I pull out numbers from a string?like:
aa012985 to 012985
12ab-059 to 12059
the letters or characters might be either at the first, middle or at the end
of a string.
thanx in advance.

  #12  
Old August 21st, 2007, 07:50 PM posted to microsoft.public.excel.misc
peyman
external usenet poster
 
Posts: 193
Default pulling out Numbers

hi Ron,
the problem in Mikes macro is , it removes the zero at the begining of a
numbers after pulling out them,like:
aab0125 turns to 125 instead of 0125

"Ron Rosenfeld" wrote:

On Tue, 21 Aug 2007 11:18:02 -0700, Mike H
wrote:

With a macro:-

Sub removeletters()
For Each cell In Selection
For a = 1 To Len(cell)
If Asc(Mid(cell, a, 1)) 47 And Asc(Mid(cell, a, 1)) 59 Or _
Asc(Mid(cell, a, 1)) 64 And Asc(Mid(cell, a, 1)) 91 Then _
newstring = newstring & Mid(cell, a, 1)
Next
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next
End Sub



Your For/Next loop can be simplified:


For a = 1 To Len(cell)
If Mid(cell, a, 1) Like "#" Then
newstring = newstring & Mid(cell, a, 1)
End If
Next


--ron

  #13  
Old August 21st, 2007, 07:52 PM posted to microsoft.public.excel.misc
Mike H
external usenet poster
 
Posts: 8,419
Default pulling out Numbers

Hi,

It doesn't I suspect the zero is a letter "o" or "O"

Mike

"peyman" wrote:

hi Mike,
the problem is , it removes the zero at the begining of a numbers after
pulling out them,like:
aab0125 turns to 125 instead of 0125

"Mike H" wrote:

Another way.

I'm a bit cofused why the previous method only removed th dash but try this

Sub anotherway()
For Each cell In Selection
For a = 1 To Len(cell)
Select Case Mid(cell, a, 1)
Case "0" To "9"
newstring = newstring & Mid(cell, a, 1)
End Select
Next a
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next cell
End Sub

Mike

"peyman" wrote:

hi Mike,
it just removes dash "-" from string!! not letters.

"Mike H" wrote:

With a macro:-

Sub removeletters()
For Each cell In Selection
For a = 1 To Len(cell)
If Asc(Mid(cell, a, 1)) 47 And Asc(Mid(cell, a, 1)) 59 Or _
Asc(Mid(cell, a, 1)) 64 And Asc(Mid(cell, a, 1)) 91 Then _
newstring = newstring & Mid(cell, a, 1)
Next
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next
End Sub

Select the cells to convert and run this

Mike

"peyman" wrote:

hi,
how can I pull out numbers from a string?like:
aa012985 to 012985
12ab-059 to 12059
the letters or characters might be either at the first, middle or at the end
of a string.
thanx in advance.

  #14  
Old August 21st, 2007, 07:58 PM posted to microsoft.public.excel.misc
Ron Rosenfeld
external usenet poster
 
Posts: 3,719
Default pulling out Numbers

Mike,

It uses "Regular Expressions" which is a feature included with VBA.

The CreateObject method sets up the reference to Microsoft VBScript Regular
Expressions 5.5. Instead of that method, one can also select Tools/References
(from the VBEditor top menu) and select that as a reference. This latter
method has the advantage that properties will pop up when you are writing the
macro, as they do for other objects.

The Pattern "\D" means "match every character that is not a digit (not 0..9).
The replace method then looks at "str" and replaces every match with nothing
(""), thereby removing all the non-digits.

http://support.microsoft.com/default...02&Product=vbb
http://msdn2.microsoft.com/en-us/library/1400241x.aspx



On Tue, 21 Aug 2007 11:36:00 -0700, Mike H
wrote:

Ron,

Excellent. any chance of a quick rundown on how it works or a web reference
please?

Mike H

"Ron Rosenfeld" wrote:

On Tue, 21 Aug 2007 10:28:00 -0700, peyman
wrote:

hi,
how can I pull out numbers from a string?like:
aa012985 to 012985
12ab-059 to 12059
the letters or characters might be either at the first, middle or at the end
of a string.
thanx in advance.


You can use a 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 this UDF, enter =ExtrNums(cell_ref) into some cell.

===============================
Option Explicit

Function ExtrNums(str As String)
Dim re As Object
Set re = CreateObject("VBScript.RegExp")
re.Global = True
re.Pattern = "\D"
ExtrNums = re.Replace(str, "")
End Function
================================


--ron


--ron
  #15  
Old August 21st, 2007, 08:10 PM posted to microsoft.public.excel.misc
Sandy Mann
external usenet poster
 
Posts: 2,264
Default pulling out Numbers

I think that it does remove leading zeros Mike. Is it not necause you
format the cell as General?

--
Regards,

Sandy
In Perth, the ancient capital of Scotland
and the crowning place of kings


Replace @mailinator.com with @tiscali.co.uk


"Mike H" wrote in message
...
Hi,

It doesn't I suspect the zero is a letter "o" or "O"

Mike

"peyman" wrote:

hi Mike,
the problem is , it removes the zero at the begining of a numbers after
pulling out them,like:
aab0125 turns to 125 instead of 0125

"Mike H" wrote:

Another way.

I'm a bit cofused why the previous method only removed th dash but try
this

Sub anotherway()
For Each cell In Selection
For a = 1 To Len(cell)
Select Case Mid(cell, a, 1)
Case "0" To "9"
newstring = newstring & Mid(cell, a, 1)
End Select
Next a
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next cell
End Sub

Mike

"peyman" wrote:

hi Mike,
it just removes dash "-" from string!! not letters.

"Mike H" wrote:

With a macro:-

Sub removeletters()
For Each cell In Selection
For a = 1 To Len(cell)
If Asc(Mid(cell, a, 1)) 47 And Asc(Mid(cell, a, 1))
59 Or _
Asc(Mid(cell, a, 1)) 64 And Asc(Mid(cell, a, 1))
91 Then _
newstring = newstring & Mid(cell, a, 1)
Next
cell.Value = newstring
ActiveCell.NumberFormat = "General"
newstring = ""
Next
End Sub

Select the cells to convert and run this

Mike

"peyman" wrote:

hi,
how can I pull out numbers from a string?like:
aa012985 to 012985
12ab-059 to 12059
the letters or characters might be either at the first, middle or
at the end
of a string.
thanx in advance.




  #16  
Old August 21st, 2007, 08:16 PM posted to microsoft.public.excel.misc
Mike H
external usenet poster
 
Posts: 8,419
Default pulling out Numbers

Thanks Ron,

I'm only on my 4th read of John Walkenbach's 2003 bible so perhaps some way
off this yet.

Mike

"Ron Rosenfeld" wrote:

Mike,

It uses "Regular Expressions" which is a feature included with VBA.

The CreateObject method sets up the reference to Microsoft VBScript Regular
Expressions 5.5. Instead of that method, one can also select Tools/References
(from the VBEditor top menu) and select that as a reference. This latter
method has the advantage that properties will pop up when you are writing the
macro, as they do for other objects.

The Pattern "\D" means "match every character that is not a digit (not 0..9).
The replace method then looks at "str" and replaces every match with nothing
(""), thereby removing all the non-digits.

http://support.microsoft.com/default...02&Product=vbb
http://msdn2.microsoft.com/en-us/library/1400241x.aspx



On Tue, 21 Aug 2007 11:36:00 -0700, Mike H
wrote:

Ron,

Excellent. any chance of a quick rundown on how it works or a web reference
please?

Mike H

"Ron Rosenfeld" wrote:

On Tue, 21 Aug 2007 10:28:00 -0700, peyman
wrote:

hi,
how can I pull out numbers from a string?like:
aa012985 to 012985
12ab-059 to 12059
the letters or characters might be either at the first, middle or at the end
of a string.
thanx in advance.

You can use a 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 this UDF, enter =ExtrNums(cell_ref) into some cell.

===============================
Option Explicit

Function ExtrNums(str As String)
Dim re As Object
Set re = CreateObject("VBScript.RegExp")
re.Global = True
re.Pattern = "\D"
ExtrNums = re.Replace(str, "")
End Function
================================


--ron


--ron

  #17  
Old August 21st, 2007, 08:58 PM posted to microsoft.public.excel.misc
Ron Rosenfeld
external usenet poster
 
Posts: 3,719
Default pulling out Numbers

On Tue, 21 Aug 2007 12:16:02 -0700, Mike H
wrote:

Thanks Ron,

I'm only on my 4th read of John Walkenbach's 2003 bible so perhaps some way
off this yet.

Mike


Regular expressions are extremely powerful tools for string manipulation.
Harlan Grove turned me on to them, and I've found them quite worthwhile,
although I'm still a novice in their use.
--ron
  #18  
Old August 21st, 2007, 11:12 PM posted to microsoft.public.excel.misc
peyman
external usenet poster
 
Posts: 193
Default pulling out Numbers


hi Ron,
Can we do it reverse.pulling out only letters.
aa125df36 to aadf????
thank you


"Ron Rosenfeld" wrote:

On Tue, 21 Aug 2007 12:16:02 -0700, Mike H
wrote:

Thanks Ron,

I'm only on my 4th read of John Walkenbach's 2003 bible so perhaps some way
off this yet.

Mike


Regular expressions are extremely powerful tools for string manipulation.
Harlan Grove turned me on to them, and I've found them quite worthwhile,
although I'm still a novice in their use.
--ron

  #19  
Old August 22nd, 2007, 12:44 AM posted to microsoft.public.excel.misc
Ron Rosenfeld
external usenet poster
 
Posts: 3,719
Default pulling out Numbers

On Tue, 21 Aug 2007 15:12:01 -0700, peyman
wrote:

hi Ron,
Can we do it reverse.pulling out only letters.
aa125df36 to aadf????
thank you


It's pretty simple. In the code I posted, you just need to change the "\D",
which selects all non-digits for removal, to a "\d" which selects all digits
for removal.

But for more flexibility, you could include the arguments for what to find, and
what to replace it with, in the function code.

For example, with this UDF:

=====================================
Option Explicit
Function ReSub(str As String, FindText As String, ReplaceWith As String)
Dim re As Object
Set re = CreateObject("VBScript.RegExp")
re.Global = True
re.Pattern = FindText
ReSub = re.Replace(str, ReplaceWith)
End Function
======================================

You could use this formula to replace all digits with a null string, resulting
in pulling out only letters:

=resub(A1,"\d","")

If you wanted to pull out only digits, then:

=resub(A1,"\D","")

If you wanted to replace the digits with a tilde, you could use:

=resub(A1,"\d","~")

If you wanted to replace all of the letters with the word Peyman, with leading
and ending spaces, then:

=resub(A6,"\D"," Peyman ")

And many other solutions

--ron
  #20  
Old August 22nd, 2007, 12:56 AM posted to microsoft.public.excel.misc
peyman
external usenet poster
 
Posts: 193
Default pulling out Numbers

thanx Ron.It's excellent

"Ron Rosenfeld" wrote:

On Tue, 21 Aug 2007 15:12:01 -0700, peyman
wrote:

hi Ron,
Can we do it reverse.pulling out only letters.
aa125df36 to aadf????
thank you


It's pretty simple. In the code I posted, you just need to change the "\D",
which selects all non-digits for removal, to a "\d" which selects all digits
for removal.

But for more flexibility, you could include the arguments for what to find, and
what to replace it with, in the function code.

For example, with this UDF:

=====================================
Option Explicit
Function ReSub(str As String, FindText As String, ReplaceWith As String)
Dim re As Object
Set re = CreateObject("VBScript.RegExp")
re.Global = True
re.Pattern = FindText
ReSub = re.Replace(str, ReplaceWith)
End Function
======================================

You could use this formula to replace all digits with a null string, resulting
in pulling out only letters:

=resub(A1,"\d","")

If you wanted to pull out only digits, then:

=resub(A1,"\D","")

If you wanted to replace the digits with a tilde, you could use:

=resub(A1,"\d","~")

If you wanted to replace all of the letters with the word Peyman, with leading
and ending spaces, then:

=resub(A6,"\D"," Peyman ")

And many other solutions

--ron

 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Forum Jump


All times are GMT +1. The time now is 02:15 PM.


Powered by vBulletin® Version 3.6.4
Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Copyright ©2004-2024 OfficeFrustration.
The comments are property of their posters.