New row for comma-separated values

Gain

New Member
Joined
Jun 4, 2012
Messages
45
Hi,

A sample spreadsheet of what I have is provided below:

ID NUMBERCHEMICAL NAMEHAZARDVALUE
1chemical acarcinogenrecognized
1chemical aRespiratory, blood, kidneysuspected
2chemical bimmunotoxic, carcinogensuspected
3chemical cliver, carcinogenrecognized
4chemical dkidneyrecognized
4chemical dneurotoxicsuspected

<tbody>
</tbody>

Only the words 'recognized' or 'suspected' can be entered into the VALUE column and hazards that are either recognized or suspected of being caused by that chemical in that row are listed in the HAZARD column. I need to have a separate entry for each hazard, like the following table, using the same chemicals as above:

CAS NUMBERCHEMICAL NAMEHAZARDVALUE
1chemical acarcinogenrecognized
1chemical arespiratorysuspected
1chemical abloodsuspected
1chemical akidneysuspected
2chemical bimmunotoxicsuspected
2chemical bcarcinogensuspected
3chemical cliverrecognized
3 chemical ccarcinogenrecognized
4chemical d kidneyrecognized
4chemical dneurotoxicsuspected

<tbody>
</tbody>

How can I create a new row for each comma-separated hazard?

Thank you in advance :)
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Gain,


Sample raw data:


Excel Workbook
ABCD
1ID NUMBERCHEMICAL NAMEHAZARDVALUE
21chemical acarcinogenrecognized
31chemical aRespiratory, blood, kidneysuspected
42chemical bimmunotoxic, carcinogensuspected
53chemical cliver, carcinogenrecognized
64chemical dkidneyrecognized
74chemical dneurotoxicsuspected
8
9
10
11
12
Sheet1





After the macro:


Excel Workbook
ABCD
1ID NUMBERCHEMICAL NAMEHAZARDVALUE
21chemical acarcinogenrecognized
31chemical aRespiratorysuspected
41chemical abloodsuspected
51chemical akidneysuspected
62chemical bimmunotoxicsuspected
72chemical bcarcinogensuspected
83chemical cliverrecognized
93chemical ccarcinogenrecognized
104chemical dkidneyrecognized
114chemical dneurotoxicsuspected
12
Sheet1





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, 06/20/2012
' http://www.mrexcel.com/forum/showthread.php?641962-New-row-for-comma-separated-values
Dim lr As Long, r As Long, Sp
Application.ScreenUpdating = False
lr = Cells(Rows.Count, 1).End(xlUp).Row
For r = lr To 2 Step -1
  If InStr(Cells(r, 3), ",") > 0 Then
    Sp = Split(Cells(r, 3), ", ")
    Rows(r + 1).Resize(UBound(Sp)).Insert
    Rows(r + 1).Resize(UBound(Sp)).Value = Rows(r).Value
    Cells(r, 3).Resize(UBound(Sp) + 1).Value = Application.Transpose(Sp)
  End If
Next r
Application.ScreenUpdating = True
End Sub


Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm


Then run the ReorgData macro.
 
Upvote 0

Forum statistics

Threads
1,215,064
Messages
6,122,939
Members
449,094
Latest member
teemeren

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