March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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
Client | Inv Num | Inv Date | Amount |
5 | 5-003 | 3/1/2020 | 3005 |
5 | 5-004 | 4/1/2020 | 4005 |
6 | 6-003 | 3/1/2020 | 3006 |
6 | 6-004 | 4/1/2020 | 4006 |
7 | 7-001 | 4/3/2020 | 4007 |
8 | 8-001 | 2/2/2020 | 2008 |
Desired Result
5 | 5-004 | 4/1/2020 | 4005 |
6 | 6-004 | 4/1/2020 | 4006 |
7 | 7-001 | 4/3/2020 | 4007 |
8 | 8-001 | 2/2/2020 | 2008 |
Actual Result
7 | 7-001 | 4/3/2020 | 4007 |
Solved! Go to 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])
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.
@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])
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
@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])
@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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
23 | |
15 | |
12 | |
9 | |
8 |
User | Count |
---|---|
41 | |
32 | |
29 | |
12 | |
12 |