Index, match, if to fill in 2D table values

excelsior00

New Member
Joined
Apr 4, 2022
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi,

I am trying to consolidate a table of somewhat binary information. I assume I need to do a mix of indexing, matching, and if functions, but getting a little bit lost. Here is what I'm trying to accomplish (blue is what I have, orange is what I'm trying to make):

1649175205586.png


As you can see, anytime a 1 appears, I'd like to return the associated color--assigning it to the proper animal and offspring--somewhat consolidating the table.

Any help would be much appreciated!
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Using Power Query

Book1
ABCDEF
1ANIMALCOLOROFFSPRING AOFSPRING BOFFSPRING COFFSPRING D
2DogBlack0010
3DogSpots1000
4CatTan0100
5BirdBrown1000
6BirdBlack0010
7BirdTan0001
8BirdSpots0100
9FishSpots0001
10FishBlack1000
11
12
13ANIMALOFFSPRING AOFSPRING BOFFSPRING COFFSPRING D
14BirdBrownSpotsBlackTan
15CatTan
16DogSpotsBlack
17FishBlackSpots
Sheet4


Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Unpivot = Table.UnpivotOtherColumns(Source, {"ANIMAL", "COLOR"}, "Attribute", "Value"),
    Filter = Table.SelectRows(Unpivot, each ([Value] = 1)),
    Pivot = Table.Pivot(Filter, List.Distinct(Filter[Attribute]), "Attribute", "COLOR"),
    RC = Table.RemoveColumns(Pivot,{"Value"}),
    Reorder = Table.ReorderColumns(RC,{"ANIMAL", "OFFSPRING A", "OFSPRING B", "OFFSPRING C", "OFFSPRING D"})
in
    Reorder
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,150
Members
448,552
Latest member
WORKINGWITHNOLEADER

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