Macro to delete hidden characters in text

Eric@SLR

New Member
Joined
Apr 1, 2002
Messages
2
I need a technique or a macro that will clean spreadsheets of hidden characters in text (a common one that I deal with is the ALT+Enter to create another space in a cell for formatting purposes). I have tried the =trim () function - but it leaves these hidden characters alone - they are shaped like a square when they are revealed - but they still blend in very well. Help please
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Hi Eric,

Here is a macro that will "clean" a selected range on a worksheet of all control characters. You should put this into a macro module. Included is a helper function that it calls.

Sub CleanSelectedRange()
' "Cleans" contents of all selected cells on the active worksheet
Dim Cell As Range
For Each Cell In Selection
If Not Cell.HasFormula Then
Cell.Value = CleanString(Cell.Value)
End If
Next Cell
End Sub

Function CleanString(StrIn As String) As String
' "Cleans" a string by removing embedded control (non-printable)
' characters, including carriage returns and linefeeds.
' Does not remove special characters like symbols, international
' characters, etc. This function runs recursively, each call
' removing one embedded character
Dim iCh As Integer
CleanString = StrIn
For iCh = 1 To Len(StrIn)
If Asc(Mid(StrIn, iCh, 1)) < 32 Then
'remove special character
CleanString = Left(StrIn, iCh - 1) & CleanString(Mid(StrIn, iCh + 1))
Exit Function
End If
Next iCh

End Function
 
Upvote 0
Hi
Hi

Sub CleanerUpper()

Cells.Replace What:=Chr(13), Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:=Chr(10), Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False

End Sub

This is identical to the find/replace. Using code, you can force the carriage return value into the find replace command.
As is, you will need to run this from every sheet.

Good Day!
Tom
 
Upvote 0
Hi Eric

Have you tried the CLEAN Function, eg

=CLEAN(A1)

Or to automate this try:

Code:
Sub CleanIt()
Dim rClean As Range

Set rClean = Range(Selection.Cells(1, 1), Selection.Cells(65536, 1).End(xlUp))
    rClean.EntireColumn.Insert
    rClean.Offset(0, -1).FormulaR1C1 = "=CLEAN(RC[1])"
    rClean = rClean.Value
End Sub
 
Upvote 0
I was able to use the macro written by Damon,the problem is the formatting was not correct now. I would like to keep the formatting the same but not see the little box. Is this even possible?
 
Upvote 0
Hi Eric@SLR,

Sorry that this is coming about a year late, but just in case you (or others) are still interested, here is a solution that removes all those control characters <u>except</u> for linefeed characters. The line feeds enable the termination of a line giving spacing between lines. It is important to note that the linefeed characters will still show up as a rectangle if the cell is not formatted to allow text wrapping.

Here's the code:

Code:
Sub CleanSelectedRange()
' "Cleans" contents of all selected cells on the active worksheet
Dim Cell As Range
For Each Cell In Selection
If Not Cell.HasFormula Then
Cell.Value = CleanString(Cell.Value)
End If
Next Cell
End Sub

Function CleanString(StrIn As String) As String

' characters, including carriage returns BUT NOT linefeeds.
' Does not remove special characters like symbols, international
' characters, etc. This function runs recursively, each call
' removing one embedded character

   Dim iCh  As Integer
   Dim Ch   As Integer      'a single character to be tested
   CleanString = StrIn
   For iCh = 1 To Len(StrIn)
      Ch = Asc(Mid(StrIn, iCh, 1))
      If Ch < 32 And Ch <> 10 Then
         'remove special character
         CleanString = Left(StrIn, iCh - 1) & CleanString(Mid(StrIn, iCh + 1))
      Exit Function
      End If
   Next iCh

End Function

You can use the CleanString function just as you would use the CLEAN worksheet function, or use CleanSelectedRange to clean all the cells in a selected range.

Damon
 
Last edited:
Upvote 0
I modified CleanString() to optionally remove LineFeeds, too:

Code:
Function CleanString(StrIn As String, Optional IsRemoveLineFeeds As Boolean = False) As String
 
' removes invisible characters, including carriage returns. By default, LINEFEEDS are NOT removed.
' to REMOVE LINEFEEDS, pass TRUE
' Does not remove special characters like symbols, international
' characters, etc. This function runs recursively, each call
' removing one embedded character
 
  Dim iCh  As Integer
  Dim Ch   As Integer      'a single character to be tested
  CleanString = StrIn
  For iCh = 1 To Len(StrIn)
    Ch = Asc(Mid(StrIn, iCh, 1))
    If Ch < 32 Then
      ' remove Ch 10 only if option is True
      If (Ch <> 10) Or (Ch = 10 And IsRemoveLineFeeds) Then
        'remove special character
        CleanString = Left(StrIn, iCh - 1) & CleanString(Mid(StrIn, iCh + 1))
      End If
      Exit Function
    End If
  Next iCh
 
End Function
 
Upvote 0

Forum statistics

Threads
1,214,431
Messages
6,119,457
Members
448,898
Latest member
drewmorgan128

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