Home |
Search |
Today's Posts |
|
#1
![]() |
|||
|
|||
![]()
I've got a sheet with 2 columns - column A has multiple values in one cell
that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#2
![]() |
|||
|
|||
![]()
I don't think you can do this with a formula. You would probably need a
fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#3
![]() |
|||
|
|||
![]()
Here's an example of such code
Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#4
![]() |
|||
|
|||
![]()
Nice, Bob! You're a braver man than I am <g.
Regards, Vasant "Bob Phillips" wrote in message ... Here's an example of such code Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#5
![]() |
|||
|
|||
![]()
Hi Vasant,
Split did the hard work, breaking the line up and providing the count :-) Regards Bob "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... Nice, Bob! You're a braver man than I am <g. Regards, Vasant "Bob Phillips" wrote in message ... Here's an example of such code Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#6
![]() |
|||
|
|||
![]()
Bob,
Once again - you are the macro maestro! If I need to add columns to the sheet, how do I add them in the macro? Thanks again! "Bob Phillips" wrote: Here's an example of such code Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#7
![]() |
|||
|
|||
![]()
Do you mean that you want to insert some new blank columns? If so, how many,
and in front of which column? Also, is this related to the previous question, in that it needs to tie in with that code, or a separate question? -- HTH RP (remove nothere from the email address if mailing direct) "adin" wrote in message ... Bob, Once again - you are the macro maestro! If I need to add columns to the sheet, how do I add them in the macro? Thanks again! "Bob Phillips" wrote: Here's an example of such code Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
#8
![]() |
|||
|
|||
![]()
Bob,
No blank columns - just more. In this case, you've got 4 or 5 total columns, and only one of them has the carriage returns - the rest are fine, but you want them all lined up together with the carriage return breaks that your macro creates. Adin "Bob Phillips" wrote: Do you mean that you want to insert some new blank columns? If so, how many, and in front of which column? Also, is this related to the previous question, in that it needs to tie in with that code, or a separate question? -- HTH RP (remove nothere from the email address if mailing direct) "adin" wrote in message ... Bob, Once again - you are the macro maestro! If I need to add columns to the sheet, how do I add them in the macro? Thanks again! "Bob Phillips" wrote: Here's an example of such code Sub FormatData() Dim cLastRow As Long Dim i As Long, j As Long Dim cLines As Long Dim aryItems cLastRow = Cells(Rows.Count, "A").End(xlUp).Row For i = cLastRow To 1 Step -1 aryItems = Split(Cells(i, "A").Value, Chr(10)) cLines = LBound(aryItems) + UBound(aryItems) If cLines 1 Then Cells(i + 1, "A").Resize(cLines).EntireRow.Insert For j = UBound(aryItems) To LBound(aryItems) Step -1 Cells(i + j, "A").Value = aryItems(j) Cells(i + j, "B").Value = Cells(i, "B").Value Next j End If Next i End Sub -- HTH RP (remove nothere from the email address if mailing direct) "Vasant Nanavati" <vasantn *AT* aol *DOT* com wrote in message ... I don't think you can do this with a formula. You would probably need a fairly involved macro. You would need to count the number of line breaks in each cell in column A, add that many rows below each cell, split the string, remove the line breaks, and copy the column B information into the new rows. Not difficult, but quite tedious. -- Vasant "adin" wrote in message ... I've got a sheet with 2 columns - column A has multiple values in one cell that are separated by carriage returns, and column B next to it has only one value per cell. I'd like to not only strip out these carriage returns, but also (the fun part) add rows for each value and maintain the reference to the column next to it. Example: A1 looks like this: Milk Eggs Juice B1 looks like this: Food I'd like A1 to contain the value "Milk" and B1 to contain "Food". A2 should contain "Eggs" and B2 should contain "Food". C1 should say "Juice", and C2 should say "Food". You get the idea. Thanks, Adin |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
how to find replace text or symbol with carriage return | New Users to Excel | |||
How to insert carriage return in the middle of a text formula to . | Excel Discussion (Misc queries) | |||
Carriage Return in Excel | Excel Discussion (Misc queries) | |||
automatic carriage return | Excel Worksheet Functions | |||
Carriage return in macros | Excel Worksheet Functions |