Text formula - reverse word

Kamolga

Well-known Member
Joined
Jan 28, 2015
Messages
1,185
Hi,

I face an issue with imported text over a few hundreds lines:

One cell (A1) is like this
Code:
Belgium BE » Flanders VLG » Antwerp Province VAN » Arrondissement of Antwerp 11 » Antwerpen 11002
and I wish to have
Code:
 Antwerpen (11002), [COLOR=#222222][FONT=Verdana]Arrondissement of Antwerp (11), [/FONT][/COLOR][COLOR=#222222][FONT=Verdana][COLOR=#222222][FONT=Verdana]Antwerp Province (VAN), [/FONT][/COLOR][/FONT][/COLOR][COLOR=#222222][FONT=Verdana][COLOR=#222222][FONT=Verdana][COLOR=#222222][FONT=Verdana]Flanders (VLG), Belgium (BE)[/FONT][/COLOR][/FONT][/COLOR][/FONT][/COLOR]

So far I have succeeded in getting
Code:
Belgium BE,Flanders VLG,Antwerp Province VAN,Arrondissement of Antwerp 11,Antwerpen 11002
through
Code:
=SUBSTITUTE(A1," » ",",")
but how can I reverse it?
 
Last edited:

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
here is with PowerQuery (Get&Transform) but I think this is not representative example, anyway:

src
Belgium BE » Flanders VLG » Antwerp Province VAN » Arrondissement of Antwerp 11 » Antwerpen 11002
Result
Antwerpen (11002), Arrondissement of Antwerp (11), Antwerp Province (VAN), Flanders (VLG), Belgium (BE)

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Split = Table.ExpandListColumn(Table.TransformColumns(Source, {{"src", Splitter.SplitTextByDelimiter(" » ", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "src"),
    ExtractAfter = Table.AddColumn(Split, "Text After Delimiter", each Text.AfterDelimiter([src], " ", {0, RelativePosition.FromEnd}), type text),
    ExtractBefore = Table.TransformColumns(ExtractAfter, {{"src", each Text.BeforeDelimiter(_, " ", {0, RelativePosition.FromEnd}), type text}}),
    Prefix = Table.TransformColumns(ExtractBefore, {{"Text After Delimiter", each "(" & _, type text}}),
    Suffix = Table.TransformColumns(Prefix, {{"Text After Delimiter", each _ & ")", type text}}),
    Merge = Table.CombineColumns(Suffix,{"src", "Text After Delimiter"},Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"Merged"),
    Reverse = Table.ReverseRows(Merge),
    Transpose = Table.Transpose(Reverse),
    Result = Table.CombineColumns(Transpose,{"Column1", "Column2", "Column3", "Column4", "Column5"},Combiner.CombineTextByDelimiter(", ", QuoteStyle.None),"Result")
in
    Result[/SIZE]
 
Upvote 0
This is finally how I did it:
Since the number of parts was variable, I had more ifs that I could handle. Instead I used VBA to split my string at each "
» " into an array. With Ubound I can easily know how many parts I have (n in follow case) and reverse them.
Then I split each part of the array into a left and a right string (the right to be placed into parenthesis).
I end wit a function :
Code:
Public Function RevText(Rng As Range) As String
[/FONT][/COLOR][COLOR=#006400][FONT=monospace]'Split input[/FONT][/COLOR][COLOR=#333333][FONT=monospace]
Dim iStr As String: iStr = Trim(Rng)
Dim iArray() As String: iArray = Split(iStr, " [COLOR=#333333][FONT=monospace]» [/FONT][/COLOR]")
'How many parts?
Dim n As Long: n = UBound(iArray)
[/FONT][/COLOR][COLOR=#006400][FONT=monospace]'Output (left and right text of each string)[/FONT][/COLOR][COLOR=#333333][FONT=monospace]
Dim lStr, rStr As String
Dim j As Long
    For j = n To 0 Step -1
     lStr = Left(iArray(j), InStrRev(iArray(j), " "))
     rStr = Right(iArray(j), Len(iArray(j)) - (InStrRev(iArray(j), " ")))
        If j = n Then
           RevText = lStr & "(" & rStr & ")"
          Else
           RevText = RevText & "," & lStr & "(" & rStr & ")"
        End If
    Next j
End Function
[/FONT][/COLOR]

and so =RevText(A1) gives me the result I was looking for.

 
Last edited:
Upvote 0
I'm a little late but having done it, I'll post it...

Code:
Public Function ReverseTxt(OrigTxt As Range) As String
Dim MyArray
Dim MyArray2
MyArray = Split(Trim(OrigTxt), " » ")
u = UBound(MyArray)
For i = 0 To u
MyArray2 = Split(MyArray(i), " ")
u2 = UBound(MyArray2)
MyArray2(u2) = "(" & MyArray2(u2) & ")"
MyArray(i) = Join(MyArray2, " ")
Next i
ReDim MyArray2(0 To u)
For i = 0 To u
MyArray2(i) = MyArray(u - i)
Next i
ReverseTxt = Join(MyArray2, ", ")
End Function
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,987
Messages
6,122,614
Members
449,090
Latest member
vivek chauhan

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