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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
waznybc
New Member

Last 100 rows for each Unique value in Column

The SQL table I'm pulling has millions of rows and I only need the last 100 records for each unique program in a column. See generic example below for pulling last 3 records for each unique program in a column:

 

DateProgram
1/1/2020D
1/2/2020A
1/3/2020D
1/4/2020A
1/5/2020B
1/6/2020B
1/7/2020A
1/8/2020D
1/9/2020B
1/10/2020D
1/11/2020B
1/12/2020D
1/13/2020C
1/14/2020B
1/15/2020C
1/16/2020C
1/17/2020C
1/18/2020C
1/19/2020A
1/20/2020A

 

I want to only return this:

DateProgram
1/20/2020A
1/19/2020A
1/7/2020A
1/14/2020B
1/11/2020B
1/9/2020B
1/18/2020C
1/17/2020C
1/16/2020C
1/12/2020D
1/10/2020D
1/8/2020D
1 ACCEPTED SOLUTION
mahoneypat
Employee
Employee

Here is one way to do it by grouping your data, sorting and keep the last 3 dates for each.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below that transforms your example data.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zc/JCcAwDETRXnQ2RFK8HrN0Ydx/GyFghzBzffwRdu9im22urhLklhFe8AXHhB2LiEVacE7ICAUnFY82nJhiYkaNU/O99loSaZWoySSFpJI0/JXrT8YD", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Program = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Program"}, {{"AllRows", each _, type table [Date=nullable text, Program=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Last3Dates", each Table.FirstN(Table.Sort([AllRows], {{"Date", Order.Descending}}),3)),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"AllRows"}),
    #"Expanded Last3Dates" = Table.ExpandTableColumn(#"Removed Columns", "Last3Dates", {"Date"}, {"Date"})
in
    #"Expanded Last3Dates"

 

Regards,

Pat

 





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


View solution in original post

1 REPLY 1
mahoneypat
Employee
Employee

Here is one way to do it by grouping your data, sorting and keep the last 3 dates for each.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below that transforms your example data.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Zc/JCcAwDETRXnQ2RFK8HrN0Ydx/GyFghzBzffwRdu9im22urhLklhFe8AXHhB2LiEVacE7ICAUnFY82nJhiYkaNU/O99loSaZWoySSFpJI0/JXrT8YD", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Program = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Program"}, {{"AllRows", each _, type table [Date=nullable text, Program=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Last3Dates", each Table.FirstN(Table.Sort([AllRows], {{"Date", Order.Descending}}),3)),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"AllRows"}),
    #"Expanded Last3Dates" = Table.ExpandTableColumn(#"Removed Columns", "Last3Dates", {"Date"}, {"Date"})
in
    #"Expanded Last3Dates"

 

Regards,

Pat

 





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors