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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
DavidG_NJ
New Member

Date Problem

I am building a model for orders. Each day, I add the set of open orders with a Load Date,  Invoice Number and Expected Shipping Date (along with several other columns). The Expected Shipping Date might change over time until the order is shipped.

 

The business person wants to be able to select a range of load dates and then return the expected shipping dates based on invoice number in Excel. Using the example below, they would like to see the first ship date and the last ship date from the selected range of load dates (in chronological order by load date).  In this case, they want the first ship date to be 10/21/2021 since it is tied to the 10/13/2021 load date – the first record in the range. They want the last ship date to be 9/20/2021 since it is tied to the 10/20/2021 load date – the last record in the range.

 

I used the FIRSTDATE Dax function and it returns 9/20/2021 instead of 10/21/2021 which is the first ship date in the range.  The LASTDATE function returns 10/21/2021 instead of the expected 9/20/2021.

 

These functions seem to be acting as MIN and MAX. Is there any DAX function  or combination of functions that would allow me to return the first date and last date based on the chronological order of the load date?

DavidG_NJ_1-1645707924481.png

 

 

David

 

 

 

 

 

1 ACCEPTED SOLUTION
v-jayw-msft
Community Support
Community Support

Hi @DavidG_NJ ,

 

You will need to calculate the first load date and last load date then get the ship date according to these two date.

formula should be like below:

first_ship = 
var first_load = calculate(MIN('Table'[load]),ALLSELECTED('Table'))
return
calculate(min('Table'[ship]),FILTER(ALLSELECTED('Table'),'Table'[load] = first_load))

 

last_ship = 
var last_load = calculate(MAX('Table'[load]),ALLSELECTED('Table'))
return
calculate(min('Table'[ship]),FILTER(ALLSELECTED('Table'),'Table'[load] = last_load))

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

2 REPLIES 2
v-jayw-msft
Community Support
Community Support

Hi @DavidG_NJ ,

 

You will need to calculate the first load date and last load date then get the ship date according to these two date.

formula should be like below:

first_ship = 
var first_load = calculate(MIN('Table'[load]),ALLSELECTED('Table'))
return
calculate(min('Table'[ship]),FILTER(ALLSELECTED('Table'),'Table'[load] = first_load))

 

last_ship = 
var last_load = calculate(MAX('Table'[load]),ALLSELECTED('Table'))
return
calculate(min('Table'[ship]),FILTER(ALLSELECTED('Table'),'Table'[load] = last_load))

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.
johnt75
Super User
Super User

You could use TOPN.

Earliest Ship Date =
SELECTCOLUMNS (
TOPN( 1, Table, Table[Load Date], ASC )
"@ship date", [Ship Date]
)
Latest Ship Date =
SELECTCOLUMNS (
TOPN( 1, Table, Table[Load Date], DESC )
"@ship date", [Ship Date]
)

 

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.

Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.