cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
stevencmlee
Frequent Visitor

Pivot Top N into Columns

Hi All,

I have a dataset with various fields that I want to pivot entirely. Please see the below example:
Power BI Help Photo.JPG
I would like to pivot the table so that they are grouped by team and sorted by power level, while keeping all other fields. If there is a matching power level, I would like Age to take second priority, then alphabetical name.Power BI Help Photo - Results.JPG

I have experimented with different unpivots and pivots, but can't find a way to do this without making a ton of calculated columns in DAX. Can anyone help me please?

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

Hi @stevencmlee ,

 

If you want to see the result in the table, We suggest matrix visual as a workaround.

 

1. add a index column based on the order you describe

 

 

Index =
VAR t = [Team]
VAR p = [Power Level]
VAR n = [Name]
VAR a = [Age]
VAR t1 =
    FILTER ( ALL ( 'Table3' ), 'Table3'[Team] = t )
VAR t2 =
    FILTER ( ALL ( 'Table3' ), 'Table3'[Team] = t && 'Table3'[Power Level] = p )
VAR t3 =
    FILTER (
        ALL ( 'Table3' ),
        'Table3'[Team] = t
            && 'Table3'[Power Level] = p
            && 'Table3'[Age] = a
    )
RETURN
    RANKX (
        t1,
        RANKX ( t1, [Power Level],, ASC, SKIP ) * 100
            + RANKX ( t2, [Age],, ASC, SKIP ) * 10
            + RANKX ( t3, [Name],, ASC, SKIP ),
        ,
        DESC,
        SKIP
    )

 

 

15.PNG

 

Create a matrix, put the field in, and close the total.

 

12.PNG13.PNG14.PNG

 

Then you can use the Index Slicer to control how many you want to show in matrix.

 

16.PNG

 

 

 

BTW, pbix as attached.

 

Best regards,

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

Community Support Team _ Dong Li
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-lid-msft
Community Support
Community Support

Hi @stevencmlee ,

 

If you want to see the result in the table, We suggest matrix visual as a workaround.

 

1. add a index column based on the order you describe

 

 

Index =
VAR t = [Team]
VAR p = [Power Level]
VAR n = [Name]
VAR a = [Age]
VAR t1 =
    FILTER ( ALL ( 'Table3' ), 'Table3'[Team] = t )
VAR t2 =
    FILTER ( ALL ( 'Table3' ), 'Table3'[Team] = t && 'Table3'[Power Level] = p )
VAR t3 =
    FILTER (
        ALL ( 'Table3' ),
        'Table3'[Team] = t
            && 'Table3'[Power Level] = p
            && 'Table3'[Age] = a
    )
RETURN
    RANKX (
        t1,
        RANKX ( t1, [Power Level],, ASC, SKIP ) * 100
            + RANKX ( t2, [Age],, ASC, SKIP ) * 10
            + RANKX ( t3, [Name],, ASC, SKIP ),
        ,
        DESC,
        SKIP
    )

 

 

15.PNG

 

Create a matrix, put the field in, and close the total.

 

12.PNG13.PNG14.PNG

 

Then you can use the Index Slicer to control how many you want to show in matrix.

 

16.PNG

 

 

 

BTW, pbix as attached.

 

Best regards,

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

Community Support Team _ Dong Li
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

Erk
Frequent Visitor

Maybe this helps you in a direction.

 

- Make a duplicate of your query in Power query

- Remove all columns except Team and Power level

- Group by Team and sum the Power Level (order it by power level)

- Left join the original table on Team with Fuzzy matching on and fill in the field Maximum number of matches with 1.

 

And so on.

Nathaniel_C
Super User I
Super User I

dfasdfsa	f
adfs	d
af	f
dfasdfsaf
adfsd
aff

l

Hi @stevencmlee ,

 

Would you copy and paste the data from you picture either directly into your message, or into the code </> so that we can paste it directly and then play around with it. It might show an error message, but just hit post again.

 

Thanks,

Nathaniel





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

Proud to be a Super User!




Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors