Create a list from another list but removing gaps

johnwhite

New Member
Joined
Sep 25, 2006
Messages
27
Hi there,

i have a sheet which looks like:

....|A|B|C - Comment|D - If A & B = x then write name
------------------------------------------------------------------
|1 |x|x| Grape........ | Grape
|2 |x| | Banana....... |[empty]
|3 | |x| Apple........ | [empty]
|4 |x|x| Strawberry | Strawberry

What I would like to be able to do on another sheet in the workbook is to list out all the fruits from column D without blanks.

i.e. current my output would look like:

Grape
[empty]
[empty]
Strawberry

and ideally i would like it to look like:

Grape
Strawberry

It's actually a much bigger sheet, but i've simplified it here to make the problem clear (or at least I think I have!). Ideally i'd like a formula rather than vb based solution if possible.

Thanks all for your help, much appreciated!

John
 
Last edited:

Some videos you may like

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.

johnwhite

New Member
Joined
Sep 25, 2006
Messages
27
Hi steve,

thanks for the response. I suspect looking again my description wasn't too hot (sorry...)

I'm actually looking for a formula which will automate it, so that I don't have to go in and do each time. effectively on page one i have a list:

Grape
[empty]
[empty]
Strawberry

and on page two i'd like a list

Grape
Strawberry

What i'd really like is some excel wizardy which identifies when the list on page one changes and automatically changes the list on page two. ie if we add another 'fruit'

page one:

Grape
banana
[empty]
strawberry

page two automatically changes to

Grape
banana
strawberry

I'm guessing the formula would be in the cells on page two and in plain english would read "look down the list on page one until you find the first non-blank cell and show it here", then "look down the list on page one until you find the next non-blank cell and show it here" hope this clears things up and thanks again for your help! And apologies for my terrible ability to communicate in excel...

John
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,192
Sheet1, A1:D4, with the headers included...

<TABLE style="WIDTH: 202pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=270><COLGROUP><COL style="WIDTH: 48pt" span=2 width=64><COL style="WIDTH: 53pt; mso-width-source: userset; mso-width-alt: 2531" span=2 width=71><TBODY><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 48pt; HEIGHT: 14.4pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19 width=64></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 48pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 width=64></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 53pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 width=71>List-1</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 53pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 width=71>List-2</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Grape</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Grape</TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Banana</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64></TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl63 height=19></TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Apple</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64></TD></TR><TR style="HEIGHT: 14.4pt" height=19><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 14.4pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 height=19>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>X</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Strawberry</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64>Strawberry</TD></TR></TBODY></TABLE>

Sheet2

A1, just enter:
Rich (BB code):
=COUNTIF(Sheet1!D2:D5,"?*")
A3, control+shift+enter, not just enter, and copy down:
Rich (BB code):
=IF(ROWS($A$3:A3)<=$A$1,INDEX(Sheet1!$D$2:$D$5,
   SMALL(IF(1-(Sheet1!$D$2:$D$5=""),ROW(Sheet1!$D$2:$D$5)-ROW(Sheet1!$D$2)+1),
    ROWS($A$3:A3))),"")
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,770
You could define these names
Name: dataRange
RefersTo: =Sheet1!$D$1:INDEX(Sheet1!$D:$D,MATCH("zzz",Sheet1!$C:$C),1)

Name: dataRangePlus
RefersTo: =Sheet1!$D$1:INDEX(Sheet1!$D:$D,ROWS(dataRange)+1,1)

Name: OneToN
RefersTo: =ROW(INDIRECT("1:"&ROWS(dataRange)))

The select a column-wise section of cells (like F1:F14) and enter the array formula.
=INDEX(dataRangePlus, SMALL(IF(LEN(dataRange), OneToN, ROWS(dataRange)+1), OneToN), 1)&""

This needs to be entered with Ctrl-Shift-Enter (Cmd+Return for Mac)
<table border=1 cellspacing=0>
<tr align="center" bgcolor=#A0A0A0><td width=25> <td width=25><b>A</b><td width=25><b>B</b><td width=25><b>C</b><td width=25><b>D</b><td width=25><b>E</b><td width=25><b>F</b></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>1</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Grape</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>2</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Banana<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Strawberry</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>3</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Apple<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Grape Two Two</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>4</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Strawberry</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>5</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF>Grape Two Two<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Grape</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>6</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Banana<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Strawberry</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>7</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Apple<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Grape</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>8</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC>Strawberry</tr>
<tr><td align="center" bgcolor=#A0A0A0><b>9</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>10</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Banana<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>11</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Apple<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>12</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>13</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF>Grape<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>14</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Banana<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FF99CC></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>15</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Apple<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF></tr>
<tr><td align="center" bgcolor=#A0A0A0><b>16</b><td align="left" bgcolor=#FFFFFF>x<td align="left" bgcolor=#FFFFFF>b<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF>Strawberry<td align="left" bgcolor=#FFFFFF><td align="left" bgcolor=#FFFFFF></tr>
</table>
 

johnwhite

New Member
Joined
Sep 25, 2006
Messages
27
Gentlemen,

two superb answers, thank you very much indeed. I have chosen to go with the first one, only by virtue of the fact I can just about understand it!

Much appreciated,

John
 

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,582
Messages
5,512,202
Members
408,885
Latest member
binduchekuri

This Week's Hot Topics

  • Sort code advice please
    Hi, I have the code below which im trying to edit but getting a little stuck. This was the original code which worked fine,columns A-F would sort...
  • SUMPRODUCT with nested If statement
    Hi everyone, Hope you're all well. I'm hoping someone will be able to point me in the right direction with a problem I'm having with a SUMPRODUCT...
  • VBA - simple sort is killing me!
    Hello all! This should be so easy, but not for me, apparently! I have a table of data that can be of varying lengths and widths. My current macro...
  • Compare Two Lists
    I have two Lists and I need to be able to Identify differences between them. List 100 comes from a workbook - the other is downloaded form the...
  • Formula that deducts points for each code I input.
    I am trying to create a formula that will have each student in my class start at 100 points and then for each code that I enter (PP for Poor...
  • Conditional formatting formula required for day of week and a value
    Hi, I have a really simple spreadsheet where column A is the date, column B is the activity total shown as a number and column C states the day of...
Top