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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
UBComma
Helper III
Helper III

Unpivot Columns of Calculated Table

I have reviewed posts with a similar problem but I'm still having trouble unpivoting select columns from a calculated table. The table looks like this:

Data[Fall Year][Total UG][FY+50NotCL][FY+35NotCL][2Y+50NotCL][2Y+35NotCL]
2013178423652580374
2012174693063569889
2014178693081996267
202119629589511377160
2015181193072189564
20161855538225100077
201819709376401304135
201920132486451263122
201719103423441210118
20202035513411191971231

 

and I need a table that looks like the sample below, and would be SO EASY if I could use Power Query. Could someone help me with the DAX to do this? (Sample of top 20 rows)


Data[Fall Year][Total UG]ScenarioBed Count
201317842[FY+50NotCL]365
201317842[FY+35NotCL]25
201317842[2Y+50NotCL]803
201317842[2Y+35NotCL]74
201217469[FY+50NotCL]306
201217469[FY+35NotCL]35
201217469[2Y+50NotCL]698
201217469[2Y+35NotCL]89
201417869[FY+50NotCL]308
201417869[FY+35NotCL]19
201417869[2Y+50NotCL]962
201417869[2Y+35NotCL]67
202119629[FY+50NotCL]589
202119629[FY+35NotCL]51
202119629[2Y+50NotCL]1377
202119629[2Y+35NotCL]160
201518119[FY+50NotCL]307
201518119[FY+35NotCL]21
201518119[2Y+50NotCL]895
201518119[2Y+35NotCL]64
1 ACCEPTED SOLUTION
v-jayw-msft
Community Support
Community Support

Hi @UBComma ,

 

Please check the formula:

Table 2 = 
var _2Y35 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[2Y+35NotCL]","Bed Count",'Table'[[2Y+35NotCL]]])
var _2Y50 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[2Y+50NotCL]","Bed Count",'Table'[[2Y+50NotCL]]])
VAR _FY35 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[FY+35NotCL]","Bed Count",'Table'[[FY+35NotCL]]])
VAR _FY50 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[FY+50NotCL]","Bed Count",'Table'[[FY+50NotCL]]])
return
UNION(_2Y35,_2Y50,_FY35,_FY50)

vjaywmsft_0-1654846299212.png

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

4 REPLIES 4
v-jayw-msft
Community Support
Community Support

Hi @UBComma ,

 

Please check the formula:

Table 2 = 
var _2Y35 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[2Y+35NotCL]","Bed Count",'Table'[[2Y+35NotCL]]])
var _2Y50 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[2Y+50NotCL]","Bed Count",'Table'[[2Y+50NotCL]]])
VAR _FY35 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[FY+35NotCL]","Bed Count",'Table'[[FY+35NotCL]]])
VAR _FY50 = SELECTCOLUMNS('Table',"Data[Fall year]",'Table'[Data[Fall Year]]],"Total UG",'Table'[[Total UG]]],"Scenario","[FY+50NotCL]","Bed Count",'Table'[[FY+50NotCL]]])
return
UNION(_2Y35,_2Y50,_FY35,_FY50)

vjaywmsft_0-1654846299212.png

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

@v-jayw-msft thank you, this is a very elegant solution

amitchandak
Super User
Super User

@UBComma ,

A new table like

 

Union (
Summarize( Data, Data[Fall Year], "Data", [Total UG], "Scenario", "FY+50NotCL", "Value", Sum(Data[FY+50NotCL])),
Summarize( Data, Data[Fall Year], "Data", [Total UG], "Scenario", "FY+35NotCL", "Value", Sum(Data[FY+35NotCL])),
Summarize( Data, Data[Fall Year], "Data", [Total UG], "Scenario", "2FY+50NotCL", "Value", Sum(Data[2FY+50NotCL])) ,
Summarize( Data, Data[Fall Year], "Data", [Total UG], "Scenario", "2FY+35NotCL", "Value", Sum(Data[2FY+35NotCL]))
)

 

 

you can use selectcolumns in place of summarize

https://docs.microsoft.com/en-us/dax/selectcolumns-function-dax

https://radacad.com/create-a-subset-of-the-table-in-power-bi-and-add-calculations-using-selectcolumn...

 

Also refer

https://www.sqlbi.com/articles/from-sql-to-dax-joining-tables/

@amitchandak thank you, that is super helpful

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors