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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
Jyaulhaq
Frequent Visitor

Top 1 value and best month from Measure

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-2420
Feb-2410
Mar-2430
Apr-2415

 

I have Month Slicer on report.

Jyaulhaq_0-1716044214490.png

 

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.

 

1 ACCEPTED SOLUTION
v-xinruzhu-msft
Community Support
Community Support

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

vxinruzhumsft_0-1716187006507.png

 

And it has a calendar table and they have a one to many relationship

vxinruzhumsft_1-1716187131073.png

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.

vxinruzhumsft_2-1716187252369.png

Output

vxinruzhumsft_3-1716187335981.png

 

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.

 

View solution in original post

4 REPLIES 4
v-xinruzhu-msft
Community Support
Community Support

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

vxinruzhumsft_0-1716187006507.png

 

And it has a calendar table and they have a one to many relationship

vxinruzhumsft_1-1716187131073.png

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.

vxinruzhumsft_2-1716187252369.png

Output

vxinruzhumsft_3-1716187335981.png

 

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.

 

Ashish_Mathur
Super User
Super User

Hi,

Share the download link of the PBI file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
sevenhills
Super User
Super User

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

sevenhills_0-1716051657788.png
sevenhills_1-1716051683599.png

 

sevenhills_2-1716051718330.png
Hope this helps!

 

 

@sevenhills 

 

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.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

March2025 Carousel

Fabric Community Update - March 2025

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

Top Kudoed Authors