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
Arnault_
Resolver III
Resolver III

MIN date using M

Dear All,

My business case is the following :

I have orders identified by a specific order_id and each order can be received in several sequences (reception_id) with different reception dates. I want to identify whether or not for each order_id, this is the first reception (earliest date).

In DAX, I have created the following formula which works perfectly and I would like to translate it into M language.

 

first_reception = IF('TABLE'[reception_date]<=CALCULATE(MIN('TABLE'[reception_date]);ALLEXCEPT('TABLE';'TABLE'[order_id]));"YES";"NO")

The dataset  :

order_idreception_idreception_date
O001R00101/01/2019
O001R00201/01/2019
O001R00315/02/2019
O002R00412/02/2019
O002R00513/02/2019
O002R00614/02/2019
O002R00715/02/2019
O003R00816/02/2019
O004R00917/02/2019
O005R01018/02/2019
O006R011

19/02/2019

1 ACCEPTED SOLUTION
Anonymous
Not applicable

 

Hi,

 

I have pasted your data into an excel sheet and loaded it into power bi and edited the Power Query to identify the first reception date. Given below is the Power Query.

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\R\Orders.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet1_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"order_id", type text}, {"reception_id", type text}, {"reception_date", type date}}),

//added codes starts here..
    TempTable = #"Changed Type",
    Orders = #"Changed Type",
//this function X filters the table based on the parameter "order_id"

    X = (y as table,z as text ) as table => Table.SelectRows(y,each Record.Field(_,"order_id")=z),

//Adds the column 'first_reception' to the table.

    AddColumn = Table.AddColumn(
        Orders,
        "first_reception",
        each Record.Field(_,"reception_date") = List.Min(  // comparison of current row's reception date with the minimum of all receptions dates of that order.
            Table.Column( //Table.Column converts the column to a list which is passed on to List.Min()
                X(TempTable,Record.Field(_,"order_id")),"reception_date" // filters the table bsed on current record's order_id and passing it on to Table.Column() funciton
            )
        )
    )
in
    AddColumn

View solution in original post

3 REPLIES 3
Arnault_
Resolver III
Resolver III

Thanks both of you for the proposed solution. It works perfectly. Cheers

Anonymous
Not applicable

 

Hi,

 

I have pasted your data into an excel sheet and loaded it into power bi and edited the Power Query to identify the first reception date. Given below is the Power Query.

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\R\Orders.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet1_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"order_id", type text}, {"reception_id", type text}, {"reception_date", type date}}),

//added codes starts here..
    TempTable = #"Changed Type",
    Orders = #"Changed Type",
//this function X filters the table based on the parameter "order_id"

    X = (y as table,z as text ) as table => Table.SelectRows(y,each Record.Field(_,"order_id")=z),

//Adds the column 'first_reception' to the table.

    AddColumn = Table.AddColumn(
        Orders,
        "first_reception",
        each Record.Field(_,"reception_date") = List.Min(  // comparison of current row's reception date with the minimum of all receptions dates of that order.
            Table.Column( //Table.Column converts the column to a list which is passed on to List.Min()
                X(TempTable,Record.Field(_,"order_id")),"reception_date" // filters the table bsed on current record's order_id and passing it on to Table.Column() funciton
            )
        )
    )
in
    AddColumn
Zubair_Muhammad
Community Champion
Community Champion

@Arnault_ 

 

You can use this Custom Column

 

let myorderid=[order_id]
in
List.Min(Table.SelectRows(#"Previous Step Name",each [order_id]=myorderid)[reception_date])=[reception_date]

Regards
Zubair

Please try my custom visuals

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.