Comma separate values into rows

Hiten_pan

New Member
Joined
Mar 13, 2018
Messages
24
I have data values which has values for eg: 9883;3883;45;567 which i want to convert into rows with use of formula. Plz advise.
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
It is in single cell, this data also has zeros in between the string which i want to ignore. The data with zero will look like 9883;3883;0;405;0;567
 
Upvote 0
Hi,

Here's a formula solution for what you described:


Book1
ABCD
19883;3883;45;5679883;3883;0;405;0;5679883;3883;45;5679883;3883;0;405;0;567
29883988398839883
33883388338833883
44540545405
5567567567567
Sheet33
Cell Formulas
RangeFormula
A2=TRIM(MID(SUBSTITUTE(";"&SUBSTITUTE(A$1,";0",""),";",REPT(" ",100)),ROW(A1)*100,100))
C2=TRIM(MID(SUBSTITUTE(";"&SUBSTITUTE(C$1,";0",""),";",REPT(" ",100)),ROW(C1)*100,100))+0


Use A2 formula if you don't need the result converted to a Real Number, use C2 formula if you do.
 
Upvote 0
In B2
9883;3883;45;567

In B3 then drag down

=IFERROR(0+TRIM(MID(SUBSTITUTE($B$2,";",REPT(" ",200)),1+200*(ROWS($B$2:$B2)-1),200)),"")
 
Upvote 0
Try this. This avoids 0 but it leaves cell BLANK.

=IFERROR(1/(1/(0+TRIM(MID(SUBSTITUTE($B$2,";",REPT(" ",200)),1+200*(ROWS($B$2:$B2)-1),200)))),"")

This formulas avoids 0 completely and other values are listed.

=IFERROR(0+TRIM(MID(SUBSTITUTE(SUBSTITUTE($B$2,"0;",""),";",REPT(" ",200)),1+200*(ROWS($B$2:$B2)-1),200)),"")
 
Last edited:
Upvote 0
to be more precise I have the following string
0;0;0;6160;1718;3191;3203;0;1

<tbody>
</tbody>
this should look like below:

6160
1718
3191
3203
1

<tbody>
</tbody><colgroup><col></colgroup>
 
Upvote 0

Forum statistics

Threads
1,214,784
Messages
6,121,535
Members
449,037
Latest member
tmmotairi

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