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

How do I get the Top X value across columns in each row?

Hello, 

I'm trying to add a column where I get the first most occurring value across columns in a row along with the second most occurring value, and 3rd most occuring value

 

IDColumn1Column2Column3Column4Column5
1234AppleAppleOrangeAppleOrange
1235OrangeOrangePearOrangeOrange

 

In other words, I'd like a column that would show "Apple" as the first most occurring value and "Orange" as the second most occuring value in the first row.  How can I do that? 

1 ACCEPTED SOLUTION

Hi, @RolandPlanet 

 

I have made a few changes on the measure. Please try the following measure to see if it works.

 

Result = 
var _id = SELECTEDVALUE('Table'[ID])
var tab = 
SUMMARIZE(
    'Table',
    'Table'[ID],
    'Table'[Value],
    "Count",
    COUNTROWS(
        FILTER(
            'Table',
            'Table'[Value] = EARLIER('Table'[Value])
        )
    )
)
var newtab = 
ADDCOLUMNS(
    tab,
    "Rank",
    RANKX(
        FILTER(
            tab,
            [ID] = _id
        ),
        [Count]
    )
)
return
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 1
    ),
    [Value],
    "-"
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 2
    ),
    [Value],
    "-"
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 3
    ),
    [Value],
    "-"
)

 

 

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

4 REPLIES 4
v-alq-msft
Community Support
Community Support

Hi, @RolandPlanet 

 

You may go to Query Editor, go to 'Transform' ribbon, make 'ID' selected and click 'unpivot other columns'.  And then you need to click 'Close and Apply'.

I1.png

 

You may create a measure as below.

 

Result = 
var _id = SELECTEDVALUE('Table'[ID])
var tab = 
SUMMARIZE(
    'Table',
    'Table'[ID],
    'Table'[Value],
    "Count",
    COUNTROWS(
        FILTER(
            'Table',
            'Table'[Value] = EARLIER('Table'[Value])
        )
    )
)
var newtab = 
ADDCOLUMNS(
    tab,
    "Rank",
    RANKX(
        FILTER(
            tab,
            [ID] = _id
        ),
        [Count]
    )
)
return
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 1
    ),
    [Value]
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 2
    ),
    [Value]
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 3
    ),
    [Value]
)

 

 

Result:

I2.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.

This is great! However, if two values have the same number of occurences, they get concatenated together as "AppleOrange" for example. Is there a way to prevent this? 

Hi, @RolandPlanet 

 

I have made a few changes on the measure. Please try the following measure to see if it works.

 

Result = 
var _id = SELECTEDVALUE('Table'[ID])
var tab = 
SUMMARIZE(
    'Table',
    'Table'[ID],
    'Table'[Value],
    "Count",
    COUNTROWS(
        FILTER(
            'Table',
            'Table'[Value] = EARLIER('Table'[Value])
        )
    )
)
var newtab = 
ADDCOLUMNS(
    tab,
    "Rank",
    RANKX(
        FILTER(
            tab,
            [ID] = _id
        ),
        [Count]
    )
)
return
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 1
    ),
    [Value],
    "-"
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 2
    ),
    [Value],
    "-"
)&" "&
CONCATENATEX(
    FILTER(
        newtab,
        [Rank] = 3
    ),
    [Value],
    "-"
)

 

 

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

amitchandak
Super User IV
Super User IV

@RolandPlanet 

Better you unpivot data

https://radacad.com/pivot-and-unpivot-with-power-bi

 

Then you can use all expect at ID level to get this answer

https://www.sqlbi.com/articles/managing-all-functions-in-dax-all-allselected-allnoblankrow-allexcept...

https://community.powerbi.com/t5/Desktop/Percentage-of-subtotal/td-p/95390



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

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

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Power Query PA Forum 768x460.png

Check it out!

Did you know that you can visit the Power Query Forum in Power BI and now Power Apps

Top Solution Authors
Top Kudoed Authors