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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
tvogel8570
Regular Visitor

Filter for newest date by client

I am trying to create pivots that summarize the most recent invoice for each client by a variety of measures (region, category, sales person, etc).  If I leave the client in the pivot, the correct invoices are used in the calculations.  As soon as I remove the client, it only uses invoices with the max date of all invoices. 

I think I could solve my need by having a filter that returns the most recent invoice by customer.  I haven't been able to figure out how to do this in DAX.  

Note I am using only Power Query/Pivot in Excel no Power BI.

Thanks,

Timothy

 

My approach 

Create a measure and then use that measure in a filter

 

 

Most Recent Invoice Date =MAX(Inv_Summary[Invoice Date])

 

 

 

 

FILTER(Inv_Summary,Inv_Summary[Invoice Date]=[Most Recent Invoice Date])

 

 

 

 

Source

ClientInv NumInv DateAmount
55-0033/1/20203005
55-0044/1/20204005
66-0033/1/20203006
66-0044/1/20204006
77-0014/3/20204007
88-0012/2/20202008

Desired Result

55-0044/1/20204005
66-0044/1/20204006
77-0014/3/20204007
88-0012/2/20202008

Actual Result

77-0014/3/20204007

 

 

1 ACCEPTED SOLUTION

@tvogel8570 OK, I think this makes things more clear. Couple quick questions. 

1. Do you have the Row column available in your data?

2. Is the logic the following - summarize (group) the data by Category and Client taking the latest date and then sum the Amt that corresponds to that grouping at those latest date values?

 

If that logic is correct, then:

Measure =
  VAR __Category = MAX([Category])
  VAR __Table =
    ADDCOLUMNS(
      SUMMARIZE(
        'Table',
        [Client],
        "__Date",MAX([Date])
      ),
      "__Amt",MAXX(FILTER(ALL('Table'),[Category]=__Category && [Client]=EARLIER([Client]) && [Date]=EARLIER([__Date])),[Amt])
    )
RETURN
  SUMX(__Table,[__Amt])
      

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

5 REPLIES 5
tvogel8570
Regular Visitor

@amitchandak , @Greg_Deckler 

Greg and Ashish,

Both of you gave me what I asked for but it doesn't really work for what I need.  😉  

I come from a strong SQL background and I'm trying to fit my SQL approach to DAX which is probably causing me problems. 

So  I am revsing my original question...

Summarize invoice details such that the result has the newest invoice for each customer by category(s). 

The challenge I have been having is that the newest invoice date differs by customer.  All of the pivot tables that do not explicitly have client in them miss clients' with invoice date that is older than the newest across the entire table, i.e. row #8 in image.

 

Source data in blue, desired result in Green, incorrect in orange / red.  

 

most recent tran 4.png

 

 

 

@tvogel8570 OK, I think this makes things more clear. Couple quick questions. 

1. Do you have the Row column available in your data?

2. Is the logic the following - summarize (group) the data by Category and Client taking the latest date and then sum the Amt that corresponds to that grouping at those latest date values?

 

If that logic is correct, then:

Measure =
  VAR __Category = MAX([Category])
  VAR __Table =
    ADDCOLUMNS(
      SUMMARIZE(
        'Table',
        [Client],
        "__Date",MAX([Date])
      ),
      "__Amt",MAXX(FILTER(ALL('Table'),[Category]=__Category && [Client]=EARLIER([Client]) && [Date]=EARLIER([__Date])),[Amt])
    )
RETURN
  SUMX(__Table,[__Amt])
      

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

Greg,

  1. The Row column I added to help with the explanation.

  2. Correct.  There will be other categories in the future that may be on a related table but I "assume" that I can get at them through the RELATED operator.  Also will likely need to UNION the invoice table with another table that has the same schema but expected sales rather than actual sales.

 

Timothy

amitchandak
Super User
Super User

@tvogel8570 , use these new measures

 

Try this as new measure

calculate( sum(Table[Amount]),filter(Table,Table[Inv Date]<=max(Table[Inv Date])),allexcept(Table,Table[Client]))

 

or these

new Inv Num =lastnonblankvalue(Table[Inv Date],Table[Inv Num])
new Inv Amount =lastnonblankvalue(Table[Inv Date],Table[Amount])
max(Table[Inv Date])

Greg_Deckler
Super User
Super User

@tvogel8570 This seems like  Lookup Min/Max - https://community.powerbi.com/t5/Quick-Measures-Gallery/Lookup-Min-Max/m-p/985814#M434

 

Like:

Date Measure = MAX('Table'[Date])

Invoice Measure = 
  VAR __Date = MAX('Table'[Date])
  VAR __Invoice = MAXX(FILTER('Table',[Date]=__Date),[NumInv)
RETURN
  __Invoice

So put Client ID and those two measures in a table visual



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

Find out what's new and trending in the Fabric Community.