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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Anonymous
Not applicable

Add new column based on whether another column's value is top N

Hey guys,

 

I've got a column of floating-point values, sorted in descending order, called "Score". I'm trying to add a new column called "Is Top 10?" where the value for the top 10 largest values in the "Score" column would be "Y" and all others would be "N". Could someone help me as to which M functions to use here?

 

Sample Data:

Score
0.9899
0.9889
0.9056
0.8463
0.8377
0.693
0.6666
0.5778
0.5602
0.489
0.3918
0.3034
0.1654
0.1012
0.0771
0.0506
0.0418
0.0053
0.0032

 

Desired result:

ScoreIs Top 10?
0.9899Y
0.9889Y
0.9056Y
0.8463Y
0.8377Y
0.693Y
0.6666Y
0.5778Y
0.5602Y
0.489Y
0.3918N
0.3034N
0.1654N
0.1012N
0.0771N
0.0506N
0.0418N
0.0053N
0.0032N

 

Thank you!

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

In a custom column, put following

 

= if List.Contains(List.FirstN(List.Sort(List.Distinct(#"Changed Type"[Score]),Order.Descending),10),[Score]) then "Y" else "N"

 

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pc3LCcBACATQXvYcwhj/tSzpv40sRPX0UGbce+HOyFzv9TOGUCuGGDfZvWjZSztTVPdoGp6iTCsn9Z3BUiTTIahTcKemoj9ApgFQHvKJvR8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Score = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Score", type number}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Is Top 10?", each if List.Contains(List.FirstN(List.Sort(List.Distinct(#"Changed Type"[Score]),Order.Descending),10),[Score]) then "Y" else "N", type text)
in
    #"Added Custom"

 

View solution in original post

4 REPLIES 4
BA_Pete
Super User
Super User

Hi @Anonymous ,

 

Try this:

if
List.Contains(
    List.FirstN(
        List.Sort(chgTypes[Score], Order.Descending),
        10
    ),
    [Score]
)
then "Y" else "N"

 

Full query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pc3LCcBACATQXvYcwhj/tSzpv40sRPX0UGbce+HOyFzv9TOGUCuGGDfZvWjZSztTVPdoGp6iTCsn9Z3BUiTTIahTcKemoj9ApgFQHvKJvR8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Score = _t]),
    chgTypes = Table.TransformColumnTypes(Source,{{"Score", type number}}),
    addIsTop10 = Table.AddColumn(chgTypes, "isTop10", each if
List.Contains(
    List.FirstN(
        List.Sort(chgTypes[Score], Order.Descending),
        10
    ),
    [Score]
)
then "Y" else "N")
in
    addIsTop10

 

Output:

BA_Pete_0-1652171982662.png

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Anonymous
Not applicable

Thank you, @BA_Pete!

Vijay_A_Verma
Super User
Super User

In a custom column, put following

 

= if List.Contains(List.FirstN(List.Sort(List.Distinct(#"Changed Type"[Score]),Order.Descending),10),[Score]) then "Y" else "N"

 

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pc3LCcBACATQXvYcwhj/tSzpv40sRPX0UGbce+HOyFzv9TOGUCuGGDfZvWjZSztTVPdoGp6iTCsn9Z3BUiTTIahTcKemoj9ApgFQHvKJvR8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Score = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Score", type number}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Is Top 10?", each if List.Contains(List.FirstN(List.Sort(List.Distinct(#"Changed Type"[Score]),Order.Descending),10),[Score]) then "Y" else "N", type text)
in
    #"Added Custom"

 

Anonymous
Not applicable

Thank you very much for your help, @Vijay_A_Verma!

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors