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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Anonymous
Not applicable

Split multiple columns into rows using DAX

Hi @Jihwan_Kim & other DAX experts,

 

Thanks @Jihwan_Kim for your help earlier.

 

My query is,

The condition to split is there are multiple columns to be splitting into rows. I have done splitting from 'Raw Data' table into rows in Table A for column 'List of Students', as below image and I would like to do as per in Table A+ (add new calculated column for the Activity) where it has multiple values. E.g. John has multiple activities.

 

Really appreciate if anyone can help me to achieve from Table A to Table A+. 


Note: I have done using Power Query before, but due to performance issue I have to move to DAX instead

 

HelpM3_0-1706169848214.png

 

Thank you

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but please check the below and the attached pbix file.

 

Expected result table = 
VAR _t =
    GENERATESERIES ( 1, 100, 1 )
VAR _pathitem =
    ADDCOLUMNS ( Data, "@path", SUBSTITUTE ( Data[List of Students], ",", "|" ) )
VAR _pathitemsinging =
    ADDCOLUMNS ( Data, "@pathsinging", SUBSTITUTE ( Data[Singing], ",", "|" ) )
VAR _pathitemdancing =
    ADDCOLUMNS ( Data, "@pathdancing", SUBSTITUTE ( Data[Dancing], ",", "|" ) )
VAR _generatetable =
    FILTER (
        GENERATE (
            _t,
            ADDCOLUMNS ( _pathitem, "@Students", PATHITEM ( [@path], [Value] ) )
        ),
        [@Students] <> BLANK ()
    )
VAR _generatesinging =
    SUMMARIZE (
        FILTER (
            GENERATE (
                _t,
                ADDCOLUMNS ( _pathitemsinging, "@sing", PATHITEM ( [@pathsinging], [Value] ) )
            ),
            [@sing] <> BLANK ()
        ),
        Data[ID],
        Data[Class Name],
        [@sing]
    )
VAR _generatedancing =
    SUMMARIZE (
        FILTER (
            GENERATE (
                _t,
                ADDCOLUMNS ( _pathitemdancing, "@dance", PATHITEM ( [@pathdancing], [Value] ) )
            ),
            [@dance] <> BLANK ()
        ),
        Data[ID],
        Data[Class Name],
        [@dance]
    )
RETURN
    SUMMARIZE (
        ADDCOLUMNS (
            _generatetable,
            "@activity",
                SWITCH (
                    TRUE (),
                    COUNTROWS (
                        FILTER (
                            _generatesinging,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@sing]
                        )
                    ) >= 1 && COUNTROWS (
                        FILTER (
                            _generatedancing,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@dance]
                        )
                    ) >= 1, "Sing,Dance",
                    COUNTROWS (
                        FILTER (
                            _generatesinging,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@sing]
                        )
                    ) >= 1, "Sing",
                    COUNTROWS (
                        FILTER (
                            _generatedancing,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@dance]
                        )
                    ) >= 1, "Dance"
                )
        ),
        Data[ID],
        Data[Class Name],
        [@Students],
        [@activity]
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

Hi @Anonymous ,

Did the above suggestions help with your scenario? if that is the case, you can consider Kudo or Accept the helpful suggestions to help others who faced similar requirements.

If these also don't help, please share more detailed information and description to help us clarify your scenario to test.

How to Get Your Question Answered Quickly 

Regards,

Xiaoxin Sheng

Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but please check the below and the attached pbix file.

 

Expected result table = 
VAR _t =
    GENERATESERIES ( 1, 100, 1 )
VAR _pathitem =
    ADDCOLUMNS ( Data, "@path", SUBSTITUTE ( Data[List of Students], ",", "|" ) )
VAR _pathitemsinging =
    ADDCOLUMNS ( Data, "@pathsinging", SUBSTITUTE ( Data[Singing], ",", "|" ) )
VAR _pathitemdancing =
    ADDCOLUMNS ( Data, "@pathdancing", SUBSTITUTE ( Data[Dancing], ",", "|" ) )
VAR _generatetable =
    FILTER (
        GENERATE (
            _t,
            ADDCOLUMNS ( _pathitem, "@Students", PATHITEM ( [@path], [Value] ) )
        ),
        [@Students] <> BLANK ()
    )
VAR _generatesinging =
    SUMMARIZE (
        FILTER (
            GENERATE (
                _t,
                ADDCOLUMNS ( _pathitemsinging, "@sing", PATHITEM ( [@pathsinging], [Value] ) )
            ),
            [@sing] <> BLANK ()
        ),
        Data[ID],
        Data[Class Name],
        [@sing]
    )
VAR _generatedancing =
    SUMMARIZE (
        FILTER (
            GENERATE (
                _t,
                ADDCOLUMNS ( _pathitemdancing, "@dance", PATHITEM ( [@pathdancing], [Value] ) )
            ),
            [@dance] <> BLANK ()
        ),
        Data[ID],
        Data[Class Name],
        [@dance]
    )
RETURN
    SUMMARIZE (
        ADDCOLUMNS (
            _generatetable,
            "@activity",
                SWITCH (
                    TRUE (),
                    COUNTROWS (
                        FILTER (
                            _generatesinging,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@sing]
                        )
                    ) >= 1 && COUNTROWS (
                        FILTER (
                            _generatedancing,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@dance]
                        )
                    ) >= 1, "Sing,Dance",
                    COUNTROWS (
                        FILTER (
                            _generatesinging,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@sing]
                        )
                    ) >= 1, "Sing",
                    COUNTROWS (
                        FILTER (
                            _generatedancing,
                            Data[ID] = EARLIER ( Data[ID] )
                                && Data[Class Name] = EARLIER ( Data[Class Name] )
                                && [@Students] = [@dance]
                        )
                    ) >= 1, "Dance"
                )
        ),
        Data[ID],
        Data[Class Name],
        [@Students],
        [@activity]
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.
Anonymous
Not applicable

Thank you so much @Jihwan_Kim 

123abc
Community Champion
Community Champion

Certainly! To achieve matching based on values in DAX, you can use relationships and create calculated columns or measures depending on your requirements. Assuming you have two tables, 'Achieved' and 'To Achieve', and they share a common column (let's say 'ID' for demonstration purposes), you can create relationships between them. Then, you can use DAX formulas to achieve matching.

Here's an example using calculated columns:

 

Table 3 ('To Achieve') =
VAR CurrentID = 'To Achieve'[ID]
RETURN
CALCULATE(
MAX('Achieved'[Value]),
'Achieved'[ID] = CurrentID
)

 

This formula assumes that 'To Achieve' and 'Achieved' tables have a relationship based on the 'ID' column. It looks up the corresponding 'Value' from the 'Achieved' table for each row in the 'To Achieve' table.

If you need to create a measure instead, you can use similar logic within the CALCULATE function.

Remember to adjust the column and table names according to your actual data structure. If you have multiple columns to match on, you might need to adjust the formula accordingly.

 

 

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

 

In case there is still a problem, please feel free and explain your issue in detail, It will be my pleasure to assist you in any way I can.

Anonymous
Not applicable

Hi @123abc & thank you for the response.

 

I want to achieve from table A to table A+ (add new calculated column named 'Activity Involved'.

HelpM3_0-1706171095540.png

 

123abc
Community Champion
Community Champion

Please explain in detail.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.