cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
New Member

Getting values based on latest available dates incl. filtered earlier dates

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:

CustomerDateSale
Client 131-Jan-2010
Client 129-Feb-2015
Client 231-Dec-208
Client 331-Dec-202
Client 331-Jan-205
Client 429-Feb-209
Client 229-Feb-206

 

Output 1 (Default):

CustomerDateSale
Client 129-Feb-2015
Client 229-Feb-206
Client 331-Jan-205
Client 429-Feb-209

 

Output 2 (Filtered for 31-Jan-20):

CustomerDateSale
Client 131-Jan-2010
Client 231-Dec-208
Client 331-Jan-205

 

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! 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Microsoft
Microsoft

Re: Getting values based on latest available dates incl. filtered earlier dates

Hi @noubstar 

I change my measure and build a slicer to achieve your goal.

Slicer table:

 

Slicer = VALUES(Table1[Date])

 

Result:

3.png

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.

1.png

Today() = 2020/8/14 so the available dates should be 2020/1/31 and 2020/2/29.

Result:

2.png

Select 2020/1/31, the available dates should be 2020/1/31.

Result:

4.png

Select 2020/2/29, the available dates should be 2020/1/31 and 2020/2/29.

Result:

5.png

Select 2020/12/31, the available dates should be 2020/1/31 , 2020/2/29 and 2020/12/31.

Result:

6.png

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?

7.png

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. 

View solution in original post

7 REPLIES 7
Highlighted
Super User IX
Super User IX

Re: Getting values based on latest available dates incl. filtered earlier dates

@noubstar , Try with Customer in visual table

lastnonblankvalue(Table[Date], Sum(Table[Sale]))
max(Table[Date])

 



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Highlighted
New Member

Re: Getting values based on latest available dates incl. filtered earlier dates

@amitchandak 

 

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 

CustomerDateMeasureSaleMeasure
Client 131-Jan-2010
Client 331-Jan-205

 

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?



Highlighted
Microsoft
Microsoft

Re: Getting values based on latest available dates incl. filtered earlier dates

Hi @noubstar 

You may try my measure.

I build a table like yours to have a test.

1.png

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:

2.png

Filter 2020/1/31 it will still show the latest date in measure:

3.png

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. 

Highlighted
New Member

Re: Getting values based on latest available dates incl. filtered earlier dates

Hi @RicoZhou 

 

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:

CustomerLatestDateLatestSale
Client 129-Feb-2015
Client 229-Feb-206
Client 331-Jan-205
Client 429-Feb-209

 

Filter (31-Jan-20):

CustomerLatestDateLatestSale
Client 131-Jan-2010
Client 231-Dec-208
Client 331-Jan-205
Highlighted
New Member

Re: Getting values based on latest available dates incl. filtered earlier dates

Sorry @RicoZhou , 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.

 

 

Highlighted
Microsoft
Microsoft

Re: Getting values based on latest available dates incl. filtered earlier dates

Hi @noubstar 

I change my measure and build a slicer to achieve your goal.

Slicer table:

 

Slicer = VALUES(Table1[Date])

 

Result:

3.png

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.

1.png

Today() = 2020/8/14 so the available dates should be 2020/1/31 and 2020/2/29.

Result:

2.png

Select 2020/1/31, the available dates should be 2020/1/31.

Result:

4.png

Select 2020/2/29, the available dates should be 2020/1/31 and 2020/2/29.

Result:

5.png

Select 2020/12/31, the available dates should be 2020/1/31 , 2020/2/29 and 2020/12/31.

Result:

6.png

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?

7.png

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. 

View solution in original post

Highlighted
New Member

Re: Getting values based on latest available dates incl. filtered earlier dates

Thanks a lot @RicoZhou 

 

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!!

Helpful resources

Announcements
Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Don't miss the Power BI Dev Camp this week!

August Community Highlights

Check out a full recap of the month!

August 2020 CYST Challenge

Check out the winners of the recent 'Can You Solve These?' community challenge!

Experience what’s next for Power BI

Join us for an in-depth look at the new Power BI features and capabilities at the free Microsoft Business Applications Launch Event.

Top Kudoed Authors