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

Sampling in power query

Hello everyone!

I would greatly appreciate your help in building this formula in power query. I need to number those cells that are above a threshold (25k here). I achieve this in excel by taking the max till the previous row and add 1 to it, as shown in the screenshot. TIA! 

Screenshot 2021-07-30 102237.jpg

2 ACCEPTED SOLUTIONS
Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

There are ways to do it, if you have duplicated numbers in the balance and many rows, this is one way

Vera_33_0-1627628149112.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrY0MDBQitWJVjI3hLGMYbSpAUzIEEobmYFFYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    below25 = Table.SelectRows(#"Added Index", each ([Value] <= 25000)),
    above25 = Table.AddIndexColumn( Table.SelectRows(#"Added Index", each ([Value] > 25000)),"result",1,1),
    Custom1 = Table.Combine({ above25,below25}),
    #"Sorted Rows" = Table.Sort(Custom1,{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns"

 

View solution in original post

wdx223_Daniel
Super User
Super User

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjRRitWJVjI2BVOGFmDKxBxMmUGkjCFSEBVGEDEDCAXUHAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Amount", type number}}),
    Custom1 = Table.AddColumn(#"Changed Type","Selected",Function.ScalarVector(Value.Type(each _),(tbl)=>let a=#"Changed Type"[Amount] in List.Transform(List.Positions(a),each if a{_}>20 then List.Count(List.Select(List.FirstN(#"Changed Type"[Amount],_+1),each _>20)) else null)))
in
    Custom1

View solution in original post

3 REPLIES 3
wdx223_Daniel
Super User
Super User

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjRRitWJVjI2BVOGFmDKxBxMmUGkjCFSEBVGEDEDCAXUHAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Amount", type number}}),
    Custom1 = Table.AddColumn(#"Changed Type","Selected",Function.ScalarVector(Value.Type(each _),(tbl)=>let a=#"Changed Type"[Amount] in List.Transform(List.Positions(a),each if a{_}>20 then List.Count(List.Select(List.FirstN(#"Changed Type"[Amount],_+1),each _>20)) else null)))
in
    Custom1
Syndicate_Admin
Administrator
Administrator

Hi @vishgop 

 

There are ways to do it, if you have duplicated numbers in the balance and many rows, this is one way

Vera_33_0-1627628149112.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrY0MDBQitWJVjI3hLGMYbSpAUzIEEobmYFFYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    below25 = Table.SelectRows(#"Added Index", each ([Value] <= 25000)),
    above25 = Table.AddIndexColumn( Table.SelectRows(#"Added Index", each ([Value] > 25000)),"result",1,1),
    Custom1 = Table.Combine({ above25,below25}),
    #"Sorted Rows" = Table.Sort(Custom1,{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns"

 

Vera_33
Resident Rockstar
Resident Rockstar

Hi @Anonymous 

 

There are ways to do it, if you have duplicated numbers in the balance and many rows, this is one way

Vera_33_0-1627628149112.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrY0MDBQitWJVjI3hLGMYbSpAUzIEEobmYFFYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
    below25 = Table.SelectRows(#"Added Index", each ([Value] <= 25000)),
    above25 = Table.AddIndexColumn( Table.SelectRows(#"Added Index", each ([Value] > 25000)),"result",1,1),
    Custom1 = Table.Combine({ above25,below25}),
    #"Sorted Rows" = Table.Sort(Custom1,{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"})
in
    #"Removed Columns"

 

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