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

Search and Return Max Value based on matching filter in Same Table

Hi all,

 

I have a dataset which i need to do a lookup, and return a value based on a column entry.

 

What im trying to work out is the time taken between two shifts points (last dump / first dump).

 

TruckShift IDDumpTimePrevShift IDPrevious Shift Final Dump
EX109-Oct-20 - Night Shift10/10/2020 - 5:15 AM09-Oct-20 - Day Shift 
EX110-Oct-20 - Day Shift10/10/2020 - 5:30PM09-Oct-20 - Night Shift 
EX110-Oct-20 - Day Shift10/10/2020 - 2:30PM09-Oct-20 - Night Shift 
EX110-Oct-20 - Day Shift10/10/2020 - 8:30AM09-Oct-20 - Night Shift 
EX110-Oct-20 - Day Shift10/10/2020 - 12:30PM09-Oct-20 - Night Shift 
EX110-Oct-20 - Night Shift10/10/2020 - 6:30 PM10-Oct-20 - Day Shift 
EX110-Oct-20 - Night Shift10/10/2020 - 8:30 PM10-Oct-20 - Day Shift 

 

What im trying to get populated in the final column is the max value of previous shift.

 

I then can use this to calculate the time taken between these two points. 

 

Below is what the "Previous Shift Final Dump (this value will repeat in the column based on the Previous Shift ID)" should be populated with (i removed the extra lines for easier viewing)

 

 

TruckShift IDDumpTimePrevShift IDPrevious Shift Final Dump
EX110-Oct-20 - Night Shift10/10/2020 - 6:30 PM10-Oct-20 - Day Shift10/10/2020 - 5:30PM
EX110-Oct-20 - Day Shift10/10/2020 - 5:30PM09-Oct-20 - Night Shift10/10/2020 - 5:15 AM

 

 

 

 

VAR Current_ID = TRIM(VALUES(TruckCycles[Prev Shift ID]))
RETURN CALCULATE(MAX(TruckCycles[Dump Time]), FILTER(TruckCycles, TRIM(VALUES(TruckCycles[Shift ID])) = Current_ID))

 

 

 

 

Not sure if im missinh something or what i can be doing to get this to work.

 

Appreciate your help.

 

Cheers

 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @GKR1981 

 

as you are posting here in the Power-Query-forum I show you how to do that in M-language. I transform the DumpTime into datetime and after a new column is added where a apply a filter to the previous table using truck and PreviousID to filter. List.Max is then delivering the max-dumptime. Here the practical example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wco0wVNJRMrDU9U8u0TUyUNBV8MtMzyhRCM7ITCsByhga6AORkQFYytTK0FTB0RdNg0tiJVR5rA7MQEMDbPIYxhkbBKCbhmw9ieYZUdk8C6B5GL6lwDxDMh2IJ0bMgCYqgI3E7gKSDbQgZGAsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Truck = _t, #"Shift ID" = _t, DumpTime = _t, #"PrevShift ID" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Truck", type text}, {"Shift ID", type text}, {"DumpTime", type text}}, "en-US"),
    TranformDateTime = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "DumpTime",
                each DateTime.From(Text.Replace(_, "-", ""), "en-US"),
                type datetime
            }
        }
    ),
    
    BufferTable = Table.Buffer(TranformDateTime),
    GetPreviousShift = Table.AddColumn
    (
        TranformDateTime,
        "Get Previous shift Max DumpTime",
        (row)=> List.Max(Table.SelectRows(BufferTable, each [Truck]=row[Truck] and [Shift ID]=row[PrevShift ID])[DumpTime]), type datetime
    )

in
    GetPreviousShift

 

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

2 REPLIES 2
v-alq-msft
Community Support
Community Support

Hi, @GKR1981 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

c1.png

 

You may create an index column in 'Query Editor'. 

c2.png

 

Then you can create a calculated column as below.

Previous Shift Final Dump = 
CALCULATE(
    MAX('Table'[DumpTime]),
    FILTER(
        'Table',
        [Index]<EARLIER('Table'[Index])&&
        [DumpTime]<EARLIER('Table'[DumpTime])
    )
)

 

Result:

c3.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

Jimmy801
Community Champion
Community Champion

Hello @GKR1981 

 

as you are posting here in the Power-Query-forum I show you how to do that in M-language. I transform the DumpTime into datetime and after a new column is added where a apply a filter to the previous table using truck and PreviousID to filter. List.Max is then delivering the max-dumptime. Here the practical example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wco0wVNJRMrDU9U8u0TUyUNBV8MtMzyhRCM7ITCsByhga6AORkQFYytTK0FTB0RdNg0tiJVR5rA7MQEMDbPIYxhkbBKCbhmw9ieYZUdk8C6B5GL6lwDxDMh2IJ0bMgCYqgI3E7gKSDbQgZGAsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Truck = _t, #"Shift ID" = _t, DumpTime = _t, #"PrevShift ID" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Truck", type text}, {"Shift ID", type text}, {"DumpTime", type text}}, "en-US"),
    TranformDateTime = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "DumpTime",
                each DateTime.From(Text.Replace(_, "-", ""), "en-US"),
                type datetime
            }
        }
    ),
    
    BufferTable = Table.Buffer(TranformDateTime),
    GetPreviousShift = Table.AddColumn
    (
        TranformDateTime,
        "Get Previous shift Max DumpTime",
        (row)=> List.Max(Table.SelectRows(BufferTable, each [Truck]=row[Truck] and [Shift ID]=row[PrevShift ID])[DumpTime]), type datetime
    )

in
    GetPreviousShift

 

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

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