Separating Values using "|" as delimiter

hrithik

Active Member
Joined
Jul 26, 2010
Messages
336
Currently I have data arranged in this format:

<TABLE style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; BORDER-COLLAPSE: collapse; DIRECTION: ltr; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid" border=1 cellSpacing=0 cellPadding=0 valign="top"><TBODY><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Qty
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.979in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Price
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 1.183in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Total
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">15|25
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.979in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">33.00|33.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 1.183in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">495.00|825.00
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
21
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.979in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
27
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 1.183in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
567
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">|1
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.979in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">|10.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 1.183in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">|10.00
</TD></TR></TBODY></TABLE>

The "|" is a delimiter that separates 2 distinct values, value before '|' is "ABC" and value after '|' is "XYZ"; If no '|' symbol is present then it is "ABC".

I'm trying to write a macro to arrange this data as shown below (on a different sheet):


<TABLE style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; BORDER-COLLAPSE: collapse; DIRECTION: ltr; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid" border=1 cellSpacing=0 cellPadding=0 valign="top"><TBODY><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.831in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> *ABC*
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.718in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> *XYZ*
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.677in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Qty
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.831in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Price
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Total
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Qty
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.718in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Price
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.677in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">Total
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 15
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.831in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 33.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 495.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 25
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.718in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 33.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.677in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 825.00
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
21
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.831in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
27
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
567
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.718in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.677in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD></TR><TR><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.831in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt">
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.667in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 1
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.718in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 10.00
</TD><TD style="BORDER-BOTTOM: #a3a3a3 1pt solid; BORDER-LEFT: #a3a3a3 1pt solid; PADDING-BOTTOM: 4pt; PADDING-LEFT: 4pt; WIDTH: 0.677in; PADDING-RIGHT: 4pt; VERTICAL-ALIGN: top; BORDER-TOP: #a3a3a3 1pt solid; BORDER-RIGHT: #a3a3a3 1pt solid; PADDING-TOP: 4pt"> 10.00
</TD></TR></TBODY></TABLE>

no success so far; experts please suggest ways to achieve this....thanks!
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Try this in the ThisWorkbook module
There is a Select Case statement to test the position of the deliminator. This determines the output.

Edit the sheet names accordingly.

Code:
[COLOR=darkblue]Sub[/COLOR] test()
   [COLOR=darkblue]Dim[/COLOR] rw [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
   [COLOR=darkblue]Dim[/COLOR] col [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
   [COLOR=darkblue]Dim[/COLOR] iPos [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Integer[/COLOR]
   [COLOR=darkblue]Dim[/COLOR] ws1 [COLOR=darkblue]As[/COLOR] Worksheet
   [COLOR=darkblue]Dim[/COLOR] ws2 [COLOR=darkblue]As[/COLOR] Worksheet
   [COLOR=darkblue]Dim[/COLOR] str [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]String[/COLOR]
 
   [COLOR=darkblue]Set[/COLOR] ws1 = Sheets("[COLOR=red]Sheet1[/COLOR]")
   [COLOR=darkblue]Set[/COLOR] ws2 = Sheets("[COLOR=red]Sheet2[/COLOR]")
 
   [COLOR=darkblue]For[/COLOR] rw = 2 [COLOR=darkblue]To[/COLOR] ws1.Range("A" & Rows.Count).End(xlUp).Row
      [COLOR=darkblue]For[/COLOR] col = 1 [COLOR=darkblue]To[/COLOR] 3
         str = ws1.Cells(rw, col).Value
         iPos = InStr(str, "|")  [COLOR=green]'get the position of the deliminator[/COLOR]
 
         [COLOR=darkblue]Select[/COLOR] [COLOR=darkblue]Case[/COLOR] iPos
            [COLOR=darkblue]Case[/COLOR] [COLOR=darkblue]Is[/COLOR] = 0
               ws2.Cells(rw + 1, col).Value = str
            [COLOR=darkblue]Case[/COLOR] [COLOR=darkblue]Is[/COLOR] = 1
               ws2.Cells(rw + 1, col + 3).Value = Right(str, Len(str) - 1)
            [COLOR=darkblue]Case[/COLOR] [COLOR=darkblue]Else[/COLOR]
               ws2.Cells(rw + 1, col).Value = Left(str, iPos - 1)
               ws2.Cells(rw + 1, col + 3).Value = Right(str, Len(str) - iPos)
         [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Select[/COLOR]
      [COLOR=darkblue]Next[/COLOR] col
   [COLOR=darkblue]Next[/COLOR] rw
 
   [COLOR=darkblue]Set[/COLOR] ws1 = [COLOR=darkblue]Nothing[/COLOR]
   [COLOR=darkblue]Set[/COLOR] ws2 = [COLOR=darkblue]Nothing[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]
 
Upvote 0
thanks @bertie, the macro works great!

the only problem is that there could be upto 50,000 lines in "Sheet1", this makes the macro run slow. is there a way to make it fast for such cases?
 
Upvote 0
Before the "For...next" loop:
Code:
Application.screenupdating = false


After the next statement:
Code:
Application.ScreenUpdating = true

Run it, go to lunch :p
 
Upvote 0
hrithik,


Sample raw data in worksheet Sheet1:


Excel Workbook
ABC
1QtyPriceTotal
215|2533.00|33.00495.00|825.00
32127567
4|1|10.00|10.00
5
Sheet1





After the macro in a new worksheet Results:


Excel Workbook
ABCDEF
1*ABC**XYZ*
2QtyPriceTotalQtyPriceTotal
315334952533825
42127567
511010
6
Results





Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).


1. Copy the below code, by highlighting the code and pressing the keys CTRL + C
2. Open your workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code by pressing the keys CTRL + V
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel, open the workbook, and press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.


Code:
Option Explicit
Sub ReorgData()
' hiker95, 03/21/2011
' http://www.mrexcel.com/forum/showthread.php?t=537653
Dim w1 As Worksheet, wR As Worksheet
Dim LR As Long, a As Long, aa As Long, NR As Long
Dim Sp
Application.ScreenUpdating = False
Set w1 = Worksheets("Sheet1")
If Not Evaluate("ISREF(Results!A1)") Then Worksheets.Add(After:=w1).Name = "Results"
Set wR = Worksheets("Results")
wR.UsedRange.Clear
Set wR = Worksheets("Results")
wR.Range("B1:E1") = [{"*ABC*","","","*XYZ*"}]
wR.Range("A2:C2") = [{"Qty","Price","Total"}]
wR.Range("D2:F2") = [{"Qty","Price","Total"}]
LR = w1.Cells(Rows.Count, 1).End(xlUp).Row
For a = 2 To LR Step 1
  NR = a + 1
  For aa = 1 To 3 Step 1
    If InStr(w1.Cells(a, aa), "|") = 0 Then
      wR.Cells(NR, aa).Value = w1.Cells(a, aa)
    Else
      Sp = Split(w1.Cells(a, aa), "|")
      If Sp(0) = "" Then
        wR.Cells(NR, aa + 3).Value = Sp(1)
      Else
        wR.Cells(NR, aa).Value = Sp(0)
        wR.Cells(NR, aa + 3).Value = Sp(1)
      End If
    End If
  Next aa
Next a
wR.Activate
Application.ScreenUpdating = True
End Sub


Then run the ReorgData macro.
 
Upvote 0
hrithik,


Sample raw data in worksheet Sheet1:


Excel Workbook
ABC
1QtyPriceTotal
215|2533.00|33.00495.00|825.00
32127567
4|1|10.00|10.00
5
Sheet1





After the macro in a new worksheet Results:


Excel Workbook
ABCDEF
1*ABC**XYZ*
2QtyPriceTotalQtyPriceTotal
31533.00495.002533.00825.00
42127567
5110.0010.00
6
Results





Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).


Code:
Option Explicit
Sub ReorgData()
' hiker95, 03/21/2011
' http://www.mrexcel.com/forum/showthread.php?t=537653
Dim w1 As Worksheet, wR As Worksheet
Dim LR As Long, a As Long, aa As Long, NR As Long
Dim Sp
Application.ScreenUpdating = False
Set w1 = Worksheets("Sheet1")
If Not Evaluate("ISREF(Results!A1)") Then Worksheets.Add(After:=w1).Name = "Results"
Set wR = Worksheets("Results")
wR.UsedRange.Clear
Set wR = Worksheets("Results")
wR.Range("B1:E1") = [{"*ABC*","","","*XYZ*"}]
wR.Range("A2:C2") = [{"Qty","Price","Total"}]
wR.Range("D2:F2") = [{"Qty","Price","Total"}]
LR = w1.Cells(Rows.Count, 1).End(xlUp).Row
For a = 2 To LR Step 1
  NR = a + 1
  For aa = 1 To 3 Step 1
    If InStr(w1.Cells(a, aa), "|") = 0 Then
      wR.Cells(NR, aa) = w1.Cells(a, aa)
    Else
      Sp = Split(w1.Cells(a, aa), "|")
      If Sp(0) = "" Then
        With wR.Cells(NR, aa + 3)
          .NumberFormat = "@"
          .Value = Sp(1)
        End With
      Else
        With wR.Cells(NR, aa)
          .NumberFormat = "@"
          .Value = Sp(0)
        End With
        With wR.Cells(NR, aa + 3)
          .NumberFormat = "@"
          .Value = Sp(1)
        End With
      End If
    End If
  Next aa
Next a
wR.Activate
Application.ScreenUpdating = True
End Sub


Then run the updated ReorgData macro.
 
Upvote 0
Have you considered using formula?
Copy in the formula.
Highlight D2:I2
Double click the handle bar in the bottom right of the highlighted area to copy the formula.
Then just copy and paste the values.

Sheet1

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Arial,Arial; FONT-SIZE: 10pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 100px"><COL style="WIDTH: 114px"><COL style="WIDTH: 124px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD><TD>I</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</TD><TD style="FONT-FAMILY: Calibri">Qty</TD><TD style="FONT-FAMILY: Calibri">Price</TD><TD style="FONT-FAMILY: Calibri">Total</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</TD><TD style="FONT-FAMILY: Calibri">15|25</TD><TD style="FONT-FAMILY: Calibri">33.00|33.00</TD><TD style="FONT-FAMILY: Calibri">495.00|825.00</TD><TD style="TEXT-ALIGN: right">15</TD><TD style="TEXT-ALIGN: right">33.00</TD><TD style="TEXT-ALIGN: right">495.00</TD><TD style="TEXT-ALIGN: right">25</TD><TD style="TEXT-ALIGN: right">33.00</TD><TD style="TEXT-ALIGN: right">825.00</TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM-STYLE: groove; BORDER-BOTTOM-COLOR: #00ff00; BORDER-RIGHT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-TOP-STYLE: groove; COLOR: #000000; BORDER-RIGHT-COLOR: #00ff00; FONT-SIZE: 10pt; BORDER-LEFT-STYLE: groove; BORDER-LEFT-COLOR: #00ff00"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-FAMILY: Arial; FONT-SIZE: 9pt" border=1 cellSpacing=0 cellPadding=2><TBODY><TR style="BACKGROUND-COLOR: #cacaca; FONT-SIZE: 10pt"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>D2</TD><TD>=IF(ISERROR(FIND("|",A2)),A2,IF(FIND("|",A2)=1,"",LEFT(A2,FIND("|",A2)-1)))</TD></TR><TR><TD>E2</TD><TD>=IF(ISERROR(FIND("|",B2)),B2,IF(FIND("|",B2)=1,"",LEFT(B2,FIND("|",B2)-1)))</TD></TR><TR><TD>F2</TD><TD>=IF(ISERROR(FIND("|",C2)),C2,IF(FIND("|",C2)=1,"",LEFT(C2,FIND("|",C2)-1)))</TD></TR><TR><TD>G2</TD><TD>=IF(ISERROR(FIND("|",A2)),"",IF(FIND("|",A2)=1,RIGHT(A2,LEN(A2)-FIND("|",A2)),RIGHT(A2,LEN(A2)-FIND("|",A2))))</TD></TR><TR><TD>H2</TD><TD>=IF(ISERROR(FIND("|",B2)),"",IF(FIND("|",B2)=1,RIGHT(B2,LEN(B2)-FIND("|",B2)),RIGHT(B2,LEN(B2)-FIND("|",B2))))</TD></TR><TR><TD>I2</TD><TD>=IF(ISERROR(FIND("|",C2)),"",IF(FIND("|",C2)=1,RIGHT(C2,LEN(C2)-FIND("|",C2)),RIGHT(C2,LEN(C2)-FIND("|",C2))))</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
 
Upvote 0

Forum statistics

Threads
1,224,590
Messages
6,179,753
Members
452,940
Latest member
rootytrip

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