Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
Anonymous
Not applicable

merge different tables into one hierarchy table

Hi community,

could you help me merging these "available tables" into the "prefered table"?

 

The problem is, that we have multiple outcome for a single ID and aswell multiple actions with action costs for that single ID. The user needs a table, which only shows him the information related to the different IDs, as you see it in the "ID_table". Meaining we don't want a table which for example lists ID A1 multiple times for each outcome etc. 

 

Is it even possible to find a solution in this data model?

 

AlexanderZa_0-1599643929627.png

 

Thank you for your help!

1 ACCEPTED SOLUTION
v-alq-msft
Community Support
Community Support

Hi, @Anonymous 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Key_Table:

e1.png

 

Action_Table:

e2.png

 

Outcome_Table:

e3.png

 

I assume that you want to show the expected result in the table visual. You may create a calculated table as below.

Table = 
ADDCOLUMNS(
    DISTINCT(Key_Table[ID]),
    "Key",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Key_Table[Key]),
            FILTER(
                Key_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Key],
        "
        "
    ),
    "Action",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Action_Table[Action]),
            FILTER(
                Action_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Action],
        "
        "
    ),
    "Action_Cost",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Action_Table[Action_Cost]),
            FILTER(
                Action_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Action_Cost],
        "
        "
    ),
    "Outcome",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Outcome_Table[Outcome]),
            FILTER(
                Outcome_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Outcome],
        "
        "
    )
)

 

Result:

e4.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-alq-msft
Community Support
Community Support

Hi, @Anonymous 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Key_Table:

e1.png

 

Action_Table:

e2.png

 

Outcome_Table:

e3.png

 

I assume that you want to show the expected result in the table visual. You may create a calculated table as below.

Table = 
ADDCOLUMNS(
    DISTINCT(Key_Table[ID]),
    "Key",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Key_Table[Key]),
            FILTER(
                Key_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Key],
        "
        "
    ),
    "Action",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Action_Table[Action]),
            FILTER(
                Action_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Action],
        "
        "
    ),
    "Action_Cost",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Action_Table[Action_Cost]),
            FILTER(
                Action_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Action_Cost],
        "
        "
    ),
    "Outcome",
    CONCATENATEX(
        CALCULATETABLE(
            DISTINCT(Outcome_Table[Outcome]),
            FILTER(
                Outcome_Table,
                [ID]=EARLIER(Key_Table[ID])
            )
        ),
        [Outcome],
        "
        "
    )
)

 

Result:

e4.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

join first Action und Outcome and join Key with the joined action and outcome. Here an example

let
    KeyTable = 
    let
        Source = #table
        (
            {"ID","Key"},
            {
                {"A1","Key1"},	{"A1","Key2"},	{"A2","Key1"}
            }
        )
    in
        Source,

    ActionTable = 
    let
        Source = #table
        (
            {"ID","Action"},
            {
                {"A1","Action1"},	{"A1","Action2"},	{"A2","Action3"}
            }
        )
    in
        Source,
    
    OutComeTable = 
    let
        Source = #table
        (
            {"ID","Outcome"},
            {
                {"A1","Outcome1"},	{"A1","Outcome2"},	{"A2","Outcome3"}
            }
        )
    in
        Source,
    
    JoinActionWithOutCome = Table.NestedJoin
    (
        ActionTable,
        "ID",
        OutComeTable,
        "ID",
        "Outcome"
    ),
    JoinActionOutcom = Table.ExpandTableColumn(JoinActionWithOutCome, "Outcome", {"Outcome"}, {"Outcome"}),
    JoinKeyWithActionOutCome = Table.NestedJoin
    (
        KeyTable,
        "ID",
        JoinActionOutcom,
        "ID",
        "ActionOutcome"
    ),
    FinalTable = Table.ExpandTableColumn(JoinKeyWithActionOutCome, "ActionOutcome", {"Action", "Outcome"}, {"Action", "Outcome"})
in
    FinalTable

image.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query, or I could create a custom function what makes it easier to apply if you are not used that much to power query.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

CNENFRNL
Community Champion
Community Champion

To my understanding, it's way much easier to use PowerPivot to produce such a pivot table by merely sereval drag&drop.

If you insist on Power Query, it takes some more click on the UI to join these tables one by one.


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Kudoed Authors