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
Anonymous
Not applicable

Incrementing index on multiple categories - Power Query M

Hi all, I have two fields in my data and want to be able to assign incremental values when the status for each ID is "Completed" using Power Query not DAX. Please see below
Problem
ID Status
A In Progress
A In Progress
A In Progress
A Completed
A In Progress
A In Progress
B Completed
C In Progress
D In Progress
E In Progress
F Completed
F Completed
F In Progress
What I Require is
ID Status No
A In Progress 1
A In Progress 2
A In Progress 3
A Completed 4
A In Progress 1
A In Progress 2
B Completed 1
C In Progress 1
D In Progress 1
E In Progress 1
F In Progress 1
F Completed 2
F In Progress 1
Please can you help? Thank you all

2 ACCEPTED SOLUTIONS
Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

I am not sure if I made it too complicated, but it got what you want:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUfLMUwgoyk8vSi0uVorVIU3MOT+3ICe1JDWFBjpdsIi5YhFzwyGGagOGqlgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Status = _t]),
#"Added Index" = Table.AddIndexColumn(Source, "SortIndex", 0, 1, Int64.Type),
GroupToDiff = Table.Group(#"Added Index", {"ID", "Status"}, {{"Table", each _, type table }}),
AddTest = Table.AddColumn(GroupToDiff, "Custom", each if [Status] = "Completed" then Table.AddIndexColumn([Table],"test",1,1) else Table.AddColumn([Table], "test", each 0)),
SelectCustom = Table.SelectColumns(AddTest,{"Custom"}),
#"Expanded Custom" = Table.ExpandTableColumn(SelectCustom, "Custom", {"ID", "Status", "SortIndex", "test"}, {"ID", "Status", "SortIndex", "test"}),
#"Sorted Rows" = Table.Sort(#"Expanded Custom",{{"SortIndex", Order.Ascending}}),
#"Grouped Rows" = Table.Group(#"Sorted Rows", {"ID"}, {{"allrows", each _, type table }}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", (OT)=> Table.AddColumn(OT[allrows],"new",
(x)=>[a=List.Min( List.Select( Table.SelectColumns( Table.SelectRows(OT[allrows],(IT)=> IT[SortIndex]>=x[SortIndex]),"test")[test], each _ <>0)),
b=List.Max( List.Select( Table.SelectColumns( Table.SelectRows(OT[allrows],(IT)=> IT[SortIndex]<=x[SortIndex]),"test")[test], each _ <>0)),
c=if a <>null then a else if b<>null then b+1 else 0][c])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "final", each Table.Group([Custom],{"ID","new"},{{"t", each _,type table}})),
#"Removed Other Columns" = Table.SelectColumns(#"Added Custom1",{"final"}),
#"Expanded final" = Table.ExpandTableColumn(#"Removed Other Columns", "final", {"t"}, {"t"}),
#"Added Custom2" = Table.AddColumn(#"Expanded final", "Custom", each Table.AddIndexColumn([t],"Index",1,1)),
#"Removed Other Columns1" = Table.SelectColumns(#"Added Custom2",{"Custom"}),
#"Expanded Custom1" = Table.ExpandTableColumn(#"Removed Other Columns1", "Custom", {"ID", "Status", "SortIndex", "Index"}, {"ID", "Status", "SortIndex", "Index"})

in
#"Expanded Custom1"

View solution in original post

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

as I can see the index has to restart whenever ID and status together are changing. So you need to apply Table.Group with GroupKind.Local. This grouped tables then get a Index column starting with 1 by applying a Table.TransformColumns. By the way I was assuming that ID and status are two different columns and therefore I splittet your data into two different columns.

Here the complete code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTwzFMIKMpPL0otLlaK1SFWxDk/tyAntSQ1hWg9Tmh6nDFUuGCIuGKIuKGZgslH0RELAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "ID", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"ID.1", "ID.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"ID.1", type text}, {"ID.2", type text}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"ID.1", "ID"}, {"ID.2", "Status"}}),
    #"Grouped Rows" = Table.Group(#"Renamed Columns", {"ID", "Status"}, {{"AllRows", each _, type table [ID=text, Status=text]}}, GroupKind.Local),
    AddIndexToTable = Table.TransformColumns
    (
        #"Grouped Rows",
        {
            {
                "AllRows",
                (tbl)=> Table.AddIndexColumn(tbl,"Index", 1)
            }
        }
    ),
    #"Expanded AllRows" = Table.ExpandTableColumn(AddIndexToTable, "AllRows", {"Index"}, {"Index"})
in
    #"Expanded AllRows"

Jimmy801_0-1613118430907.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

8 REPLIES 8
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

as I can see the index has to restart whenever ID and status together are changing. So you need to apply Table.Group with GroupKind.Local. This grouped tables then get a Index column starting with 1 by applying a Table.TransformColumns. By the way I was assuming that ID and status are two different columns and therefore I splittet your data into two different columns.

Here the complete code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTwzFMIKMpPL0otLlaK1SFWxDk/tyAntSQ1hWg9Tmh6nDFUuGCIuGKIuKGZgslH0RELAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "ID", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"ID.1", "ID.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"ID.1", type text}, {"ID.2", type text}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"ID.1", "ID"}, {"ID.2", "Status"}}),
    #"Grouped Rows" = Table.Group(#"Renamed Columns", {"ID", "Status"}, {{"AllRows", each _, type table [ID=text, Status=text]}}, GroupKind.Local),
    AddIndexToTable = Table.TransformColumns
    (
        #"Grouped Rows",
        {
            {
                "AllRows",
                (tbl)=> Table.AddIndexColumn(tbl,"Index", 1)
            }
        }
    ),
    #"Expanded AllRows" = Table.ExpandTableColumn(AddIndexToTable, "AllRows", {"Index"}, {"Index"})
in
    #"Expanded AllRows"

Jimmy801_0-1613118430907.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

So nice!

Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

I am not sure if I made it too complicated, but it got what you want:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUfLMUwgoyk8vSi0uVorVIU3MOT+3ICe1JDWFBjpdsIi5YhFzwyGGagOGqlgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Status = _t]),
#"Added Index" = Table.AddIndexColumn(Source, "SortIndex", 0, 1, Int64.Type),
GroupToDiff = Table.Group(#"Added Index", {"ID", "Status"}, {{"Table", each _, type table }}),
AddTest = Table.AddColumn(GroupToDiff, "Custom", each if [Status] = "Completed" then Table.AddIndexColumn([Table],"test",1,1) else Table.AddColumn([Table], "test", each 0)),
SelectCustom = Table.SelectColumns(AddTest,{"Custom"}),
#"Expanded Custom" = Table.ExpandTableColumn(SelectCustom, "Custom", {"ID", "Status", "SortIndex", "test"}, {"ID", "Status", "SortIndex", "test"}),
#"Sorted Rows" = Table.Sort(#"Expanded Custom",{{"SortIndex", Order.Ascending}}),
#"Grouped Rows" = Table.Group(#"Sorted Rows", {"ID"}, {{"allrows", each _, type table }}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", (OT)=> Table.AddColumn(OT[allrows],"new",
(x)=>[a=List.Min( List.Select( Table.SelectColumns( Table.SelectRows(OT[allrows],(IT)=> IT[SortIndex]>=x[SortIndex]),"test")[test], each _ <>0)),
b=List.Max( List.Select( Table.SelectColumns( Table.SelectRows(OT[allrows],(IT)=> IT[SortIndex]<=x[SortIndex]),"test")[test], each _ <>0)),
c=if a <>null then a else if b<>null then b+1 else 0][c])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "final", each Table.Group([Custom],{"ID","new"},{{"t", each _,type table}})),
#"Removed Other Columns" = Table.SelectColumns(#"Added Custom1",{"final"}),
#"Expanded final" = Table.ExpandTableColumn(#"Removed Other Columns", "final", {"t"}, {"t"}),
#"Added Custom2" = Table.AddColumn(#"Expanded final", "Custom", each Table.AddIndexColumn([t],"Index",1,1)),
#"Removed Other Columns1" = Table.SelectColumns(#"Added Custom2",{"Custom"}),
#"Expanded Custom1" = Table.ExpandTableColumn(#"Removed Other Columns1", "Custom", {"ID", "Status", "SortIndex", "Index"}, {"ID", "Status", "SortIndex", "Index"})

in
#"Expanded Custom1"
Anonymous
Not applicable

Thanks so much, i dont understand whats going on in the code but it solved my problem. Thanks

Hi @Anonymous 

 

The SortIndex is to keep the original order, 

the first GroupBy to find how many "Completed" for each ID,

the second GroupBy to put every "In Progress" into their own "Completed" accordingly -  the logic is to find after current SortIndex the min Completed, if null to find the max Completed before current SortIndex, if both are null then there is no "Completed" for this ID,

after find their own "Completed" add new Index within their group

 

I hope there is a better way to write it

 

edhans
Super User
Super User

See this code @Anonymous 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTwzFMIKMpPL0otLlaK1SFWxDk/tyAntSQ1hWg9Tmh6nDFUuGCIuGKIuKGZgslH0RELAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"ID Status" = _t]),
    #"Grouped Rows" = Table.Group(Source, {"ID Status"}, {{"All Rows", each Table.AddIndexColumn(_, "Index", 1, 1), type table [ID Status=nullable text, Index = Int64.Type]}}),
    #"Expanded All Rows" = Table.ExpandTableColumn(#"Grouped Rows", "All Rows", {"Index"}, {"Index"}),
    #"Added Custom" = Table.AddColumn(#"Expanded All Rows", "New ID Status", each [ID Status] & " " & Text.From([Index]), Text.Type),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"New ID Status"})
in
    #"Removed Other Columns"

It turns this:

edhans_0-1612923969623.png

into this:

edhans_1-1612923986735.png

I could have done this in fewer steps with more manual code but it would have been more difficult to follow. Here you can see in each step what I am doing. The key is the Group Rows step. I manually edited the code to add an index within each grouping. Then I expanded that column out, merged the columns and returned the above result.

 

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

Hey @Anonymous - I'm just curious what I missed in your original post that my code isn't doing for you.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
Vera_33
Resident Rockstar
Resident Rockstar

Hi @edhans 

 

To my understanding, you are counting "In progress" and "Completed" seperately. Have a look at the sample data, my understanding is a loop, counting from In progress to Completed then from In progress to Completed for each ID. I know I made it too complicated, hope you have a better solution.

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