Method to Distribute a list to proper columns

sbawnh

Board Regular
Joined
Feb 25, 2019
Messages
50
Office Version
  1. 365
Platform
  1. Windows
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Type[/TD]
[TD]Date[/TD]
[TD]Dog[/TD]
[TD]Date[/TD]
[TD]Cat[/TD]
[TD]Date[/TD]
[/TR]
[TR]
[TD]Dog[/TD]
[TD]1/14/2016[/TD]
[TD]Dog[/TD]
[TD]1/14/2016[/TD]
[TD]Cat[/TD]
[TD]7/8/2018[/TD]
[/TR]
[TR]
[TD]Dog[/TD]
[TD]5/8/2017[/TD]
[TD]Dog[/TD]
[TD]5/8/2017[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Cat[/TD]
[TD]7/8/2018[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Given Column A:B, I want to distribute the dog data to the dog columns {C,D} and the cat data to the cat columns {E,F}.

Any ideas?

Thanks!!
 
Last edited:

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Try this

Code:
Sub [COLOR=#0000ff]Distribute[/COLOR]()
    Dim c As Range, f As Range
    For Each c In Range("A2", Range("A" & Rows.Count).End(xlUp))
        Set f = Rows(1).Find(c.Value, LookIn:=xlValues, lookat:=xlWhole)
        If Not f Is Nothing Then
            Cells(Cells(Rows.Count, f.Column).End(xlUp)(2).Row, f.Column).Resize(1, 2).Value = c.Resize(1, 2).Value
        End If
    Next
End Sub

INSERT A MODULE
Press Alt-F11 to open the VBA editor. From the menu select Insert > Module. On the sheet that opens, paste the code previous.
Close the editor (press Alt-Q). From Excel, press Alt-F8 to open the macro selector, and select Distribute and press Run.
 
Upvote 0
Lovely solution. I really appreciate your time! Thank you.

BTW, For my sanity, This cannot be done with a formula?
I was hoping some combination of Index/matches with countifs could make it work, but I haven't been successful.
 
Upvote 0
This is so useful!

This Distributes A:A and brings along B:B to the new destination.

What if A:A is C:C and I want to bring along A:A and B:B instead of B:B?

(The two columns to the left instead of the column to the right)
 
Upvote 0
Lovely solution. I really appreciate your time! Thank you.

BTW, For my sanity, This cannot be done with a formula?
I was hoping some combination of Index/matches with countifs could make it work, but I haven't been successful.

Array formulas

<br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><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></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Type</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Dog</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Cat</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">mar</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">date</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >Dog</td><td style="text-align:right; ">04/01/2019</td><td >Dog</td><td style="text-align:right; ">04/01/2019</td><td >Dog</td><td style="text-align:right; ">04/01/2019</td><td >Dog</td><td style="text-align:right; ">04/01/2019</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >Dog</td><td style="text-align:right; ">05/08/2017</td><td >Dog</td><td style="text-align:right; ">05/08/2017</td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >Cat</td><td style="text-align:right; ">07/08/2018</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >mar</td><td style="text-align:right; ">06/05/2019</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >C2</td><td >{=IFERROR(INDEX($A$1:$A$5, SMALL(IF($A$2:$A$5=C$1, ROW()), ROW()-1)),"")}</td></tr><tr><td >D2</td><td >{=IFERROR(INDEX($B$1:$B$5, SMALL(IF($A$2:$A$5=C$1, ROW()), ROW()-1)),"")}</td></tr><tr><td >E2</td><td >{=IFERROR(INDEX($A$1:$A$5, SMALL(IF($A$2:$A$5=E$1, ROW()), ROW()-1)),"")}</td></tr><tr><td >F2</td><td >{=IFERROR(INDEX($B$1:$B$5, SMALL(IF($A$2:$A$5=E$1, ROW()), ROW()-1)),"")}</td></tr><tr><td >G2</td><td >{=IFERROR(INDEX($A$1:$A$5, SMALL(IF($A$2:$A$5=G$1, ROW()), ROW()-1)),"")}</td></tr><tr><td >H2</td><td >{=IFERROR(INDEX($B$1:$B$5, SMALL(IF($A$2:$A$5=G$1, ROW()), ROW()-1)),"")}</td></tr></table></td></tr></table>
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0
Here is another way with non-array formulas. You will need Excel 2010 or later for the AGGREGATE function.
Copy formulas down as needed.
Excel Workbook
ABCDEF
1TypeDateDogDateCatDate
2Dog1/14/2016Dog1/14/2016Cat7/8/2018
3Dog5/8/2017Dog5/8/2017
4Cat7/8/2018
Sheet
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,176
Members
453,021
Latest member
Justyna P

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