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
JOHN14400
Frequent Visitor

rank index custom columns query

Hello

 

I would like create in power query  a custom column in order to have rank index max 1 to 3 . I explain with a list of first name

Name          Index

ALBERT           1

ROGER           2

GILBERT         3

SOPHIE          1

THERESE        2

MARIE           3

JEAN             1

PAUL             2

etc and so on

what is the instructions in language M ?

thanks for your help

 

2 ACCEPTED SOLUTIONS
ziying35
Impactful Individual
Impactful Individual

Hi, @JOHN14400 

 

let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65W8kvMTVWIKTUwSDTASilZKTn6OLkGhUC4uEilWh2izAryd3cNoo5R7p543UWsMcH+AR6ertRxUoiHa5BrME7DiDXG1zGIWi7ycnX0w28SaeYFOIb6EGdeLAA=",BinaryEncoding.Base64),Compression.Deflate))),
    addidx = Table.AddIndexColumn(Source,"Index"),
    result = Table.TransformColumns(addidx, {"Index", each Number.Mod(_, 3)+1, type number})
in
    result

If my code solves your problem, mark it as a solution

 

View solution in original post

ziying35
Impactful Individual
Impactful Individual

@JOHN14400 

According to the description of your problem, modify the code as follows. But I see that you are expecting the result to be a change every three lines, in which case the loop number doesn't need to be added. Just start directly with the split step.

 

 

let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65W8kvMTVWyUnL0cXINCokpNTBINMBFKtXqwNUH+bu7BhGv3N0Tr/nISoP9Azw8XYk3OsTDNcg1GKcGZKW+jkGkmOzl6uiHXzWmngDHUB/i9MQCAA==",BinaryEncoding.Base64),Compression.Deflate))),
    addidx = Table.AddIndexColumn(Source,"Index"),
    mod = Table.TransformColumns(addidx, {"Index", each Number.Mod(_, 3)+1, type number}),
    split = Table.Split(mod, 3),
    trans = List.Transform(split, each Table.PromoteHeaders(Table.Transpose(Table.ReorderColumns(_,{"Index", "Name"})))),
    result = Table.Combine(trans)
in
    result

 

 

But that would require a code change, so you'll try with code above

View solution in original post

6 REPLIES 6
JOHN14400
Frequent Visitor

JOHN14400_0-1597394943971.png

 

ziying35
Impactful Individual
Impactful Individual

@JOHN14400 

According to the description of your problem, modify the code as follows. But I see that you are expecting the result to be a change every three lines, in which case the loop number doesn't need to be added. Just start directly with the split step.

 

 

let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65W8kvMTVWyUnL0cXINCokpNTBINMBFKtXqwNUH+bu7BhGv3N0Tr/nISoP9Azw8XYk3OsTDNcg1GKcGZKW+jkGkmOzl6uiHXzWmngDHUB/i9MQCAA==",BinaryEncoding.Base64),Compression.Deflate))),
    addidx = Table.AddIndexColumn(Source,"Index"),
    mod = Table.TransformColumns(addidx, {"Index", each Number.Mod(_, 3)+1, type number}),
    split = Table.Split(mod, 3),
    trans = List.Transform(split, each Table.PromoteHeaders(Table.Transpose(Table.ReorderColumns(_,{"Index", "Name"})))),
    result = Table.Combine(trans)
in
    result

 

 

But that would require a code change, so you'll try with code above

Hello ziying 35

Thanks for yours fasters answers it works !

 

ziying35
Impactful Individual
Impactful Individual

@JOHN14400 

According to the description of your problem, modify the code as follows. But I see that you are expecting the result to be a change every three lines, in which case the loop index number doesn't need to be added. Just start directly with the split step.

 

 

 

let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65W8kvMTVWyUnL0cXINCokpNTBINMBFKtXqwNUH+bu7BhGv3N0Tr/nISoP9Azw8XYk3OsTDNcg1GKcGZKW+jkGkmOzl6uiHXzWmngDHUB/i9MQCAA==",BinaryEncoding.Base64),Compression.Deflate))),
    addidx = Table.AddIndexColumn(Source,"Index"),
    mod = Table.TransformColumns(addidx, {"Index", each Number.Mod(_, 3)+1, type number}),
    split = Table.Split(mod, 3),
    trans = List.Transform(split, each Table.PromoteHeaders(Table.Transpose(Table.ReorderColumns(_,{"Index", "Name"})))),
    result = Table.Combine(trans)
in
    result

 

 

 

 

ziying35
Impactful Individual
Impactful Individual

Hi, @JOHN14400 

 

let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65W8kvMTVWIKTUwSDTASilZKTn6OLkGhUC4uEilWh2izAryd3cNoo5R7p543UWsMcH+AR6ertRxUoiHa5BrME7DiDXG1zGIWi7ycnX0w28SaeYFOIb6EGdeLAA=",BinaryEncoding.Base64),Compression.Deflate))),
    addidx = Table.AddIndexColumn(Source,"Index"),
    result = Table.TransformColumns(addidx, {"Index", each Number.Mod(_, 3)+1, type number})
in
    result

If my code solves your problem, mark it as a solution

 

THanks  for your solution via the function Mod. But in final way , i Would like to pivot in order to have the first name like a values.

I have a message error like (

There were too many elements in the enumeration to complete the operation).

Yet there is only 8 rows

 

 

 

 

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
Top Kudoed Authors