Excel Smart Find and Replace only specific characters

3

1

I want to change INT to INTERNATIONAL and NA to NATIONAL ASSEMBLY in whole excel workbook through an excel Macro or Find and Replace dialogue box. But when I run the macro or change it through Find and Replace dialogue box it also replace NA from CHINA last 2 characters and it became CHINATIONAL ASSEMBLY and INTERIOR to INTERNATIONALERIOR.

Now, I want that Excel should only smartly find the character NA in the workbook which is not included with any other character likewise character INT which is not attach to any other character.

Asim

Posted 2012-09-14T14:46:16.127

Reputation: 33

Can you share the macro (assuming it's VBa code) – Dave – 2012-09-14T14:52:13.803

What version of Excel are you running? – dangowans – 2012-09-16T15:02:59.487

Answers

1

If you go the VBA route, try using Regular Expressions

Here's a start

Sub ReplaceWithRE()
    Dim re As Object 'RegExp
    Dim rng As Range, cl As Range
    Dim sh As Worksheet
    Dim wb As Workbook
    Dim sReplace As String
    Dim aReplace(0 To 1, 0 To 1) As String
    Dim i As Long

    Set wb = ActiveWorkbook
    Set re = CreateObject("vbscript.regexp") ' New RegExp
    re.Global = True
    re.IgnoreCase = False
    re.MultiLine = True

    ' Load array of patterns and replacements
    aReplace(0, 0) = "\bINT\b"
    aReplace(0, 1) = "INTERNATIONAL"
    aReplace(1, 0) = "\bNA\b"
    aReplace(1, 1) = "NATIONAL ASSEMBLY"

    For Each sh In wb.Worksheets
        On Error Resume Next
        Set rng = sh.UsedRange.SpecialCells(xlCellTypeConstants)
        If Err.Number <> 0 Then
            Err.Clear
        Else
            On Error GoTo 0
            For Each cl In rng
                sReplace = cl.Value
                ' Test each cell for each pattern, replace when found
                For i = 0 To UBound(aReplace, 1)
                    re.Pattern = aReplace(i, 0)
                    If re.Test(sReplace) Then
                        sReplace = re.Replace(sReplace, aReplace(i, 1))
                    End If
                Next
                cl.Value = sReplace
            Next
        End If
    Next


End Sub

chris neilsen

Posted 2012-09-14T14:46:16.127

Reputation: 4 005

You are great!! Thank you so much for such a great help, its a great macro for me to work with. It helped me alot. Thanks once again. – Asim – 2012-09-24T14:47:33.890

3

If the values you are looking to replace are by themselves in the cells (no other text), definitely follow CharlieRB's solution. If the values are located in the cells, along with additional text, a slightly modified version would work.

Open the Find and Replace window. Click the "Replace" tab.

Find and Replace

Enter the "Find what" and the "Replace with" values. Click the "Find All" button.

Review the list at the bottom that details what records were found. Highlight the record you want to update, and click the "Replace" button.

dangowans

Posted 2012-09-14T14:46:16.127

Reputation: 1 774

… but you might want to edit your answer to say “Highlight the record s you want to update” (“I want to change … in whole Excel workbook”) and maybe say something about Shift+click and Ctrl+click. – Scott – 2012-09-24T16:41:10.853

2

In the Find and Replace window, you need to check the box Match entire cell contents then run it.

enter image description here

CharlieRB

Posted 2012-09-14T14:46:16.127

Reputation: 21 303

1@pnuts: FWIW, I believe that's not obvious from the question. – Scott – 2012-09-14T17:10:54.853

@pnuts: Given that the questioner seems to be struggling with English, "likewise character INT which is not attach to any other character" *could* very well mean the same as "the character NA in the workbook which is not included with any other character"; i.e., "string X in a cell by itself, without any other characters." – Scott – 2012-09-17T15:22:18.443

Scott is right, sorry for my weak English, likewise mean as the case mention before. But its solved now by chris neilsen. – Asim – 2012-09-24T14:46:12.780

I believe that we all understood what you meant by “likewise”; it was the other words we were unsure about.  By the way, when you answer somebody’s question (from a comment) in a new comment, it’s conventional to mention that person’s name, preceded by “@”, as in “@Scott, @pnuts”.  That way we get notified.  See the Replying in comments paragraphs of the Comment formatting section of the Markdown Editing Help page.

– Scott – 2012-09-24T16:25:31.433

1

  1. Save your file as a CSV file.  If you want to manipulate a subset of your worksheet (e.g., selected columns and/or rows), copy that region into a scratch file (or sheet) and save that as CSV.  If you need to modify multiple sheets, repeat this process for each sheet.
  2. Edit the CSV file with some sort of smart text editor (i.e., smarter than Notepad).  vi is good for this; use a command such as %s/\<INT\>/INTERNATIONAL/g.  Microsoft Word will probably suffice; use the “Find whole words only” option under More>> in “Find and Replace”.
  3. Read the edited CSV file back into Excel.
  4. Copy the modified values into your original workbook, to preserve formatting.

Scott

Posted 2012-09-14T14:46:16.127

Reputation: 17 653

Thank you so much for your help but its a lengthy process. – Asim – 2012-09-24T14:47:16.650

1And you believe that a 700+ character VBA routine is faster? – Scott – 2012-09-24T16:12:25.070

1@Scott It is if the code is provided for you. :) – Excellll – 2012-09-25T21:22:44.080