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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Measures/calculated columns to show max value with date, and latest date with value.

Hi I have a sample scenerio data set(actual data set used has thousands of rows):

LocationDateItem% of total of the day
East1/1/2012Burger80
West1/1/2012Burger40
North1/1/2012Burger30
East1/1/2012Fries20
West1/1/2012Fries60
North1/1/2012Fries70
East2/1/2012Burger40
West2/1/2012Burger50
North2/1/2012Burger30
East2/1/2012Fries60
West2/1/2012Fries50
North2/1/2012Fries70

So i have 2 slicers to select the menu item and location. And i want to add card/table to show for example:
Slicer option selected: Burger and East.
Results shown:
Latest Date2/1/2012
% of the total of the day 40
 
Date of Max % of the total of the day1/1/2012
Max % of the total of the day80
If understand what this means, it's basically to monitor the latest date for the selected item(due note there are hundreds of items and some items are not regular items) and location, together with the value of  % of the total of the day;
And to see which date have the highest % of the total of the day together with max % value.
So any ideas/ measures/calculated columns to help with creating a card/table to show the above results?
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi sorry for the late reply, the solution presented has helped solved part of this proble. I found a simpler solution butit is not completed.
measure for Max % of the total of the day:
Max % of the total of the day = 
CALCULATE(MAX('data'[% of total of the day]),ALLEXCEPT('data','data'[location],'data'[item]))


measure for Date of Max % of the total of the day:
Date of Max % of the total of the day =
LOOKUPVALUE('data'[Date],'data'[% of total of the day],[Max % of total of the day])

 

measure for latest date:
Latest Date = 
CALCULATE(LASTDATE('data'[date]),ALLEXCEPT('data','data'[item],'data'[location]))

But for the corresponding value which is % of the total of the day, i thought I could use the same measure(lookupvalue) as Date of Max % of the total of the day, but it gave me an error, this was the DAX I used:
 % of the total of the day for latest date = LOOKUPVALUE('data'[% of the total of the day],'data'[date],[Latest Date])
So I'm now focusing on solving this last problem, I started a new thread focusing more on it with more information of the scenerio:, link is below:
Last value of a calculated column based on slicer options. 

View solution in original post

4 REPLIES 4
stevedep
Memorable Member
Memorable Member

This would do the trick:

 

 

___IsHighestOftheDay	 = 	var _tblSum = SUMMARIZE('Table','Table'[Date]//,'Table'[Item],'Table'[Location]
,'Table'[% of total of the day], "H",  CALCULATE(MAX([% of total of the day]), ALLEXCEPT('Table',//'Table'[Location],
'Table'[Date])))
return 
COUNTROWS(FILTER(_tblSum,[% of total of the day]=[H]))
__LatestDate	 = 	CALCULATE(MAX([Date]),ALLEXCEPT('Table','Table'[Location],'Table'[Item]))
___LatestDateWithHighestPosition	 = 	CALCULATE(MAX([Date]), FILTER(ALLEXCEPT('Table','Table'[Location],'Table'[Item]),[___IsHighestOftheDay]=1))
___LatestPercValithHighestPosition	 = 	CALCULATE(MAX([% of total of the day]), FILTER(ALLEXCEPT('Table','Table'[Location],'Table'[Item]),[___IsHighestOftheDay]=1))
___LatestDateWithHighestPosition = CALCULATE(MAX([Date]), FILTER(ALLEXCEPT('Table','Table'[Location],'Table'[Item]),[___IsHighestOftheDay]=1))

 

 

As seen here:

2020-09-29_07-31-51.gif

File is available here

pls mark as solution if so. Thumbs up for the effort is appreciated.

 

Kind regards, 

 

 

Steve. 

 

Anonymous
Not applicable

Hi , thank you for the reply, but I don't think this is the outcome I would want. To make it clearer, let me re explain,

I have two slicers, one for the item and another for the location.
For example my Slicer option selected: Burger and East.
I want to have a way to show these results:
Latest Date2/1/2012
% of the total of the day 40
 
Date of Max % of the total of the day   1/1/2012
Max % of the total of the day80

 

I would like to be able to select the menu and the location, and see when was the latest date that menu item was sold and how much % was it sold on that day. And in addition, also be able to see in the past history the date which had that menu item having the highest % of the day amoung all the other dates, so i can know whats the highest % I've ever sold on a day for that item and at that location.

Burger and fries are a simplified version of the actual data, the actual data has thousand of rows with years of data, each day there are like 20 items. And every day the items change. Hope this clarifies.

@Anonymous , I was a bit to quick with my initial response. I updated my response, pls take a look and see if this works for you. 

 

Kind regards, Steve. 

Anonymous
Not applicable

Hi sorry for the late reply, the solution presented has helped solved part of this proble. I found a simpler solution butit is not completed.
measure for Max % of the total of the day:
Max % of the total of the day = 
CALCULATE(MAX('data'[% of total of the day]),ALLEXCEPT('data','data'[location],'data'[item]))


measure for Date of Max % of the total of the day:
Date of Max % of the total of the day =
LOOKUPVALUE('data'[Date],'data'[% of total of the day],[Max % of total of the day])

 

measure for latest date:
Latest Date = 
CALCULATE(LASTDATE('data'[date]),ALLEXCEPT('data','data'[item],'data'[location]))

But for the corresponding value which is % of the total of the day, i thought I could use the same measure(lookupvalue) as Date of Max % of the total of the day, but it gave me an error, this was the DAX I used:
 % of the total of the day for latest date = LOOKUPVALUE('data'[% of the total of the day],'data'[date],[Latest Date])
So I'm now focusing on solving this last problem, I started a new thread focusing more on it with more information of the scenerio:, link is below:
Last value of a calculated column based on slicer options. 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors