Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
I have a Sharepoint List which contains Locations and data input times - as below.
Location | Date |
FH | 20/10/2016 00:00 |
FH | 20/10/2016 12:00 |
FF | 20/10/2016 01:00 |
FF | 20/10/2016 10:00 |
FF | 20/10/2016 11:00 |
GCC | 20/10/2016 00:00 |
GCC | 20/10/2016 12:00 |
JC | 20/10/2016 00:00 |
JC | 20/10/2016 12:00 |
MH | 20/10/2016 01:00 |
MH | 20/10/2016 12:00 |
ML | 20/10/2016 00:00 |
ML | 20/10/2016 12:00 |
NV | 20/10/2016 00:00 |
NV | 20/10/2016 12:00 |
Within Power BI I need to be able to identify - as a Calculated Column - the Maximum and Minimum Dates per Location so it looks like the below
Location | Date | Loc Min Date | Loc Max Date |
FH | 20/10/2016 00:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
FH | 20/10/2016 12:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
FF | 20/10/2016 01:00 | 20/10/2016 01:00 | 20/10/2016 11:00 |
FF | 20/10/2016 10:00 | 20/10/2016 01:00 | 20/10/2016 11:00 |
FF | 20/10/2016 11:00 | 20/10/2016 01:00 | 20/10/2016 11:00 |
GCC | 20/10/2016 00:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
GCC | 20/10/2016 12:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
JC | 20/10/2016 00:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
JC | 20/10/2016 12:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
MH | 20/10/2016 01:00 | 20/10/2016 01:00 | 20/10/2016 12:00 |
MH | 20/10/2016 12:00 | 20/10/2016 01:00 | 20/10/2016 12:00 |
ML | 20/10/2016 00:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
ML | 20/10/2016 12:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
NV | 20/10/2016 00:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
NV | 20/10/2016 12:00 | 20/10/2016 00:00 | 20/10/2016 12:00 |
Is anybody able to assist as I am currently struggling as this is all very new to me
Thanks
Solved! Go to Solution.
Hi cobdeng,
This could be done by the following ways.
We need to create another column (Or create another date table, then create the relationship between the date table and main tbale) to help calculate.
YMD = format('Table'[ReportDate], "yyyy-mm-dd")
Then add this column in earlier calculated column, for example:
MaxDate = maxx(
filter(Sheet1, And(Sheet1[Location]=earlier(Sheet1[Location]),
Sheet1[YMD]=earlier(Sheet1[YMD])),
Sheet1[Date] )
Check to see if this would work.
Regards
Not sure that will give me the right answers as there is other data as well apart from the dates
Hi cobdeng,
In addition to what suggested by ankitpatira, we could also take a try with the method below:
1. First sort the table by Location in Power BI Desktop, this would bring all the same location together,
2. Under Modeling Tab, click Add a column, with the following formula:
MinDate = minx( filter(Sheet1, Sheet1[Location]=earlier(Sheet1[Location])), Sheet1[Date] )
3. Click the Add a column again, with the formula below:
MaxDate = maxx( filter(Sheet1, Sheet1[Location]=earlier(Sheet1[Location])), Sheet1[Date] )
4. Check my testing result:
If you need any further assistance on this, please post back.
Regards
Thanks Michael_Shao
Nearly, but not quite as we can have multiple dates/times as per the screenshot below
Where there are multiple dates/times, I need to identify the maximum and minimum date time on each individual date, so, for location 2 in the above, on 19/10/2016 both max and min should be 19/10/2016 11:00 but on 20/10/2016 minimum should be 20/10/2016 01:00 and the maximum 20/10/2016 11:00. For location 4, on 19/10/2016 min/max should be 19/10/2016 00:00 - 19/10/2016 12:00, and on 20/10/2016 min/max should be 20/10/2016 00:00 - 20/10/2016 12:00.
Thanks in advance
Hi cobdeng,
This could be done by the following ways.
We need to create another column (Or create another date table, then create the relationship between the date table and main tbale) to help calculate.
YMD = format('Table'[ReportDate], "yyyy-mm-dd")
Then add this column in earlier calculated column, for example:
MaxDate = maxx(
filter(Sheet1, And(Sheet1[Location]=earlier(Sheet1[Location]),
Sheet1[YMD]=earlier(Sheet1[YMD])),
Sheet1[Date] )
Check to see if this would work.
Regards
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
93 | |
85 | |
83 | |
74 | |
49 |
User | Count |
---|---|
142 | |
141 | |
110 | |
69 | |
55 |