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
Hi Everyone,
I have tried a number of different equations and have looked through Google to no avail. I have some data I need to be able to filter based upon the maximum number in a column, however this maximum number can change.
Data exampl
The Sequence column has a number for every movement between locations. This can max at 5, 6, 10, 13 whatever, depends on the trip i.e its a changing variable each day. The Train Id and Date column will always be unique in the sense that a Train ID will only appear once in a day.
What I am trying to do is set a page filter so that only the data contained in the row with the largest sequence number will appear. I have tried using this formula:
Max sequence = CALCULATE(MAX(Table[sequence]),VALUES(Table[Train ID and Date]))
This doesnt work as each row contains a sequence number.
Hope someone can help with a formula.
Thanks,
Giles
Solved! Go to Solution.
@GilesWalker - Try switching your ALL to an ALLEXCEPT in order to preserve the Train ID context filter:
max = CALCULATE(MAX(Train_Movements[sequence]),ALLEXCEPT(Train_Movements,[Train id]))
I'm thinking a Measure and a Custom Column.
Measure:
Max = CALCULATE(MAX([Value]),ALL(Averages2))
Column
IsMax = IF([Value] = [Max],1,0)
Now you can set your page filter to "IsMax = 1" and you should be good to go.
Basically, the Max measure uses CALCULATE with an ALL filter to ensure that it calculates the MAX regardless of row context, etc. Then, IsMax creates a boolean value that tells you whether or not it is the MAX. To incorporate Train ID and Date, you could use an ALLEXCEPT clause in your CALCULATE filter if needed. So, think of it as all records except those filtered by this particular column kind of thing. Should get you there with a little messing around with it.
@smoupre Thanks for the response. I may of not understood your formula as I got the same result as the formula I mentioned in the intial post.
I created the max measure like this:
max = CALCULATE(MAX([Sequence]),ALL([date])) and this does indeed give you snapshot of the max sequence number, see picture below:
However when you create the custom column all values are the same "1".:
If I enter the [Sequence] data into the table and select dont summarize you can see what happens:
Each row is considered the max. This is as far as I got intially before asking for help. Its a bit of a pickle.
Thanks,
Giles
I believe the error is the ALL( Date).. In your table there is no date or ta least ( the Train ID & Date is text )..You need to add ALL( table that has the sequence ).
If is not a help then you need to give us more details..Also please add the table name is you are refering to a column so we know is a column and not a measure i.e. CALCULATE( MAX(Table1[Sequence]), ALL( 'Table2' ) )
Thanks for clarifying the formula @konstantinos. I shouldn't have left it like I did with my testing table names in it. As pointed out, I had a single table called Averages2 and a column in that table called [Value]. So, @GilesWalker in your formula where you reference ALL([date]) I do not believe that was equivalent to what I was doing if you are not getting the expected result. Probably has to do with your data model being different than my very simple single table data model. Same basic premise should apply ubt would need more information on your model to get specific.
@Greg_Deckler Sorry I wasn't reffering to your formula..but mostly on @GilesWalker formula on ALL([Date]) that seems to be a column ( due to [ ] ) but not sure if is in the same table as the [Sequence] column, since we only see dates consolidated with train ID...
@konstantinos @Greg_Deckler - thanks for the replies, I am out of the office today (public holiday), I will try what you said with the ALL(table). I will send through a better example of the table.
Thanks again for all the help.
Giles
@konstantinos @Greg_Deckler Please see the screenshot of the table Train-Movements:
The sequence column changes to represent how many stops the train made along its route. The max number in the sequence could be anything (3,4,8,9,13, etc...) This max number represents the final destination.
I changed my measure to be this:
max = CALCULATE(MAX(Train_Movements[sequence]),ALL(Train_Movements))
and the calculated column is:
IsMax = IF(Train_Movements[sequence]=[max],1,0)
This was the result I got:
It seems as though the forumla is picking the highest number in the sequence column (this case was 13). If you look at the above data Train 636 had a max of 10 in its sequence, 654 had a max of 4, 677 had a max of 5.
Thanks again for your efforts with helping on this.
Giles
i'm having a very similar problem, however i'm struggling to get this to work.
is the - max = CALCULATE(MAX(Train_Movements[sequence]),ALL(Train_Movements) you mention a custom column or something else?
in my table the JAP_SEQUENCE column indicates the most recent appointment date against a specific job - JAP_JOB_REF.
I need to create a custom column like yourself which indicates a 1 against the most recent appointment (highest sequence number against the specific job) and a 0 againt old appointment, I can then filter out the 0 and have a table which only shows the most recent appointment date.
@GilesWalker - Try switching your ALL to an ALLEXCEPT in order to preserve the Train ID context filter:
max = CALCULATE(MAX(Train_Movements[sequence]),ALLEXCEPT(Train_Movements,[Train id]))
@Greg_Deckler - I found this page which described it well:
https://msdn.microsoft.com/en-us/library/ee634795.aspx
Thansk again.
Giles
@Greg_Deckler You are a legend. Thank you for sorting this out for me. Are you able to explain how the formula works with the ALLEXCEPT?
Thanks,
Giles
@GilesWalker - Cool, glad we could arrive at a solution.
The ALLEXCEPT formula removes all context except for filters applied to the specified column(s) as explained here:
https://msdn.microsoft.com/en-us/library/ee634795.aspx
So, basically the ALL filter was removing all context from the CALCULATION, meaning that it returned the highst (MAX) value from all of the rows.
The ALLEXCEPT preserves the "Train Id" context but removes all other context like date, etc, meaning that the use of ALLEXCEPT returns the highest (MAX) value from all of the rows filtered by the "Train Id" context of the row of the visualization, and ONLY the Train Id context of the visualization row.
If you are truly thinking DAX, you are thinking in terms of the "context" in which the DAX formula is being executed. Weird, because most other languages do not so heavily feature context as a thing, but DAX does. In my opinion, this is one of the most powerful things about DAX is that you can essentially create dynamic "views" of the same data, the views basically translating to context. Generally in most other languages, there is a single context by which you process information. The flexibility of dynamically creating context makes DAX super cool and powerful, but it is a learning curve at the same time.
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 |
---|---|
124 | |
89 | |
84 | |
70 | |
51 |
User | Count |
---|---|
206 | |
143 | |
97 | |
79 | |
68 |