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

Add column with list.generate

i want to add an index column (b) which is increased by  another column (a) while value is changed.

Like This

 

A

B

0

1

1

2

0

3

0

3

1

4

0

5

 i found two solutions for this.

 

First one;

= Table.AddColumn(#"Added Custom", "B", each let index=[Index],custom=[Custom]
in
Table.RowCount(
Table.SelectRows(#"Added Custom",each [Index]<=index and [Custom]=1
)
))

 

but this makes query too slow.

 

another one;

= Table.AddColumn(#"Added Custom", "B", each (let Custom=#"Added Custom"[Custom] in
List.Generate( () =>
[CurrentItem = Custom{0}, Index =1 , Counter = 1],
each [Counter] <= List.Count(Custom),
each [
CurrentItem = Custom{[Counter]},
DifferenceToPrevious = CurrentItem - [CurrentItem],
Index = if DifferenceToPrevious >= 1 then [Index] + 1 else [Index],
Counter = [Counter] + 1
],
each [Index]
)))

 

this query assigned a list instead of a value in every cell.  

 

Thank you in advance.

2 ACCEPTED SOLUTIONS
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

I would suggest you to do this with List.Accumulate. After you created the list that represents your index-column you have to integrate it your current table with Table.ToColumns and Table.FromColumns. Check out this example.

Give it a try and if you have performance issue we can check if we can enhance it a little bit

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlCK1YlWMgSTBkgkXCQWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}}),
    CreateNewIndexColumn = List.RemoveFirstN
    (
        List.Accumulate
        (
            #"Changed Type"[A],
            {1},
            (state,current)=> state & {List.Last(state) + current}
        )
    )
,

    AddIndexColumnToTable = Table.FromColumns
    (
        Table.ToColumns(#"Changed Type" ) & {CreateNewIndexColumn},
        Table.ColumnNames(#"Changed Type") & {"Index"}
    )
in
    AddIndexColumnToTable

 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

Anonymous
Not applicable

ten millions rows worked in less than1'

 

let
    Source = List.Transform(List.Random(10000000), each Number.Round(_)),
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Grouped Rows" = Table.Group(#"Converted to Table", {"Column1"}, {{"Count", each Table.RowCount(_), Int64.Type}},GroupKind.Local),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "idx", each List.Repeat({[Index]},[Count])),
    #"Expanded idx" = Table.ExpandListColumn(#"Added Custom", "idx")
in
    #"Expanded idx"

View solution in original post

10 REPLIES 10
Anonymous
Not applicable

2MrowsX20cols in 1'30"

 

let
    Source = List.Transform(List.Random(2000000), each Number.Round(_)),
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Muplicated Column" = Table.FromColumns(List.Repeat({#"Converted to Table"[Column1]}, 20)),
   
    #"Grouped Rows" = Table.Group(#"Muplicated Column", {"Column1"}, {{"all",each _}},GroupKind.Local),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
    #"Expanded all" = Table.ExpandTableColumn(#"Added Index", "all", {"Column2", "Column3", "Column4", "Column5", "Column6", "Column7", "Column8", "Column9", "Column10", "Column11", "Column12", "Column13", "Column14", "Column15", "Column16", "Column17", "Column18", "Column19", "Column20"}, {"all.Column2", "all.Column3", "all.Column4", "all.Column5", "all.Column6", "all.Column7", "all.Column8", "all.Column9", "all.Column10", "all.Column11", "all.Column12", "all.Column13", "all.Column14", "all.Column15", "all.Column16", "all.Column17", "all.Column18", "all.Column19", "all.Column20"})
in
    #"Expanded all"
Anonymous
Not applicable

try this

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlDSUTJUitWJBpI6SkZgFkjMGI0FkjWBi5kqxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}, {"B", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"A"}, {{"Count", each Table.RowCount(_), Int64.Type}},GroupKind.Local),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "idx", each List.Repeat({[Index]},[Count])),
    #"Expanded idx" = Table.ExpandListColumn(#"Added Custom", "idx")
in
    #"Expanded idx"
Anonymous
Not applicable

Hello Jimmy,

Thank you very much for your kind response. Your code is successfull for a new table. But my dataset is too large. If i use it with Table.ToColumns and Table.FromColumns functions the process takes a long time. Do you have any idea about how I should use it with add.column function?

Thank you, 

 

test.jpg

Hello @Anonymous 

 

is this screenshot coming from the solutions I proposed? Because the added column doesn't contain lists, but numbers. The problem with AddColumns is that you cannot refer the value of the prior row of the function. So you have to use List.Generate or List.Accumulate to produce a list, and this list you have to integrate with Table.FromColumns.


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

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

I would suggest you to do this with List.Accumulate. After you created the list that represents your index-column you have to integrate it your current table with Table.ToColumns and Table.FromColumns. Check out this example.

Give it a try and if you have performance issue we can check if we can enhance it a little bit

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlCK1YlWMgSTBkgkXCQWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"A", Int64.Type}}),
    CreateNewIndexColumn = List.RemoveFirstN
    (
        List.Accumulate
        (
            #"Changed Type"[A],
            {1},
            (state,current)=> state & {List.Last(state) + current}
        )
    )
,

    AddIndexColumnToTable = Table.FromColumns
    (
        Table.ToColumns(#"Changed Type" ) & {CreateNewIndexColumn},
        Table.ColumnNames(#"Changed Type") & {"Index"}
    )
in
    AddIndexColumnToTable

 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

Anonymous
Not applicable

Thank you @Jimmy801 it works perfect! do you have advice for how i can make it faster.

Hello @Anonymous 

 

how long it runs? How big is your dataset (columns/rows?)

 

BR

 

Jimmy

Anonymous
Not applicable

@Jimmy801  Daily data contains 1.5 million rows and 20 columns. It would take about 10 minutes to get data from the server before adding this column. This time it took more than 30 minutes. When I try to get data for 2 days or more, it gives this error: Expression.Error: The evaluation resulted in a stack capacity that is exceeded and can not continue.

Anonymous
Not applicable

ten millions rows worked in less than1'

 

let
    Source = List.Transform(List.Random(10000000), each Number.Round(_)),
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Grouped Rows" = Table.Group(#"Converted to Table", {"Column1"}, {{"Count", each Table.RowCount(_), Int64.Type}},GroupKind.Local),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "idx", each List.Repeat({[Index]},[Count])),
    #"Expanded idx" = Table.ExpandListColumn(#"Added Custom", "idx")
in
    #"Expanded idx"
Anonymous
Not applicable

Hello @Anonymous @

it was very useful. thank you so much.

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