The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.
Hello,
I'm trying to create a table that shows the fields based on the latest available date by default, as well as when filtered.
Sample data:
Customer | Date | Sale |
Client 1 | 31-Jan-20 | 10 |
Client 1 | 29-Feb-20 | 15 |
Client 2 | 31-Dec-20 | 8 |
Client 3 | 31-Dec-20 | 2 |
Client 3 | 31-Jan-20 | 5 |
Client 4 | 29-Feb-20 | 9 |
Client 2 | 29-Feb-20 | 6 |
Output 1 (Default):
Customer | Date | Sale |
Client 1 | 29-Feb-20 | 15 |
Client 2 | 29-Feb-20 | 6 |
Client 3 | 31-Jan-20 | 5 |
Client 4 | 29-Feb-20 | 9 |
Output 2 (Filtered for 31-Jan-20):
Customer | Date | Sale |
Client 1 | 31-Jan-20 | 10 |
Client 2 | 31-Dec-20 | 8 |
Client 3 | 31-Jan-20 | 5 |
LatestDate = MAXX(Table1, Table1[Date]) can generate Output 1, but is missing Client 2 details for Output 2.
Guidance from the gurus will great gratitude!
Solved! Go to Solution.
Hi @Anonymous
I change my measure and build a slicer to achieve your goal.
Slicer table:
Slicer = VALUES(Table1[Date])
Result:
Measure
LatestDate =
VAR _SELECT =
SELECTEDVALUE ( Slicer[Date] )
VAR _A =
MAXX (
FILTER (
ALL ( Table1 ),
Table1[Customer] = MAX ( Table1[Customer] )
&& Table1[Date] <= _SELECT
),
Table1[Date]
)
VAR _B =
MAXX (
FILTER (
ALL ( Table1 ),
Table1[Customer] = MAX ( Table1[Customer] )
&& Table1[Date] <= TODAY ()
),
Table1[Date]
)
RETURN
IF ( ISFILTERED ( Slicer[Date] ), _A, _B )
LastSales = SUMX(FILTER(ALLEXCEPT(Table1,Table1[Customer]),Table1[Date]=[LatestDate]),Table1[Sale])
As default, we will get values based on the latest available dates compare with toady.
Today() = 2020/8/14 so the available dates should be 2020/1/31 and 2020/2/29.
Result:
Select 2020/1/31, the available dates should be 2020/1/31.
Result:
Select 2020/2/29, the available dates should be 2020/1/31 and 2020/2/29.
Result:
Select 2020/12/31, the available dates should be 2020/1/31 , 2020/2/29 and 2020/12/31.
Result:
If this reply still couldn't help you to solve your problem, please tell me more details.
I am confused about why when you select 2020/1/31, the result will show 2020/12/31. Could you tell me your calculate logic?
You can download the pbix file from this link: Getting values based on latest available dates incl. filtered earlier dates
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks for the response.
I've set
SaleMeasure = lastnonblankvalue(Table[Date], Sum(Table[Sale]))
DateMeasure = max(Table[Date])
and my output when filtering Date = "31-Jan-20" is still
Customer | DateMeasure | SaleMeasure |
Client 1 | 31-Jan-20 | 10 |
Client 3 | 31-Jan-20 | 5 |
I think it's because my Filter is based on Date because I can't put DateMeasure in the Filter section - any idea how to do this?
Hi @Anonymous
You may try my measure.
I build a table like yours to have a test.
Measure:
LatestDate = MAXX(FILTER(all(Table1),Table1[Customer]=MAX(Table1[Customer])), Table1[Date])
LastSales = SUMX(FILTER(ALLEXCEPT(Table1,Table1[Customer]),Table1[Date]=[LatestDate]),Table1[Sale])
Result:
Default:
Filter 2020/1/31 it will still show the latest date in measure:
You can download the pbix file from this link: Getting values based on latest available dates incl. filtered earlier dates
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous
Thank you for building out the dataset. However, your outputs still do not match the desired output of "latest available value, subject to any date filters". Have highlighted difference in blue font.
Default:
Customer | LatestDate | LatestSale |
Client 1 | 29-Feb-20 | 15 |
Client 2 | 29-Feb-20 | 6 |
Client 3 | 31-Jan-20 | 5 |
Client 4 | 29-Feb-20 | 9 |
Filter (31-Jan-20):
Customer | LatestDate | LatestSale |
Client 1 | 31-Jan-20 | 10 |
Client 2 | 31-Dec-20 | 8 |
Client 3 | 31-Jan-20 | 5 |
Sorry @Anonymous , just noticed your dates are Jan-20, Feb-20 and Dec-20. The max portion works for the Default mode, but still doesn't work for the filtered dates.
I want the same output for Default as the filter for Dec-20, but only 2 entries are shown for your workbook.
Hi @Anonymous
I change my measure and build a slicer to achieve your goal.
Slicer table:
Slicer = VALUES(Table1[Date])
Result:
Measure
LatestDate =
VAR _SELECT =
SELECTEDVALUE ( Slicer[Date] )
VAR _A =
MAXX (
FILTER (
ALL ( Table1 ),
Table1[Customer] = MAX ( Table1[Customer] )
&& Table1[Date] <= _SELECT
),
Table1[Date]
)
VAR _B =
MAXX (
FILTER (
ALL ( Table1 ),
Table1[Customer] = MAX ( Table1[Customer] )
&& Table1[Date] <= TODAY ()
),
Table1[Date]
)
RETURN
IF ( ISFILTERED ( Slicer[Date] ), _A, _B )
LastSales = SUMX(FILTER(ALLEXCEPT(Table1,Table1[Customer]),Table1[Date]=[LatestDate]),Table1[Sale])
As default, we will get values based on the latest available dates compare with toady.
Today() = 2020/8/14 so the available dates should be 2020/1/31 and 2020/2/29.
Result:
Select 2020/1/31, the available dates should be 2020/1/31.
Result:
Select 2020/2/29, the available dates should be 2020/1/31 and 2020/2/29.
Result:
Select 2020/12/31, the available dates should be 2020/1/31 , 2020/2/29 and 2020/12/31.
Result:
If this reply still couldn't help you to solve your problem, please tell me more details.
I am confused about why when you select 2020/1/31, the result will show 2020/12/31. Could you tell me your calculate logic?
You can download the pbix file from this link: Getting values based on latest available dates incl. filtered earlier dates
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks a lot @Anonymous
The new Latest Date measure + slicer work perfectly!
FYI, the output I showed was what I wanted to get but could not seem to get with the earlier measures, but your current solution has solved this.
Thanks again!!