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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.

Reply
Hoping
Helper III
Helper III

Unpivot - Columns to Rows using DAX

I have table in the below format which I want to transform into a shape where columns 3 and 4 are rows and the Amounts are summed. I want to achieve this using DAX only (not Power Query). Is this possible ?  Year can be a filter and therefore number of columns need to be controlled by the slicer year range.

 

Can this be achieved in DAX query?

 

IDYearCategory 1 SalesCategory 2 Sales
12019    109
12019123
2201976
2202069
2202046

 

Format Expected:

 

IDMeasure20192020
1Category 1 Sales           22    blank or 0
1Category 2 Sales12    blank or 0
2Category 1 Sales7    10
2Category 2 Sales6    15
3 ACCEPTED SOLUTIONS
Ritaf1983
Super User
Super User

Hi @Hoping 
Try the linked video :

https://www.youtube.com/watch?v=9Xv8COs59tc

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

Regards,
Rita Fainshtein | Microsoft MVP
https://www.linkedin.com/in/rita-fainshtein/
Blog : https://www.madeiradata.com/profile/ritaf/profile

View solution in original post

danextian
Super User
Super User

Hi @Hoping ,

 

Why not do it in Power Query? It will be real pain doing it in DAX and very manual at that. You will have to update your formula everytime a new Category column and Year is added.





Dane Belarmino | Microsoft MVP | Proud to be a Super User!

Did I answer your question? Mark my post as a solution!


"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

AnalyticsWizard
Solution Supplier
Solution Supplier

@Hoping 

Yes, you can achieve this transformation using DAX. However, please note that DAX is not as flexible as Power Query when it comes to reshaping data. Here’s how you can do it:

First, you need to create two separate tables for each category of sales. You can do this using the SUMMARIZE function in DAX:

Category1Sales = 
SUMMARIZE(
    FILTER(YourTable, YourTable[Year] >= MIN(YearSlicer[Year]) && YourTable[Year] <= MAX(YearSlicer[Year])),
    "ID", YourTable[ID],
    "Measure", "Category 1 Sales",
    "Year", YourTable[Year],
    "Sales", SUM(YourTable[Category 1 Sales])
)

Category2Sales = 
SUMMARIZE(
    FILTER(YourTable, YourTable[Year] >= MIN(YearSlicer[Year]) && YourTable[Year] <= MAX(YearSlicer[Year])),
    "ID", YourTable[ID],
    "Measure", "Category 2 Sales",
    "Year", YourTable[Year],
    "Sales", SUM(YourTable[Category 2 Sales])
)

Then, you can union these two tables together:

FinalTable = UNION(Category1Sales, Category2Sales)

This will give you a table with the columns “ID”, “Measure”, “Year”, and “Sales”. You can then use this table to create a matrix visual in Power BI, with “ID” and “Measure” on the rows, “Year” on the columns, and “Sales” in the values.

Please replace YourTable and YearSlicer with the actual names of your table and slicer. Also, ensure that your slicer is connected to a table that contains all the possible years, and that this table is related to your main table.

Remember, DAX operates on tables and columns, not on individual cells or rows. Therefore, transformations that require cell-by-cell operations are often more complex in DAX than i...1.

 

View solution in original post

3 REPLIES 3
AnalyticsWizard
Solution Supplier
Solution Supplier

@Hoping 

Yes, you can achieve this transformation using DAX. However, please note that DAX is not as flexible as Power Query when it comes to reshaping data. Here’s how you can do it:

First, you need to create two separate tables for each category of sales. You can do this using the SUMMARIZE function in DAX:

Category1Sales = 
SUMMARIZE(
    FILTER(YourTable, YourTable[Year] >= MIN(YearSlicer[Year]) && YourTable[Year] <= MAX(YearSlicer[Year])),
    "ID", YourTable[ID],
    "Measure", "Category 1 Sales",
    "Year", YourTable[Year],
    "Sales", SUM(YourTable[Category 1 Sales])
)

Category2Sales = 
SUMMARIZE(
    FILTER(YourTable, YourTable[Year] >= MIN(YearSlicer[Year]) && YourTable[Year] <= MAX(YearSlicer[Year])),
    "ID", YourTable[ID],
    "Measure", "Category 2 Sales",
    "Year", YourTable[Year],
    "Sales", SUM(YourTable[Category 2 Sales])
)

Then, you can union these two tables together:

FinalTable = UNION(Category1Sales, Category2Sales)

This will give you a table with the columns “ID”, “Measure”, “Year”, and “Sales”. You can then use this table to create a matrix visual in Power BI, with “ID” and “Measure” on the rows, “Year” on the columns, and “Sales” in the values.

Please replace YourTable and YearSlicer with the actual names of your table and slicer. Also, ensure that your slicer is connected to a table that contains all the possible years, and that this table is related to your main table.

Remember, DAX operates on tables and columns, not on individual cells or rows. Therefore, transformations that require cell-by-cell operations are often more complex in DAX than i...1.

 
danextian
Super User
Super User

Hi @Hoping ,

 

Why not do it in Power Query? It will be real pain doing it in DAX and very manual at that. You will have to update your formula everytime a new Category column and Year is added.





Dane Belarmino | Microsoft MVP | Proud to be a Super User!

Did I answer your question? Mark my post as a solution!


"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.
Ritaf1983
Super User
Super User

Hi @Hoping 
Try the linked video :

https://www.youtube.com/watch?v=9Xv8COs59tc

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

Regards,
Rita Fainshtein | Microsoft MVP
https://www.linkedin.com/in/rita-fainshtein/
Blog : https://www.madeiradata.com/profile/ritaf/profile

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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