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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
CL7777
Helper III
Helper III

finding the product in a selected prod group that has the highest revenue or quantity sold

I consider myself an intermediate Dax user but Im having problems figuring out this measure. I have a table that has the following (sample) data:

 

year       part num     prod group     revenue    qty sold

2020       xx                   X                       5              2

2020       xx                   X                       17            4

2020       xx2                 X                       50            2

2020       xx2                 X                       59            3

2020       yy                   Y                       15            1

2020       yy                   Y                       50            4

2020       yy3                 Y                       5              5

2020       yy3                 Y                       65            9

2019       xx                   X                       75            6

2019       xx2                 X                       5              2

2019       xx                   X                       5              2

 

I want to select a product group and a year from slicers, and have measures that will show the part number with the greatest total revenue and greatest total quantity sold for that product group and year, along with the value of the total revenue and quantity. In the above data, if we select product group X and 2020 as the year in the slicers, I want the measure to show that product xx had the most quantity sold at 6 and product xx2 had the most revenue generated at 109. 

 

any help I could get would be much appreciated.

1 ACCEPTED SOLUTION
DataInsights
Super User
Super User

@CL7777,

 

Try these measures. The ADDCOLUMNS function allows you to calculate the total quantity or revenue at the part level, and TOPN filters for the largest amount.

 

Total Quantity Sold = SUM (Table1[qty sold] )
Total Revenue = SUM ( Table1[revenue] )
Most Quantity Sold = 
VAR vTable =
    ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Quantity Sold] )
VAR vTopRow =
    TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
    MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
    MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
    vResult
Most Revenue Generated = 
VAR vTable =
    ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Revenue] )
VAR vTopRow =
    TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
    MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
    MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
    vResult

 

DataInsights_0-1651764525428.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

3 REPLIES 3
DataInsights
Super User
Super User

@CL7777,

 

Try these measures. The ADDCOLUMNS function allows you to calculate the total quantity or revenue at the part level, and TOPN filters for the largest amount.

 

Total Quantity Sold = SUM (Table1[qty sold] )
Total Revenue = SUM ( Table1[revenue] )
Most Quantity Sold = 
VAR vTable =
    ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Quantity Sold] )
VAR vTopRow =
    TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
    MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
    MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
    vResult
Most Revenue Generated = 
VAR vTable =
    ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Revenue] )
VAR vTopRow =
    TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
    MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
    MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
    vResult

 

DataInsights_0-1651764525428.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




thank you SO much, that is really elegant and works perfectly. I will accept as a solution

@CL7777,

 

Thanks, glad to hear that!





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
July 2024 Power BI Update

Power BI Monthly Update - July 2024

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

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

Top Solution Authors