The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Dear Friend,
I have two tables, Calendar(Date,Month) and Sales(Date,Sales) Tables. I calculated Measure1 using dax with help of Dates column and Sales Column from Sales Table.The output of Measure1 as shown below by Calendar(Month).
Calendar(Month) | Measure1 |
Jan-24 | 20 |
Feb-24 | 10 |
Mar-24 | 30 |
Apr-24 | 15 |
I have Month Slicer on report.
Requirement: when I select any month slicer i want to get top 1 value where Month<=Max(month) from Measure1. For example: i select Feb-24 , output will be Measure2=20 and MonthTop=Jan-2024, or when i select Apr-2024 the output will be Measure2=30 and MonthTop=Mar-2024. How can i achieve this using DAX.
Solved! Go to Solution.
Hi,
Thanks for the solution @Ashish_Mathur and @sevenhills provided, and i want to offer some more informaiton for user to refer to.
hello @Jyaulhaq , based on your description, you can refer to the following sulution.
Sample data
And it has a calendar table and they have a one to many relationship
Create the following measures.
Measure1 = SUM(Sales[Sales])
Measure2 =
VAR a =
ADDCOLUMNS ( ALL ( Sales ), "Month", EOMONTH ( [Date], 0 ) )
VAR b =
SUMMARIZE ( a, [Month], "Sales", [Measure1] )
RETURN
MAXX (
FILTER ( b, [Month] <= EOMONTH ( MAX ( 'Calendar'[Date] ), 0 ) ),
[Sales]
)
Measure3 =
VAR a =
ADDCOLUMNS ( ALL ( Sales ), "Month", EOMONTH ( [Date], 0 ) )
VAR b =
SUMMARIZE ( a, [Month], "Sales", [Measure1], "Max_Sales", [Measure 2] )
RETURN
FORMAT (
MAXX (
FILTER (
b,
[Sales] = [Max_Sales]
&& [Month] <= EOMONTH ( MAX ( 'Calendar'[Date] ), 0 )
),
[Month]
),
"MMM-YYYY"
)
Then put the measures to the visual.
Output
Best Regards!
Yolo Zhu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
Thanks for the solution @Ashish_Mathur and @sevenhills provided, and i want to offer some more informaiton for user to refer to.
hello @Jyaulhaq , based on your description, you can refer to the following sulution.
Sample data
And it has a calendar table and they have a one to many relationship
Create the following measures.
Measure1 = SUM(Sales[Sales])
Measure2 =
VAR a =
ADDCOLUMNS ( ALL ( Sales ), "Month", EOMONTH ( [Date], 0 ) )
VAR b =
SUMMARIZE ( a, [Month], "Sales", [Measure1] )
RETURN
MAXX (
FILTER ( b, [Month] <= EOMONTH ( MAX ( 'Calendar'[Date] ), 0 ) ),
[Sales]
)
Measure3 =
VAR a =
ADDCOLUMNS ( ALL ( Sales ), "Month", EOMONTH ( [Date], 0 ) )
VAR b =
SUMMARIZE ( a, [Month], "Sales", [Measure1], "Max_Sales", [Measure 2] )
RETURN
FORMAT (
MAXX (
FILTER (
b,
[Sales] = [Max_Sales]
&& [Month] <= EOMONTH ( MAX ( 'Calendar'[Date] ), 0 )
),
[Month]
),
"MMM-YYYY"
)
Then put the measures to the visual.
Output
Best Regards!
Yolo Zhu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
Share the download link of the PBI file.
To get the top 1 value,
Get Top 1 Measure1 = CALCULATE( Max('Table'[Measure1]), 'Table'[Calendar(Month)] <= Max('Table'[Calendar(Month)]))
To get the month based on the top 1 value,
Get Top 1 Measure1 CM =
var _s = CALCULATE( Max('Table'[Measure1]), 'Table'[Calendar(Month)] <= Max('Table'[Calendar(Month)]))
RETURN CALCULATE(max('Table'[Calendar(Month)]), FILTER(all('Table'), 'Table'[Measure1] = _s))
Samples of output
Hope this helps!
Dear Friend,
Thanks for your reply, Measure1 is the measures not column, that used already many columns and many condition like date<=max(date) and more. i need to get top 1 value as mentioned above.
@Ashish_Mathur i can't share PBIX file because of confidentially.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
113 | |
83 | |
72 | |
49 | |
41 |
User | Count |
---|---|
139 | |
113 | |
74 | |
64 | |
63 |