Convert strings

hanasamo

Board Regular
Joined
May 31, 2005
Messages
83
A B
PEK BEIJING
SHA SHANGHAI
CAN GUANGZHOU

In sheet1 I have a database like the above, the column A is city code, and the column B contains theie corresponding city name.

In sheet2 there are citypairs as follows:
PEK-SHA
PEK-SHA-PEK
PEK-SHA-CAN-SHA
PEK-SHA-CAN-SHA-PEK

What I want to do is convert the citypairs into their actual city names, for example, PEK-SHA-CAN-SHA, I want it to be BEIJING-SHANGHAI-GUANGZHOU-SHANGHAI. I have tried a several time by using functions, mid, left,right,index,match,if, but I failed because it's too long to be kept correct. Can you experts tell me how to do it, VBA and functions are both fine. Thanks in advance.
 

al_b_cnu

Well-known Member
Joined
Jul 18, 2003
Messages
4,493
Hi,

A VBA UDF solution, assuming you have Excel 2002 or higher:
Code:
Function CityCodes(ByVal Codes As String, ByVal CodeTable As Range)
Dim iPtr As Integer
Dim rTable As Range, rBase As Range
Dim vElements As Variant, vResult As Variant
Dim wsTable As Worksheet

Set wsTable = Sheets(CodeTable.Parent.Name)
Set rBase = wsTable.Range(Cells(CodeTable.Row, CodeTable.Column).Address)

Set rTable = wsTable.Range(rBase.Address, _
                           wsTable.Cells(CodeTable.Row + CodeTable.Rows.Count - 1, _
                                         CodeTable.Column).Address)
vElements = Split(Codes, "-")
For iPtr = 0 To UBound(vElements)
    vResult = "*"
    On Error Resume Next
    vResult = WorksheetFunction.Match(vElements(iPtr), rTable, 0)
    On Error GoTo 0
    If IsNumeric(vResult) = True Then
        vElements(iPtr) = rBase.Offset(vResult - 1, 1).Text
    End If
Next iPtr
CityCodes = Join(vElements, "-")
End Function
Book1
ABCD
1CodeCity
2PEKBEIJING
3SHASHANGHAI
4CANGUANGZHOU
Sheet1


Formula in B2 & copied down is =citycodes(A2,Sheet1!A:B)
 

jindon

MrExcel MVP
Joined
Aug 21, 2004
Messages
16,995
Hi
using Replace Method
Code:
Sub test()
Dim a, i As Long
a = Sheets("sheet1").Range("a1").CurrentRegion.Resize(, 2).Value
For i = 1 To UBound(a, 1)
    With Sheets("sheet2")
        .Columns("a").Replace what:=a(i, 1), replacement:=a(i, 2)
    End With
Next
Erase a
End Sub
 

Forum statistics

Threads
1,078,535
Messages
5,341,025
Members
399,411
Latest member
Bryanhj

Some videos you may like

This Week's Hot Topics

  • Problem with Radio Button's format control
    I am creating an employee evaluation template (a sample is below) Column A is the category Column B, C D, E and F will be ratings (unacceptable...
  • Last Display on userform to a Listbox
    [CODE=vba] lstdisplay.ColumnCount = 15 lstdisplay.RowSource = "A1:O600000" [/CODE] So when i do this it Displays everything on the sheet i am...
  • Rename and move files to a new location
    Dear all, I have an excel file with the following information. The actual file name is at column A but i want to rename it using the following...
  • Help with True/False Formula
    Hello! Am stumped how to fix this formula, in which my result returns 'True', but it should return False. =IF(AG2=True...
  • Clear extra characters from a provided range of cells
    Dear All, I have following code which gives me desired output to remove extra characters from a provided range. But it takes too much time when...
  • Help with Current and highest streaks
    Hi there, I've just joined the forum and this is my first post. I've already spent quite a bit of time searching the net and this forum for a...
Top