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
Ilias_pal
Regular Visitor

How to combine TOP 6 & BOTTOM 2 results from another DAX measure into new measure

I have linked SAP with PowerBI two different tables, one containing current year sales per product & country and the other containing previous year sales per product & country.

 

I have created a DAX measure to calculate "vs. Prior Year" sales and now I have been asked to create a chart that will show the top 6 and bottom 2 products, so each country lead can get this info.

 

I am trying to filter in the chart of "vs. Prior Year" both Top 6 and Bottom 2 filter, but it`s not allowing.

 

Also, i am trying to use a new DAX measure that will combine Top 6 & bottom 2 "vs. Prior Year", however TOPN measure requires a table in the 2nd position and it doesn`t accept another DAX measure 

 

TOPN(<N_Value>, <Table>, <OrderBy_Expression>, [<Order>[, <OrderBy_Expression>, [<Order>]]…])

 

Any idea how I can solve this?

 

Thank you in advance.

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @Ilias_pal 

Please place the following measure in the filter pane of the chart, select "is not blnak" and apply the filter.

FilterMeasure =
VAR CurrentBrand =
    SELECTEDVALUE ( 'Product List'[Brand] )
VAR T1 =
    ADDCOLUMNS (
        ALLSELECTED ( 'Product List'[Brand] ),
        "@PYSales", [vs. PY Net Sales]
    )
VAR Top6 =
    TOPN ( 6, T1, [@PYSales] )
VAR Bottom2 =
    TOPN ( 2, T1, [@PYSales], ASC )
VAR T2 =
    SELECTCOLUMNS ( UNION ( Top6, Bottom2 ), "@Brand", [Brand] )
RETURN
    IF ( CurrentBrand IN T2, 1 )

View solution in original post

6 REPLIES 6
tamerj1
Super User
Super User

Hi @Ilias_pal 

Please place the following measure in the filter pane of the chart, select "is not blnak" and apply the filter.

FilterMeasure =
VAR CurrentBrand =
    SELECTEDVALUE ( 'Product List'[Brand] )
VAR T1 =
    ADDCOLUMNS (
        ALLSELECTED ( 'Product List'[Brand] ),
        "@PYSales", [vs. PY Net Sales]
    )
VAR Top6 =
    TOPN ( 6, T1, [@PYSales] )
VAR Bottom2 =
    TOPN ( 2, T1, [@PYSales], ASC )
VAR T2 =
    SELECTCOLUMNS ( UNION ( Top6, Bottom2 ), "@Brand", [Brand] )
RETURN
    IF ( CurrentBrand IN T2, 1 )

Hi @tamerj1 ,

 

Thanks a lot! This DAX measure worked 🙂

tamerj1
Super User
Super User

Hi @Ilias_pal 

i don't have enough information to generate dax code that serves your requirement but I can give you an idea on how to proceed. 
So my understanding is that your chart will slice the [Sales Amount] measure by product leaving a country slicer on the side. The way to move forward is create a filter measure and place it in tge filter pane of the visual. 
The measure shall be based on a virtual table that UNION the TOPN - 6 - DESC and TOPN - 2 - ASC of ALLSELECTED products then checks IF the CrrentProduct is within these products and if so returns a fixed value otherwise returns blank. 
This way you can filter the chart by selecting "Is not blank" for this filter measure. 

Hi @tamerj1 ,

 

This is the first DAX measure, I have created which calculates the "vs. PY Net Sales"

 

Ilias_pal_1-1667490030101.png

 

 The Current Year Net Sales are sourced from the table "CV_BPC_BRIDGES_R4_FC", while the Prior Year Net Sales were already calculated in the " PY Actual Net Sales' that is included in the measure and are sourced from the table "CV_BPC_BRIDGES_R4_ACT"

Ilias_pal_3-1667490362369.png

 

Ilias_pal_2-1667490333496.png

 

As you correctly mentioned, the country selection will be through a slicer, however since the two tables "CV_BPC_BRIDGES_R4_FC" & CV_BPC_BRIDGES_R4_ACT" do not contain similar rows, it`s not possible to use UNION measure.

 

Do you have any other idea how I can create a measure which will show me dynamically the top 6 and bottom 2 products "vs. PY Net Sales" measure so I can visualize it like this?

 

Ilias_pal_4-1667490659878.png

 

Thank you very much in advance.

@Ilias_pal 
What is the name of the prduct name column that is used in the chart and from which table?

Hi @tamerj1 , 

 

It`s called "Brand" from product list table. 

Ilias_pal_0-1667494585874.png

Product list table and the other two tables above, are linked with relationship 1 to many (1 brand can be many times in the other two tables)

 

 

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